Skip to content

Commit

Permalink
features and bug fixes for 5.2.0
Browse files Browse the repository at this point in the history
  • Loading branch information
keithf4 committed Oct 17, 2024
1 parent df602e8 commit b968372
Show file tree
Hide file tree
Showing 19 changed files with 3,784 additions and 1,562 deletions.
10 changes: 9 additions & 1 deletion CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -4,10 +4,18 @@
NEW FEATURES
------------
- Add support for microsecond precisions in epoch partitioning. (Github PR #659)
- Improve partition maintenance performance when determining next partition to created. (Github Issue #660)
- Improve partition maintenance performance when determining next partition to be created. (Github Issue #660)
- Removed requirement for pg_partman to be installed as a superuser. See "superuser" parameter in control file documentation for more details - https://www.postgresql.org/docs/current/extend-extensions.html#EXTEND-EXTENSIONS-FILES
- Do not create partitions during a maintenance run that aren't going to be kept as part of retention anyway. (Github Issue #649)
- Removed `default_table` column from `part_config` table. It's only necessary in `part_config_sub` to determine whether future sub-partition parents should have defaults made. Adjusted other code to look up whether a default table actually exists to determine its behavior. (Github Issue #637)
- Allow the control column to be NULL. This is not advised without very careful review and an explicit use-case defined as it can cause unexpected behavior or excessive data in the DEFAULT child partition. A new flag `p_control_not_null` has been added to the `create_parent()` and `create_sub_parent()` functions.

BUG FIXES
---------
- Enforcement of the control column being NOT NULL was not being done as intended. This has been fixed. If you'd like to allow the control column to be NULL, see the new feature flag in 5.2.0
- Fixed `reapply_constraint_proc()` to work properly when there are no relevant child tables to place additional constraints. In the process reworked the logic to determine the target child tables for both that procedure and the apply_constraints() function. The determining factor is now always the newest child table that contains data (other than the default). Updated documentation to clarify how the optimize_constraint flag works. (Github Issue #694)
- Properly handle partial indexes that are inherited from the template table. (Github Issue #657)
- Move the retention logic for dropping tables later in the maintenance process to help avoid longer running heavy locks on partition sets. (Github Issue #678)


5.1.0
Expand Down
2 changes: 1 addition & 1 deletion doc/pg_partman.md
Original file line number Diff line number Diff line change
Expand Up @@ -787,7 +787,7 @@ Stores all configuration data for partition sets managed by the extension.
- `constraint_cols`
- Array column that lists columns to have additional constraints applied. See **About** section for more information on how this feature works.
- `optimize_constraint`
- Manages which old tables get additional constraints set if configured to do so. See **About** section for more info. Default 30.
- Manages which old tables get additional constraints set if configured to do so. This value is a count on the number of child tables backwards from the newest child table that contains data. The default value of 30 means that the constraints will be created on the the child table that is 30 behind the newest child table that contains data. See **About** section for more info.
- `infinite_time_partitions`
- By default, new partitions in a time-based set will not be created if new data is not inserted to keep an infinite amount of empty tables from being created.
- If you'd still like new partitions to be made despite there being no new data, set this to TRUE.
Expand Down
2 changes: 1 addition & 1 deletion pg_partman.control
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
default_version = '5.1.0'
default_version = '5.2.0'
comment = 'Extension to manage partitioned tables by time or ID'
relocatable = false
superuser = false
36 changes: 24 additions & 12 deletions sql/functions/apply_constraints.sql
Original file line number Diff line number Diff line change
Expand Up @@ -15,6 +15,7 @@ ex_hint text;
ex_message text;
v_child_exists text;
v_child_tablename text;
v_child_value text;
v_col text;
v_constraint_cols text[];
v_constraint_name text;
Expand All @@ -34,6 +35,8 @@ v_last_partition_timestamp timestamptz;
v_new_search_path text;
v_old_search_path text;
v_optimize_constraint int;
v_optimize_counter int := 0;
v_row_max_value record;
v_parent_schema text;
v_parent_table text;
v_parent_tablename text;
Expand Down Expand Up @@ -114,20 +117,29 @@ IF p_child_table IS NULL THEN
v_step_id := add_step(v_job_id, 'Applying additional constraints: Automatically determining most recent child on which to apply constraints');
END IF;

SELECT partition_tablename INTO v_last_partition FROM @extschema@.show_partitions(v_parent_table, 'DESC') LIMIT 1;
-- Loop through child tables starting from highest to get a value from the highest non-empty partition in the set
-- Once a child table with a value is found, go back <optimize_constraint> children to make the constraint on that child
FOR v_row_max_value IN
SELECT partition_schemaname, partition_tablename FROM @extschema@.show_partitions(p_parent_table, 'DESC', false)
LOOP
IF v_child_value IS NULL THEN
EXECUTE format('SELECT %L::text FROM %I.%I LIMIT 1'
, v_control
, v_row_max_value.partition_schemaname
, v_row_max_value.partition_tablename
) INTO v_child_value;

IF v_control_type = 'time' OR (v_control_type = 'id' AND v_epoch <> 'none') THEN
SELECT child_start_time INTO v_last_partition_timestamp FROM @extschema@.show_partition_info(v_parent_schema||'.'||v_last_partition, v_partition_interval, v_parent_table);
v_partition_suffix := to_char(v_last_partition_timestamp - (v_partition_interval::interval * (v_optimize_constraint + v_premake + 1) ), v_datetime_string);
ELSIF v_control_type = 'id' THEN
SELECT child_start_id INTO v_last_partition_id FROM @extschema@.show_partition_info(v_parent_schema||'.'||v_last_partition, v_partition_interval, v_parent_table);
v_partition_suffix := (v_last_partition_id - (v_partition_interval::bigint * (v_optimize_constraint + v_premake + 1) ))::text;
END IF;

RAISE DEBUG 'apply_constraint: v_parent_tablename: %, v_last_partition: %, v_last_partition_timestamp: %, v_partition_suffix: %'
, v_parent_tablename, v_last_partition, v_last_partition_timestamp, v_partition_suffix;
ELSE
v_optimize_counter := v_optimize_counter + 1;
IF v_optimize_counter = v_optimize_constraint THEN
v_child_tablename = v_row_max_value.partition_tablename;
EXIT;
END IF;
END IF;
END LOOP;

v_child_tablename := @extschema@.check_name_length(v_parent_tablename, v_partition_suffix, TRUE);
RAISE DEBUG 'apply_constraint: v_parent_tablename: %, v_last_partition: %, v_child_tablename: %, v_optimize_counter: %'
, v_parent_tablename, v_last_partition, v_child_tablename, v_optimize_counter;

IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', format('Target child table: %s.%s', v_parent_schema, v_child_tablename));
Expand Down
5 changes: 2 additions & 3 deletions sql/functions/check_name_length.sql
Original file line number Diff line number Diff line change
Expand Up @@ -4,18 +4,17 @@ CREATE FUNCTION @extschema@.check_name_length (
, p_table_partition boolean DEFAULT FALSE
)
RETURNS text
LANGUAGE plpgsql IMMUTABLE SECURITY DEFINER
LANGUAGE plpgsql IMMUTABLE
SET search_path TO pg_catalog, pg_temp
AS $$
DECLARE
v_new_name text;
v_suffix text;
BEGIN
/*
* Truncate the name of the given object if it is greater than the postgres default max (63 characters).
* Truncate the name of the given object if it is greater than the postgres default max (63 bytes).
* Also appends given suffix and schema if given and truncates the name so that the entire suffix will fit.
* Returns original name (with suffix if given) if it doesn't require truncation
* Retains SECURITY DEFINER since it is called by trigger functions and did not want to break installations prior to 4.0.0
*/

IF p_table_partition IS TRUE AND (NULLIF(p_suffix, '') IS NULL) THEN
Expand Down
2 changes: 2 additions & 0 deletions sql/functions/check_subpart_sameconfig.sql
Original file line number Diff line number Diff line change
Expand Up @@ -22,6 +22,7 @@ CREATE FUNCTION @extschema@.check_subpart_sameconfig(p_parent_table text)
, sub_default_table boolean
, sub_maintenance_order int
, sub_retention_keep_publication boolean
, sub_control_not_null boolean
)
LANGUAGE sql STABLE
SET search_path = @extschema@,pg_temp
Expand Down Expand Up @@ -74,6 +75,7 @@ AS $$
, a.sub_default_table
, a.sub_maintenance_order
, a.sub_retention_keep_publication
, a.sub_control_not_null
FROM @extschema@.part_config_sub a
JOIN child_tables b on a.sub_parent = b.tablename;
$$;
11 changes: 5 additions & 6 deletions sql/functions/create_parent.sql
Original file line number Diff line number Diff line change
Expand Up @@ -12,6 +12,7 @@ CREATE FUNCTION @extschema@.create_parent(
, p_template_table text DEFAULT NULL
, p_jobmon boolean DEFAULT true
, p_date_trunc_interval text DEFAULT NULL
, p_control_not_null boolean DEFAULT true
)
RETURNS boolean
LANGUAGE plpgsql
Expand Down Expand Up @@ -116,8 +117,10 @@ JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE c.relname = v_parent_tablename::name
AND n.nspname = v_parent_schema::name
AND a.attname = p_control::name;
IF (v_notnull = false OR v_notnull IS NULL) THEN
RAISE EXCEPTION 'Control column given (%) for parent table (%) does not exist or must be set to NOT NULL', p_control, p_parent_table;
IF (v_notnull IS NULL) THEN
RAISE EXCEPTION 'Control column given (%) for parent table (%) does not exist', p_control, p_parent_table;
ELSIF (v_notnull = false and p_control_not_null = true) THEN
RAISE EXCEPTION 'Control column given (%) for parent table (%) must be set to NOT NULL', p_control, p_parent_table;
END IF;

SELECT general_type, exact_type INTO v_control_type, v_control_exact_type
Expand Down Expand Up @@ -372,7 +375,6 @@ IF v_control_type = 'time' OR (v_control_type = 'id' AND p_epoch <> 'none') THEN
, jobmon
, template_table
, inherit_privileges
, default_table
, date_trunc_interval)
VALUES (
p_parent_table
Expand All @@ -387,7 +389,6 @@ IF v_control_type = 'time' OR (v_control_type = 'id' AND p_epoch <> 'none') THEN
, p_jobmon
, v_template_schema||'.'||v_template_tablename
, v_inherit_privileges
, p_default_table
, p_date_trunc_interval);

RAISE DEBUG 'create_parent: v_partition_time_array: %', v_partition_time_array;
Expand Down Expand Up @@ -524,7 +525,6 @@ IF v_control_type = 'id' AND p_epoch = 'none' THEN
, jobmon
, template_table
, inherit_privileges
, default_table
, date_trunc_interval)
VALUES (
p_parent_table
Expand All @@ -537,7 +537,6 @@ IF v_control_type = 'id' AND p_epoch = 'none' THEN
, p_jobmon
, v_template_schema||'.'||v_template_tablename
, v_inherit_privileges
, p_default_table
, p_date_trunc_interval);

v_last_partition_created := @extschema@.create_partition_id(p_parent_table, v_partition_id_array);
Expand Down
7 changes: 5 additions & 2 deletions sql/functions/create_partition_id.sql
Original file line number Diff line number Diff line change
Expand Up @@ -211,6 +211,7 @@ FOREACH v_id IN ARRAY p_partition_ids LOOP
, sub_default_table
, sub_maintenance_order
, sub_retention_keep_publication
, sub_control_not_null
FROM @extschema@.part_config_sub
WHERE sub_parent = p_parent_table
LOOP
Expand All @@ -230,7 +231,8 @@ FOREACH v_id IN ARRAY p_partition_ids LOOP
, p_template_table := %L
, p_jobmon := %L
, p_start_partition := %L
, p_date_trunc_interval := %L )'
, p_date_trunc_interval := %L
, p_control_not_null := %L )'
, v_parent_schema||'.'||v_partition_name
, v_row.sub_control
, v_row.sub_partition_type
Expand All @@ -243,7 +245,8 @@ FOREACH v_id IN ARRAY p_partition_ids LOOP
, v_row.sub_template_table
, v_row.sub_jobmon
, p_start_partition
, v_row.sub_date_trunc_interval);
, v_row.sub_date_trunc_interval
, v_row.sub_control_not_null);
RAISE DEBUG 'create_partition_id (create_parent loop): %', v_sql;
EXECUTE v_sql;

Expand Down
7 changes: 5 additions & 2 deletions sql/functions/create_partition_time.sql
Original file line number Diff line number Diff line change
Expand Up @@ -302,6 +302,7 @@ FOREACH v_time IN ARRAY p_partition_times LOOP
, sub_default_table
, sub_maintenance_order
, sub_retention_keep_publication
, sub_control_not_null
FROM @extschema@.part_config_sub
WHERE sub_parent = p_parent_table
LOOP
Expand All @@ -321,7 +322,8 @@ FOREACH v_time IN ARRAY p_partition_times LOOP
, p_template_table := %L
, p_jobmon := %L
, p_start_partition := %L
, p_date_trunc_interval := %L )'
, p_date_trunc_interval := %L
, p_control_not_null := %L )'
, v_parent_schema||'.'||v_partition_name
, v_row.sub_control
, v_row.sub_partition_interval
Expand All @@ -334,7 +336,8 @@ FOREACH v_time IN ARRAY p_partition_times LOOP
, v_row.sub_template_table
, v_row.sub_jobmon
, p_start_partition
, v_row.sub_date_trunc_interval);
, v_row.sub_date_trunc_interval
, v_row.sub_control_not_null);

RAISE DEBUG 'create_partition_time (create_parent loop): %', v_sql;
EXECUTE v_sql;
Expand Down
13 changes: 9 additions & 4 deletions sql/functions/create_sub_parent.sql
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,7 @@ CREATE FUNCTION @extschema@.create_sub_parent(
, p_epoch text DEFAULT 'none'
, p_jobmon boolean DEFAULT true
, p_date_trunc_interval text DEFAULT NULL
, p_control_not_null boolean DEFAULT true
)
RETURNS boolean
LANGUAGE plpgsql
Expand Down Expand Up @@ -86,7 +87,8 @@ INSERT INTO @extschema@.part_config_sub (
, sub_epoch
, sub_jobmon
, sub_template_table
, sub_date_trunc_interval)
, sub_date_trunc_interval
, sub_control_not_null)
VALUES (
p_top_parent
, p_control
Expand All @@ -99,7 +101,8 @@ VALUES (
, p_epoch
, p_jobmon
, v_template_table
, p_date_trunc_interval);
, p_date_trunc_interval
, p_control_not_null);

FOR v_row IN
-- Loop through all current children to turn them into partitioned tables
Expand Down Expand Up @@ -190,7 +193,8 @@ IF v_recreate_child = false THEN
, p_epoch := %L
, p_template_table := %L
, p_jobmon := %L
, p_date_trunc_interval := %L)'
, p_date_trunc_interval := %L
, p_control_not_null := %L)'
, v_row.child_schema||'.'||v_row.child_tablename
, p_control
, p_interval
Expand All @@ -203,7 +207,8 @@ IF v_recreate_child = false THEN
, p_epoch
, v_template_table
, p_jobmon
, p_date_trunc_interval);
, p_date_trunc_interval
, p_control_not_null);
RAISE DEBUG 'create_sub_parent: create parent v_sql: %', v_sql;
EXECUTE v_sql;
END IF; -- end recreate check
Expand Down
48 changes: 42 additions & 6 deletions sql/functions/dump_partitioned_table_definition.sql
Original file line number Diff line number Diff line change
Expand Up @@ -31,9 +31,14 @@ DECLARE
v_constraint_valid boolean; -- DEFAULT true NOT NULL
v_ignore_default_data boolean; -- DEFAULT false NOT NULL
v_date_trunc_interval text;
v_default_table boolean;
v_maintenance_order int;
v_retention_keep_publication boolean;
v_parent_schemaname text;
v_parent_tablename text;
v_default_exists boolean;
v_default_tablename text;
v_sql text;
v_notnull boolean;
BEGIN
SELECT
pc.parent_table,
Expand All @@ -58,7 +63,6 @@ BEGIN
pc.constraint_valid,
pc.ignore_default_data,
pc.date_trunc_interval,
pc.default_table,
pc.maintenance_order,
pc.retention_keep_publication
INTO
Expand All @@ -84,7 +88,6 @@ BEGIN
v_constraint_valid,
v_ignore_default_data,
v_date_trunc_interval,
v_default_table,
v_maintenance_order,
v_retention_keep_publication
FROM @extschema@.part_config pc
Expand All @@ -98,6 +101,37 @@ BEGIN
v_template_table := NULL;
END IF;

SELECT schemaname, tablename
INTO v_parent_schemaname, v_parent_tablename
FROM pg_catalog.pg_tables
WHERE schemaname = split_part(p_parent_table, '.', 1)::name
AND tablename = split_part(p_parent_table, '.', 2)::name;

-- Check to see if table has a default
v_sql := format('SELECT c.relname
FROM pg_catalog.pg_inherits h
JOIN pg_catalog.pg_class c ON c.oid = h.inhrelid
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE h.inhparent = ''%I.%I''::regclass
AND pg_get_expr(relpartbound, c.oid) = ''DEFAULT'''
, v_parent_schemaname
, v_parent_tablename);

EXECUTE v_sql INTO v_default_tablename;
IF v_default_tablename IS NOT NULL THEN
v_default_exists := true;
ELSE
v_default_exists := false;
END IF;

SELECT attnotnull INTO v_notnull
FROM pg_catalog.pg_attribute a
JOIN pg_catalog.pg_class c ON a.attrelid = c.oid
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE c.relname = v_parent_tablename::name
AND n.nspname = v_parent_schemaname::name
AND a.attname = v_control::name;

v_create_parent_definition := format(
E'SELECT @extschema@.create_parent(
\tp_parent_table := %L,
Expand All @@ -111,20 +145,22 @@ E'SELECT @extschema@.create_parent(
\tp_constraint_cols := %L,
\tp_template_table := %L,
\tp_jobmon := %L,
\tp_date_trunc_interval := %L
\tp_date_trunc_interval := %L,
\tp_control_not_null := %L
);',
v_parent_table,
v_control,
v_partition_interval,
v_partition_type,
v_epoch,
v_premake,
v_default_table,
v_default_exists,
v_automatic_maintenance,
v_constraint_cols,
v_template_table,
v_jobmon,
v_date_trunc_interval
v_date_trunc_interval,
v_notnull
);

v_update_part_config_definition := format(
Expand Down
Loading

0 comments on commit b968372

Please sign in to comment.