diff --git a/CHANGELOG b/CHANGELOG index 44654ed6..f2aee9be 100644 --- a/CHANGELOG +++ b/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. diff --git a/META.json b/META.json index eba9803b..b1ac59ab 100644 --- a/META.json +++ b/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 " ], @@ -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" } }, diff --git a/doc/pg_partman.md b/doc/pg_partman.md index b897f3b7..e3b89b93 100644 --- a/doc/pg_partman.md +++ b/doc/pg_partman.md @@ -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 @@ -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. @@ -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')* @@ -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. diff --git a/pg_partman.control b/pg_partman.control index 3924379d..788bea06 100644 --- a/pg_partman.control +++ b/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 diff --git a/sql/functions/apply_foreign_keys.sql b/sql/functions/apply_foreign_keys.sql index a235ff8c..84956d7d 100644 --- a/sql/functions/apply_foreign_keys.sql +++ b/sql/functions/apply_foreign_keys.sql @@ -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 @@ -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)', @@ -116,4 +116,3 @@ EXCEPTION END $$; - diff --git a/sql/functions/create_id_partition.sql b/sql/functions/create_id_partition.sql index 438526f4..d2df72f7 100644 --- a/sql/functions/create_id_partition.sql +++ b/sql/functions/create_id_partition.sql @@ -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; @@ -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 @@ -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'); @@ -152,3 +157,4 @@ EXCEPTION END $$; + diff --git a/sql/functions/create_parent.sql b/sql/functions/create_parent.sql index 48befa13..095c9119 100644 --- a/sql/functions/create_parent.sql +++ b/sql/functions/create_parent.sql @@ -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 @@ -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; @@ -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; @@ -275,4 +314,3 @@ EXCEPTION END $$; - diff --git a/sql/functions/create_time_partition.sql b/sql/functions/create_time_partition.sql index f24937bd..ad400f87 100644 --- a/sql/functions/create_time_partition.sql +++ b/sql/functions/create_time_partition.sql @@ -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; @@ -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 @@ -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'); diff --git a/sql/tables/tables.sql b/sql/tables/tables.sql index 6135481f..5e38a4fa 100644 --- a/sql/tables/tables.sql +++ b/sql/tables/tables.sql @@ -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, diff --git a/test/test-id-dynamic.sql b/test/test-id-dynamic.sql index 76378fca..4cffc408 100644 --- a/test/test-id-dynamic.sql +++ b/test/test-id-dynamic.sql @@ -1,5 +1,5 @@ -- ########## ID DYNAMIC TESTS ########## --- Additional tests: UNLOGGED +-- Additional tests: UNLOGGED, Make sure option to not inherit foreign keys works \set ON_ERROR_ROLLBACK 1 \set ON_ERROR_STOP true @@ -7,18 +7,24 @@ BEGIN; SELECT set_config('search_path','partman, public',false); -SELECT plan(111); +SELECT plan(119); CREATE SCHEMA partman_test; CREATE ROLE partman_basic; CREATE ROLE partman_revoke; CREATE ROLE partman_owner; -CREATE UNLOGGED TABLE partman_test.id_dynamic_table (col1 int primary key, col2 text, col3 timestamptz DEFAULT now()); +CREATE TABLE partman_test.fk_test_reference (col2 text unique not null); +INSERT INTO partman_test.fk_test_reference VALUES ('stuff'); + +CREATE UNLOGGED TABLE partman_test.id_dynamic_table ( + col1 int primary key + , col2 text not null default 'stuff' references partman_test.fk_test_reference (col2) + , col3 timestamptz DEFAULT now()); INSERT INTO partman_test.id_dynamic_table (col1) VALUES (generate_series(1,9)); GRANT SELECT,INSERT,UPDATE ON partman_test.id_dynamic_table TO partman_basic; GRANT ALL ON partman_test.id_dynamic_table TO partman_revoke; -SELECT create_parent('partman_test.id_dynamic_table', 'col1', 'id-dynamic', '10'); +SELECT create_parent('partman_test.id_dynamic_table', 'col1', 'id-dynamic', '10', p_inherit_fk := false); SELECT has_table('partman_test', 'id_dynamic_table_p0', 'Check id_dynamic_table_p0 exists'); SELECT has_table('partman_test', 'id_dynamic_table_p10', 'Check id_dynamic_table_p10 exists'); SELECT has_table('partman_test', 'id_dynamic_table_p20', 'Check id_dynamic_table_p20 exists'); @@ -30,6 +36,11 @@ SELECT col_is_pk('partman_test', 'id_dynamic_table_p10', ARRAY['col1'], 'Check f SELECT col_is_pk('partman_test', 'id_dynamic_table_p20', ARRAY['col1'], 'Check for primary key in id_dynamic_table_p20'); SELECT col_is_pk('partman_test', 'id_dynamic_table_p30', ARRAY['col1'], 'Check for primary key in id_dynamic_table_p30'); SELECT col_is_pk('partman_test', 'id_dynamic_table_p40', ARRAY['col1'], 'Check for primary key in id_dynamic_table_p40'); +SELECT col_isnt_fk('partman_test', 'id_dynamic_table_p0', 'col2', 'Check that foreign key was NOT inherited to id_dynamic_table_p0'); +SELECT col_isnt_fk('partman_test', 'id_dynamic_table_p10', 'col2', 'Check that foreign key was NOT inherited to id_dynamic_table_p10'); +SELECT col_isnt_fk('partman_test', 'id_dynamic_table_p20', 'col2', 'Check that foreign key was NOT inherited to id_dynamic_table_p20'); +SELECT col_isnt_fk('partman_test', 'id_dynamic_table_p30', 'col2', 'Check that foreign key was NOT inherited to id_dynamic_table_p30'); +SELECT col_isnt_fk('partman_test', 'id_dynamic_table_p40', 'col2', 'Check that foreign key was NOT inherited to id_dynamic_table_p40'); SELECT table_privs_are('partman_test', 'id_dynamic_table_p0', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p0'); SELECT table_privs_are('partman_test', 'id_dynamic_table_p10', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p10'); SELECT table_privs_are('partman_test', 'id_dynamic_table_p20', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p20'); @@ -63,6 +74,7 @@ SELECT has_table('partman_test', 'id_dynamic_table_p50', 'Check id_dynamic_table SELECT results_eq('SELECT relpersistence::text FROM pg_catalog.pg_class WHERE oid::regclass = ''partman_test.id_dynamic_table_p50''::regclass', ARRAY['u'], 'Check that id_dynamic_table_p50 is unlogged'); SELECT hasnt_table('partman_test', 'id_dynamic_table_p60', 'Check id_dynamic_table_p60 doesn''t exists yet'); SELECT col_is_pk('partman_test', 'id_dynamic_table_p50', ARRAY['col1'], 'Check for primary key in id_dynamic_table_p50'); +SELECT col_isnt_fk('partman_test', 'id_dynamic_table_p50', 'col2', 'Check that foreign key was NOT inherited to id_dynamic_table_p50'); SELECT table_privs_are('partman_test', 'id_dynamic_table_p0', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p0'); SELECT table_privs_are('partman_test', 'id_dynamic_table_p10', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p10'); SELECT table_privs_are('partman_test', 'id_dynamic_table_p20', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p20'); @@ -88,6 +100,8 @@ SELECT results_eq('SELECT relpersistence::text FROM pg_catalog.pg_class WHERE oi SELECT hasnt_table('partman_test', 'id_dynamic_table_p80', 'Check id_dynamic_table_p80 doesn''t exists yet'); SELECT col_is_pk('partman_test', 'id_dynamic_table_p60', ARRAY['col1'], 'Check for primary key in id_dynamic_table_p60'); SELECT col_is_pk('partman_test', 'id_dynamic_table_p70', ARRAY['col1'], 'Check for primary key in id_dynamic_table_p70'); +SELECT col_isnt_fk('partman_test', 'id_dynamic_table_p60', 'col2', 'Check that foreign key was NOT inherited to id_dynamic_table_p60'); +SELECT col_isnt_fk('partman_test', 'id_dynamic_table_p70', 'col2', 'Check that foreign key was NOT inherited to id_dynamic_table_p70'); SELECT table_privs_are('partman_test', 'id_dynamic_table_p0', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p0'); SELECT table_privs_are('partman_test', 'id_dynamic_table_p10', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p10'); SELECT table_privs_are('partman_test', 'id_dynamic_table_p20', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p20'); diff --git a/test/test-time-dynamic-yearly.sql b/test/test-time-dynamic-yearly.sql index 3a4ca17a..d8fcdc52 100644 --- a/test/test-time-dynamic-yearly.sql +++ b/test/test-time-dynamic-yearly.sql @@ -5,7 +5,7 @@ \set ON_ERROR_STOP true BEGIN; -SELECT set_config('search_path','partman, public',false); +SELECT set_config('search_path','partman, public, partman_test',false); SELECT plan(90); CREATE SCHEMA partman_test; diff --git a/test/test-time-static-monthly.sql b/test/test-time-static-monthly.sql index 3cd0e2c9..2356dc83 100644 --- a/test/test-time-static-monthly.sql +++ b/test/test-time-static-monthly.sql @@ -1,4 +1,5 @@ -- ########## TIME STATIC TESTS ########## +-- Other tests: Make sure option to not inherit foreign keys works \set ON_ERROR_ROLLBACK 1 \set ON_ERROR_STOP true @@ -6,18 +7,27 @@ BEGIN; SELECT set_config('search_path','partman, public',false); -SELECT plan(128); +SELECT plan(138); CREATE SCHEMA partman_test; CREATE ROLE partman_basic; CREATE ROLE partman_revoke; CREATE ROLE partman_owner; -CREATE TABLE partman_test.time_static_table (col1 int primary key, col2 text, col3 timestamptz NOT NULL DEFAULT now()); +CREATE TABLE partman_test.fk_test_reference (col2 text not null); +CREATE UNIQUE INDEX ON partman_test.fk_test_reference(col2); +INSERT INTO partman_test.fk_test_reference VALUES ('stuff'); + +CREATE TABLE partman_test.time_static_table ( + col1 int primary key + , col2 text not null default 'stuff' + , col3 timestamptz NOT NULL DEFAULT now() + , FOREIGN KEY (col2) REFERENCES partman_test.fk_test_reference(col2)); INSERT INTO partman_test.time_static_table (col1, col3) VALUES (generate_series(1,10), CURRENT_TIMESTAMP); GRANT SELECT,INSERT,UPDATE ON partman_test.time_static_table TO partman_basic; GRANT ALL ON partman_test.time_static_table TO partman_revoke; -SELECT create_parent('partman_test.time_static_table', 'col3', 'time-static', 'monthly'); +SELECT create_parent('partman_test.time_static_table', 'col3', 'time-static', 'monthly', p_inherit_fk := false); +--SELECT create_parent('partman_test.time_static_table', 'col3', 'time-static', 'monthly'); SELECT has_table('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM'), 'Check time_static_table_'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM')||' exists'); SELECT has_table('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 month'::interval, 'YYYY_MM'), 'Check time_static_table_'||to_char(CURRENT_TIMESTAMP+'1 month'::interval, 'YYYY_MM')||' exists'); @@ -50,8 +60,6 @@ SELECT col_is_pk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAM 'Check for primary key in time_static_table_p'||to_char(CURRENT_TIMESTAMP+'3 months'::interval, 'YYYY_MM')); SELECT col_is_pk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 months'::interval, 'YYYY_MM'), ARRAY['col1'], 'Check for primary key in time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 months'::interval, 'YYYY_MM')); -SELECT col_is_pk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM'), ARRAY['col1'], - 'Check for primary key in time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM')); SELECT col_is_pk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP-'1 month'::interval, 'YYYY_MM'), ARRAY['col1'], 'Check for primary key in time_static_table_p'||to_char(CURRENT_TIMESTAMP-'1 month'::interval, 'YYYY_MM')); SELECT col_is_pk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP-'2 months'::interval, 'YYYY_MM'), ARRAY['col1'], @@ -60,6 +68,24 @@ SELECT col_is_pk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAM 'Check for primary key in time_static_table_p'||to_char(CURRENT_TIMESTAMP-'3 months'::interval, 'YYYY_MM')); SELECT col_is_pk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP-'4 months'::interval, 'YYYY_MM'), ARRAY['col1'], 'Check for primary key in time_static_table_p'||to_char(CURRENT_TIMESTAMP-'4 months'::interval, 'YYYY_MM')); +SELECT col_isnt_fk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM'), 'col2', + 'Check that foreign key was NOT inherited for time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM')); +SELECT col_isnt_fk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 month'::interval, 'YYYY_MM'), 'col2', + 'Check that foreign key was NOT inherited for time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 month'::interval, 'YYYY_MM')); +SELECT col_isnt_fk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 months'::interval, 'YYYY_MM'), 'col2', + 'Check that foreign key was NOT inherited for time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 months'::interval, 'YYYY_MM')); +SELECT col_isnt_fk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'3 months'::interval, 'YYYY_MM'), 'col2', + 'Check that foreign key was NOT inherited for time_static_table_p'||to_char(CURRENT_TIMESTAMP+'3 months'::interval, 'YYYY_MM')); +SELECT col_isnt_fk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 months'::interval, 'YYYY_MM'), 'col2', + 'Check that foreign key was NOT inherited for time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 months'::interval, 'YYYY_MM')); +SELECT col_isnt_fk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP-'1 month'::interval, 'YYYY_MM'), 'col2', + 'Check that foreign key was NOT inherited for time_static_table_p'||to_char(CURRENT_TIMESTAMP-'1 month'::interval, 'YYYY_MM')); +SELECT col_isnt_fk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP-'2 months'::interval, 'YYYY_MM'), 'col2', + 'Check that foreign key was NOT inherited for time_static_table_p'||to_char(CURRENT_TIMESTAMP-'2 months'::interval, 'YYYY_MM')); +SELECT col_isnt_fk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP-'3 months'::interval, 'YYYY_MM'), 'col2', + 'Check that foreign key was NOT inherited for time_static_table_p'||to_char(CURRENT_TIMESTAMP-'3 months'::interval, 'YYYY_MM')); +SELECT col_isnt_fk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP-'4 months'::interval, 'YYYY_MM'), 'col2', + 'Check that foreign key was NOT inherited for time_static_table_p'||to_char(CURRENT_TIMESTAMP-'4 months'::interval, 'YYYY_MM')); SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM'), 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], @@ -161,6 +187,8 @@ SELECT hasnt_table('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMEST 'Check time_static_table_'||to_char(CURRENT_TIMESTAMP+'6 months'::interval, 'YYYY_MM')||' exists'); SELECT col_is_pk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'5 months'::interval, 'YYYY_MM'), ARRAY['col1'], 'Check for primary key in time_static_table_p'||to_char(CURRENT_TIMESTAMP+'5 months'::interval, 'YYYY_MM')); +SELECT col_isnt_fk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP-'5 months'::interval, 'YYYY_MM'), 'col2', + 'Check that foreign key was NOT inherited for time_static_table_p'||to_char(CURRENT_TIMESTAMP-'5 months'::interval, 'YYYY_MM')); SELECT is_empty('SELECT * FROM ONLY partman_test.time_static_table', 'Check that parent table has had no data inserted to it'); SELECT results_eq('SELECT count(*)::int FROM partman_test.time_static_table_p'||to_char(CURRENT_TIMESTAMP+'5 months'::interval, 'YYYY_MM'), @@ -215,6 +243,8 @@ SELECT hasnt_table('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMEST 'Check time_static_table_'||to_char(CURRENT_TIMESTAMP+'7 months'::interval, 'YYYY_MM')||' exists'); SELECT col_is_pk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'6 months'::interval, 'YYYY_MM'), ARRAY['col1'], 'Check for primary key in time_static_table_p'||to_char(CURRENT_TIMESTAMP+'6 months'::interval, 'YYYY_MM')); +SELECT col_isnt_fk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP-'6 months'::interval, 'YYYY_MM'), 'col2', + 'Check that foreign key was NOT inherited for time_static_table_p'||to_char(CURRENT_TIMESTAMP-'6 months'::interval, 'YYYY_MM')); SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM'), 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM')); SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 month'::interval, 'YYYY_MM'), 'partman_basic', @@ -328,6 +358,7 @@ SELECT table_owner_is ('partman_test', 'time_static_table_p'||to_char(CURRENT_TI SELECT table_owner_is ('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP-'4 months'::interval, 'YYYY_MM'), 'partman_owner', 'Check that ownership change worked for time_static_table_p'||to_char(CURRENT_TIMESTAMP-'4 months'::interval, 'YYYY_MM')); + -- Currently unable to do drop_partition test reliably for monthly due to differing month lengths (sometimes drops 2 partitions instead of 1) SELECT undo_partition_time('partman_test.time_static_table', 20, p_keep_table := false); SELECT results_eq('SELECT count(*)::int FROM ONLY partman_test.time_static_table', ARRAY[159], 'Check count from parent table after undo'); diff --git a/updates/pg_partman--1.7.0--1.7.1.sql b/updates/pg_partman--1.7.0--1.7.1.sql index 4b5aaf30..ca6d20a5 100644 --- a/updates/pg_partman--1.7.0--1.7.1.sql +++ b/updates/pg_partman--1.7.0--1.7.1.sql @@ -1256,4 +1256,4 @@ BEGIN END $$; -DROP TABLE partman_preserve_privs_temp; +DROP TABLE IF EXISTS partman_preserve_privs_temp; diff --git a/updates/pg_partman--1.7.1--1.7.2.sql b/updates/pg_partman--1.7.1--1.7.2.sql new file mode 100644 index 00000000..fcda2d22 --- /dev/null +++ b/updates/pg_partman--1.7.1--1.7.2.sql @@ -0,0 +1,841 @@ +-- 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(). + +ALTER TABLE @extschema@.part_config ADD inherit_fk boolean NOT NULL DEFAULT true; + +CREATE TEMP TABLE partman_preserve_privs_temp (statement text); + +INSERT INTO partman_preserve_privs_temp +SELECT 'GRANT EXECUTE ON FUNCTION @extschema@.create_parent(text, text, text, text, text[], int, boolean, text, boolean, boolean, boolean) TO '||array_to_string(array_agg(grantee::text), ',')||';' +FROM information_schema.routine_privileges +WHERE routine_schema = '@extschema@' +AND routine_name = 'create_parent'; + +DROP FUNCTION create_parent(text, text, text, text, text[], int, boolean, text, boolean, boolean); + +/* + * Apply foreign keys that exist on the given parent to the given child table + */ +CREATE OR REPLACE FUNCTION apply_foreign_keys(p_parent_table text, p_child_table text DEFAULT NULL, p_debug boolean DEFAULT false) RETURNS void + LANGUAGE plpgsql + AS $$ +DECLARE + +v_job_id bigint; +v_jobmon text; +v_jobmon_schema text; +v_old_search_path text; +v_ref_schema text; +v_ref_table text; +v_row record; +v_schemaname text; +v_sql text; +v_step_id bigint; +v_tablename text; + +BEGIN + +SELECT jobmon INTO v_jobmon FROM @extschema@.part_config WHERE parent_table = p_parent_table; + +IF v_jobmon THEN + SELECT nspname INTO v_jobmon_schema FROM pg_catalog.pg_namespace n, pg_catalog.pg_extension e WHERE e.extname = 'pg_jobmon' AND e.extnamespace = n.oid; + IF v_jobmon_schema IS NOT NULL THEN + SELECT current_setting('search_path') INTO v_old_search_path; + EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')'; + END IF; +END IF; + +IF v_jobmon_schema IS NOT NULL THEN + v_job_id := add_job('PARTMAN APPLYING FOREIGN KEYS: '||p_parent_table); +END IF; + +IF v_jobmon_schema IS NOT NULL THEN + v_step_id := add_step(v_job_id, 'Checking if target child table exists'); +END IF; + +SELECT schemaname, tablename INTO v_schemaname, v_tablename +FROM pg_catalog.pg_tables +WHERE schemaname||'.'||tablename = p_child_table; + +IF v_tablename IS NULL THEN + IF v_jobmon_schema IS NOT NULL THEN + PERFORM update_step(v_step_id, 'CRITICAL', 'Target child table ('||v_child_table||') does not exist.'); + PERFORM fail_job(v_job_id); + EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')'; + END IF; + RAISE EXCEPTION 'Target child table (%.%) does not exist.', v_schemaname, v_tablename; + RETURN; +ELSE + IF v_jobmon_schema IS NOT NULL THEN + PERFORM update_step(v_step_id, 'OK', 'Done'); + END IF; +END IF; + +FOR v_row IN + SELECT n.nspname||'.'||cl.relname AS ref_table + , '"'||string_agg(att.attname, '","')||'"' AS ref_column + , '"'||string_agg(att2.attname, '","')||'"' AS child_column + FROM + ( SELECT con.conname + , unnest(con.conkey) as ref + , unnest(con.confkey) as child + , con.confrelid + , con.conrelid + FROM pg_catalog.pg_class c + JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid + JOIN pg_catalog.pg_constraint con ON c.oid = con.conrelid + WHERE n.nspname ||'.'|| c.relname = p_parent_table + AND con.contype = 'f' + 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, 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)', + v_schemaname, v_tablename, v_row.child_column, v_ref_schema, v_ref_table, v_row.ref_column); + + IF v_jobmon_schema IS NOT NULL THEN + v_step_id := add_step(v_job_id, 'Applying FK: '||v_sql); + END IF; + + EXECUTE v_sql; + + IF v_jobmon_schema IS NOT NULL THEN + PERFORM update_step(v_step_id, 'OK', 'FK applied'); + END IF; + +END LOOP; + +IF v_jobmon_schema IS NOT NULL THEN + PERFORM close_job(v_job_id); + EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')'; +END IF; + +EXCEPTION + WHEN OTHERS THEN + IF v_jobmon_schema IS NOT NULL THEN + IF v_job_id IS NULL THEN + EXECUTE 'SELECT '||v_jobmon_schema||'.add_job(''PARTMAN APPLYING FOREIGN KEYS: '||p_parent_table||''')' INTO v_job_id; + EXECUTE 'SELECT '||v_jobmon_schema||'.add_step('||v_job_id||', ''EXCEPTION before job logging started'')' INTO v_step_id; + ELSIF v_step_id IS NULL THEN + EXECUTE 'SELECT '||v_jobmon_schema||'.add_step('||v_job_id||', ''EXCEPTION before first step logged'')' INTO v_step_id; + END IF; + EXECUTE 'SELECT '||v_jobmon_schema||'.update_step('||v_step_id||', ''CRITICAL'', ''ERROR: '||coalesce(SQLERRM,'unknown')||''')'; + EXECUTE 'SELECT '||v_jobmon_schema||'.fail_job('||v_job_id||')'; + END IF; + RAISE EXCEPTION '%', SQLERRM; +END +$$; + + +/* + * Function to turn a table into the parent of a partition set + */ +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) +RETURNS void + LANGUAGE plpgsql SECURITY DEFINER + AS $$ +DECLARE + +v_base_timestamp timestamp; +v_count int := 1; +v_datetime_string text; +v_id_interval bigint; +v_job_id bigint; +v_jobmon_schema text; +v_last_partition_name text; +v_old_search_path text; +v_partition_time timestamp; +v_partition_time_array timestamp[]; +v_partition_id bigint[]; +v_max bigint; +v_notnull boolean; +v_run_maint boolean; +v_start_time timestamp; +v_starting_partition_id bigint; +v_step_id bigint; +v_step_overflow_id bigint; +v_tablename text; +v_time_interval interval; + +BEGIN + +IF position('.' in p_parent_table) = 0 THEN + RAISE EXCEPTION 'Parent table must be schema qualified'; +END IF; + +SELECT tablename INTO v_tablename FROM pg_tables WHERE schemaname || '.' || tablename = p_parent_table; + IF v_tablename IS NULL THEN + RAISE EXCEPTION 'Please create given parent table first: %', p_parent_table; + END IF; + +SELECT attnotnull INTO v_notnull FROM pg_attribute WHERE attrelid = p_parent_table::regclass AND attname = p_control; + IF v_notnull = false OR v_notnull IS NULL THEN + RAISE EXCEPTION 'Control column (%) for parent table (%) must be NOT NULL', p_control, p_parent_table; + END IF; + +IF NOT @extschema@.check_partition_type(p_type) THEN + RAISE EXCEPTION '% is not a valid partitioning type', p_type; +END IF; + +IF p_type = 'time-custom' AND @extschema@.check_version('9.2.0') IS FALSE THEN + RAISE EXCEPTION 'The "time-custom" type requires a minimum PostgreSQL version of 9.2.0'; +END IF; + +EXECUTE 'LOCK TABLE '||p_parent_table||' IN ACCESS EXCLUSIVE MODE'; + +IF p_jobmon THEN + SELECT nspname INTO v_jobmon_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'pg_jobmon' AND e.extnamespace = n.oid; + IF v_jobmon_schema IS NOT NULL THEN + SELECT current_setting('search_path') INTO v_old_search_path; + EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')'; + END IF; +END IF; + +IF p_use_run_maintenance IS NOT NULL THEN + IF p_use_run_maintenance IS FALSE AND (p_type = 'time-static' OR p_type = 'time-dynamic' OR p_type = 'time-custom') THEN + RAISE EXCEPTION 'p_run_maintenance cannot be set to false for time based partitioning'; + END IF; + v_run_maint := p_use_run_maintenance; +ELSIF p_type = 'time-static' OR p_type = 'time-dynamic' OR p_type = 'time-custom' THEN + v_run_maint := TRUE; +ELSIF p_type = 'id-static' OR p_type ='id-dynamic' THEN + v_run_maint := FALSE; +ELSE + RAISE EXCEPTION 'use_run_maintenance value cannot be set NULL'; +END IF; + +IF v_jobmon_schema IS NOT NULL THEN + v_job_id := add_job('PARTMAN SETUP PARENT: '||p_parent_table); + v_step_id := add_step(v_job_id, 'Creating initial partitions on new parent table: '||p_parent_table); +END IF; + +IF p_type = 'time-static' OR p_type = 'time-dynamic' OR p_type = 'time-custom' THEN + + CASE + WHEN p_interval = 'yearly' THEN + v_time_interval := '1 year'; + WHEN p_interval = 'quarterly' THEN + v_time_interval := '3 months'; + WHEN p_interval = 'monthly' THEN + v_time_interval := '1 month'; + WHEN p_interval = 'weekly' THEN + v_time_interval := '1 week'; + WHEN p_interval = 'daily' THEN + v_time_interval := '1 day'; + WHEN p_interval = 'hourly' THEN + v_time_interval := '1 hour'; + WHEN p_interval = 'half-hour' THEN + v_time_interval := '30 mins'; + WHEN p_interval = 'quarter-hour' THEN + v_time_interval := '15 mins'; + ELSE + IF p_type <> 'time-custom' THEN + RAISE EXCEPTION 'Must use a predefined time interval if not using type "time-custom". See documentation.'; + END IF; + v_time_interval := p_interval::interval; + IF v_time_interval < '1 second'::interval THEN + RAISE EXCEPTION 'Partitioning interval must be 1 second or greater'; + END IF; + END CASE; + + -- First partition is either the min premake or p_start_partition + v_start_time := COALESCE(p_start_partition::timestamp, CURRENT_TIMESTAMP - (v_time_interval * p_premake)); + + IF v_time_interval >= '1 year' THEN + v_base_timestamp := date_trunc('year', v_start_time); + IF v_time_interval >= '10 years' THEN + v_base_timestamp := date_trunc('decade', v_start_time); + IF v_time_interval >= '100 years' THEN + v_base_timestamp := date_trunc('century', v_start_time); + IF v_time_interval >= '1000 years' THEN + v_base_timestamp := date_trunc('millennium', v_start_time); + END IF; -- 1000 + END IF; -- 100 + END IF; -- 10 + END IF; -- 1 + + v_datetime_string := 'YYYY'; + IF v_time_interval < '1 year' THEN + IF p_interval = 'quarterly' THEN + v_base_timestamp := date_trunc('quarter', v_start_time); + v_datetime_string = 'YYYY"q"Q'; + ELSE + v_base_timestamp := date_trunc('month', v_start_time); + v_datetime_string := v_datetime_string || '_MM'; + END IF; + IF v_time_interval < '1 month' THEN + IF p_interval = 'weekly' THEN + v_base_timestamp := date_trunc('week', v_start_time); + v_datetime_string := 'IYYY"w"IW'; + ELSE + v_base_timestamp := date_trunc('day', v_start_time); + v_datetime_string := v_datetime_string || '_DD'; + END IF; + IF v_time_interval < '1 day' THEN + v_base_timestamp := date_trunc('hour', v_start_time); + v_datetime_string := v_datetime_string || '_HH24MI'; + IF v_time_interval < '1 minute' THEN + v_base_timestamp := date_trunc('minute', v_start_time); + v_datetime_string := v_datetime_string || 'SS'; + END IF; -- minute + END IF; -- day + END IF; -- month + END IF; -- year + + 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 + BEGIN + v_partition_time := (v_base_timestamp + (v_time_interval * v_count))::timestamp; + v_partition_time_array := array_append(v_partition_time_array, v_partition_time); + EXCEPTION WHEN datetime_field_overflow THEN + RAISE WARNING 'Attempted partition time interval is outside PostgreSQL''s supported time range. + Child partition creation after time % skipped', v_partition_time; + v_step_overflow_id := add_step(v_job_id, 'Attempted partition time interval is outside PostgreSQL''s supported time range.'); + PERFORM update_step(v_step_overflow_id, 'CRITICAL', 'Child partition creation after time '||v_partition_time||' skipped'); + CONTINUE; + END; + ELSE + EXIT; -- all needed partitions added to array. Exit the loop. + END IF; + 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 + , 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; + + IF v_jobmon_schema IS NOT NULL THEN + PERFORM update_step(v_step_id, 'OK', 'Time partitions premade: '||p_premake); + END IF; +END IF; + +IF p_type = 'id-static' OR p_type = 'id-dynamic' THEN + v_id_interval := p_interval::bigint; + IF v_id_interval <= 1 THEN + RAISE EXCEPTION 'Interval for serial partitioning must be greater than 1'; + END IF; + + -- If custom start partition is set, use that. + -- If custom start is not set and there is already data, start partitioning with the highest current value + EXECUTE 'SELECT COALESCE('||quote_nullable(p_start_partition::bigint)||', max('||p_control||')::bigint, 0) FROM '||p_parent_table||' LIMIT 1' INTO v_max; + v_starting_partition_id := v_max - (v_max % v_id_interval); + FOR i IN 0..p_premake LOOP + -- Only make previous partitions if ID value is less than the starting value and positive (and custom start partition wasn't set) + IF p_start_partition IS NULL AND + (v_starting_partition_id - (v_id_interval*i)) > 0 + AND (v_starting_partition_id - (v_id_interval*i)) < v_starting_partition_id + THEN + v_partition_id = array_append(v_partition_id, (v_starting_partition_id - v_id_interval*i)); + END IF; + 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 + , 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; + + IF v_jobmon_schema IS NOT NULL THEN + PERFORM update_step(v_step_id, 'OK', 'ID partitions premade: '||p_premake); + END IF; + +END IF; + +IF v_jobmon_schema IS NOT NULL THEN + v_step_id := add_step(v_job_id, 'Creating partition function'); +END IF; + +IF p_type = 'time-static' OR p_type = 'time-dynamic' OR p_type = 'time-custom' THEN + PERFORM @extschema@.create_time_function(p_parent_table); + IF v_jobmon_schema IS NOT NULL THEN + PERFORM update_step(v_step_id, 'OK', 'Time function created'); + END IF; +ELSIF p_type = 'id-static' OR p_type = 'id-dynamic' THEN + PERFORM @extschema@.create_id_function(p_parent_table); + IF v_jobmon_schema IS NOT NULL THEN + PERFORM update_step(v_step_id, 'OK', 'ID function created'); + END IF; +END IF; + +IF v_jobmon_schema IS NOT NULL THEN + v_step_id := add_step(v_job_id, 'Creating partition trigger'); +END IF; + +PERFORM @extschema@.create_trigger(p_parent_table); + +IF v_jobmon_schema IS NOT NULL THEN + PERFORM update_step(v_step_id, 'OK', 'Done'); + IF v_step_overflow_id IS NOT NULL THEN + PERFORM fail_job(v_job_id); + ELSE + PERFORM close_job(v_job_id); + END IF; + EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')'; +END IF; + +EXCEPTION + WHEN OTHERS THEN + IF v_jobmon_schema IS NOT NULL THEN + IF v_job_id IS NULL THEN + EXECUTE 'SELECT '||v_jobmon_schema||'.add_job(''PARTMAN CREATE PARENT: '||p_parent_table||''')' INTO v_job_id; + EXECUTE 'SELECT '||v_jobmon_schema||'.add_step('||v_job_id||', ''Partition creation for table '||p_parent_table||' failed'')' INTO v_step_id; + ELSIF v_step_id IS NULL THEN + EXECUTE 'SELECT '||v_jobmon_schema||'.add_step('||v_job_id||', ''EXCEPTION before first step logged'')' INTO v_step_id; + END IF; + EXECUTE 'SELECT '||v_jobmon_schema||'.update_step('||v_step_id||', ''CRITICAL'', ''ERROR: '||coalesce(SQLERRM,'unknown')||''')'; + EXECUTE 'SELECT '||v_jobmon_schema||'.fail_job('||v_job_id||')'; + END IF; + RAISE EXCEPTION '%', SQLERRM; +END +$$; + + +/* + * Function to create id partitions + */ +CREATE OR REPLACE FUNCTION create_id_partition (p_parent_table text, p_partition_ids bigint[]) RETURNS text + LANGUAGE plpgsql SECURITY DEFINER + AS $$ +DECLARE + +v_all text[] := ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER']; +v_analyze boolean := FALSE; +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; +v_old_search_path text; +v_parent_grant record; +v_parent_owner text; +v_parent_schema text; +v_parent_tablename text; +v_parent_tablespace text; +v_part_interval bigint; +v_partition_name text; +v_revoke text[]; +v_sql text; +v_step_id bigint; +v_tablename text; +v_unlogged char; + +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 +AND (type = 'id-static' OR type = 'id-dynamic'); + +IF NOT FOUND THEN + RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table; +END IF; + +IF v_jobmon THEN + SELECT nspname INTO v_jobmon_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'pg_jobmon' AND e.extnamespace = n.oid; + IF v_jobmon_schema IS NOT NULL THEN + SELECT current_setting('search_path') INTO v_old_search_path; + EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')'; + END IF; +END IF; + +SELECT tableowner, schemaname, tablename, tablespace INTO v_parent_owner, v_parent_schema, v_parent_tablename, v_parent_tablespace FROM pg_tables WHERE schemaname ||'.'|| tablename = p_parent_table; + +FOREACH v_id IN ARRAY p_partition_ids LOOP + v_partition_name := @extschema@.check_name_length(v_parent_tablename, v_parent_schema, v_id::text, TRUE); + + -- If child table already exists, skip creation + SELECT tablename INTO v_tablename FROM pg_catalog.pg_tables WHERE schemaname ||'.'|| tablename = v_partition_name; + IF v_tablename IS NOT NULL THEN + CONTINUE; + END IF; + + -- Ensure analyze is run if a new partition is created. Otherwise if one isn't, will be false and analyze will be skipped + v_analyze := TRUE; + + IF v_jobmon_schema IS NOT NULL THEN + v_job_id := add_job('PARTMAN CREATE TABLE: '||p_parent_table); + v_step_id := add_step(v_job_id, 'Creating new partition '||v_partition_name||' with interval from '||v_id||' to '||(v_id + v_part_interval)-1); + END IF; + + SELECT relpersistence INTO v_unlogged FROM pg_catalog.pg_class WHERE oid::regclass = p_parent_table::regclass; + v_sql := 'CREATE'; + IF v_unlogged = 'u' THEN + v_sql := v_sql || ' UNLOGGED'; + END IF; + v_sql := v_sql || ' TABLE '||v_partition_name||' (LIKE '||p_parent_table||' INCLUDING DEFAULTS INCLUDING CONSTRAINTS INCLUDING INDEXES INCLUDING STORAGE INCLUDING COMMENTS)'; + SELECT relhasoids INTO v_hasoids FROM pg_catalog.pg_class WHERE oid::regclass = p_parent_table::regclass; + IF v_hasoids IS TRUE THEN + v_sql := v_sql || ' WITH (OIDS)'; + END IF; + EXECUTE v_sql; + SELECT tablename INTO v_tablename FROM pg_catalog.pg_tables WHERE schemaname ||'.'|| tablename = v_partition_name; + IF v_parent_tablespace IS NOT NULL THEN + EXECUTE 'ALTER TABLE '||v_partition_name||' SET TABLESPACE '||v_parent_tablespace; + END IF; + EXECUTE 'ALTER TABLE '||v_partition_name||' ADD CONSTRAINT '||v_tablename||'_partition_check + CHECK ('||v_control||'>='||quote_literal(v_id)||' AND '||v_control||'<'||quote_literal(v_id + v_part_interval)||')'; + EXECUTE 'ALTER TABLE '||v_partition_name||' INHERIT '||p_parent_table; + + FOR v_parent_grant IN + SELECT array_agg(DISTINCT privilege_type::text ORDER BY privilege_type::text) AS types, grantee + FROM information_schema.table_privileges + WHERE table_schema ||'.'|| table_name = p_parent_table + GROUP BY grantee + LOOP + EXECUTE 'GRANT '||array_to_string(v_parent_grant.types, ',')||' ON '||v_partition_name||' TO '||v_parent_grant.grantee; + SELECT array_agg(r) INTO v_revoke FROM (SELECT unnest(v_all) AS r EXCEPT SELECT unnest(v_parent_grant.types)) x; + IF v_revoke IS NOT NULL THEN + EXECUTE 'REVOKE '||array_to_string(v_revoke, ',')||' ON '||v_partition_name||' FROM '||v_parent_grant.grantee||' CASCADE'; + END IF; + v_grantees := array_append(v_grantees, v_parent_grant.grantee::text); + END LOOP; + -- Revoke all privileges from roles that have none on the parent + IF v_grantees IS NOT NULL THEN + SELECT array_agg(r) INTO v_revoke FROM ( + SELECT DISTINCT grantee::text AS r FROM information_schema.table_privileges WHERE table_schema ||'.'|| table_name = v_partition_name + EXCEPT + SELECT unnest(v_grantees)) x; + IF v_revoke IS NOT NULL THEN + EXECUTE 'REVOKE ALL ON '||v_partition_name||' FROM '||array_to_string(v_revoke, ','); + END IF; + END IF; + + EXECUTE 'ALTER TABLE '||v_partition_name||' OWNER TO '||v_parent_owner; + + 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'); + PERFORM close_job(v_job_id); + END IF; + +END LOOP; + +IF v_analyze THEN + EXECUTE 'ANALYZE '||p_parent_table; +END IF; + +IF v_jobmon_schema IS NOT NULL THEN + EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')'; +END IF; + +RETURN v_partition_name; + +EXCEPTION + WHEN OTHERS THEN + IF v_jobmon_schema IS NOT NULL THEN + IF v_job_id IS NULL THEN + EXECUTE 'SELECT '||v_jobmon_schema||'.add_job(''PARTMAN CREATE TABLE: '||p_parent_table||''')' INTO v_job_id; + EXECUTE 'SELECT '||v_jobmon_schema||'.add_step('||v_job_id||', ''EXCEPTION before job logging started'')' INTO v_step_id; + ELSIF v_step_id IS NULL THEN + EXECUTE 'SELECT '||v_jobmon_schema||'.add_step('||v_job_id||', ''EXCEPTION before first step logged'')' INTO v_step_id; + END IF; + EXECUTE 'SELECT '||v_jobmon_schema||'.update_step('||v_step_id||', ''CRITICAL'', ''ERROR: '||coalesce(SQLERRM,'unknown')||''')'; + EXECUTE 'SELECT '||v_jobmon_schema||'.fail_job('||v_job_id||')'; + END IF; + RAISE EXCEPTION '%', SQLERRM; +END +$$; + + +/* + * Function to create a child table in a time-based partition set + */ +CREATE OR REPLACE FUNCTION create_time_partition (p_parent_table text, p_partition_times timestamp[]) +RETURNS text + LANGUAGE plpgsql SECURITY DEFINER + AS $$ +DECLARE + +v_all text[] := ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER']; +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; +v_old_search_path text; +v_parent_grant record; +v_parent_owner text; +v_parent_schema text; +v_parent_tablename text; +v_partition_name text; +v_partition_suffix text; +v_parent_tablespace text; +v_part_interval interval; +v_partition_timestamp_end timestamp; +v_partition_timestamp_start timestamp; +v_quarter text; +v_revoke text[]; +v_sql text; +v_step_id bigint; +v_step_overflow_id bigint; +v_tablename text; +v_trunc_value text; +v_time timestamp; +v_type text; +v_unlogged char; +v_year text; + +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 +AND (type = 'time-static' OR type = 'time-dynamic' OR type = 'time-custom'); + +IF NOT FOUND THEN + RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table; +END IF; + +IF v_jobmon THEN + SELECT nspname INTO v_jobmon_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'pg_jobmon' AND e.extnamespace = n.oid; + IF v_jobmon_schema IS NOT NULL THEN + SELECT current_setting('search_path') INTO v_old_search_path; + EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')'; + END IF; +END IF; + +SELECT tableowner, schemaname, tablename, tablespace INTO v_parent_owner, v_parent_schema, v_parent_tablename, v_parent_tablespace FROM pg_tables WHERE schemaname ||'.'|| tablename = p_parent_table; + +FOREACH v_time IN ARRAY p_partition_times LOOP + + v_partition_suffix := to_char(v_time, 'YYYY'); + IF v_part_interval < '1 year' AND v_part_interval <> '1 week' THEN + v_partition_suffix := v_partition_suffix ||'_'|| to_char(v_time, 'MM'); + IF v_part_interval < '1 month' AND v_part_interval <> '1 week' THEN + v_partition_suffix := v_partition_suffix ||'_'|| to_char(v_time, 'DD'); + IF v_part_interval < '1 day' THEN + v_partition_suffix := v_partition_suffix || '_' || to_char(v_time, 'HH24MI'); + IF v_part_interval < '1 minute' THEN + v_partition_suffix := v_partition_suffix || to_char(v_time, 'SS'); + END IF; -- end < minute IF + END IF; -- end < day IF + END IF; -- end < month IF + END IF; -- end < year IF + + v_partition_timestamp_start := v_time; + BEGIN + v_partition_timestamp_end := v_time + v_part_interval; + EXCEPTION WHEN datetime_field_overflow THEN + RAISE WARNING 'Attempted partition time interval is outside PostgreSQL''s supported time range. + Child partition creation after time % skipped', v_time; + v_step_overflow_id := add_step(v_job_id, 'Attempted partition time interval is outside PostgreSQL''s supported time range.'); + PERFORM update_step(v_step_overflow_id, 'CRITICAL', 'Child partition creation after time '||v_time||' skipped'); + CONTINUE; + END; + + IF v_part_interval = '1 week' THEN + v_partition_suffix := to_char(v_time, 'IYYY') || 'w' || to_char(v_time, 'IW'); + END IF; + + -- "Q" is ignored in to_timestamp, so handle special case + IF v_part_interval = '3 months' AND (v_type = 'time-static' OR v_type = 'time-dynamic') THEN + v_year := to_char(v_time, 'YYYY'); + v_quarter := to_char(v_time, 'Q'); + v_partition_suffix := v_year || 'q' || v_quarter; + END IF; + + v_partition_name := @extschema@.check_name_length(v_parent_tablename, v_parent_schema, v_partition_suffix, TRUE); + + SELECT tablename INTO v_tablename FROM pg_catalog.pg_tables WHERE schemaname ||'.'|| tablename = v_partition_name; + IF v_tablename IS NOT NULL THEN + CONTINUE; + END IF; + + -- Ensure analyze is run if a new partition is created. Otherwise if one isn't, will be false and analyze will be skipped + v_analyze := TRUE; + + IF v_jobmon_schema IS NOT NULL THEN + v_job_id := add_job('PARTMAN CREATE TABLE: '||p_parent_table); + v_step_id := add_step(v_job_id, 'Creating new partition '||v_partition_name||' with interval from '||v_partition_timestamp_start||' to '||(v_partition_timestamp_end-'1sec'::interval)); + END IF; + + SELECT relpersistence INTO v_unlogged FROM pg_catalog.pg_class WHERE oid::regclass = p_parent_table::regclass; + v_sql := 'CREATE'; + IF v_unlogged = 'u' THEN + v_sql := v_sql || ' UNLOGGED'; + END IF; + v_sql := v_sql || ' TABLE '||v_partition_name||' (LIKE '||p_parent_table||' INCLUDING DEFAULTS INCLUDING CONSTRAINTS INCLUDING INDEXES INCLUDING STORAGE INCLUDING COMMENTS)'; + SELECT relhasoids INTO v_hasoids FROM pg_catalog.pg_class WHERE oid::regclass = p_parent_table::regclass; + IF v_hasoids IS TRUE THEN + v_sql := v_sql || ' WITH (OIDS)'; + END IF; + EXECUTE v_sql; + SELECT tablename INTO v_tablename FROM pg_catalog.pg_tables WHERE schemaname ||'.'|| tablename = v_partition_name; + IF v_parent_tablespace IS NOT NULL THEN + EXECUTE 'ALTER TABLE '||v_partition_name||' SET TABLESPACE '||v_parent_tablespace; + END IF; + EXECUTE 'ALTER TABLE '||v_partition_name||' ADD CONSTRAINT '||v_tablename||'_partition_check + CHECK ('||v_control||'>='||quote_literal(v_partition_timestamp_start)||' AND '||v_control||'<'||quote_literal(v_partition_timestamp_end)||')'; + EXECUTE 'ALTER TABLE '||v_partition_name||' INHERIT '||p_parent_table; + + -- If custom time, set extra config options. + IF v_type = 'time-custom' THEN + INSERT INTO @extschema@.custom_time_partitions (parent_table, child_table, partition_range) + VALUES ( p_parent_table, v_partition_name, tstzrange(v_partition_timestamp_start, v_partition_timestamp_end, '[)') ); + END IF; + + FOR v_parent_grant IN + SELECT array_agg(DISTINCT privilege_type::text ORDER BY privilege_type::text) AS types, grantee + FROM information_schema.table_privileges + WHERE table_schema ||'.'|| table_name = p_parent_table + GROUP BY grantee + LOOP + EXECUTE 'GRANT '||array_to_string(v_parent_grant.types, ',')||' ON '||v_partition_name||' TO '||v_parent_grant.grantee; + SELECT array_agg(r) INTO v_revoke FROM (SELECT unnest(v_all) AS r EXCEPT SELECT unnest(v_parent_grant.types)) x; + IF v_revoke IS NOT NULL THEN + EXECUTE 'REVOKE '||array_to_string(v_revoke, ',')||' ON '||v_partition_name||' FROM '||v_parent_grant.grantee||' CASCADE'; + END IF; + v_grantees := array_append(v_grantees, v_parent_grant.grantee::text); + END LOOP; + -- Revoke all privileges from roles that have none on the parent + IF v_grantees IS NOT NULL THEN + SELECT array_agg(r) INTO v_revoke FROM ( + SELECT DISTINCT grantee::text AS r FROM information_schema.table_privileges WHERE table_schema ||'.'|| table_name = v_partition_name + EXCEPT + SELECT unnest(v_grantees)) x; + IF v_revoke IS NOT NULL THEN + EXECUTE 'REVOKE ALL ON '||v_partition_name||' FROM '||array_to_string(v_revoke, ','); + END IF; + END IF; + + EXECUTE 'ALTER TABLE '||v_partition_name||' OWNER TO '||v_parent_owner; + + 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'); + IF v_step_overflow_id IS NOT NULL THEN + PERFORM fail_job(v_job_id); + ELSE + PERFORM close_job(v_job_id); + END IF; + END IF; + +END LOOP; + +IF v_analyze THEN + EXECUTE 'ANALYZE '||p_parent_table; +END IF; + +IF v_jobmon_schema IS NOT NULL THEN + EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')'; +END IF; + +RETURN v_partition_name; + +EXCEPTION + WHEN OTHERS THEN + IF v_jobmon_schema IS NOT NULL THEN + IF v_job_id IS NULL THEN + EXECUTE 'SELECT '||v_jobmon_schema||'.add_job(''PARTMAN CREATE TABLE: '||p_parent_table||''')' INTO v_job_id; + EXECUTE 'SELECT '||v_jobmon_schema||'.add_step('||v_job_id||', ''EXCEPTION before job logging started'')' INTO v_step_id; + ELSIF v_step_id IS NULL THEN + EXECUTE 'SELECT '||v_jobmon_schema||'.add_step('||v_job_id||', ''EXCEPTION before first step logged'')' INTO v_step_id; + END IF; + EXECUTE 'SELECT '||v_jobmon_schema||'.update_step('||v_step_id||', ''CRITICAL'', ''ERROR: '||coalesce(SQLERRM,'unknown')||''')'; + EXECUTE 'SELECT '||v_jobmon_schema||'.fail_job('||v_job_id||')'; + END IF; + RAISE EXCEPTION '%', SQLERRM; +END +$$; + +-- Restore dropped object privileges +DO $$ +DECLARE +v_row record; +BEGIN + FOR v_row IN SELECT statement FROM partman_preserve_privs_temp LOOP + IF v_row.statement IS NOT NULL THEN + EXECUTE v_row.statement; + END IF; + END LOOP; +END +$$; + +DROP TABLE IF EXISTS partman_preserve_privs_temp;