-
Notifications
You must be signed in to change notification settings - Fork 284
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Feature: add support for text and uuid type control columns (#683)
* Feature: add support for text and uuid type control columns This change introduces two new parameters on create_parent, a pair of encoder/decoder functions that users can define to describe how a text/uuid column maps to time information. Once we derive time from the column, we can leverage existing time partitioning logic to manage partitions for text columns. Allowing users to define functions brings flexibility to support various formats of identifiers such as UUIDv7, ULID, Snowflake IDs etc. As a convenience, encoder/decoder functions are included for UUIDv7 given the widespread standard. * address review comments: simplify time based partitioning condition expressions fix sub-partitioning using text/uuid control type on sub partitions revert change to fix sort order for time columns in show_partitions() * address review comments: convert partition bounds to timestamp in show_partitions to ensure that the result is time-ordered * address review comments: add tests for sub-partitioning with uuid7 column improve test comments to describe column data types clearly * address review comments: fix upstream conflict in run_maintenance query
- Loading branch information
Showing
25 changed files
with
5,290 additions
and
67 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -13,6 +13,8 @@ CREATE FUNCTION @[email protected]_parent( | |
, p_jobmon boolean DEFAULT true | ||
, p_date_trunc_interval text DEFAULT NULL | ||
, p_control_not_null boolean DEFAULT true | ||
, p_time_encoder text DEFAULT NULL | ||
, p_time_decoder text DEFAULT NULL | ||
) | ||
RETURNS boolean | ||
LANGUAGE plpgsql | ||
|
@@ -176,8 +178,12 @@ IF p_control <> v_part_col OR v_control_exact_type <> v_part_type THEN | |
END IF; | ||
|
||
-- Check that control column is a usable type for pg_partman. | ||
IF v_control_type NOT IN ('time', 'id') THEN | ||
RAISE EXCEPTION 'Only date/time or integer types are allowed for the control column.'; | ||
IF v_control_type NOT IN ('time', 'id', 'text', 'uuid') THEN | ||
RAISE EXCEPTION 'Only date/time, text/uuid or integer types are allowed for the control column.'; | ||
ELSIF v_control_type IN ('text', 'uuid') AND (p_time_encoder IS NULL OR p_time_decoder IS NULL) THEN | ||
RAISE EXCEPTION 'p_time_encoder and p_time_decoder needs to be set for text/uuid type control column.'; | ||
ELSIF v_control_type NOT IN ('text', 'uuid') AND (p_time_encoder IS NOT NULL OR p_time_decoder IS NOT NULL) THEN | ||
RAISE EXCEPTION 'p_time_encoder and p_time_decoder can only be used with text/uuid type control column.'; | ||
END IF; | ||
|
||
-- Table to handle properties not managed by core PostgreSQL yet | ||
|
@@ -326,7 +332,7 @@ LOOP | |
v_inherit_privileges = v_row.sub_inherit_privileges; | ||
END LOOP; | ||
|
||
IF v_control_type = 'time' OR (v_control_type = 'id' AND p_epoch <> 'none') THEN | ||
IF v_control_type IN ('time', 'text', 'uuid') OR (v_control_type = 'id' AND p_epoch <> 'none') THEN | ||
|
||
v_time_interval := p_interval::interval; | ||
IF v_time_interval < '1 second'::interval THEN | ||
|
@@ -343,6 +349,7 @@ IF v_control_type = 'time' OR (v_control_type = 'id' AND p_epoch <> 'none') THEN | |
RAISE DEBUG 'create_parent(): parent_table: %, v_base_timestamp: %', p_parent_table, v_base_timestamp; | ||
|
||
v_partition_time_array := array_append(v_partition_time_array, v_base_timestamp); | ||
|
||
LOOP | ||
-- If current loop value is less than or equal to the value of the max premake, add time to array. | ||
IF (v_base_timestamp + (v_time_interval * v_count)) < (CURRENT_TIMESTAMP + (v_time_interval * p_premake)) THEN | ||
|
@@ -369,6 +376,8 @@ IF v_control_type = 'time' OR (v_control_type = 'id' AND p_epoch <> 'none') THEN | |
, epoch | ||
, control | ||
, premake | ||
, time_encoder | ||
, time_decoder | ||
, constraint_cols | ||
, datetime_string | ||
, automatic_maintenance | ||
|
@@ -383,6 +392,8 @@ IF v_control_type = 'time' OR (v_control_type = 'id' AND p_epoch <> 'none') THEN | |
, p_epoch | ||
, p_control | ||
, p_premake | ||
, p_time_encoder | ||
, p_time_decoder | ||
, p_constraint_cols | ||
, v_datetime_string | ||
, p_automatic_maintenance | ||
|
Oops, something went wrong.