Skip to content

Commit

Permalink
v1.7.2 Fixed permission bug when inheriting foreign keys. Inheriting …
Browse files Browse the repository at this point in the history
…FKs now optional
  • Loading branch information
keithf4 committed Jun 10, 2014
1 parent d941cd2 commit 2b75107
Show file tree
Hide file tree
Showing 14 changed files with 972 additions and 28 deletions.
5 changes: 5 additions & 0 deletions CHANGELOG
@@ -1,3 +1,8 @@
1.7.2
-- Fixed bug in apply_foreign_keys() where new partition creation would fail when the partition set's schema is in the current search_path. Most commonly happened when partition sets with foreig keys were in public, but any schema in current search_path would cause this to manifest. Reported by Isaías Sánchez via my blog. (Github Issue #27)
-- Foreign key inheritance is now optional since more complex FK relationships may not work ideally with pg_partman's default method. New configuration option in part_config table and parameter to create_parent().


1.7.1
-- Foreign keys placed on the parent table are now inherited to child tables.
-- Any new partitions created after this update is installed will have the FKs applied to children.
Expand Down
6 changes: 3 additions & 3 deletions META.json
@@ -1,7 +1,7 @@
{
"name": "pg_partman",
"abstract": "Extension to manage partitioned tables by time or ID",
"version": "1.7.1",
"version": "1.7.2",
"maintainer": [
"Keith Fiske <keith@omniti.com>"
],
Expand All @@ -20,9 +20,9 @@
},
"provides": {
"pg_partman": {
"file": "sql/pg_partman--1.7.1.sql",
"file": "sql/pg_partman--1.7.2.sql",
"docfile": "doc/pg_partman.md",
"version": "1.7.1",
"version": "1.7.2",
"abstract": "Extension to manage partitioned tables by time or ID"
}
},
Expand Down
8 changes: 6 additions & 2 deletions doc/pg_partman.md
Expand Up @@ -9,7 +9,7 @@ If you attempt to insert data into a partition set that contains data for a part

### Child Table Property Inheritance

For this extension, most of the attributes of the child partitions are all obtained from the original parent. This includes defaults, indexes (primary keys, unique, etc), foreign keys, tablespace, constraints, privileges & ownership. This also includes the OID and UNLOGGED table properties. For managing privileges, whenever a new partition is created it will obtain its privilege & ownership information from what the parent has at that time. Previous partition privileges are not changed. If previous partitions require that their privileges be updated, a separate function is available. This is kept as a separate process due to being an expensive operation when the partition set grows larger. The defaults, indexes, tablespace & constraints on the parent are only applied to newly created partitions and are not retroactively set on ones that already existed. While you would not normally create indexes on the parent of a partition set, doing so makes it much easier to manage in this case. There will be no data in the parent table (if everything is working right), so they will not take up any space or have any impact on system performance. Using the parent table as a control to the details of the child tables like this gives a better place to manage things that's a little more natural than a configuration table or using setup functions.
For this extension, most of the attributes of the child partitions are all obtained from the original parent. This includes defaults, indexes (primary keys, unique, etc), foreign keys (optional), tablespace, constraints, privileges & ownership. This also includes the OID and UNLOGGED table properties. For managing privileges, whenever a new partition is created it will obtain its privilege & ownership information from what the parent has at that time. Previous partition privileges are not changed. If previous partitions require that their privileges be updated, a separate function is available. This is kept as a separate process due to being an expensive operation when the partition set grows larger. The defaults, indexes, tablespace & constraints on the parent are only applied to newly created partitions and are not retroactively set on ones that already existed. While you would not normally create indexes on the parent of a partition set, doing so makes it much easier to manage in this case. There will be no data in the parent table (if everything is working right), so they will not take up any space or have any impact on system performance. Using the parent table as a control to the details of the child tables like this gives a better place to manage things that's a little more natural than a configuration table or using setup functions.

### Retention

Expand Down Expand Up @@ -45,7 +45,7 @@ A superuser must be used to run all these functions in order to set privileges &

### Creation Functions

*create_parent(p_parent_table text, p_control text, p_type text, p_interval text, p_constraint_cols text[] DEFAULT NULL, p_premake int DEFAULT 4, p_use_run_maintenance boolean DEFAULT NULL, p_start_partition text DEFAULT NULL, p_jobmon boolean DEFAULT true, p_debug boolean DEFAULT false)*
CREATE FUNCTION create_parent(p_parent_table text , p_control text, p_type text, p_interval text, p_constraint_cols text[] DEFAULT NULL, p_premake int DEFAULT 4, p_use_run_maintenance boolean DEFAULT NULL, p_start_partition text DEFAULT NULL, p_inherit_fk boolean DEFAULT true, p_jobmon boolean DEFAULT true, p_debug boolean DEFAULT false)
* Main function to create a partition set with one parent table and inherited children. Parent table must already exist. Please apply all defaults, indexes, constraints, privileges & ownership to parent table so they will propagate to children.
* 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.
* p_parent_table - the existing parent table. MUST be schema qualified, even if in public schema.
Expand Down Expand Up @@ -102,6 +102,8 @@ quarter-hour - One partition per 15 minute interval on the quarter-hour (1200
* p_premake - is how many additional partitions to always stay ahead of the current partition. Default value is 4. This will keep at minimum 5 partitions made, including the current one. For example, if today was Sept 6, 2012, and premake was set to 4 for a daily partition, then partitions would be made for the 6th as well as the 7th, 8th, 9th and 10th. As stated above, this value also determines how many partitions outside of the current one the static partitioning trigger function will handle (behind & ahead) and also influences which old partitions get additional constraints applied. Note some intervals may occasionally cause an extra partition to be premade or one to be missed due to leap years, differing month lengths, daylight savings (on non-UTC systems), etc. This won't hurt anything and will self-correct. If partitioning ever falls behind the premake value, normal running of run_maintenance() and data insertion to id-based tables should automatically catch things up.
* p_use_run_maintenance - Used to tell partman whether you'd like to override the default way that child partitions are created. Set this value to TRUE to allow you to use the run_maintenance() function to create new child tables for serial partitioning instead of using 50% method mentioned above. Time based partitining MUST use run_maintenance() and this parameter cannot be set to FALSE for it. See **run_mainteanance** in Maintenance Functions section below for more info.
* p_start_partition - allows the first partition of a set to be specified instead of it being automatically determined. Must be a valid timestamp (for time-based) or positive integer (for id-based) value. Be aware, though, the actual paramater data type is text. For time-based partitioning, all partitions starting with the given timestamp up to CURRENT_TIMESTAMP (plus premake) will be created. For id-based partitioning, only the partition starting at the given value (plus premake) will be made.
* p_inherit_fk - allows pg_partman to automatically manage inheriting any foreign keys that exist on the parent table to all its children. Defaults to TRUE.
* p_jobmon - allow pg_partman to use the pg_jobmon extension to monitor that partitioning is working correctly. Defaults to TRUE.
* p_debug - turns on additional debugging information (not yet working).

*partition_data_time(p_parent_table text, p_batch_count int DEFAULT 1, p_batch_interval interval DEFAULT NULL, p_lock_wait numeric DEFAULT 0, p_order text DEFAULT 'ASC')*
Expand Down Expand Up @@ -260,6 +262,8 @@ quarter-hour - One partition per 15 minute interval on the quarter-hour (1200
premake - How many partitions to keep pre-made ahead of the current partition. Default is 4.
Manages number of partitions handled by static partitioning method. See create_parent() function for more info.
Manages which old tables get additional constraints set if configured to do so. See **About** section for more info.
inherit_fk - Set whether pg_partman manages inheriting foreign keys from the parent table to all children.
Defaults to TRUE. Can be set with the create_parent() function at creation time as well.
retention - Text type value that determines how old the data in a child partition can be before it is dropped.
Must be a value that can either be cast to the interval or bigint data types.
Leave this column NULL (the default) to always keep all child partitions. See **About** section for more info.
Expand Down
2 changes: 1 addition & 1 deletion pg_partman.control
@@ -1,3 +1,3 @@
default_version = '1.7.1'
default_version = '1.7.2'
comment = 'Extension to manage partitioned tables by time or ID'
relocatable = false
7 changes: 3 additions & 4 deletions sql/functions/apply_foreign_keys.sql
Expand Up @@ -57,8 +57,7 @@ ELSE
END IF;

FOR v_row IN
SELECT keys.conname
, keys.confrelid::regclass::text AS ref_table
SELECT n.nspname||'.'||cl.relname AS ref_table
, '"'||string_agg(att.attname, '","')||'"' AS ref_column
, '"'||string_agg(att2.attname, '","')||'"' AS child_column
FROM
Expand All @@ -75,9 +74,10 @@ FOR v_row IN
ORDER BY con.conkey
) keys
JOIN pg_catalog.pg_class cl ON cl.oid = keys.confrelid
JOIN pg_catalog.pg_namespace n ON cl.relnamespace = n.oid
JOIN pg_catalog.pg_attribute att ON att.attrelid = keys.confrelid AND att.attnum = keys.child
JOIN pg_catalog.pg_attribute att2 ON att2.attrelid = keys.conrelid AND att2.attnum = keys.ref
GROUP BY keys.conname, keys.confrelid
GROUP BY keys.conname, n.nspname, cl.relname
LOOP
SELECT schemaname, tablename INTO v_ref_schema, v_ref_table FROM pg_tables WHERE schemaname||'.'||tablename = v_row.ref_table;
v_sql := format('ALTER TABLE %I.%I ADD FOREIGN KEY (%s) REFERENCES %I.%I (%s)',
Expand Down Expand Up @@ -116,4 +116,3 @@ EXCEPTION
END
$$;


8 changes: 7 additions & 1 deletion sql/functions/create_id_partition.sql
Expand Up @@ -12,6 +12,7 @@ v_control text;
v_grantees text[];
v_hasoids boolean;
v_id bigint;
v_inherit_fk boolean;
v_job_id bigint;
v_jobmon boolean;
v_jobmon_schema text;
Expand All @@ -33,9 +34,11 @@ BEGIN

SELECT control
, part_interval
, inherit_fk
, jobmon
INTO v_control
, v_part_interval
, v_inherit_fk
, v_jobmon
FROM @extschema@.part_config
WHERE parent_table = p_parent_table
Expand Down Expand Up @@ -117,7 +120,9 @@ FOREACH v_id IN ARRAY p_partition_ids LOOP

EXECUTE 'ALTER TABLE '||v_partition_name||' OWNER TO '||v_parent_owner;

PERFORM @extschema@.apply_foreign_keys(quote_ident(v_parent_schema)||'.'||quote_ident(v_parent_tablename), v_partition_name);
IF v_inherit_fk THEN
PERFORM @extschema@.apply_foreign_keys(quote_ident(v_parent_schema)||'.'||quote_ident(v_parent_tablename), v_partition_name);
END IF;

IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
Expand Down Expand Up @@ -152,3 +157,4 @@ EXCEPTION
END
$$;


48 changes: 43 additions & 5 deletions sql/functions/create_parent.sql
Expand Up @@ -10,6 +10,7 @@ CREATE FUNCTION create_parent(
, p_premake int DEFAULT 4
, p_use_run_maintenance boolean DEFAULT NULL
, p_start_partition text DEFAULT NULL
, p_inherit_fk boolean DEFAULT true
, p_jobmon boolean DEFAULT true
, p_debug boolean DEFAULT false)
RETURNS void
Expand Down Expand Up @@ -183,8 +184,28 @@ IF p_type = 'time-static' OR p_type = 'time-dynamic' OR p_type = 'time-custom' T
v_count := v_count + 1;
END LOOP;

INSERT INTO @extschema@.part_config (parent_table, type, part_interval, control, premake, constraint_cols, datetime_string, use_run_maintenance, jobmon) VALUES
(p_parent_table, p_type, v_time_interval, p_control, p_premake, p_constraint_cols, v_datetime_string, v_run_maint, p_jobmon);
INSERT INTO @extschema@.part_config (
parent_table
, type
, part_interval
, control
, premake
, constraint_cols
, datetime_string
, use_run_maintenance
, inherit_fk
, jobmon)
VALUES (
p_parent_table
, p_type
, v_time_interval
, p_control
, p_premake
, p_constraint_cols
, v_datetime_string
, v_run_maint
, p_inherit_fk
, p_jobmon);
v_last_partition_name := @extschema@.create_time_partition(p_parent_table, v_partition_time_array);
-- Doing separate update because create function requires in config table last_partition to be set
UPDATE @extschema@.part_config SET last_partition = v_last_partition_name WHERE parent_table = p_parent_table;
Expand Down Expand Up @@ -215,8 +236,26 @@ IF p_type = 'id-static' OR p_type = 'id-dynamic' THEN
v_partition_id = array_append(v_partition_id, (v_id_interval*i) + v_starting_partition_id);
END LOOP;

INSERT INTO @extschema@.part_config (parent_table, type, part_interval, control, premake, constraint_cols, use_run_maintenance, jobmon) VALUES
(p_parent_table, p_type, v_id_interval, p_control, p_premake, p_constraint_cols, v_run_maint, p_jobmon);
INSERT INTO @extschema@.part_config (
parent_table
, type
, part_interval
, control
, premake
, constraint_cols
, use_run_maintenance
, inherit_fk
, jobmon)
VALUES (
p_parent_table
, p_type
, v_id_interval
, p_control
, p_premake
, p_constraint_cols
, v_run_maint
, p_inherit_fk
, p_jobmon);
v_last_partition_name := @extschema@.create_id_partition(p_parent_table, v_partition_id);
-- Doing separate update because create function needs parent table in config table for apply_grants()
UPDATE @extschema@.part_config SET last_partition = v_last_partition_name WHERE parent_table = p_parent_table;
Expand Down Expand Up @@ -275,4 +314,3 @@ EXCEPTION
END
$$;


7 changes: 6 additions & 1 deletion sql/functions/create_time_partition.sql
Expand Up @@ -12,6 +12,7 @@ v_analyze boolean := FALSE;
v_control text;
v_grantees text[];
v_hasoids boolean;
v_inherit_fk boolean;
v_job_id bigint;
v_jobmon boolean;
v_jobmon_schema text;
Expand Down Expand Up @@ -43,10 +44,12 @@ BEGIN
SELECT type
, control
, part_interval
, inherit_fk
, jobmon
INTO v_type
, v_control
, v_part_interval
, v_inherit_fk
, v_jobmon
FROM @extschema@.part_config
WHERE parent_table = p_parent_table
Expand Down Expand Up @@ -170,7 +173,9 @@ FOREACH v_time IN ARRAY p_partition_times LOOP

EXECUTE 'ALTER TABLE '||v_partition_name||' OWNER TO '||v_parent_owner;

PERFORM @extschema@.apply_foreign_keys(quote_ident(v_parent_schema)||'.'||quote_ident(v_parent_tablename), v_partition_name);
IF v_inherit_fk THEN
PERFORM @extschema@.apply_foreign_keys(quote_ident(v_parent_schema)||'.'||quote_ident(v_parent_tablename), v_partition_name);
END IF;

IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
Expand Down
1 change: 1 addition & 0 deletions sql/tables/tables.sql
Expand Up @@ -5,6 +5,7 @@ CREATE TABLE part_config (
control text NOT NULL,
constraint_cols text[],
premake int NOT NULL DEFAULT 4,
inherit_fk boolean NOT NULL DEFAULT true,
retention text,
retention_schema text,
retention_keep_table boolean NOT NULL DEFAULT true,
Expand Down

0 comments on commit 2b75107

Please sign in to comment.