Browse files

v1.2.0 Fixed child table lookup method. Renamed drop functions. See C…

…HANGELOG for more info
  • Loading branch information...
1 parent 0a4e7a2 commit 2eb6c025bb13cbdf8e5cbbbbd754b16a5c78713d @keithf4 committed Mar 20, 2013
View
1 .gitignore
@@ -1 +1,2 @@
ignore/*
+*.swp
View
7 CHANGELOG
@@ -1,3 +1,10 @@
+1.2.0
+-- Bug fix: Make child table lookups more intelligent to be able to deal with schemas being in the current search_path. Functions this affects are: drop_time_partition(), drop_id_partition(), reapply_privileges(), undo_partition(), undo_partition_id(), undo_partition_time(). Before table names may not have matched properly when looping through all tables to drop or reset privileges. Thanks to https://github.com/terrorobe for reporting this issue.
+-- Bug fix: reapply_privileges() had unconditional calls to pg_jobmon functions and would fail if it wasn't installed.
+-- Added new parameter to drop partition functions to manually set an interval you'd like to drop. Makes it easier to cleanup a bunch of old partitions you don't need anymore without having to go through the whole retention policy setup if that's not needed.
+-- Renamed drop_time_partition() to drop_partition_time() and drop_id_partition() to drop_partition_id() to be more consistent with the other function names. Please check function ownership & privileges before and after update to ensure they are reset properly.
+
+
1.1.0
-- New python scripts in extras folder to allow partition creation and undoing using smaller commit batches, as is suggested in the documentation for the partition_data_* and undo_partition_* functions. This helps avoid transaction locks when there is a large amount of data to move around. There are also options to commit more slowly and ease the load on very busy systems.
-- Changed the ordering of batch arguments in partition_data_id() & partition_data_time(). This makes their order the same as the undo functions and is a more sensical order (I think anyway).
View
6 META.json
@@ -1,7 +1,7 @@
{
"name": "pg_partman",
"abstract": "Extension to manage partitioned tables by time or ID",
- "version": "1.1.0",
+ "version": "1.2.0",
"maintainer": [
"Keith Fiske <keith@omniti.com>"
],
@@ -20,9 +20,9 @@
},
"provides": {
"pg_partman": {
- "file": "sql/pg_partman--1.1.0.sql",
+ "file": "sql/pg_partman--1.2.0.sql",
"docfile": "doc/pg_partman.md",
- "version": "1.1.0",
+ "version": "1.2.0",
"abstract": "Extension to manage partitioned tables by time or ID"
}
},
View
2 README.md
@@ -30,7 +30,7 @@ Make sure all the upgrade scripts for the version you have installed up to the m
EXAMPLE
-------
-First create a parent table with an appropriate column type for the partitioning type you will do. Apply all defaults, indexes, constraints, privileges & ownership to the parent table and they will be inherited to newly created child tables automatically (not already existing partitions). Here's one with columns that can be used for either
+First create a parent table with an appropriate column type for the partitioning type you will do. Apply all defaults, indexes, constraints, privileges & ownership to the parent table and they will be inherited to newly created child tables automatically (not already existing partitions, see docs for how to fix that). Here's one with columns that can be used for either
CREATE schema test;
CREATE TABLE test.part_test (col1 serial, col2 text, col3 timestamptz DEFAULT now());
View
29 doc/pg_partman.md
@@ -9,7 +9,7 @@ For this extension, most of the attributes of the child partitions are all obtai
If you attempt to insert data into a partition set that contains data for a partition that does not exist, that data will be placed into the set's parent table. This is preferred over automatically creating new partitions to match that data since a mistake that is causing non-partitioned data to be inserted could cause a lot of unwanted child tables to be made. The check_parent() function provides monitoring for any data getting inserted into parents and the partition_data_* set of functions can easily partition that data for you if it is valid data. That is much easier than having to clean up potentially hundreds or thousands of unwanted partitions. And also better than throwing an error and losing the data!
-If you don't need to keep data in older partitions, a retention system is available to automatically drop unneeded child partitions. By default, they are only uninherited not actually dropped, but that can be configured if desired. If the old partitions are kept, dropping their indexes can also be configured to recover disk space. Note that this will also remove any primary key or unique constraints in order to allow the indexes to be dropped. To set the retention policy, enter either an interval or integer value into the **retention** column of the **part_config** table. For time-based partitioning, the interval value will set that any partitions containing data older than that will be dropped. For id-based partitioning, the integer value will set that any partitions with an id value less than the current maximum id value minus the retention value will be dropped. For example, if the current max id is 100 and the retention value is 30, any partitions with id values less than 70 will be dropped. The current maximum id value at the time the drop function is run is always used.
+If you don't need to keep data in older partitions, a retention system is available to automatically drop unneeded child partitions. By default, they are only uninherited not actually dropped, but that can be configured if desired. If the old partitions are kept, dropping their indexes can also be configured to recover disk space. Note that this will also remove any primary key or unique constraints in order to allow the indexes to be dropped. To set the retention policy, enter either an interval or integer value into the **retention** column of the **part_config** table. For time-based partitioning, the interval value will set that any partitions containing only data older than that will be dropped. For id-based partitioning, the integer value will set that any partitions with an id value less than the current maximum id value minus the retention value will be dropped. For example, if the current max id is 100 and the retention value is 30, any partitions with id values less than 70 will be dropped. The current maximum id value at the time the drop function is run is always used.
The PG Jobmon extension (https://github.com/omniti-labs/pg_jobmon) is optional and allows auditing and monitoring of partition maintenance. If jobmon is installed and configured properly, it will automatically be used by partman with no additional setup needed. By default, any function that fails to run successfully 3 consecutive times will cause jobmon to raise an alert. This is why the default pre-make value is set to 4 so that an alert will be raised in time for intervention with no additional configuration of jobmon needed. You can of course configure jobmon to alert before (or later) than 3 failures if needed. If you're running partman in a production environment it is HIGHLY recommended to have jobmon installed and some sort of 3rd-party monitoring configured with it to alert when partitioning fails (Nagios, Circonus, etc).
@@ -73,18 +73,6 @@ A superuser must be used to run these functions in order to set privileges & own
* Run this function to monitor that the parent tables of the partition sets that pg_partman manages do not get rows inserted to them.
* Returns a row for each parent table along with the number of rows it contains. Returns zero rows if none found.
-*drop_time_partition(p_parent_table text, p_keep_table boolean DEFAULT NULL, p_keep_index boolean DEFAULT NULL)*
- * This function is used to drop child tables from a time-based partition set. By default, the table is just uninherited and not actually dropped. It is recommended to use the **run_maintenance()** function to manage dropping old child tables and not call it directly unless needed.
- * p_parent_table - the existing parent table of a time-based partition set. MUST be schema qualified, even if in public schema.
- * p_keep_table - optional parameter to tell partman whether to keep or drop the table in addition to uninheriting it. TRUE means the table will not actually be dropped; FALSE means the table will be dropped. This function will just use the value configured in **part_config** if not explicitly set.
- * p_keep_index - optional parameter to tell partman whether to keep or drop the indexes of the child table when it is uninherited. TRUE means the indexes will be kept; FALSE means all indexes will be dropped. This function will just use the value configured in **part_config** if not explicitly set. This option is ignored if p_keep_table is set to FALSE.
-
-*drop_id_partition(p_parent_table text, p_keep_table boolean DEFAULT NULL, p_keep_index boolean DEFAULT NULL)*
- * This function is used to drop child tables from an id-based partition set. By default, the table just uninherited and not actually dropped. It is recommended to use the **run_maintenance()** function to manage dropping old child tables and not call it directly unless needed.
- * p_parent_table - the existing parent table of a time-based partition set. MUST be schema qualified, even if in public schema.
- * p_keep_table - optional parameter to tell partman whether to keep or drop the table in addition to uninheriting it. TRUE means the table will not actually be dropped; FALSE means the table will be dropped. This function will just use the value configured in **part_config** if not explicitly set.
- * p_keep_index - optional parameter to tell partman whether to keep or drop the indexes of the child table when it is uninherited. TRUE means the indexes will be kept; FALSE means all indexes will be dropped. This function will just use the value configured in **part_config** if not explicitly set. This option is ignored if p_keep_table is set to FALSE.
-
*reapply_privileges(p_parent_table text)*
* This function is used to reapply ownership & grants on all child tables based on what the parent table has set.
* Privileges that the parent table has will be granted to all child tables and privilges that the parent does not have will be revoked (with CASCADE).
@@ -131,6 +119,21 @@ A superuser must be used to run these functions in order to set privileges & own
* p_keep_table - an optional argument, setting this to false will cause the old child table to be dropped instead of uninherited.
* Returns the number of rows moved to the parent table. Returns zero when child tables are all empty.
+*drop_partition_time(p_parent_table text, p_retention interval DEFAULT NULL, p_keep_table boolean DEFAULT NULL, p_keep_index boolean DEFAULT NULL)*
+ * This function is used to drop child tables from a time-based partition set. By default, the table is just uninherited and not actually dropped. For automatically dropping old tables, it is recommended to use the **run_maintenance()** function with retention configured instead of calling this directly.
+ * p_parent_table - the existing parent table of a time-based partition set. MUST be schema qualified, even if in public schema.
+ * p_retention - optional parameter to give a retention time interval and immediately drop tables containing only data older than the given interval. If you have a retention value set in the config table already, the function will use that, otherwise this will override it. If not, this parameter is required. See the **About** section above for more information on retention settings.
+ * p_keep_table - optional parameter to tell partman whether to keep or drop the table in addition to uninheriting it. TRUE means the table will not actually be dropped; FALSE means the table will be dropped. This function will just use the value configured in **part_config** if not explicitly set.
+ * p_keep_index - optional parameter to tell partman whether to keep or drop the indexes of the child table when it is uninherited. TRUE means the indexes will be kept; FALSE means all indexes will be dropped. This function will just use the value configured in **part_config** if not explicitly set. This option is ignored if p_keep_table is set to FALSE.
+
+*drop_partition_id(p_parent_table text, p_retention interval DEFAULT NULL, p_keep_table boolean DEFAULT NULL, p_keep_index boolean DEFAULT NULL)*
+ * This function is used to drop child tables from an id-based partition set. By default, the table just uninherited and not actually dropped. For automatically dropping old tables, it is recommended to use the **run_maintenance()** function with retention configured instead of calling this directly.
+ * p_parent_table - the existing parent table of a time-based partition set. MUST be schema qualified, even if in public schema.
+ * p_retention - optional parameter to give a retention integer interval and immediately drop tables containing only data older than the given interval. If you have a retention value set in the config table already, the function will use that, otherwise this will override it. If not, this parameter is required. See the **About** section above for more information on retention settings.
+ * p_keep_table - optional parameter to tell partman whether to keep or drop the table in addition to uninheriting it. TRUE means the table will not actually be dropped; FALSE means the table will be dropped. This function will just use the value configured in **part_config** if not explicitly set.
+ * p_keep_index - optional parameter to tell partman whether to keep or drop the indexes of the child table when it is uninherited. TRUE means the indexes will be kept; FALSE means all indexes will be dropped. This function will just use the value configured in **part_config** if not explicitly set. This option is ignored if p_keep_table is set to FALSE.
+
+
Tables
------
*part_config*
View
2 pg_partman.control
@@ -1,3 +1,3 @@
-default_version = '1.1.0'
+default_version = '1.2.0'
comment = 'Extension to manage partitioned tables by time or ID'
relocatable = false
View
76 sql/functions/drop_id_partition.sql → sql/functions/drop_partition_id.sql
@@ -1,7 +1,7 @@
/*
* Function to drop child tables from a time-based partition set. Options to drop indexes or actually drop the table from the database.
*/
-CREATE FUNCTION drop_id_partition(p_parent_table text, p_keep_table boolean DEFAULT NULL, p_keep_index boolean DEFAULT NULL) RETURNS int
+CREATE FUNCTION drop_partition_id(p_parent_table text, p_retention bigint DEFAULT NULL, p_keep_table boolean DEFAULT NULL, p_keep_index boolean DEFAULT NULL) RETURNS int
LANGUAGE plpgsql SECURITY DEFINER
AS $$
DECLARE
@@ -24,9 +24,9 @@ v_step_id bigint;
BEGIN
-v_adv_lock := pg_try_advisory_lock(hashtext('pg_partman drop_id_partition'));
+v_adv_lock := pg_try_advisory_lock(hashtext('pg_partman drop_partition_id'));
IF v_adv_lock = 'false' THEN
- RAISE NOTICE 'drop_id_partition already running.';
+ RAISE NOTICE 'drop_partition_id already running.';
RETURN 0;
END IF;
@@ -36,28 +36,50 @@ IF v_jobmon_schema IS NOT NULL THEN
EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
END IF;
-SELECT
- part_interval::bigint
- , control
- , retention::bigint
- , retention_keep_table
- , retention_keep_index
-INTO
- v_part_interval
- , v_control
- , v_retention
- , v_retention_keep_table
- , v_retention_keep_index
-FROM @extschema@.part_config
-WHERE parent_table = p_parent_table
-AND (type = 'id-static' OR type = 'id-dynamic')
-AND retention IS NOT NULL;
-
-IF v_part_interval IS NULL THEN
- RAISE EXCEPTION 'Configuration for given parent table not found: %', p_parent_table;
+
+-- Allow override of configuration options
+IF p_retention IS NULL THEN
+ SELECT
+ part_interval::bigint
+ , control
+ , retention::bigint
+ , retention_keep_table
+ , retention_keep_index
+ INTO
+ v_part_interval
+ , v_control
+ , v_retention
+ , v_retention_keep_table
+ , v_retention_keep_index
+ FROM @extschema@.part_config
+ WHERE parent_table = p_parent_table
+ AND (type = 'id-static' OR type = 'id-dynamic')
+ 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
+ part_interval::bigint
+ , control
+ , retention_keep_table
+ , retention_keep_index
+ INTO
+ v_part_interval
+ , v_control
+ , v_retention_keep_table
+ , v_retention_keep_index
+ FROM @extschema@.part_config
+ WHERE parent_table = p_parent_table
+ AND (type = 'id-static' OR type = 'id-dynamic');
+ 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;
--- Allow override of keeping tables or indexes from input parameters
IF p_keep_table IS NOT NULL THEN
v_retention_keep_table = p_keep_table;
END IF;
@@ -73,7 +95,7 @@ EXECUTE 'SELECT max('||v_control||') FROM '||p_parent_table INTO v_max;
-- Loop through child tables of the given parent
FOR v_child_table IN
- SELECT inhrelid::regclass FROM pg_catalog.pg_inherits WHERE inhparent::regclass = p_parent_table::regclass ORDER BY inhrelid::regclass ASC
+ 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
v_partition_id := substring(v_child_table from char_length(p_parent_table||'_p')+1)::bigint;
@@ -127,13 +149,13 @@ IF v_jobmon_schema IS NOT NULL THEN
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;
-PERFORM pg_advisory_unlock(hashtext('pg_partman drop_id_partition'));
+PERFORM pg_advisory_unlock(hashtext('pg_partman drop_partition_id'));
RETURN v_drop_count;
EXCEPTION
WHEN QUERY_CANCELED THEN
- PERFORM pg_advisory_unlock(hashtext('pg_partman drop_id_partition'));
+ PERFORM pg_advisory_unlock(hashtext('pg_partman drop_partition_id'));
RAISE EXCEPTION '%', SQLERRM;
WHEN OTHERS THEN
IF v_jobmon_schema IS NOT NULL THEN
@@ -149,7 +171,7 @@ EXCEPTION
PERFORM fail_job(v_job_id);
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;
- PERFORM pg_advisory_unlock(hashtext('pg_partman drop_id_partition'));
+ PERFORM pg_advisory_unlock(hashtext('pg_partman drop_partition_id'));
RAISE EXCEPTION '%', SQLERRM;
END
$$;
View
75 sql/functions/drop_time_partition.sql → sql/functions/drop_partition_time.sql
@@ -1,7 +1,7 @@
/*
* Function to drop child tables from a time-based partition set. Options to drop indexes or actually drop the table from the database.
*/
-CREATE FUNCTION drop_time_partition(p_parent_table text, p_keep_table boolean DEFAULT NULL, p_keep_index boolean DEFAULT NULL) RETURNS int
+CREATE 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) RETURNS int
LANGUAGE plpgsql SECURITY DEFINER
AS $$
DECLARE
@@ -25,9 +25,9 @@ v_year text;
BEGIN
-v_adv_lock := pg_try_advisory_lock(hashtext('pg_partman drop_time_partition'));
+v_adv_lock := pg_try_advisory_lock(hashtext('pg_partman drop_partition_time'));
IF v_adv_lock = 'false' THEN
- RAISE NOTICE 'drop_time_partition already running.';
+ RAISE NOTICE 'drop_partition_time already running.';
RETURN 0;
END IF;
@@ -37,28 +37,49 @@ IF v_jobmon_schema IS NOT NULL THEN
EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
END IF;
-SELECT
- part_interval::interval
- , retention::interval
- , retention_keep_table
- , retention_keep_index
- , datetime_string
-INTO
- v_part_interval
- , v_retention
- , v_retention_keep_table
- , v_retention_keep_index
- , v_datetime_string
-FROM @extschema@.part_config
-WHERE parent_table = p_parent_table
-AND (type = 'time-static' OR type = 'time-dynamic')
-AND retention IS NOT NULL;
-
-IF v_part_interval IS NULL THEN
- RAISE EXCEPTION 'Configuration for given parent table not found: %', p_parent_table;
+-- Allow override of configuration options
+IF p_retention IS NULL THEN
+ SELECT
+ part_interval::interval
+ , retention::interval
+ , retention_keep_table
+ , retention_keep_index
+ , datetime_string
+ INTO
+ v_part_interval
+ , v_retention
+ , v_retention_keep_table
+ , v_retention_keep_index
+ , v_datetime_string
+ FROM @extschema@.part_config
+ WHERE parent_table = p_parent_table
+ AND (type = 'time-static' OR type = 'time-dynamic')
+ 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
+ part_interval::interval
+ , retention_keep_table
+ , retention_keep_index
+ , datetime_string
+ INTO
+ v_part_interval
+ , v_retention_keep_table
+ , v_retention_keep_index
+ , v_datetime_string
+ FROM @extschema@.part_config
+ WHERE parent_table = p_parent_table
+ AND (type = 'time-static' OR type = 'time-dynamic');
+ 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;
--- Allow override of keeping tables or indexes from input parameters
IF p_keep_table IS NOT NULL THEN
v_retention_keep_table = p_keep_table;
END IF;
@@ -72,7 +93,7 @@ END IF;
-- Loop through child tables of the given parent
FOR v_child_table IN
- SELECT inhrelid::regclass FROM pg_catalog.pg_inherits WHERE inhparent::regclass = p_parent_table::regclass ORDER BY inhrelid::regclass ASC
+ 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 last partition's tablename to make the next one
IF v_part_interval != '3 months' THEN
@@ -143,13 +164,13 @@ IF v_jobmon_schema IS NOT NULL THEN
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;
-PERFORM pg_advisory_unlock(hashtext('pg_partman drop_time_partition'));
+PERFORM pg_advisory_unlock(hashtext('pg_partman drop_partition_time'));
RETURN v_drop_count;
EXCEPTION
WHEN QUERY_CANCELED THEN
- PERFORM pg_advisory_unlock(hashtext('pg_partman drop_time_partition'));
+ PERFORM pg_advisory_unlock(hashtext('pg_partman drop_partition_time'));
RAISE EXCEPTION '%', SQLERRM;
WHEN OTHERS THEN
IF v_jobmon_schema IS NOT NULL THEN
@@ -165,7 +186,7 @@ EXCEPTION
PERFORM fail_job(v_job_id);
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;
- PERFORM pg_advisory_unlock(hashtext('pg_partman drop_time_partition'));
+ PERFORM pg_advisory_unlock(hashtext('pg_partman drop_partition_time'));
RAISE EXCEPTION '%', SQLERRM;
END
$$;
View
6 sql/functions/reapply_privileges.sql
@@ -45,9 +45,11 @@ END IF;
SELECT tableowner INTO v_parent_owner FROM pg_tables WHERE schemaname ||'.'|| tablename = p_parent_table;
FOR v_child_table IN
- SELECT inhrelid::regclass FROM pg_catalog.pg_inherits WHERE inhparent::regclass = p_parent_table::regclass ORDER BY inhrelid::regclass ASC
+ 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
- PERFORM update_step(v_step_id, 'PENDING', 'Currently on child partition in ascending order: '||v_child_table);
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'PENDING', 'Currently on child partition in ascending order: '||v_child_table);
+ END IF;
v_grantees := NULL;
FOR v_parent_grant IN
SELECT array_agg(DISTINCT privilege_type::text ORDER BY privilege_type::text) AS types, grantee
View
4 sql/functions/run_maintenance.sql
@@ -114,12 +114,12 @@ END LOOP; -- end of creation loop
FOR v_row IN
SELECT parent_table FROM @extschema@.part_config WHERE retention IS NOT NULL AND undo_in_progress = false AND (type = 'time-static' OR type = 'time-dynamic')
LOOP
- v_drop_count := v_drop_count + @extschema@.drop_time_partition(v_row.parent_table);
+ v_drop_count := v_drop_count + @extschema@.drop_partition_time(v_row.parent_table);
END LOOP;
FOR v_row IN
SELECT parent_table FROM @extschema@.part_config WHERE retention IS NOT NULL AND undo_in_progress = false AND (type = 'id-static' OR type = 'id-dynamic')
LOOP
- v_drop_count := v_drop_count + @extschema@.drop_id_partition(v_row.parent_table);
+ v_drop_count := v_drop_count + @extschema@.drop_partition_id(v_row.parent_table);
END LOOP;
IF v_jobmon_schema IS NOT NULL THEN
View
10 sql/functions/undo_partition.sql
@@ -53,10 +53,12 @@ IF v_jobmon_schema IS NOT NULL THEN
END IF;
WHILE v_batch_loop_count < p_batch_count LOOP
- SELECT inhrelid::regclass INTO v_child_table
- FROM pg_catalog.pg_inherits
- WHERE inhparent::regclass = p_parent_table::regclass
- ORDER BY inhrelid ASC;
+ 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;
View
10 sql/functions/undo_partition_id.sql
@@ -73,10 +73,12 @@ END IF;
<<outer_child_loop>>
WHILE v_batch_loop_count < p_batch_count LOOP
- SELECT inhrelid::regclass INTO v_child_table
- FROM pg_catalog.pg_inherits
- WHERE inhparent::regclass = p_parent_table::regclass
- ORDER BY inhrelid ASC;
+ 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;
View
10 sql/functions/undo_partition_time.sql
@@ -73,10 +73,12 @@ END IF;
<<outer_child_loop>>
WHILE v_batch_loop_count < p_batch_count LOOP
- SELECT inhrelid::regclass INTO v_child_table
- FROM pg_catalog.pg_inherits
- WHERE inhparent::regclass = p_parent_table::regclass
- ORDER BY inhrelid ASC;
+ 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;
View
1,154 updates/pg_partman--1.1.0--1.2.0.sql
@@ -0,0 +1,1154 @@
+-- Bug fix: Make child table lookups more intelligent to be able to deal with schemas being in the current search_path. Functions this affects are: drop_time_partition(), drop_id_partition(), reapply_privileges(), undo_partition(), undo_partition_id(), undo_partition_time(). Before table names may not have matched properly when looping through all tables to drop or reset privileges. Thanks to https://github.com/terrorobe for reporting this issue.
+-- Bug fix: reapply_privileges() had unconditional calls to pg_jobmon functions and would fail if it wasn't installed.
+-- Added new parameter to drop partition functions to manually set an interval you'd like to drop. Makes it easier to cleanup a bunch of old partitions you don't need anymore without having to go through the whole retention policy setup if that's not needed.
+-- Renamed drop_time_partition() to drop_partition_time() and drop_id_partition() to drop_partition_id() to be more consistent with the other function names. Please check function ownership & privileges before and after update to ensure they are reset properly.
+
+DROP FUNCTION @extschema@.drop_time_partition(text, boolean, boolean);
+DROP FUNCTION @extschema@.drop_id_partition(text, boolean, boolean);
+
+/*
+ * Function to drop child tables from a time-based partition set. Options to drop indexes or actually drop the table from the database.
+ */
+CREATE 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) 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_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_step_id bigint;
+v_year text;
+
+BEGIN
+
+v_adv_lock := pg_try_advisory_lock(hashtext('pg_partman drop_partition_time'));
+IF v_adv_lock = 'false' THEN
+ RAISE NOTICE 'drop_partition_time already running.';
+ RETURN 0;
+END IF;
+
+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;
+
+-- Allow override of configuration options
+IF p_retention IS NULL THEN
+ SELECT
+ part_interval::interval
+ , retention::interval
+ , retention_keep_table
+ , retention_keep_index
+ , datetime_string
+ INTO
+ v_part_interval
+ , v_retention
+ , v_retention_keep_table
+ , v_retention_keep_index
+ , v_datetime_string
+ FROM @extschema@.part_config
+ WHERE parent_table = p_parent_table
+ AND (type = 'time-static' OR type = 'time-dynamic')
+ 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
+ part_interval::interval
+ , retention_keep_table
+ , retention_keep_index
+ , datetime_string
+ INTO
+ v_part_interval
+ , v_retention_keep_table
+ , v_retention_keep_index
+ , v_datetime_string
+ FROM @extschema@.part_config
+ WHERE parent_table = p_parent_table
+ AND (type = 'time-static' OR type = 'time-dynamic');
+ 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 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 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 last partition's tablename to make the next one
+ IF v_part_interval != '3 months' THEN
+ v_partition_timestamp := to_timestamp(substring(v_child_table from char_length(p_parent_table||'_p')+1), v_datetime_string);
+ ELSE
+ -- to_timestamp doesn't recognize 'Q' date string formater. Handle it
+ v_year := split_part(substring(v_child_table from char_length(p_parent_table||'_p')+1), 'q', 1);
+ v_quarter := split_part(substring(v_child_table from char_length(p_parent_table||'_p')+1), '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;
+ 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_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;
+ 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;
+ 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;
+
+PERFORM pg_advisory_unlock(hashtext('pg_partman drop_partition_time'));
+
+RETURN v_drop_count;
+
+EXCEPTION
+ WHEN QUERY_CANCELED THEN
+ PERFORM pg_advisory_unlock(hashtext('pg_partman drop_partition_time'));
+ RAISE EXCEPTION '%', SQLERRM;
+ WHEN OTHERS THEN
+ IF v_jobmon_schema IS NOT NULL THEN
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+ IF v_job_id IS NULL THEN
+ v_job_id := add_job('PARTMAN DROP TIME PARTITION');
+ v_step_id := add_step(v_job_id, 'EXCEPTION before job logging started');
+ END IF;
+ IF v_step_id IS NULL THEN
+ v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
+ END IF;
+ PERFORM update_step(v_step_id, 'CRITICAL', 'ERROR: '||coalesce(SQLERRM,'unknown'));
+ PERFORM fail_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+ END IF;
+ PERFORM pg_advisory_unlock(hashtext('pg_partman drop_partition_time'));
+ RAISE EXCEPTION '%', SQLERRM;
+END
+$$;
+
+
+/*
+ * Function to drop child tables from a time-based partition set. Options to drop indexes or actually drop the table from the database.
+ */
+CREATE FUNCTION drop_partition_id(p_parent_table text, p_retention bigint DEFAULT NULL, p_keep_table boolean DEFAULT NULL, p_keep_index boolean DEFAULT NULL) RETURNS int
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_adv_lock boolean;
+v_child_table text;
+v_control text;
+v_drop_count int := 0;
+v_index record;
+v_job_id bigint;
+v_jobmon_schema text;
+v_max bigint;
+v_old_search_path text;
+v_part_interval bigint;
+v_partition_id bigint;
+v_retention bigint;
+v_retention_keep_index boolean;
+v_retention_keep_table boolean;
+v_step_id bigint;
+
+BEGIN
+
+v_adv_lock := pg_try_advisory_lock(hashtext('pg_partman drop_partition_id'));
+IF v_adv_lock = 'false' THEN
+ RAISE NOTICE 'drop_partition_id already running.';
+ RETURN 0;
+END IF;
+
+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;
+
+
+-- Allow override of configuration options
+IF p_retention IS NULL THEN
+ SELECT
+ part_interval::bigint
+ , control
+ , retention::bigint
+ , retention_keep_table
+ , retention_keep_index
+ INTO
+ v_part_interval
+ , v_control
+ , v_retention
+ , v_retention_keep_table
+ , v_retention_keep_index
+ FROM @extschema@.part_config
+ WHERE parent_table = p_parent_table
+ AND (type = 'id-static' OR type = 'id-dynamic')
+ 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
+ part_interval::bigint
+ , control
+ , retention_keep_table
+ , retention_keep_index
+ INTO
+ v_part_interval
+ , v_control
+ , v_retention_keep_table
+ , v_retention_keep_index
+ FROM @extschema@.part_config
+ WHERE parent_table = p_parent_table
+ AND (type = 'id-static' OR type = 'id-dynamic');
+ 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 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 v_jobmon_schema IS NOT NULL THEN
+ v_job_id := add_job('PARTMAN DROP ID PARTITION: '|| p_parent_table);
+END IF;
+
+EXECUTE 'SELECT max('||v_control||') FROM '||p_parent_table INTO v_max;
+
+-- 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
+ v_partition_id := substring(v_child_table from char_length(p_parent_table||'_p')+1)::bigint;
+
+ -- Add one interval since partition names contain the start of the constraint period
+ IF v_retention <= (v_max - (v_partition_id + 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;
+ 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_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;
+ 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;
+ 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;
+
+PERFORM pg_advisory_unlock(hashtext('pg_partman drop_partition_id'));
+
+RETURN v_drop_count;
+
+EXCEPTION
+ WHEN QUERY_CANCELED THEN
+ PERFORM pg_advisory_unlock(hashtext('pg_partman drop_partition_id'));
+ RAISE EXCEPTION '%', SQLERRM;
+ WHEN OTHERS THEN
+ IF v_jobmon_schema IS NOT NULL THEN
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+ IF v_job_id IS NULL THEN
+ v_job_id := add_job('PARTMAN DROP ID PARTITION');
+ v_step_id := add_step(v_job_id, 'EXCEPTION before job logging started');
+ END IF;
+ IF v_step_id IS NULL THEN
+ v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
+ END IF;
+ PERFORM update_step(v_step_id, 'CRITICAL', 'ERROR: '||coalesce(SQLERRM,'unknown'));
+ PERFORM fail_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+ END IF;
+ PERFORM pg_advisory_unlock(hashtext('pg_partman drop_partition_id'));
+ RAISE EXCEPTION '%', SQLERRM;
+END
+$$;
+
+
+/*
+ * Function to re-apply ownership & privileges on all child tables in a partition set using parent table as reference
+ */
+CREATE OR REPLACE FUNCTION reapply_privileges(p_parent_table text) RETURNS void
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_all text[] := ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'];
+v_child_owner text;
+v_child_table text;
+v_child_grant record;
+v_count int;
+v_grant text;
+v_grantees text[];
+v_job_id bigint;
+v_jobmon_schema text;
+v_match boolean;
+v_old_search_path text;
+v_parent_owner text;
+v_owner_sql text;
+v_revoke text[];
+v_parent_grant record;
+v_sql text;
+v_step_id bigint;
+
+BEGIN
+
+SELECT count(*) INTO v_count FROM @extschema@.part_config WHERE parent_table = p_parent_table;
+IF v_count = 0 THEN
+ RAISE EXCEPTION 'Given table is not managed by this extention: %', p_parent_table;
+END IF;
+
+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;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ v_job_id := add_job('PARTMAN RE-APPLYING PRIVILEGES TO ALL CHILD TABLES OF: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Setting new child table privileges');
+END IF;
+
+SELECT tableowner INTO v_parent_owner FROM pg_tables WHERE schemaname ||'.'|| tablename = p_parent_table;
+
+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
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'PENDING', 'Currently on child partition in ascending order: '||v_child_table);
+ END IF;
+ v_grantees := NULL;
+ 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
+ -- Compare parent & child grants. Don't re-apply if it already exists
+ v_match := false;
+ FOR v_child_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 = v_child_table
+ GROUP BY grantee
+ LOOP
+ IF v_parent_grant.types = v_child_grant.types AND v_parent_grant.grantee = v_child_grant.grantee THEN
+ v_match := true;
+ END IF;
+ END LOOP;
+
+ IF v_match = false THEN
+ EXECUTE 'GRANT '||array_to_string(v_parent_grant.types, ',')||' ON '||v_child_table||' 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_child_table||' FROM '||v_parent_grant.grantee||' CASCADE';
+ END IF;
+ 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_child_table
+ EXCEPT
+ SELECT unnest(v_grantees)) x;
+ IF v_revoke IS NOT NULL THEN
+ EXECUTE 'REVOKE ALL ON '||v_child_table||' FROM '||array_to_string(v_revoke, ',');
+ END IF;
+ END IF;
+
+ SELECT tableowner INTO v_child_owner FROM pg_tables WHERE schemaname ||'.'|| tablename = v_child_table;
+ IF v_parent_owner <> v_child_owner THEN
+ EXECUTE 'ALTER TABLE '||v_child_table||' OWNER TO '||v_parent_owner;
+ END IF;
+
+END LOOP;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Done');
+ 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;
+
+EXCEPTION
+ WHEN OTHERS THEN
+ IF v_jobmon_schema IS NOT NULL THEN
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+ IF v_job_id IS NULL THEN
+ v_job_id := add_job('PARTMAN CREATE TABLE: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Partition maintenance for table '||p_parent_table||' failed');
+ ELSIF v_step_id IS NULL THEN
+ v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
+ END IF;
+ PERFORM update_step(v_step_id, 'BAD', 'ERROR: '||coalesce(SQLERRM,'unknown'));
+ PERFORM fail_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+ END IF;
+ RAISE EXCEPTION '%', SQLERRM;
+END
+$$;
+
+
+/*
+ * Function to undo partitioning.
+ * Will actually work on any parent/child table set, not just ones created by pg_partman.
+ */
+CREATE OR REPLACE FUNCTION undo_partition(p_parent_table text, p_batch_count int DEFAULT 1, p_keep_table boolean DEFAULT true) RETURNS bigint
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_adv_lock boolean;
+v_batch_loop_count bigint := 0;
+v_child_count bigint;
+v_child_table text;
+v_copy_sql text;
+v_job_id bigint;
+v_jobmon_schema text;
+v_old_search_path text;
+v_part_interval interval;
+v_rowcount bigint;
+v_step_id bigint;
+v_tablename text;
+v_total bigint := 0;
+v_undo_count int := 0;
+
+BEGIN
+
+v_adv_lock := pg_try_advisory_lock(hashtext('pg_partman undo_partition'));
+IF v_adv_lock = 'false' THEN
+ RAISE NOTICE 'undo_partition already running.';
+ RETURN 0;
+END IF;
+
+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;
+
+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;
+
+-- 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 and stop new id partitions from being made.
+v_tablename := substring(p_parent_table from position('.' in p_parent_table)+1);
+EXECUTE 'DROP TRIGGER IF EXISTS '||v_tablename||'_part_trig ON '||p_parent_table;
+EXECUTE 'DROP FUNCTION IF EXISTS '||p_parent_table||'_part_trig_func()';
+
+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;
+
+ EXECUTE 'SELECT count(*) FROM '||v_child_table INTO v_child_count;
+ IF v_child_count = 0 THEN
+ -- No rows left in this child table. Remove from partition set.
+ 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 '||coalesce(v_rowcount, 0)||' 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. Copied '||coalesce(v_rowcount, 0)||' rows to parent');
+ END IF;
+ END IF;
+ v_undo_count := v_undo_count + 1;
+ CONTINUE;
+ END IF;
+
+ IF v_jobmon_schema IS NOT NULL THEN
+ v_step_id := add_step(v_job_id, 'Removing child partition: '||v_child_table);
+ END IF;
+
+ v_copy_sql := 'INSERT INTO '||p_parent_table||' SELECT * FROM '||v_child_table;
+ EXECUTE v_copy_sql;
+ GET DIAGNOSTICS v_rowcount = ROW_COUNT;
+ v_total := v_total + v_rowcount;
+
+ 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_rowcount||' 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. Copied '||v_rowcount||' rows to parent');
+ END IF;
+ END IF;
+ v_batch_loop_count := v_batch_loop_count + 1;
+ v_undo_count := v_undo_count + 1;
+END LOOP;
+
+IF v_undo_count = 0 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 (if it existed)');
+ PERFORM update_step(v_step_id, 'OK', 'Done');
+ END IF;
+END IF;
+
+RAISE NOTICE 'Copied % row(s) from % child table(s) to the parent: %', v_total, v_undo_count, p_parent_table;
+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) from '||v_undo_count||' child table(s) to the parent');
+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;
+
+PERFORM pg_advisory_unlock(hashtext('pg_partman undo_partition'));
+
+RETURN v_total;
+
+EXCEPTION
+ WHEN OTHERS THEN
+ IF v_jobmon_schema IS NOT NULL THEN
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+ IF v_job_id IS NULL THEN
+ v_job_id := add_job('PARTMAN UNDO PARTITIONING: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Partition function maintenance for table '||p_parent_table||' failed');
+ ELSIF v_step_id IS NULL THEN
+ v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
+ END IF;
+ PERFORM update_step(v_step_id, 'CRITICAL', 'ERROR: '||coalesce(SQLERRM,'unknown'));
+ PERFORM fail_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+ END IF;
+ RAISE EXCEPTION '%', SQLERRM;
+END
+$$;
+
+
+/*
+ * Function to undo id-based partitioning created by this extension
+ */
+CREATE OR REPLACE FUNCTION undo_partition_id(p_parent_table text, p_batch_count int DEFAULT 1, p_batch_interval bigint DEFAULT NULL, p_keep_table boolean DEFAULT true) RETURNS bigint
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_adv_lock boolean;
+v_batch_loop_count int := 0;
+v_child_loop_total bigint := 0;
+v_child_min bigint;
+v_child_table text;
+v_control text;
+v_inner_loop_count int;
+v_job_id bigint;
+v_jobmon_schema text;
+v_move_sql text;
+v_old_search_path text;
+v_part_interval bigint;
+v_row record;
+v_rowcount bigint;
+v_step_id bigint;
+v_tablename text;
+v_total bigint := 0;
+v_undo_count int := 0;
+
+BEGIN
+
+v_adv_lock := pg_try_advisory_lock(hashtext('pg_partman undo_id_partition'));
+IF v_adv_lock = 'false' THEN
+ RAISE NOTICE 'undo_id_partition already running.';
+ RETURN 0;
+END IF;
+
+SELECT part_interval::bigint
+ , control
+INTO v_part_interval
+ , v_control
+FROM @extschema@.part_config
+WHERE parent_table = p_parent_table
+AND (type = 'id-static' OR type = 'id-dynamic');
+
+IF v_part_interval IS NULL THEN
+ RAISE EXCEPTION 'Configuration for given parent table not found: %', p_parent_table;
+END IF;
+
+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;
+
+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 and stop new id partitions from being made.
+v_tablename := substring(p_parent_table from position('.' in p_parent_table)+1);
+EXECUTE 'DROP TRIGGER IF EXISTS '||v_tablename||'_part_trig ON '||p_parent_table;
+EXECUTE 'DROP FUNCTION IF EXISTS '||p_parent_table||'_part_trig_func()';
+
+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;
+
+<<outer_child_loop>>
+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.
+ 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;
+ v_undo_count := v_undo_count + 1;
+ CONTINUE outer_child_loop;
+ END IF;
+ v_inner_loop_count := 1;
+ v_child_loop_total := 0;
+ <<inner_child_loop>>
+ LOOP
+ -- 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;
+
+PERFORM pg_advisory_unlock(hashtext('pg_partman undo_id_partition'));
+
+RETURN v_total;
+
+EXCEPTION
+ WHEN OTHERS THEN
+ IF v_jobmon_schema IS NOT NULL THEN
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+ IF v_job_id IS NULL THEN
+ v_job_id := add_job('PARTMAN UNDO PARTITIONING: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Partition function maintenance for table '||p_parent_table||' failed');
+ ELSIF v_step_id IS NULL THEN
+ v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
+ END IF;
+ PERFORM update_step(v_step_id, 'CRITICAL', 'ERROR: '||coalesce(SQLERRM,'unknown'));
+ PERFORM fail_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+ END IF;
+ RAISE EXCEPTION '%', SQLERRM;
+END
+$$;
+
+
+/*
+ * 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) 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_inner_loop_count int;
+v_job_id bigint;
+v_jobmon_schema text;
+v_move_sql text;
+v_old_search_path text;
+v_part_interval interval;
+v_row record;
+v_rowcount bigint;
+v_step_id bigint;
+v_tablename text;
+v_total bigint := 0;
+v_undo_count int := 0;
+
+BEGIN
+
+v_adv_lock := pg_try_advisory_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 part_interval::interval
+ , control
+INTO v_part_interval
+ , v_control
+FROM @extschema@.part_config
+WHERE parent_table = p_parent_table
+AND (type = 'time-static' OR type = 'time-dynamic');
+
+IF v_part_interval IS NULL THEN
+ RAISE EXCEPTION 'Configuration for given parent table not found: %', p_parent_table;
+END IF;
+
+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;
+
+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 and stop new id partitions from being made.
+v_tablename := substring(p_parent_table from position('.' in p_parent_table)+1);
+EXECUTE 'DROP TRIGGER IF EXISTS '||v_tablename||'_part_trig ON '||p_parent_table;
+EXECUTE 'DROP FUNCTION IF EXISTS '||p_parent_table||'_part_trig_func()';
+
+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;
+
+<<outer_child_loop>>
+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.
+ 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;
+ v_undo_count := v_undo_count + 1;
+ CONTINUE outer_child_loop;
+ END IF;
+ v_inner_loop_count := 1;
+ v_child_loop_total := 0;
+ <<inner_child_loop>>
+ LOOP
+ -- 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;
+
+PERFORM pg_advisory_unlock(hashtext('pg_partman undo_time_partition'));
+
+RETURN v_total;
+
+EXCEPTION
+ WHEN OTHERS THEN
+ IF v_jobmon_schema IS NOT NULL THEN
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+ IF v_job_id IS NULL THEN
+ v_job_id := add_job('PARTMAN UNDO PARTITIONING: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Partition function maintenance for table '||p_parent_table||' failed');
+ ELSIF v_step_id IS NULL THEN
+ v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
+ END IF;
+ PERFORM update_step(v_step_id, 'CRITICAL', 'ERROR: '||coalesce(SQLERRM,'unknown'));
+ PERFORM fail_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+ END IF;
+ RAISE EXCEPTION '%', SQLERRM;
+END
+$$;
+
+
+/*
+ * Function to manage pre-creation of the next partitions in a time-based partition set.
+ * Also manages dropping old partitions if the retention option is set.
+ */
+CREATE OR REPLACE FUNCTION run_maintenance() RETURNS void
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_adv_lock boolean;
+v_create_count int := 0;
+v_current_partition_timestamp timestamp;
+v_datetime_string text;
+v_drop_count int := 0;
+v_job_id bigint;
+v_jobmon_schema text;
+v_last_partition_timestamp timestamp;
+v_old_search_path text;
+v_premade_count real;
+v_quarter text;
+v_step_id bigint;
+v_row record;
+v_year text;
+
+BEGIN
+
+v_adv_lock := pg_try_advisory_lock(hashtext('pg_partman run_maintenance'));
+IF v_adv_lock = 'false' THEN
+ RAISE NOTICE 'Partman maintenance already running.';
+ RETURN;
+END IF;
+
+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;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ v_job_id := add_job('PARTMAN RUN MAINTENANCE');
+ v_step_id := add_step(v_job_id, 'Running maintenance loop');
+END IF;
+
+FOR v_row IN
+SELECT parent_table
+ , type
+ , part_interval::interval
+ , control
+ , premake
+ , datetime_string
+ , last_partition
+ , undo_in_progress
+FROM @extschema@.part_config WHERE type = 'time-static' OR type = 'time-dynamic'
+LOOP
+
+ CONTINUE WHEN v_row.undo_in_progress;
+
+ CASE
+ WHEN v_row.part_interval = '15 mins' THEN
+ v_current_partition_timestamp := date_trunc('hour', CURRENT_TIMESTAMP) +
+ '15min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 15.0);
+ WHEN v_row.part_interval = '30 mins' THEN
+ v_current_partition_timestamp := date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0);
+ WHEN v_row.part_interval = '1 hour' THEN
+ v_current_partition_timestamp := date_trunc('hour', CURRENT_TIMESTAMP);
+ WHEN v_row.part_interval = '1 day' THEN
+ v_current_partition_timestamp := date_trunc('day', CURRENT_TIMESTAMP);
+ WHEN v_row.part_interval = '1 week' THEN
+ v_current_partition_timestamp := date_trunc('week', CURRENT_TIMESTAMP);
+ WHEN v_row.part_interval = '1 month' THEN
+ v_current_partition_timestamp := date_trunc('month', CURRENT_TIMESTAMP);
+ WHEN v_row.part_interval = '3 months' THEN
+ v_current_partition_timestamp := date_trunc('quarter', CURRENT_TIMESTAMP);
+ WHEN v_row.part_interval = '1 year' THEN
+ v_current_partition_timestamp := date_trunc('year', CURRENT_TIMESTAMP);
+ END CASE;
+
+ IF v_row.part_interval != '3 months' THEN
+ v_last_partition_timestamp := to_timestamp(substring(v_row.last_partition from char_length(v_row.parent_table||'_p')+1), v_row.datetime_string);
+ ELSE
+ -- to_timestamp doesn't recognize 'Q' date string formater. Handle it
+ v_year := split_part(substring(v_row.last_partition from char_length(v_row.parent_table||'_p')+1), 'q', 1);
+ v_quarter := split_part(substring(v_row.last_partition from char_length(v_row.parent_table||'_p')+1), 'q', 2);
+ CASE
+ WHEN v_quarter = '1' THEN
+ v_last_partition_timestamp := to_timestamp(v_year || '-01-01', 'YYYY-MM-DD');
+ WHEN v_quarter = '2' THEN
+ v_last_partition_timestamp := to_timestamp(v_year || '-04-01', 'YYYY-MM-DD');
+ WHEN v_quarter = '3' THEN
+ v_last_partition_timestamp := to_timestamp(v_year || '-07-01', 'YYYY-MM-DD');
+ WHEN v_quarter = '4' THEN
+ v_last_partition_timestamp := to_timestamp(v_year || '-10-01', 'YYYY-MM-DD');
+ END CASE;
+ END IF;
+
+ -- Check and see how many premade partitions there are. If it's less than premake in config table, make another
+ v_premade_count = EXTRACT('epoch' FROM age(v_last_partition_timestamp, v_current_partition_timestamp)) / EXTRACT('epoch' FROM v_row.part_interval::interval);
+
+ -- Loop premaking until config setting is met. Allows it to catch up if it fell behind or if premake changed.
+ WHILE v_premade_count < v_row.premake LOOP
+ EXECUTE 'SELECT @extschema@.create_next_time_partition('||quote_literal(v_row.parent_table)||')';
+ v_create_count := v_create_count + 1;
+ IF v_row.type = 'time-static' THEN
+ EXECUTE 'SELECT @extschema@.create_time_function('||quote_literal(v_row.parent_table)||')';
+ END IF;
+ v_last_partition_timestamp := v_last_partition_timestamp + v_row.part_interval;
+ v_premade_count = EXTRACT('epoch' FROM age(v_last_partition_timestamp, v_current_partition_timestamp)) / EXTRACT('epoch' FROM v_row.part_interval::interval);
+ END LOOP;
+
+END LOOP; -- end of creation loop
+
+-- Manage dropping old partitions if retention option is set
+FOR v_row IN
+ SELECT parent_table FROM @extschema@.part_config WHERE retention IS NOT NULL AND undo_in_progress = false AND (type = 'time-static' OR type = 'time-dynamic')
+LOOP
+ v_drop_count := v_drop_count + @extschema@.drop_partition_time(v_row.parent_table);
+END LOOP;
+FOR v_row IN
+ SELECT parent_table FROM @extschema@.part_config WHERE retention IS NOT NULL AND undo_in_progress = false AND (type = 'id-static' OR type = 'id-dynamic')
+LOOP
+ v_drop_count := v_drop_count + @extschema@.drop_partition_id(v_row.parent_table);
+END LOOP;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Partition maintenance finished. '||v_create_count||' partitons made. '||v_drop_count||' partitions dropped.');
+ PERFORM close_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+END IF;
+
+PERFORM pg_advisory_unlock(hashtext('pg_partman run_maintenance'));
+
+EXCEPTION
+ WHEN QUERY_CANCELED THEN
+ PERFORM pg_advisory_unlock(hashtext('pg_partman run_maintenance'));
+ RAISE EXCEPTION '%', SQLERRM;
+ WHEN OTHERS THEN
+ IF v_jobmon_schema IS NOT NULL THEN
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+ IF v_job_id IS NULL THEN
+ v_job_id := add_job('PARTMAN RUN MAINTENANCE');
+ v_step_id := add_step(v_job_id, 'EXCEPTION before job logging started');
+ END IF;
+ IF v_step_id IS NULL THEN
+ v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
+ END IF;
+ PERFORM update_step(v_step_id, 'CRITICAL', 'ERROR: '||coalesce(SQLERRM,'unknown'));
+ PERFORM fail_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+ END IF;
+ PERFORM pg_advisory_unlock(hashtext('pg_partman run_maintenance'));
+ RAISE EXCEPTION '%', SQLERRM;
+END
+$$;

0 comments on commit 2eb6c02

Please sign in to comment.