Skip to content

Commit

Permalink
Feature: add support for text and uuid type control columns (#683)
Browse files Browse the repository at this point in the history
* 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
akulapid authored Nov 21, 2024
1 parent 54de647 commit 77aebe7
Show file tree
Hide file tree
Showing 25 changed files with 5,290 additions and 67 deletions.
8 changes: 7 additions & 1 deletion doc/pg_partman.md
Original file line number Diff line number Diff line change
Expand Up @@ -195,6 +195,8 @@ create_parent(
, p_template_table text DEFAULT NULL
, p_jobmon boolean DEFAULT true
, p_date_trunc_interval text DEFAULT NULL
, p_time_encoder text DEFAULT NULL
, p_time_decoder text DEFAULT NULL
)
RETURNS boolean
```
Expand All @@ -203,7 +205,7 @@ RETURNS boolean
* An ACCESS EXCLUSIVE lock is taken on the parent table during the running of this function. No data is moved when running this function, so lock should be brief
* A default partition and template table are created by default unless otherwise configured
* `p_parent_table` - the existing parent table. MUST be schema qualified, even if in public schema
* `p_control` - the column that the partitioning will be based on. Must be a time or integer based column
* `p_control` - the column that the partitioning will be based on. Must be a time, integer, text or uuid based column. When control is of type text/uuid, p_time_encoder and p_time_decoder must be set.
* `p_interval` - the time or integer range interval for each partition. No matter the partitioning type, value must be given as text.
+ *\<interval\>* - Any valid value for the interval data type. Do not type cast the parameter value, just leave as text.
+ *\<integer\>* - For ID based partitions, the integer value range of the ID that should be set per partition. Enter this as an integer in text format ('100' not 100). If the interval is >=2, then the `p_type` must be `range`. If the interval equals 1, then the `p_type` must be `list`. Also note that while numeric values are supported for id-based partitioning, the interval must still be a whole number integer.
Expand All @@ -217,6 +219,8 @@ RETURNS boolean
* `p_template_table` - If you do not pass a value here, a template table will automatically be made for you in same schema that pg_partman was installed to. If you pre-create a template table and pass its name here, then the initial child tables will obtain these properties discussed in the **About** section immediately.
* `p_jobmon` - allow `pg_partman` to use the `pg_jobmon` extension to monitor that partitioning is working correctly. Defaults to TRUE.
* `p_date_trunc_interval` - By default, pg_partman's time-based partitioning will truncate the child table starting values to line up at the beginning of typical boundaries (midnight for daily, day 1 for monthly, Jan 1 for yearly, etc). If a partitioning interval that does not fall on those boundaries is desired, this option may be required to ensure the child table has the expected boundaries (especially if you also set `p_start_partition`). The valid values allowed for this parameter are the interval values accepted by PostgreSQL's built-in `date_trunc()` function (day, week, month, etc). For example, if you set a 9-week interval, by default pg_partman would truncate the tables by month (since the interval is greater than one month but less than 1 year) and unexpectedly start on the first of the month in some cases. Set this parameter value to `week`, so that the child table start values are properly truncated on a weekly basis to line up with the 9-week interval. If you are using a custom time interval, please experiment with this option to get the expected set of child tables you desire or use a more typical partitioning interval to simplify partition management.
* `p_time_encoder` - name of function that encodes a timestamp into a string representing your partition bounds. Setting this implicitly enables time based partitioning and is mandatory for text/uuid control column types. This enables paritioning tables using time based identifiers like uuidv7, ulid, snowflake ids and others. The function must handle NULL input safely. See test-time-daily.sql and test-uuid-daily for usage examples.
* `p_time_decoder` - name of function that decodes a text/uuid control value into a timestamp. Setting this implicitly enables time based partitioning and is mandatory for text/uuid control column types. This enables paritioning tables using time based identifiers like uuidv7, ulid, snowflake ids and others. The function must handle NULL input safely. See test-time-daily.sql and test-uuid-daily for usage examples.


<a id="create_sub_parent"></a>
Expand All @@ -234,6 +238,7 @@ create_sub_parent(
, p_constraint_cols text[] DEFAULT NULL
, p_jobmon boolean DEFAULT true
, p_date_trunc_interval text DEFAULT NULL
, p_time_encoder text DEFAULT NULL
)
RETURNS boolean
```
Expand All @@ -246,6 +251,7 @@ RETURNS boolean
* It is advised that you keep table names short for subpartition sets if you plan on relying on the table names for organization. The suffix added on to the end of a table name is always guaranteed to be there for whatever partition type is active for that set. Longer table names may cause the original parent table names to be truncated and possibly cut off the top level partitioning suffix. This cannot be controlled and ensures the lowest level partitioning suffix survives.
* Note that for the first level of subpartitions, the `p_parent_table` argument you originally gave to `create_parent()` would be the exact same value you give to `create_sub_parent()`. If you need further subpartitioning, you would then start giving `create_sub_parent()` a different value (the child tables of the top level partition set).
* The template table that is already set for the given p_top_parent will automatically be used.
* `p_time_encoder` - name of function that encodes a timestamp into a string representing your partition bounds. Setting this implicitly enables time based partitioning and is mandatory for text/uuid control column types. This enables paritioning tables using time based identifiers like uuidv7, ulid, snowflake ids and others. The function must handle NULL input safely. See test-time-daily.sql and test-uuid-daily for usage examples.


<a id="partition_data_time"></a>
Expand Down
176 changes: 176 additions & 0 deletions doc/pg_partman_howto.md
Original file line number Diff line number Diff line change
Expand Up @@ -2,6 +2,8 @@ Example Guide On Setting Up Native Partitioning
========================================

- [Simple Time Based: 1 Partition Per Day](#simple-time-based-1-partition-per-day)
- [Simple Time Based with UUIDv7 type: 1 Partition Per Day](#simple-time-based-with-uuidv7-type-1-partition-per-day)
- [Simple Time Based with Text Type: 1 Partition Per Day](#simple-time-based-with-text-type-1-partition-per-day)
- [Simple Serial ID: 1 Partition Per 10 ID Values](#simple-serial-id-1-partition-Per-10-id-values)
- [Partitioning an Existing Table](#partitioning-an-existing-table)
* [Offline Partitioning](#offline-partitioning)
Expand Down Expand Up @@ -109,6 +111,180 @@ Indexes:
Access method: heap
```

### Simple Time Based with UUIDv7 type: 1 Partition Per Day
This is similar to simple time based paritioning but using UUIDv7 identifiers.

```sql
CREATE SCHEMA IF NOT EXISTS partman_test;

CREATE TABLE partman_test.time_taptest_table
(col1 int,
col2 text default 'stuff',
col3 uuid PRIMARY KEY)
PARTITION BY RANGE (col3);

```
```sql
\d+ partman_test.time_taptest_table
Partitioned table "partman_test.time_taptest_table"
Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
--------+---------+-----------+----------+---------------+----------+-------------+--------------+-------------
col1 | integer | | | | plain | | |
col2 | text | | | 'stuff'::text | extended | | |
col3 | uuid | | not null | | plain | | |
Partition key: RANGE (col3)
Indexes:
"time_taptest_table_pkey" PRIMARY KEY, btree (col3)
Number of partitions: 0

```
For this example we use col3 as the partition key and builtin uuidv7 encoder/decoder functions to enable time based paritioning on col3. Because col3 is the partition key, the primary key index is automatically inherited by child partitions.
```sql
SELECT partman.create_parent(
p_parent_table := 'partman_test.time_taptest_table'
, p_control := 'col3'
, p_interval := '1 day'
, p_time_encoder := 'partman.uuid7_time_encoder'
, p_time_decoder := 'partman.uuid7_time_decoder'
);
create_parent
---------------
t
(1 row)
```
```sql
\d+ partman_test.time_taptest_table
--------+---------+-----------+----------+---------------+----------+-------------+--------------+-------------
col1 | integer | | | | plain | | |
col2 | text | | | 'stuff'::text | extended | | |
col3 | uuid | | not null | | plain | | |
Partition key: RANGE (col3)
Indexes:
"time_taptest_table_pkey" PRIMARY KEY, btree (col3)
Partitions: partman_test.time_taptest_table_p20240813 FOR VALUES FROM ('019147da-b040-0000-0000-000000000000') TO ('01914d01-0c40-0000-0000-000000000000'),
partman_test.time_taptest_table_p20240814 FOR VALUES FROM ('01914d01-0c40-0000-0000-000000000000') TO ('01915227-6840-0000-0000-000000000000'),
partman_test.time_taptest_table_p20240815 FOR VALUES FROM ('01915227-6840-0000-0000-000000000000') TO ('0191574d-c440-0000-0000-000000000000'),
partman_test.time_taptest_table_p20240816 FOR VALUES FROM ('0191574d-c440-0000-0000-000000000000') TO ('01915c74-2040-0000-0000-000000000000'),
partman_test.time_taptest_table_p20240817 FOR VALUES FROM ('01915c74-2040-0000-0000-000000000000') TO ('0191619a-7c40-0000-0000-000000000000'),
partman_test.time_taptest_table_p20240818 FOR VALUES FROM ('0191619a-7c40-0000-0000-000000000000') TO ('019166c0-d840-0000-0000-000000000000'),
partman_test.time_taptest_table_p20240819 FOR VALUES FROM ('019166c0-d840-0000-0000-000000000000') TO ('01916be7-3440-0000-0000-000000000000'),
partman_test.time_taptest_table_p20240820 FOR VALUES FROM ('01916be7-3440-0000-0000-000000000000') TO ('0191710d-9040-0000-0000-000000000000'),
partman_test.time_taptest_table_p20240821 FOR VALUES FROM ('0191710d-9040-0000-0000-000000000000') TO ('01917633-ec40-0000-0000-000000000000'),
partman_test.time_taptest_table_default DEFAULT
```
```sql
\d+ partman_test.time_taptest_table_p20240813
Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
--------+---------+-----------+----------+---------------+----------+-------------+--------------+-------------
col1 | integer | | | | plain | | |
col2 | text | | | 'stuff'::text | extended | | |
col3 | uuid | | not null | | plain | | |
Partition of: partman_test.time_taptest_table FOR VALUES FROM ('019147da-b040-0000-0000-000000000000') TO ('01914d01-0c40-0000-0000-000000000000')
Partition constraint: ((col3 IS NOT NULL) AND (col3 >= '019147da-b040-0000-0000-000000000000'::uuid) AND (col3 < '01914d01-0c40-0000-0000-000000000000'::uuid))
Indexes:
"time_taptest_table_p20240813_pkey" PRIMARY KEY, btree (col3)
Access method: heap
```


### Simple Time Based with Text Type: 1 Partition Per Day
This is similar to simple time based paritioning but using text control column.
For this example we will assume col3 contains identifiers formatted as `INVYYYYMMDD` where `INV` is a static application defined prefix and the remaining is a timestamp component.

```sql
CREATE SCHEMA IF NOT EXISTS partman_test;

CREATE TABLE partman_test.time_taptest_table
(col1 int,
col2 text default 'stuff',
col3 text PRIMARY KEY)
PARTITION BY RANGE (col3);

```
```sql
\d+ partman_test.time_taptest_table
Partitioned table "partman_test.time_taptest_table"
Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
--------+---------+-----------+----------+---------------+----------+-------------+--------------+-------------
col1 | integer | | | | plain | | |
col2 | text | | | 'stuff'::text | extended | | |
col3 | text | | not null | | extended | | |
Partition key: RANGE (col3)
Indexes:
"time_taptest_table_pkey" PRIMARY KEY, btree (col3)
Number of partitions: 0

```
In order to use col3 as control column for time partitioning, we need to define encoder/decoder functions that tell pg_partman how to derive time information from the identifier.

```sql
CREATE FUNCTION public.encode_timestamp(p_timestamp timestamptz, OUT encoded text)
RETURNS text
LANGUAGE plpgsql STABLE
AS $$
BEGIN
SELECT concat('INV', to_char(p_timestamp, 'YYYYMMDD')) INTO encoded;
END
$$;

CREATE FUNCTION public.decode_timestamp(p_str text, OUT ts timestamptz)
RETURNS TIMESTAMPTZ
LANGUAGE plpgsql STABLE
AS $$
BEGIN
SELECT substr(p_str, 4) INTO ts;
END
$$;
```

```sql
SELECT partman.create_parent(
p_parent_table := 'partman_test.time_taptest_table'
, p_control := 'col3'
, p_interval := '1 day'
, p_time_encoder := 'public.encode_timestamp'
, p_time_decoder := 'public.decode_timestamp'
);
create_parent
---------------
t
(1 row)
```
```sql
Partitioned table "partman_test.time_taptest_table"
Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
--------+---------+-----------+----------+---------------+----------+-------------+--------------+-------------
col1 | integer | | | | plain | | |
col2 | text | | | 'stuff'::text | extended | | |
col3 | text | | not null | | extended | | |
Partition key: RANGE (col3)
Indexes:
"time_taptest_table_pkey" PRIMARY KEY, btree (col3)
Partitions: time_taptest_table_p20240815 FOR VALUES FROM ('INV20240815') TO ('INV20240816'),
time_taptest_table_p20240816 FOR VALUES FROM ('INV20240816') TO ('INV20240817'),
time_taptest_table_p20240817 FOR VALUES FROM ('INV20240817') TO ('INV20240818'),
time_taptest_table_p20240818 FOR VALUES FROM ('INV20240818') TO ('INV20240819'),
time_taptest_table_p20240819 FOR VALUES FROM ('INV20240819') TO ('INV20240820'),
time_taptest_table_p20240820 FOR VALUES FROM ('INV20240820') TO ('INV20240821'),
time_taptest_table_p20240821 FOR VALUES FROM ('INV20240821') TO ('INV20240822'),
time_taptest_table_p20240822 FOR VALUES FROM ('INV20240822') TO ('INV20240823'),
time_taptest_table_p20240823 FOR VALUES FROM ('INV20240823') TO ('INV20240824'),
time_taptest_table_default DEFAULT
```
```sql
\d+ partman_test.time_taptest_table_p20240815
Table "partman_test.time_taptest_table_p20240815"
Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
--------+---------+-----------+----------+---------------+----------+-------------+--------------+-------------
col1 | integer | | | | plain | | |
col2 | text | | | 'stuff'::text | extended | | |
col3 | text | | not null | | extended | | |
Partition of: time_taptest_table FOR VALUES FROM ('INV20240815') TO ('INV20240816')
Partition constraint: ((col3 IS NOT NULL) AND (col3 >= 'INV20240815'::text) AND (col3 < 'INV20240816'::text))
Indexes:
"time_taptest_table_p20240815_pkey" PRIMARY KEY, btree (col3)
Access method: heap
```
### Simple Serial ID: 1 Partition Per 10 ID Values
For this use-case, the template table is not created manually before calling `create_parent()`. So it shows that if a primary/unique key is added later, it does not apply to the currently existing child tables. That will have to be done manually.

Expand Down
4 changes: 4 additions & 0 deletions sql/functions/check_control_type.sql
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,10 @@ SELECT CASE
'time'
WHEN typname IN ('int2', 'int4', 'int8', 'numeric' ) THEN
'id'
WHEN typname IN ('text', 'varchar') THEN
'text'
WHEN typname IN ('uuid') THEN
'uuid'
END
, typname::text
FROM pg_catalog.pg_type t
Expand Down
17 changes: 14 additions & 3 deletions sql/functions/create_parent.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down Expand Up @@ -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
Expand Down Expand Up @@ -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
Expand All @@ -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
Expand All @@ -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
Expand All @@ -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
Expand Down
Loading

0 comments on commit 77aebe7

Please sign in to comment.