diff --git a/CHANGELOG b/CHANGELOG.txt similarity index 95% rename from CHANGELOG rename to CHANGELOG.txt index 45334074..8515b61c 100644 --- a/CHANGELOG +++ b/CHANGELOG.txt @@ -1,3 +1,10 @@ +1.8.3 +-- Fix both the retention system and the undo partitioning functions/scripts not cleaning up the custom_time_partitions table when using a custom time interval (Github Issue #49). +-- When using sub-partitioning, the call to create_parent() that is within create_partition_id() & create_partition_time() was passing 2 of the parameters through incorrectly. p_use_run_maintenance was being fed to p_inherit_fk and vice versa, so the inherit_fk and use_run_maintenance columns in part_config & part_config_sub may be reversed. Since these are both boolean parameters, no error was being raised. If you've used sub-partitioning and used anything other than the default values for either of these configuration options, please double-check the part_config & part_config_sub tables to ensure the proper values are there. If you did not set them specifically, the default values were set for both and things should be fine. + -- If p_use_run_maintenance was set wrong, you likely noticed that new partitons were not getting created for new sub-partition sets. You'll still have to fix any existing config settings, but future ones shoould be fine now. + -- If p_inherit_fk was set wrong, child tables were likely not inheriting FKs or they were inheriting them when you didn't want them to. Again, fix this for existing partition sets by correcting the config table and all future sub-partitions should now be set properly. If you need to generate FKs on child tables that were missing them, you can use the reapply_foreign_keys.py script. + + 1.8.2 -- Fixed a bug in sub-partitioning that would cause child tables outside of the time boundaries of the parent partitions to be created when using time->time sub-partitioning. A user encountered the error when doing weekly->daily subpartitioning, but it was possible it could have happened in other interval combinations I had not tested as well (Github Issue #47). -- Updated reapply_indexes.py script to, by default, only add new indexes and drop ones that don't exist on the parent. Previously it would drop all indexes on all children and recreate them to match the parent. Now it only does the minimal amount of work to make the children match the parent. An additional option (--recreate_all/-R) was added to allow the old behavior of redoing all indexes from scratch if desired (Github Issue #41) diff --git a/META.json b/META.json index cb27680e..547cd506 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.8.2", + "version": "1.8.3", "maintainer": [ "Keith Fiske " ], @@ -20,9 +20,9 @@ }, "provides": { "pg_partman": { - "file": "sql/pg_partman--1.8.2.sql", + "file": "sql/pg_partman--1.8.3.sql", "docfile": "doc/pg_partman.md", - "version": "1.8.2", + "version": "1.8.3", "abstract": "Extension to manage partitioned tables by time or ID" } }, diff --git a/pg_partman.control b/pg_partman.control index 3ac37734..bcdf075d 100644 --- a/pg_partman.control +++ b/pg_partman.control @@ -1,3 +1,3 @@ -default_version = '1.8.2' +default_version = '1.8.3' comment = 'Extension to manage partitioned tables by time or ID' relocatable = false diff --git a/sql/functions/create_partition_id.sql b/sql/functions/create_partition_id.sql index e206c151..02ed8247 100644 --- a/sql/functions/create_partition_id.sql +++ b/sql/functions/create_partition_id.sql @@ -206,8 +206,8 @@ FOREACH v_id IN ARRAY p_partition_ids LOOP , v_row.sub_part_interval , v_row.sub_constraint_cols , v_row.sub_premake - , v_row.sub_inherit_fk , v_row.sub_use_run_maintenance + , v_row.sub_inherit_fk , v_row.sub_jobmon); EXECUTE v_sql; @@ -272,4 +272,3 @@ EXCEPTION END $$; - diff --git a/sql/functions/create_partition_time.sql b/sql/functions/create_partition_time.sql index bfc1ac31..eb0b9701 100644 --- a/sql/functions/create_partition_time.sql +++ b/sql/functions/create_partition_time.sql @@ -282,8 +282,8 @@ FOREACH v_time IN ARRAY p_partition_times LOOP , v_row.sub_part_interval , v_row.sub_constraint_cols , v_row.sub_premake - , v_row.sub_inherit_fk , v_row.sub_use_run_maintenance + , v_row.sub_inherit_fk , v_row.sub_jobmon); EXECUTE v_sql; diff --git a/sql/functions/drop_partition_time.sql b/sql/functions/drop_partition_time.sql index bf4e3cec..68cbcf84 100644 --- a/sql/functions/drop_partition_time.sql +++ b/sql/functions/drop_partition_time.sql @@ -142,6 +142,9 @@ LOOP IF v_jobmon_schema IS NOT NULL THEN v_step_id := add_step(v_job_id, 'Uninherit table '||v_child_table||' from '||p_parent_table); END IF; + IF v_type = 'time-custom' THEN + DELETE FROM @extschema@.custom_time_partitions WHERE parent_table = p_parent_table AND child_table = v_child_table; + END IF; EXECUTE 'ALTER TABLE '||v_child_table||' NO INHERIT ' || p_parent_table; IF v_jobmon_schema IS NOT NULL THEN PERFORM update_step(v_step_id, 'OK', 'Done'); @@ -221,3 +224,4 @@ EXCEPTION END $$; + diff --git a/sql/functions/undo_partition_time.sql b/sql/functions/undo_partition_time.sql index 000a5f47..34d289b1 100644 --- a/sql/functions/undo_partition_time.sql +++ b/sql/functions/undo_partition_time.sql @@ -30,6 +30,7 @@ v_step_id bigint; v_sub_count int; v_total bigint := 0; v_trig_name text; +v_type text; v_undo_count int := 0; BEGIN @@ -40,10 +41,12 @@ IF v_adv_lock = 'false' THEN RETURN 0; END IF; -SELECT part_interval::interval +SELECT type + , part_interval::interval , control , jobmon -INTO v_part_interval +INTO v_type + , v_part_interval , v_control , v_jobmon FROM @extschema@.part_config @@ -176,6 +179,9 @@ WHILE v_batch_loop_count < p_batch_count LOOP PERFORM update_step(v_step_id, 'OK', 'Child table UNINHERITED, not DROPPED. Moved '||v_child_loop_total||' rows to parent'); END IF; END IF; + IF v_type = 'time-custom' THEN + DELETE FROM @extschema@.custom_time_partitions WHERE parent_table = p_parent_table AND child_table = v_child_table; + END IF; v_undo_count := v_undo_count + 1; CONTINUE outer_child_loop; END IF; @@ -262,4 +268,3 @@ EXCEPTION END $$; - diff --git a/test/test_custom_time/test-time-custom-100years.sql b/test/test_custom_time/test-time-custom-100years.sql index 21a6c8fc..8e07f54b 100644 --- a/test/test_custom_time/test-time-custom-100years.sql +++ b/test/test_custom_time/test-time-custom-100years.sql @@ -6,7 +6,7 @@ BEGIN; SELECT set_config('search_path','partman, public',false); -SELECT plan(128); +SELECT plan(129); CREATE SCHEMA partman_test; CREATE SCHEMA partman_retention_test; CREATE ROLE partman_basic; @@ -361,5 +361,7 @@ SELECT hasnt_table('partman_test', 'time_static_table_p'||to_char(date_trunc('ce SELECT hasnt_table('partman_test', 'time_static_table_p'||to_char(date_trunc('century', CURRENT_TIMESTAMP)-'200 years'::interval, 'YYYY'), 'Check time_static_table_'||to_char(date_trunc('century', CURRENT_TIMESTAMP)-'200 years'::interval, 'YYYY')||' does not exist'); +SELECT is_empty('SELECT * FROM custom_time_partitions WHERE parent_table = ''partman_test.time_static_table''', 'Check that custom_time_partitions table is empty'); + SELECT * FROM finish(); ROLLBACK; diff --git a/updates/pg_partman--1.8.2--1.8.3.sql b/updates/pg_partman--1.8.2--1.8.3.sql new file mode 100644 index 00000000..640bc336 --- /dev/null +++ b/updates/pg_partman--1.8.2--1.8.3.sql @@ -0,0 +1,1130 @@ +-- Fix both the retention system and the undo partitioning functions/scripts not cleaning up the custom_time_partitions table when using a custom time interval (Github Issue #49). +-- When using sub-partitioning, the call to create_parent() that is within create_partition_id() & create_partition_time() was passing 2 of the parameters through incorrectly. p_use_run_maintenance was being fed to p_inherit_fk and vice versa, so the inherit_fk and use_run_maintenance columns in part_config & part_config_sub may be reversed. Since these are both boolean parameters, no error was being raised. If you've used sub-partitioning and used anything other than the default values for either of these configuration options, please double-check the part_config & part_config_sub tables to ensure the proper values are there. If you did not set them specifically, the default values were set for both and things should be fine. + -- If p_use_run_maintenance was set wrong, you likely noticed that new partitons were not getting created for new sub-partition sets. You'll still have to fix any existing config settings, but future ones shoould be fine now. + -- If p_inherit_fk was set wrong, child tables were likely not inheriting FKs or they were inheriting them when you didn't want them to. Again, fix this for existing partition sets by correcting the config table and all future sub-partitions should now be set properly. If you need to generate FKs on child tables that were missing them, you can use the reapply_foreign_keys.py script. + +/* + * Function to undo time-based partitioning created by this extension + */ +CREATE OR REPLACE FUNCTION undo_partition_time(p_parent_table text, p_batch_count int DEFAULT 1, p_batch_interval interval DEFAULT NULL, p_keep_table boolean DEFAULT true, p_lock_wait numeric DEFAULT 0) RETURNS bigint + LANGUAGE plpgsql SECURITY DEFINER + AS $$ +DECLARE + +v_adv_lock boolean; +v_batch_loop_count int := 0; +v_child_min timestamptz; +v_child_loop_total bigint := 0; +v_child_table text; +v_control text; +v_function_name text; +v_inner_loop_count int; +v_lock_iter int := 1; +v_lock_obtained boolean := FALSE; +v_job_id bigint; +v_jobmon boolean; +v_jobmon_schema text; +v_move_sql text; +v_old_search_path text; +v_parent_schema text; +v_parent_tablename text; +v_part_interval interval; +v_row record; +v_rowcount bigint; +v_step_id bigint; +v_sub_count int; +v_total bigint := 0; +v_trig_name text; +v_type text; +v_undo_count int := 0; + +BEGIN + +v_adv_lock := pg_try_advisory_xact_lock(hashtext('pg_partman undo_time_partition')); +IF v_adv_lock = 'false' THEN + RAISE NOTICE 'undo_time_partition already running.'; + RETURN 0; +END IF; + +SELECT type + , part_interval::interval + , control + , jobmon +INTO v_type + , v_part_interval + , v_control + , 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 v_part_interval IS NULL THEN + RAISE EXCEPTION 'Configuration for given parent table not found: %', p_parent_table; +END IF; + +-- Check if any child tables are themselves partitioned or part of an inheritance tree. Prevent undo at this level if so. +-- Need to either lock child tables at all levels or handle the proper removal of triggers on all child tables first +-- before multi-level undo can be performed safely. +FOR v_row IN + SELECT show_partitions AS child_table FROM @extschema@.show_partitions(p_parent_table) +LOOP + SELECT count(*) INTO v_sub_count + FROM pg_catalog.pg_inherits + WHERE inhparent::regclass = v_row.child_table::regclass; + IF v_sub_count > 0 THEN + RAISE EXCEPTION 'Child table for this parent has child table(s) itself (%). Run undo partitioning on this table or remove inheritance first to ensure all data is properly moved to parent', v_row.child_table; + END IF; +END LOOP; + +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; + +IF v_jobmon_schema IS NOT NULL THEN + v_job_id := add_job('PARTMAN UNDO PARTITIONING: '||p_parent_table); + v_step_id := add_step(v_job_id, 'Undoing partitioning for table '||p_parent_table); +END IF; + +IF p_batch_interval IS NULL THEN + p_batch_interval := v_part_interval; +END IF; + +-- Stops new time partitons from being made as well as stopping child tables from being dropped if they were configured with a retention period. +UPDATE @extschema@.part_config SET undo_in_progress = true WHERE parent_table = p_parent_table; +-- Stop data going into child tables. +SELECT schemaname, tablename INTO v_parent_schema, v_parent_tablename FROM pg_tables WHERE schemaname ||'.'|| tablename = p_parent_table; +v_trig_name := @extschema@.check_name_length(p_object_name := v_parent_tablename, p_suffix := '_part_trig'); +v_function_name := @extschema@.check_name_length(v_parent_tablename, v_parent_schema, '_part_trig_func', FALSE); + +SELECT tgname INTO v_trig_name FROM pg_catalog.pg_trigger t WHERE tgname = v_trig_name; +IF v_trig_name IS NOT NULL THEN + -- lockwait for trigger drop + IF p_lock_wait > 0 THEN + v_lock_iter := 0; + WHILE v_lock_iter <= 5 LOOP + v_lock_iter := v_lock_iter + 1; + BEGIN + EXECUTE 'LOCK TABLE ONLY '||p_parent_table||' IN ACCESS EXCLUSIVE MODE NOWAIT'; + v_lock_obtained := TRUE; + EXCEPTION + WHEN lock_not_available THEN + PERFORM pg_sleep( p_lock_wait / 5.0 ); + CONTINUE; + END; + EXIT WHEN v_lock_obtained; + END LOOP; + IF NOT v_lock_obtained THEN + RAISE NOTICE 'Unable to obtain lock on parent table to remove trigger'; + RETURN -1; + END IF; + END IF; -- END p_lock_wait IF + EXECUTE 'DROP TRIGGER IF EXISTS '||v_trig_name||' ON '||p_parent_table; +END IF; -- END trigger IF +v_lock_obtained := FALSE; -- reset for reuse later + +EXECUTE 'DROP FUNCTION IF EXISTS '||v_function_name||'()'; + +IF v_jobmon_schema IS NOT NULL THEN + PERFORM update_step(v_step_id, 'OK', 'Stopped partition creation process. Removed trigger & trigger function'); +END IF; + +<> +WHILE v_batch_loop_count < p_batch_count LOOP + SELECT n.nspname||'.'||c.relname INTO v_child_table + FROM pg_inherits i + JOIN pg_class c ON i.inhrelid = c.oid + JOIN pg_namespace n ON c.relnamespace = n.oid + WHERE i.inhparent::regclass = p_parent_table::regclass + ORDER BY i.inhrelid ASC; + + EXIT WHEN v_child_table IS NULL; + + IF v_jobmon_schema IS NOT NULL THEN + v_step_id := add_step(v_job_id, 'Removing child partition: '||v_child_table); + END IF; + + EXECUTE 'SELECT min('||v_control||') FROM '||v_child_table INTO v_child_min; + IF v_child_min IS NULL THEN + -- No rows left in this child table. Remove from partition set. + + -- lockwait timeout for table drop + IF p_lock_wait > 0 THEN + v_lock_iter := 0; + WHILE v_lock_iter <= 5 LOOP + v_lock_iter := v_lock_iter + 1; + BEGIN + EXECUTE 'LOCK TABLE ONLY '||v_child_table||' IN ACCESS EXCLUSIVE MODE NOWAIT'; + v_lock_obtained := TRUE; + EXCEPTION + WHEN lock_not_available THEN + PERFORM pg_sleep( p_lock_wait / 5.0 ); + CONTINUE; + END; + EXIT WHEN v_lock_obtained; + END LOOP; + IF NOT v_lock_obtained THEN + RAISE NOTICE 'Unable to obtain lock on child table for removal from partition set'; + RETURN -1; + END IF; + END IF; -- END p_lock_wait IF + v_lock_obtained := FALSE; -- reset for reuse later + + EXECUTE 'ALTER TABLE '||v_child_table||' NO INHERIT ' || p_parent_table; + IF p_keep_table = false THEN + EXECUTE 'DROP TABLE '||v_child_table; + IF v_jobmon_schema IS NOT NULL THEN + PERFORM update_step(v_step_id, 'OK', 'Child table DROPPED. Moved '||v_child_loop_total||' rows to parent'); + END IF; + ELSE + IF v_jobmon_schema IS NOT NULL THEN + PERFORM update_step(v_step_id, 'OK', 'Child table UNINHERITED, not DROPPED. Moved '||v_child_loop_total||' rows to parent'); + END IF; + END IF; + IF v_type = 'time-custom' THEN + DELETE FROM @extschema@.custom_time_partitions WHERE parent_table = p_parent_table AND child_table = v_child_table; + END IF; + v_undo_count := v_undo_count + 1; + CONTINUE outer_child_loop; + END IF; + v_inner_loop_count := 1; + v_child_loop_total := 0; + <> + LOOP + -- do some locking with timeout, if required + IF p_lock_wait > 0 THEN + v_lock_iter := 0; + WHILE v_lock_iter <= 5 LOOP + v_lock_iter := v_lock_iter + 1; + BEGIN + EXECUTE 'SELECT * FROM ' || v_child_table || + ' WHERE '||v_control||' <= '||quote_literal(v_child_min + (p_batch_interval * v_inner_loop_count)) + ||' FOR UPDATE NOWAIT'; + v_lock_obtained := TRUE; + EXCEPTION + WHEN lock_not_available THEN + PERFORM pg_sleep( p_lock_wait / 5.0 ); + CONTINUE; + END; + EXIT WHEN v_lock_obtained; + END LOOP; + IF NOT v_lock_obtained THEN + RAISE NOTICE 'Unable to obtain lock on batch of rows to move'; + RETURN -1; + END IF; + END IF; + + -- Get everything from the current child minimum up to the multiples of the given interval + v_move_sql := 'WITH move_data AS (DELETE FROM '||v_child_table|| + ' WHERE '||v_control||' <= '||quote_literal(v_child_min + (p_batch_interval * v_inner_loop_count))||' RETURNING *) + INSERT INTO '||p_parent_table||' SELECT * FROM move_data'; + EXECUTE v_move_sql; + GET DIAGNOSTICS v_rowcount = ROW_COUNT; + v_total := v_total + v_rowcount; + v_child_loop_total := v_child_loop_total + v_rowcount; + IF v_jobmon_schema IS NOT NULL THEN + PERFORM update_step(v_step_id, 'OK', 'Moved '||v_child_loop_total||' rows to parent.'); + END IF; + EXIT inner_child_loop WHEN v_rowcount = 0; -- exit before loop incr if table is empty + v_inner_loop_count := v_inner_loop_count + 1; + v_batch_loop_count := v_batch_loop_count + 1; + EXIT outer_child_loop WHEN v_batch_loop_count >= p_batch_count; -- Exit outer FOR loop if p_batch_count is reached + END LOOP inner_child_loop; +END LOOP outer_child_loop; + +IF v_batch_loop_count < p_batch_count THEN + -- FOR loop never ran, so there's no child tables left. + DELETE FROM @extschema@.part_config WHERE parent_table = p_parent_table; + IF v_jobmon_schema IS NOT NULL THEN + v_step_id := add_step(v_job_id, 'Removing config from pg_partman'); + PERFORM update_step(v_step_id, 'OK', 'Done'); + END IF; +END IF; + +RAISE NOTICE 'Copied % row(s) to the parent. Removed % partitions.', v_total, v_undo_count; +IF v_jobmon_schema IS NOT NULL THEN + v_step_id := add_step(v_job_id, 'Final stats'); + PERFORM update_step(v_step_id, 'OK', 'Copied '||v_total||' row(s) to the parent. Removed '||v_undo_count||' partitions.'); +END IF; + +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; + +RETURN v_total; + +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 UNDO PARTITIONING: '||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 drop child tables from a time-based partition set. + * Options to move table to different schema, drop only indexes or actually drop the table from the database. + */ +CREATE OR REPLACE FUNCTION drop_partition_time(p_parent_table text, p_retention interval DEFAULT NULL, p_keep_table boolean DEFAULT NULL, p_keep_index boolean DEFAULT NULL, p_retention_schema text DEFAULT NULL) RETURNS int + LANGUAGE plpgsql SECURITY DEFINER + AS $$ +DECLARE + +v_adv_lock boolean; +v_child_table text; +v_datetime_string text; +v_drop_count int := 0; +v_index record; +v_job_id bigint; +v_jobmon boolean; +v_jobmon_schema text; +v_old_search_path text; +v_part_interval interval; +v_partition_timestamp timestamp; +v_quarter text; +v_retention interval; +v_retention_keep_index boolean; +v_retention_keep_table boolean; +v_retention_schema text; +v_step_id bigint; +v_time_position int; +v_type text; +v_year text; + +BEGIN + +v_adv_lock := pg_try_advisory_xact_lock(hashtext('pg_partman drop_partition_time')); +IF v_adv_lock = 'false' THEN + RAISE NOTICE 'drop_partition_time already running.'; + RETURN 0; +END IF; + +-- Allow override of configuration options +IF p_retention IS NULL THEN + SELECT + type + , part_interval::interval + , retention::interval + , retention_keep_table + , retention_keep_index + , datetime_string + , retention_schema + , jobmon + INTO + v_type + , v_part_interval + , v_retention + , v_retention_keep_table + , v_retention_keep_index + , v_datetime_string + , v_retention_schema + , v_jobmon + FROM @extschema@.part_config + WHERE parent_table = p_parent_table + AND (type = 'time-static' OR type = 'time-dynamic' OR type = 'time-custom') + AND retention IS NOT NULL; + + IF v_part_interval IS NULL THEN + RAISE EXCEPTION 'Configuration for given parent table with a retention period not found: %', p_parent_table; + END IF; +ELSE + SELECT + type + , part_interval::interval + , retention_keep_table + , retention_keep_index + , datetime_string + , retention_schema + , jobmon + INTO + v_type + , v_part_interval + , v_retention_keep_table + , v_retention_keep_index + , v_datetime_string + , v_retention_schema + , v_jobmon + FROM @extschema@.part_config + WHERE parent_table = p_parent_table + AND (type = 'time-static' OR type = 'time-dynamic' OR type = 'time-custom'); + v_retention := p_retention; + + IF v_part_interval IS NULL THEN + RAISE EXCEPTION 'Configuration for given parent table not found: %', p_parent_table; + END IF; +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; + +IF p_keep_table IS NOT NULL THEN + v_retention_keep_table = p_keep_table; +END IF; +IF p_keep_index IS NOT NULL THEN + v_retention_keep_index = p_keep_index; +END IF; +IF p_retention_schema IS NOT NULL THEN + v_retention_schema = p_retention_schema; +END IF; + +IF v_jobmon_schema IS NOT NULL THEN + v_job_id := add_job('PARTMAN DROP TIME PARTITION: '|| p_parent_table); +END IF; + +-- Loop through child tables of the given parent +FOR v_child_table IN + SELECT n.nspname||'.'||c.relname FROM pg_inherits i join pg_class c ON i.inhrelid = c.oid join pg_namespace n ON c.relnamespace = n.oid WHERE i.inhparent::regclass = p_parent_table::regclass ORDER BY i.inhrelid ASC +LOOP + -- pull out datetime portion of partition's tablename to make the next one + v_time_position := (length(v_child_table) - position('p_' in reverse(v_child_table))) + 2; + IF v_part_interval <> '3 months' OR (v_part_interval = '3 months' AND v_type = 'time-custom') THEN + v_partition_timestamp := to_timestamp(substring(v_child_table from v_time_position), v_datetime_string); + ELSE + -- to_timestamp doesn't recognize 'Q' date string formater. Handle it + v_year := split_part(substring(v_child_table from v_time_position), 'q', 1); + v_quarter := split_part(substring(v_child_table from v_time_position), 'q', 2); + CASE + WHEN v_quarter = '1' THEN + v_partition_timestamp := to_timestamp(v_year || '-01-01', 'YYYY-MM-DD'); + WHEN v_quarter = '2' THEN + v_partition_timestamp := to_timestamp(v_year || '-04-01', 'YYYY-MM-DD'); + WHEN v_quarter = '3' THEN + v_partition_timestamp := to_timestamp(v_year || '-07-01', 'YYYY-MM-DD'); + WHEN v_quarter = '4' THEN + v_partition_timestamp := to_timestamp(v_year || '-10-01', 'YYYY-MM-DD'); + END CASE; + END IF; + + -- Add one interval since partition names contain the start of the constraint period + IF v_retention < (CURRENT_TIMESTAMP - (v_partition_timestamp + v_part_interval)) THEN + IF v_jobmon_schema IS NOT NULL THEN + v_step_id := add_step(v_job_id, 'Uninherit table '||v_child_table||' from '||p_parent_table); + END IF; + IF v_type = 'time-custom' THEN + DELETE FROM @extschema@.custom_time_partitions WHERE parent_table = p_parent_table AND child_table = v_child_table; + END IF; + EXECUTE 'ALTER TABLE '||v_child_table||' NO INHERIT ' || p_parent_table; + IF v_jobmon_schema IS NOT NULL THEN + PERFORM update_step(v_step_id, 'OK', 'Done'); + END IF; + IF v_retention_schema IS NULL THEN + IF v_retention_keep_table = false THEN + IF v_jobmon_schema IS NOT NULL THEN + v_step_id := add_step(v_job_id, 'Drop table '||v_child_table); + END IF; + EXECUTE 'DROP TABLE '||v_child_table||' CASCADE'; + IF v_jobmon_schema IS NOT NULL THEN + PERFORM update_step(v_step_id, 'OK', 'Done'); + END IF; + ELSIF v_retention_keep_index = false THEN + FOR v_index IN + SELECT i.indexrelid::regclass AS name + , c.conname + FROM pg_catalog.pg_index i + LEFT JOIN pg_catalog.pg_constraint c ON i.indexrelid = c.conindid + WHERE i.indrelid = v_child_table::regclass + LOOP + IF v_jobmon_schema IS NOT NULL THEN + v_step_id := add_step(v_job_id, 'Drop index '||v_index.name||' from '||v_child_table); + END IF; + IF v_index.conname IS NOT NULL THEN + EXECUTE 'ALTER TABLE '||v_child_table||' DROP CONSTRAINT '||v_index.conname; + ELSE + EXECUTE 'DROP INDEX '||v_index.name; + END IF; + IF v_jobmon_schema IS NOT NULL THEN + PERFORM update_step(v_step_id, 'OK', 'Done'); + END IF; + END LOOP; + END IF; + ELSE -- Move to new schema + IF v_jobmon_schema IS NOT NULL THEN + v_step_id := add_step(v_job_id, 'Moving table '||v_child_table||' to schema '||v_retention_schema); + END IF; + + EXECUTE 'ALTER TABLE '||v_child_table||' SET SCHEMA '||v_retention_schema; + + IF v_jobmon_schema IS NOT NULL THEN + PERFORM update_step(v_step_id, 'OK', 'Done'); + END IF; + END IF; -- End retention schema if + + -- If child table is a subpartition, remove it from part_config & part_config_sub (should cascade due to FK) + DELETE FROM @extschema@.part_config WHERE parent_table = v_child_table; + + v_drop_count := v_drop_count + 1; + END IF; -- End retention check IF + +END LOOP; -- End child table loop + +IF v_jobmon_schema IS NOT NULL THEN + v_step_id := add_step(v_job_id, 'Finished partition drop maintenance'); + PERFORM update_step(v_step_id, 'OK', v_drop_count||' partitions dropped.'); + PERFORM close_job(v_job_id); + EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')'; +END IF; + +RETURN v_drop_count; + +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 DROP TIME PARTITION: '||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 id partitions + */ +CREATE OR REPLACE FUNCTION create_partition_id(p_parent_table text, p_partition_ids bigint[], p_analyze boolean DEFAULT true) RETURNS boolean + 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_id_position int; +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_created boolean := false; +v_partition_name text; +v_revoke text[]; +v_row record; +v_sql text; +v_step_id bigint; +v_sub_id_max bigint; +v_sub_id_min bigint; +v_tablename text; +v_top_interval bigint; +v_top_parent 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; + +-- Check if parent table is a subpartition of an already existing id based partition set managed by pg_partman +-- If so, limit what child tables can be created based on parent suffix +WITH top_oid AS ( + SELECT i.inhparent AS top_parent_oid + FROM pg_catalog.pg_class c + JOIN pg_catalog.pg_inherits i ON c.oid = i.inhrelid + JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace + WHERE n.nspname||'.'||c.relname = p_parent_table +) SELECT n.nspname||'.'||c.relname + INTO v_top_parent + FROM pg_catalog.pg_class c + JOIN top_oid t ON c.oid = t.top_parent_oid + JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace + JOIN @extschema@.part_config p ON p.parent_table = n.nspname||'.'||c.relname + WHERE c.oid = t.top_parent_oid + AND p.type = 'id-static' OR p.type = 'id-dynamic'; + +IF v_top_parent IS NOT NULL THEN + SELECT part_interval::bigint INTO v_top_interval FROM @extschema@.part_config WHERE parent_table = v_top_parent; + v_id_position := (length(p_parent_table) - position('p_' in reverse(p_parent_table))) + 2; + v_sub_id_min = substring(p_parent_table from v_id_position)::bigint; + v_sub_id_max = (v_sub_id_min + v_top_interval) - 1; +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; + +IF v_jobmon_schema IS NOT NULL THEN + v_job_id := add_job('PARTMAN CREATE TABLE: '||p_parent_table); +END IF; + +FOREACH v_id IN ARRAY p_partition_ids LOOP +-- Do not create the child table if it's outside the bounds of the top parent. + IF v_sub_id_min IS NOT NULL THEN + IF v_id < v_sub_id_min OR v_id > v_sub_id_max THEN + CONTINUE; + END IF; + END IF; + + 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_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'); + END IF; + + -- Will only loop once and only if sub_partitioning is actually configured + -- This seemed easier than assigning a bunch of variables then doing an IF condition + FOR v_row IN + SELECT sub_parent + , sub_control + , sub_type + , sub_part_interval + , sub_constraint_cols + , sub_premake + , sub_inherit_fk + , sub_retention + , sub_retention_schema + , sub_retention_keep_table + , sub_retention_keep_index + , sub_use_run_maintenance + , sub_jobmon + FROM @extschema@.part_config_sub + WHERE sub_parent = p_parent_table + LOOP + IF v_jobmon_schema IS NOT NULL THEN + v_step_id := add_step(v_job_id, 'Subpartitioning '||v_partition_name); + END IF; + v_sql := format('SELECT @extschema@.create_parent( + p_parent_table := %L + , p_control := %L + , p_type := %L + , p_interval := %L + , p_constraint_cols := %L + , p_premake := %L + , p_use_run_maintenance := %L + , p_inherit_fk := %L + , p_jobmon := %L )' + , v_partition_name + , v_row.sub_control + , v_row.sub_type + , v_row.sub_part_interval + , v_row.sub_constraint_cols + , v_row.sub_premake + , v_row.sub_use_run_maintenance + , v_row.sub_inherit_fk + , v_row.sub_jobmon); + EXECUTE v_sql; + + UPDATE @extschema@.part_config SET + retention_schema = v_row.sub_retention_schema + , retention_keep_table = v_row.sub_retention_keep_table + , retention_keep_index = v_row.sub_retention_keep_index + WHERE parent_table = v_partition_name; + + IF v_jobmon_schema IS NOT NULL THEN + PERFORM update_step(v_step_id, 'OK', 'Done'); + END IF; + + END LOOP; -- end sub partitioning LOOP + + v_partition_created := true; + +END LOOP; + +-- v_analyze is a local check if a new table is made. +-- p_analyze is a parameter to say whether to run the analyze at all. Used by create_parent() to avoid long exclusive lock or run_maintenence() to avoid long creation runs. +IF v_analyze AND p_analyze THEN + IF v_jobmon_schema IS NOT NULL THEN + v_step_id := add_step(v_job_id, 'Analyzing partition set: '||p_parent_table); + END IF; + + EXECUTE 'ANALYZE '||p_parent_table; + + IF v_jobmon_schema IS NOT NULL THEN + PERFORM update_step(v_step_id, 'OK', 'Done'); + END IF; +END IF; + +IF v_jobmon_schema IS NOT NULL THEN + IF v_partition_created = false THEN + v_step_id := add_step(v_job_id, 'No partitions created for partition set: '||p_parent_table); + PERFORM update_step(v_step_id, 'OK', 'Done'); + END IF; + + PERFORM close_job(v_job_id); +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_created; + +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_partition_time (p_parent_table text, p_partition_times timestamp[], p_analyze boolean DEFAULT true) +RETURNS boolean + 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_datetime_string 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_created boolean := false; +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_row record; +v_sql text; +v_step_id bigint; +v_step_overflow_id bigint; +v_sub_timestamp_max timestamp; +v_sub_timestamp_min timestamp; +v_tablename text; +v_time_position int; +v_top_datetime_string text; +v_top_interval interval; +v_top_parent 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 + , datetime_string +INTO v_type + , v_control + , v_part_interval + , v_inherit_fk + , v_jobmon + , v_datetime_string +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; + +-- Check if parent table is a subpartition of an already existing time-based partition set managed by pg_partman +-- If so, limit what child tables can be created based on parent suffix +WITH top_oid AS ( + SELECT i.inhparent AS top_parent_oid + FROM pg_catalog.pg_class c + JOIN pg_catalog.pg_inherits i ON c.oid = i.inhrelid + JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace + WHERE n.nspname||'.'||c.relname = p_parent_table +) SELECT n.nspname||'.'||c.relname, p.datetime_string + INTO v_top_parent, v_top_datetime_string + FROM pg_catalog.pg_class c + JOIN top_oid t ON c.oid = t.top_parent_oid + JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace + JOIN @extschema@.part_config p ON p.parent_table = n.nspname||'.'||c.relname + WHERE c.oid = t.top_parent_oid + AND p.type = 'time-static' OR p.type = 'time-dynamic' OR p.type = 'time-custom'; + +IF v_top_parent IS NOT NULL THEN + + SELECT part_interval::interval INTO v_top_interval FROM @extschema@.part_config WHERE parent_table = v_top_parent; + + v_time_position := (length(p_parent_table) - position('p_' in reverse(p_parent_table))) + 2; + IF v_part_interval::interval <> '3 months' OR (v_part_interval::interval = '3 months' AND v_type = 'time-custom') THEN + v_sub_timestamp_min := to_timestamp(substring(p_parent_table from v_time_position), v_top_datetime_string); + ELSE + -- to_timestamp doesn't recognize 'Q' date string formater. Handle it + v_year := split_part(substring(p_parent_table from v_time_position), 'q', 1); + v_quarter := split_part(substring(p_parent_table from v_time_position), 'q', 2); + CASE + WHEN v_quarter = '1' THEN + v_sub_timestamp_min := to_timestamp(v_year || '-01-01', 'YYYY-MM-DD'); + WHEN v_quarter = '2' THEN + v_sub_timestamp_min := to_timestamp(v_year || '-04-01', 'YYYY-MM-DD'); + WHEN v_quarter = '3' THEN + v_sub_timestamp_min := to_timestamp(v_year || '-07-01', 'YYYY-MM-DD'); + WHEN v_quarter = '4' THEN + v_sub_timestamp_min := to_timestamp(v_year || '-10-01', 'YYYY-MM-DD'); + END CASE; + END IF; + v_sub_timestamp_max = (v_sub_timestamp_min + v_top_interval::interval) - '1 sec'::interval; +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; + +IF v_jobmon_schema IS NOT NULL THEN + v_job_id := add_job('PARTMAN CREATE TABLE: '||p_parent_table); +END IF; + +FOREACH v_time IN ARRAY p_partition_times LOOP + 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; + + -- This suffix generation code is in partition_data_time() as well + 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 + + 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; + + +-- Do not create the child table if it's outside the bounds of the top parent. + IF v_sub_timestamp_min IS NOT NULL THEN + IF v_time < v_sub_timestamp_min OR v_time > v_sub_timestamp_max THEN + CONTINUE; + END IF; + 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_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'); + END IF; + + -- Will only loop once and only if sub_partitioning is actually configured + -- This seemed easier than assigning a bunch of variables then doing an IF condition + FOR v_row IN + SELECT sub_parent + , sub_control + , sub_type + , sub_part_interval + , sub_constraint_cols + , sub_premake + , sub_inherit_fk + , sub_retention + , sub_retention_schema + , sub_retention_keep_table + , sub_retention_keep_index + , sub_use_run_maintenance + , sub_jobmon + FROM @extschema@.part_config_sub + WHERE sub_parent = p_parent_table + LOOP + IF v_jobmon_schema IS NOT NULL THEN + v_step_id := add_step(v_job_id, 'Subpartitioning '||v_partition_name); + END IF; + v_sql := format('SELECT @extschema@.create_parent( + p_parent_table := %L + , p_control := %L + , p_type := %L + , p_interval := %L + , p_constraint_cols := %L + , p_premake := %L + , p_use_run_maintenance := %L + , p_inherit_fk := %L + , p_jobmon := %L )' + , v_partition_name + , v_row.sub_control + , v_row.sub_type + , v_row.sub_part_interval + , v_row.sub_constraint_cols + , v_row.sub_premake + , v_row.sub_use_run_maintenance + , v_row.sub_inherit_fk + , v_row.sub_jobmon); + EXECUTE v_sql; + + UPDATE @extschema@.part_config SET + retention_schema = v_row.sub_retention_schema + , retention_keep_table = v_row.sub_retention_keep_table + , retention_keep_index = v_row.sub_retention_keep_index + WHERE parent_table = v_partition_name; + + END LOOP; -- end sub partitioning LOOP + + v_partition_created := true; + +END LOOP; + +-- v_analyze is a local check if a new table is made. +-- p_analyze is a parameter to say whether to run the analyze at all. Used by create_parent() to avoid long exclusive lock or run_maintenence() to avoid long creation runs. +IF v_analyze AND p_analyze THEN + IF v_jobmon_schema IS NOT NULL THEN + v_step_id := add_step(v_job_id, 'Analyzing partition set: '||p_parent_table); + END IF; + + EXECUTE 'ANALYZE '||p_parent_table; + + IF v_jobmon_schema IS NOT NULL THEN + PERFORM update_step(v_step_id, 'OK', 'Done'); + END IF; +END IF; + +IF v_jobmon_schema IS NOT NULL THEN + IF v_partition_created = false THEN + v_step_id := add_step(v_job_id, 'No partitions created for partition set: '||p_parent_table); + PERFORM update_step(v_step_id, 'OK', 'Done'); + END IF; + + 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; + +IF v_jobmon_schema IS NOT NULL THEN + EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')'; +END IF; + +RETURN v_partition_created; + +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 +$$; + + +