From 1b00bb42803f623ca2f008b2cea7a43400884f36 Mon Sep 17 00:00:00 2001 From: Keith Fiske Date: Thu, 7 Mar 2013 00:41:06 -0500 Subject: [PATCH] v1.1.0 New python scripts to aid in partitioning/undoing. Small tweaks. Bug fix. See CHANGELOG for more. --- CHANGELOG | 8 + META.json | 6 +- doc/pg_partman.md | 45 +- extras/partition_data.py | 113 +++++ extras/undo_partition.py | 118 +++++ pg_partman.control | 2 +- sql/functions/partition_data_id.sql | 10 +- sql/functions/partition_data_time.sql | 10 +- sql/functions/undo_partition.sql | 25 +- sql/functions/undo_partition_id.sql | 2 +- sql/functions/undo_partition_time.sql | 2 +- updates/pg_partman--1.0.0--1.1.0.sql | 668 ++++++++++++++++++++++++++ 12 files changed, 986 insertions(+), 23 deletions(-) create mode 100644 extras/partition_data.py create mode 100644 extras/undo_partition.py create mode 100644 updates/pg_partman--1.0.0--1.1.0.sql diff --git a/CHANGELOG b/CHANGELOG index b16a5c57..18aa5393 100644 --- a/CHANGELOG +++ b/CHANGELOG @@ -1,3 +1,11 @@ +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). +-- Made partition functions quieter. No more notices and just returns number of rows moved. +-- Changed the undo partition functions to remove partitions in the order they were originally created. They were doing it alphabetically before, which could cause an odd order for serial based partitioning (p100 would be before p2). Creation order may not remove them in ascending order of the data at first, which would be ideal, but it makes more sense than alphabetically. +-- Bug fix: undo_partition() could return 0 prematurely if some of the partitions were empty. Will now automatically uninherit/drop any empty partitions and continue on if there are still child tables, not counting them against p_batch_count if given. + + 1.0.0 -- New functions to undo partitioning. These all either move or copy data from the child tables and put it into the parent. All have an option to allow you either uninherit the child tables (default) or drop them when all their data has been put into the parent. -- undo_partition_time() & undo_partition_id are functions that move the data from the child partitions to the parent tables. Data is deleted from the child table and inserted to the parent. These functions allow smaller interval batches to be given as a parameter and are better able to handle larger partitioning sets. diff --git a/META.json b/META.json index 840eb748..46b885a5 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.0.0", + "version": "1.1.0", "maintainer": [ "Keith Fiske " ], @@ -20,9 +20,9 @@ }, "provides": { "pg_partman": { - "file": "sql/pg_partman--1.0.0.sql", + "file": "sql/pg_partman--1.1.0.sql", "docfile": "doc/pg_partman.md", - "version": "1.0.0", + "version": "1.1.0", "abstract": "Extension to manage partitioned tables by time or ID" } }, diff --git a/doc/pg_partman.md b/doc/pg_partman.md index 87573a71..d7a78652 100644 --- a/doc/pg_partman.md +++ b/doc/pg_partman.md @@ -40,6 +40,7 @@ A superuser must be used to run these functions in order to set privileges & own > **half-hour** - One partition per 30 minute interval on the half-hour (1200, 1230) > **quarter-hour** - One partition per 15 minute interval on the quarter-hour (1200, 1215, 1230, 1245) > **** - For ID based partitions, the integer value range of the ID that should be set per partition. This is the actual integer value, not text values like time-based partitioning. Must be greater than zero. + > *Author's Note: If people want decade, century or millenium let me know. They are not trivial to add but I will upon request.* * p_premake - is how many additional partitions to always stay ahead of the current partition. Default value is 4. This will keep at minimum 5 partitions made, including the current one. For example, if today was Sept 6, 2012, and premake was set to 4 for a daily partition, then partitions would be made for the 6th as well as the 7th, 8th, 9th and 10th. As stated above, this value also determines how many partitions outside of the current one the static partitioning trigger function will handle (behind & ahead). Note that weekly partitioning may occasionally cause an extra partition to be premade due to differing month lengths and daylight savings (on non-UTC systems). This won't hurt anything and will self-correct. If partitioning ever falls behind the premake value, normal running of run_maintenance() and data insertion to id-based tables should automatically catch things up. * p_debug - turns on additional debugging information (not yet working). @@ -53,7 +54,7 @@ A superuser must be used to run these functions in order to set privileges & own *partition_data_time(p_parent_table text, p_batch_interval interval DEFAULT NULL, p_batch_count int DEFAULT 1) RETURNS bigint* * This function is used to partition data that may have existed prior to setting up the parent table as a time-based partition set, or to fix data that accidentally gets inserted into the parent. * If the needed partition does not exist, it will automatically be created. If the needed partition already exists, the data will be moved there. - * If you are trying to partition a large amount of previous data automatically, it is recommended to run this function with an external script and appropriate batch settings. This will help avoid transactional locks and prevent a failure from causing an extensive rollback. + * If you are trying to partition a large amount of previous data automatically, it is recommended to run this function with an external script and appropriate batch settings. This will help avoid transactional locks and prevent a failure from causing an extensive rollback. See **Extras** section for an included python script that will do this for you. * p_parent_table - the existing parent table. This is assumed to be where the unpartitioned data is located. MUST be schema qualified, even if in public schema. * p_batch_interval - optional argument, a time interval of how much of the data to move. This can be smaller than the partition interval, allowing for very large sized partitions to be broken up into smaller commit batches. Defaults to the configured partition interval if not given or if you give an interval larger than the partition interval. * p_batch_count - optional argument, how many times to run the batch_interval in a single call of this function. Default value is 1. @@ -62,7 +63,7 @@ A superuser must be used to run these functions in order to set privileges & own *partition_data_id(p_parent_table text, p_batch_interval int DEFAULT NULL, p_batch_count int DEFAULT 1) RETURNS bigint* * This function is used to partition data that may have existed prior to setting up the parent table as a serial id partition set, or to fix data that accidentally gets inserted into the parent. * If the needed partition does not exist, it will automatically be created. If the needed partition already exists, the data will be moved there. - * If you are trying to partition a large amount of previous data automatically, it is recommended to run this function with an external script and appropriate batch settings. This will help avoid transactional locks and prevent a failure from causing an extensive rollback. + * If you are trying to partition a large amount of previous data automatically, it is recommended to run this function with an external script and appropriate batch settings. This will help avoid transactional locks and prevent a failure from causing an extensive rollback. See **Extras** section for an included python script that will do this for you. * p_parent_table - the existing parent table. This is assumed to be where the unpartitioned data is located. MUST be schema qualified, even if in public schema. * p_batch_interval - optional argument, an integer amount representing an interval of how much of the data to move. This can be smaller than the partition interval, allowing for very large sized partitions to be broken up into smaller commit batches. Defaults to the configured partition interval if not given or if you give an interval larger than the partition interval. * p_batch_count - optional argument, how many times to run the batch_interval in a single call of this function. Default value is 1. @@ -95,7 +96,7 @@ A superuser must be used to run these functions in order to set privileges & own * Undo a time-based partition set created by pg_partman. This function MOVES the data from existing child partitions to the parent table. * When this function is run, the trigger on the parent table & the trigger function are immediately dropped (if they still exist). This means any further writes are done to the parent. * When this function is run, the **undo_in_progress** column in the configuration table is set. This causes all partition creation and retention management by the run_maintenance() function to stop. - * If you are trying to un-partition a large amount of data automatically, it is recommended to run this function with an external script and appropriate batch settings. This will help avoid transactional locks and prevent a failure from causing an extensive rollback. + * If you are trying to un-partition a large amount of data automatically, it is recommended to run this function with an external script and appropriate batch settings. This will help avoid transactional locks and prevent a failure from causing an extensive rollback. See **Extras** section for an included python script that will do this for you. * By default, partitions are not DROPPED, they are UNINHERITED. This leave previous child tables as empty, independent tables. * Without setting either batch argument manually, each run of the function will move all the data from a single partition into the parent. * Once all child tables have been uninherited/dropped, the configuration data is removed from pg_partman automatically. @@ -109,7 +110,7 @@ A superuser must be used to run these functions in order to set privileges & own * Undo an id-based partition set created by pg_partman. This function MOVES the data from existing child partitions to the parent table. * When this function is run, the trigger on the parent table & the trigger function are immediately dropped (if they still exist). This means any further writes are done to the parent. * When this function is run, the **undo_in_progress** column in the configuration table is set. This causes all partition creation and retention management by the run_maintenance() function to stop. - * If you are trying to un-partition a large amount of data automatically, it is recommended to run this function with an external script and appropriate batch settings. This will help avoid transactional locks and prevent a failure from causing an extensive rollback. + * If you are trying to un-partition a large amount of data automatically, it is recommended to run this function with an external script and appropriate batch settings. This will help avoid transactional locks and prevent a failure from causing an extensive rollback. See **Extras** section for an included python script that will do this for you. * By default, partitions are not DROPPED, they are UNINHERITED. This leave previous child tables as empty, independent tables. * Without setting either batch argument manually, each run of the function will move all the data from a single partition into the parent. * Once all child tables have been uninherited/dropped, the configuration data is removed from pg_partman automatically. @@ -123,7 +124,7 @@ A superuser must be used to run these functions in order to set privileges & own * Undo the parent/child table inheritance of any partition set, not just ones managed by pg_partman. This function COPIES the data from existing child partitions to the parent table. * If you need to keep the data in your child tables after it is put into the parent, use this function. * Unlike the other undo functions, data cannot be copied in batches smaller than the partition interval. Every run of the function copies an entire partition to the parent. - * If you are trying to un-partition a large amount of data automatically, it is recommended to run this function with an external script and appropriate batch settings. This will help avoid transactional locks and prevent a failure from causing an extensive rollback. + * If you are trying to un-partition a large amount of data automatically, it is recommended to run this function with an external script and appropriate batch settings. This will help avoid transactional locks and prevent a failure from causing an extensive rollback. See **Extras** section for an included python script that will do this for you. * By default, partitions are not DROPPED, they are UNINHERITED. This leave previous child tables exactly as they were but no longer inherited from the parent. * p_parent_table - parent table of the partition set. Must be schema qualified but does NOT have to be managed by pg_partman. * p_batch_count - an optional argument, this sets how many partitions to copy data from in a single run. Defaults to 1. @@ -155,3 +156,37 @@ Tables last_partition - Tracks the last successfully created partition and used to determine the next one. undo_in_progress - Set by the undo_partition functions whenever they are run. If true, This causes all partition creation and retention management by the run_maintenance() function to stop. Default is false. + +Extras +------ +*partition_data.py* + * A python script to make partitioning in committed batches easier. + * Calls either partition_data_time() or partition_data_id depending on the value given for --type. + * A commit is done at the end of each --interval and/or fully created partition. + * Returns the total number of rows moved to partitions. Automatically stops when parent is empty. + * --parent (-p): Parent table an already created partition set. Required. + * --type (-t): Type of partitioning. Valid values are "time" and "id". Required. + * --connection (-c): Connection string for use by psycopg to connect to your database. Defaults to "host=localhost". Highly recommended to use .pgpass file or environment variables to keep credentials secure. + * --interval (-i): Value that is passed on to the partitioning function as p_batch_interval argument. Use this to set an interval smaller than the partition interval to commit data in smaller batches. Defaults to the partition interval if not given. + * --batch (-b): How many times to loop through the value given for --interval. If --interval not set, will use default partition interval and make at most -b partition(s). Script commits at the end of each individual batch. (NOT passed as p_batch_count to partitioning function). If not set, all data in the parent table will be partitioned in a single run of the script. + * --wait (-w): Cause the script to pause for a given number of seconds between commits (batches). + * --schema (-s): The schema that pg_partman was installed to. Default is "partman". + * --quiet (-q): Switch setting to stop all output during and after partitioning. + * Please see --help option for some examples. + +*undo_partition.py* + * A python script to make undoing partitions in committed batches easier. + * Can also work on any parent/child partition set not managed by pg_partman if --type option is not set. + * This script calls either undo_partition(), undo_partition_time() or undo_partition_id depending on the value given for --type. + * A commit is done at the end of each --interval and/or emptied partition. + * Returns the total number of rows put into the to parent. Automatically stops when last child table is empty. + * --parent (-p): Parent table of the partition set. Required. + * --type (-t): Type of partitioning. Valid values are "time" and "id". Not setting this argument will use undo_partition() and work on any parent/child table set. + * --connection (-c): Connection string for use by psycopg to connect to your database. Defaults to "host=localhost". Highly recommended to use .pgpass file or environment variables to keep credentials secure. + * --interval (-i): Value that is passed on to the partitioning function as p_batch_interval. Use this to set an interval smaller than the partition interval to commit data in smaller batches. Defaults to the partition interval if not given. + * --batch (-b): How many times to loop through the value given for --interval. If --interval not set, will use default partition interval and undo at most -b partition(s). Script commits at the end of each individual batch. (NOT passed as p_batch_count to undo function). If not set, all data will be moved to the parent table in a single run of the script. + * --wait (-w): Cause the script to pause for a given number of seconds between commits (batches). + * --schema (-s): The schema that pg_partman was installed to. Default is "partman". + * --droptable (-d): Switch setting for whether to drop child tables when they are empty. Leave off option to just uninherit. + * --quiet (-q): Switch setting to stop all output during and after partitioning undo. + * Please see --help option for some examples. diff --git a/extras/partition_data.py b/extras/partition_data.py new file mode 100644 index 00000000..23e17bb4 --- /dev/null +++ b/extras/partition_data.py @@ -0,0 +1,113 @@ +#!/usr/bin/env python + +import psycopg2, sys, getopt, time + +help_string = """ +This script calls either partition_data_time() or partition_data_id depending on the value given for --type. +A commit is done at the end of each --interval and/or fully created partition. +Returns the total number of rows moved to partitions. Automatically stops when parent is empty. + + --parent (-p): Parent table an already created partition set. Required.\n + --type (-t): Type of partitioning. Valid values are "time" and "id". Required.\n + --connection (-c): Connection string for use by psycopg to connect to your database. Defaults to "host=localhost". + Highly recommended to use .pgpass file or environment variables to keep credentials secure.\n + --interval (-i): Value that is passed on to the partitioning function as p_batch_interval argument. + Use this to set an interval smaller than the partition interval to commit data in smaller batches. + Defaults to the partition interval if not given.\n + --batch (-b): How many times to loop through the value given for --interval. + If --interval not set, will use default partition interval and make at most -b partition(s). + Script commits at the end of each individual batch. (NOT passed as p_batch_count to partitioning function). + If not set, all data in the parent table will be partitioned in a single run of the script.\n + --wait (-w): Cause the script to pause for a given number of seconds between commits (batches).\n + --schema (-s): The schema that pg_partman was installed to. Default is "partman".\n + --quiet (-q): Switch setting to stop all output during and after partitioning. + +Example to partition all data in a parent table. Commit after each partition is made.\n + python partition_data.py -c "host=localhost dbname=mydb" -p schema.parent_table -t time\n +Example to partition by id in smaller intervals and pause between them for 5 seconds (assume >100 partition interval)\n + python partition_data.py -p schema.parent_table -t id -i 100 -w 5\n +Example to partition by time in smaller intervals for at most 10 partitions in a single run (assume monthly partition interval)\n + python partition_data.py -p schema.parent_table -t time -i "1 week" -b 10 +""" + +try: + opts, args = getopt.getopt(sys.argv[1:], "hqt:p:c:b:i:s:w:", ["help","quiet","type=","parent=","connection=","batch=","interval=","schema=", "wait"]) +except getopt.GetoptError: + print "Invalid argument" + print help_string + sys.exit(2) + +arg_parent = "" +arg_type = "" +arg_batch = "" +arg_interval = "" +arg_wait = "" +arg_connection = "host=localhost" +arg_schema = "partman" +arg_quiet = 0 +batch_count = 0 +total = 0 +for opt, arg in opts: + if opt in ("-h", "--help"): + print help_string + sys.exit() + elif opt in ("-p", "--parent"): + arg_parent = arg + elif opt in ("-t", "--type"): + arg_type = arg + if arg_type not in ("time", "id"): + print "--type (-t) must be one of the following: time, id" + sys.exit(2) + elif opt in ("-c", "--connection"): + arg_connection = arg + elif opt in ("-b", "--batch"): + arg_batch = arg + elif opt in ("-i", "--interval"): + arg_interval = arg + elif opt in ("-w", "--wait"): + arg_wait = arg + elif opt in ("-s", "--schema"): + arg_schema = arg + elif opt in ("-q", "--quiet"): + arg_quiet = 1 + +if arg_parent == "": + print "--parent (-p) argument is required" + sys.exit(2) +if arg_type == "": + print "--type (-t) argument is required" + sys.exit(2) + +conn = psycopg2.connect(arg_connection) + +cur = conn.cursor() + +sql = "SELECT " + arg_schema + ".partition_data_" + arg_type + "(%s" +if arg_interval != "": + sql += ", p_batch_interval := %s" +sql += ")" + +while True: + if arg_interval != "": + li = [arg_parent, arg_interval] + else: + li = [arg_parent] +# print cur.mogrify(sql, li) + cur.execute(sql, li) + result = cur.fetchone() + conn.commit() + if arg_quiet == 0: + print "Rows moved: " + str(result[0]) + total += result[0] + batch_count += 1 + # If no rows left or given batch argument limit is reached + if (result[0] == 0) or (arg_batch != "" and batch_count >= int(arg_batch)): + break + if arg_wait != "": + time.sleep(float(arg_wait)) + +if arg_quiet == 0: + print total + +cur.close() +conn.close() diff --git a/extras/undo_partition.py b/extras/undo_partition.py new file mode 100644 index 00000000..124702fa --- /dev/null +++ b/extras/undo_partition.py @@ -0,0 +1,118 @@ +#!/usr/bin/env python + +import psycopg2, sys, getopt, time + +help_string = """ +This script calls either undo_partition(), undo_partition_time() or undo_partition_id depending on the value given for --type. +A commit is done at the end of each --interval and/or emptied partition. +Returns the total number of rows put into the to parent. Automatically stops when last child table is empty. + + --parent (-p): Parent table of the partition set. Required.\n + --type (-t): Type of partitioning. Valid values are "time" and "id". + Not setting this argument will use undo_partition() and work on any parent/child table set.\n + --connection (-c): Connection string for use by psycopg to connect to your database. Defaults to "host=localhost". + Highly recommended to use .pgpass file or environment variables to keep credentials secure.\n + --interval (-i): Value that is passed on to the partitioning function as p_batch_interval. + Use this to set an interval smaller than the partition interval to commit data in smaller batches. + Defaults to the partition interval if not given.\n + --batch (-b): How many times to loop through the value given for --interval. + If --interval not set, will use default partition interval and undo at most -b partition(s). + Script commits at the end of each individual batch. (NOT passed as p_batch_count to undo function). + If not set, all data will be moved to the parent table in a single run of the script.\n + --wait (-w): Cause the script to pause for a given number of seconds between commits (batches).\n + --schema (-s): The schema that pg_partman was installed to. Default is "partman".\n + --droptable (-d): Switch setting for whether to drop child tables when they are empty. Leave off option to just uninherit.\n + --quiet (-q): Switch setting to stop all output during and after partitioning undo. + +Example to unpartition all data into the parent table. Commit after each partition is undone.\n + python undo_partition.py -c "host=localhost dbname=mydb" -p schema.parent_table -t time\n +Example to unpartition by id in smaller intervals and pause between them for 5 seconds (assume >100 partition interval)\n + python undo_partition.py -p schema.parent_table -t id -i 100 -w 5\n +Example to unpartition by time in smaller intervals for at most 10 partitions in a single run (assume monthly partition interval)\n + python undo_partition.py -p schema.parent_table -t time -i "1 week" -b 10 +""" + +try: + opts, args = getopt.getopt(sys.argv[1:], "hqdt:p:c:b:i:s:w:", ["help","quiet","drop","type=","parent=","connection=","batch=","interval=","schema=", "wait"]) +except getopt.GetoptError: + print "Invalid argument" + print help_string + sys.exit(2) + +arg_parent = "" +arg_type = "" +arg_batch = "" +arg_interval = "" +arg_wait = "" +arg_connection = "host=localhost" +arg_schema = "partman" +arg_quiet = 0 +batch_count = 0 +arg_drop = "true" +total = 0 +for opt, arg in opts: + if opt in ("-h", "--help"): + print help_string + sys.exit() + elif opt in ("-p", "--parent"): + arg_parent = arg + elif opt in ("-t", "--type"): + arg_type = arg + if arg_type not in ("time", "id"): + print "--type (-t) must be one of the following: time, id" + sys.exit(2) + elif opt in ("-c", "--connection"): + arg_connection = arg + elif opt in ("-b", "--batch"): + arg_batch = arg + elif opt in ("-i", "--interval"): + arg_interval = arg + elif opt in ("-d", "--droptable"): + arg_drop = "false"; + elif opt in ("-w", "--wait"): + arg_wait = arg + elif opt in ("-s", "--schema"): + arg_schema = arg + elif opt in ("-q", "--quiet"): + arg_quiet = 1 + +if arg_parent == "": + print "--parent (-p) argument is required" + sys.exit(2) + +conn = psycopg2.connect(arg_connection) + +cur = conn.cursor() + +sql = "SELECT " + arg_schema + ".undo_partition" +if arg_type != "": + sql += "_" + arg_type +sql += "(%s, p_keep_table := %s" +if arg_interval != "": + sql += ", p_batch_interval := %s" +sql += ")" + +while True: + if arg_interval != "": + li = [arg_parent, arg_drop, arg_interval] + else: + li = [arg_parent, arg_drop] +# print cur.mogrify(sql, li) + cur.execute(sql, li) + result = cur.fetchone() + conn.commit() + if arg_quiet == 0: + print "Rows put into parent: " + str(result[0]) + total += result[0] + batch_count += 1 + # If no rows left or given batch argument limit is reached + if (result[0] == 0) or (arg_batch != "" and batch_count >= int(arg_batch)): + break + if arg_wait != "": + time.sleep(float(arg_wait)) + +if arg_quiet == 0: + print total + +cur.close() +conn.close() diff --git a/pg_partman.control b/pg_partman.control index 1a4ce379..6c7de4b9 100644 --- a/pg_partman.control +++ b/pg_partman.control @@ -1,3 +1,3 @@ -default_version = '1.0.0' +default_version = '1.1.0' comment = 'Extension to manage partitioned tables by time or ID' relocatable = false diff --git a/sql/functions/partition_data_id.sql b/sql/functions/partition_data_id.sql index 52e02792..7cd0d554 100644 --- a/sql/functions/partition_data_id.sql +++ b/sql/functions/partition_data_id.sql @@ -1,7 +1,7 @@ /* * Populate the child table(s) of an id-based partition set with old data from the original parent */ -CREATE FUNCTION partition_data_id(p_parent_table text, p_batch_interval int DEFAULT NULL, p_batch_count int DEFAULT 1) RETURNS bigint +CREATE FUNCTION partition_data_id(p_parent_table text, p_batch_count int DEFAULT 1, p_batch_interval int DEFAULT NULL) RETURNS bigint LANGUAGE plpgsql SECURITY DEFINER AS $$ DECLARE @@ -42,17 +42,17 @@ FOR i IN 1..p_batch_count LOOP v_min_partition_id = v_min_control - (v_min_control % v_part_interval); v_partition_id := ARRAY[v_min_partition_id]; - RAISE NOTICE 'v_partition_id: %',v_partition_id; +-- RAISE NOTICE 'v_partition_id: %',v_partition_id; IF (v_min_control + p_batch_interval) >= (v_min_partition_id + v_part_interval) THEN v_max_partition_id := v_min_partition_id + v_part_interval; ELSE v_max_partition_id := v_min_control + p_batch_interval; END IF; - RAISE NOTICE 'v_max_partition_id: %',v_max_partition_id; +-- RAISE NOTICE 'v_max_partition_id: %',v_max_partition_id; v_sql := 'SELECT @extschema@.create_id_partition('||quote_literal(p_parent_table)||','||quote_literal(v_control)||',' ||v_part_interval||','||quote_literal(v_partition_id)||')'; - RAISE NOTICE 'v_sql: %', v_sql; +-- RAISE NOTICE 'v_sql: %', v_sql; EXECUTE v_sql INTO v_last_partition_name; v_sql := 'WITH partition_data AS ( @@ -60,7 +60,7 @@ FOR i IN 1..p_batch_count LOOP ' AND '||v_control||' < '||v_max_partition_id||' RETURNING *) INSERT INTO '||v_last_partition_name||' SELECT * FROM partition_data'; - RAISE NOTICE 'v_sql: %', v_sql; +-- RAISE NOTICE 'v_sql: %', v_sql; EXECUTE v_sql; GET DIAGNOSTICS v_rowcount = ROW_COUNT; diff --git a/sql/functions/partition_data_time.sql b/sql/functions/partition_data_time.sql index d04e1281..4f28c7cf 100644 --- a/sql/functions/partition_data_time.sql +++ b/sql/functions/partition_data_time.sql @@ -1,7 +1,7 @@ /* * Populate the child table(s) of a time-based partition set with old data from the original parent */ -CREATE FUNCTION partition_data_time(p_parent_table text, p_batch_interval interval DEFAULT NULL, p_batch_count int DEFAULT 1) RETURNS bigint +CREATE FUNCTION partition_data_time(p_parent_table text, p_batch_count int DEFAULT 1, p_batch_interval interval DEFAULT NULL) RETURNS bigint LANGUAGE plpgsql SECURITY DEFINER AS $$ DECLARE @@ -62,24 +62,24 @@ FOR i IN 1..p_batch_count LOOP END CASE; v_partition_timestamp := ARRAY[v_min_partition_timestamp]; - RAISE NOTICE 'v_partition_timestamp: %',v_partition_timestamp; +-- RAISE NOTICE 'v_partition_timestamp: %',v_partition_timestamp; IF (v_min_control + p_batch_interval) >= (v_min_partition_timestamp + v_part_interval) THEN v_max_partition_timestamp := v_min_partition_timestamp + v_part_interval; ELSE v_max_partition_timestamp := v_min_control + p_batch_interval; END IF; - RAISE NOTICE 'v_max_partition_timestamp: %',v_max_partition_timestamp; +-- RAISE NOTICE 'v_max_partition_timestamp: %',v_max_partition_timestamp; v_sql := 'SELECT @extschema@.create_time_partition('||quote_literal(p_parent_table)||','||quote_literal(v_control)||',' ||quote_literal(v_part_interval)||','||quote_literal(v_datetime_string)||','||quote_literal(v_partition_timestamp)||')'; - RAISE NOTICE 'v_sql: %', v_sql; +-- RAISE NOTICE 'v_sql: %', v_sql; EXECUTE v_sql INTO v_last_partition_name; v_sql := 'WITH partition_data AS ( DELETE FROM ONLY '||p_parent_table||' WHERE '||v_control||' >= '||quote_literal(v_min_control)|| ' AND '||v_control||' < '||quote_literal(v_max_partition_timestamp)||' RETURNING *) INSERT INTO '||v_last_partition_name||' SELECT * FROM partition_data'; - RAISE NOTICE 'v_sql: %', v_sql; +-- RAISE NOTICE 'v_sql: %', v_sql; EXECUTE v_sql; GET DIAGNOSTICS v_rowcount = ROW_COUNT; diff --git a/sql/functions/undo_partition.sql b/sql/functions/undo_partition.sql index 8da0a862..ee67660d 100644 --- a/sql/functions/undo_partition.sql +++ b/sql/functions/undo_partition.sql @@ -8,6 +8,8 @@ CREATE FUNCTION undo_partition(p_parent_table text, p_batch_count int DEFAULT 1, 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; @@ -50,14 +52,32 @@ 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; -FOR i IN 1..p_batch_count 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::regclass::text ASC; + ORDER BY 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; @@ -78,6 +98,7 @@ FOR i IN 1..p_batch_count LOOP 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; diff --git a/sql/functions/undo_partition_id.sql b/sql/functions/undo_partition_id.sql index 34f07846..41cf9f9e 100644 --- a/sql/functions/undo_partition_id.sql +++ b/sql/functions/undo_partition_id.sql @@ -76,7 +76,7 @@ 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::regclass::text ASC; + ORDER BY inhrelid ASC; EXIT WHEN v_child_table IS NULL; diff --git a/sql/functions/undo_partition_time.sql b/sql/functions/undo_partition_time.sql index 705de755..2e956f77 100644 --- a/sql/functions/undo_partition_time.sql +++ b/sql/functions/undo_partition_time.sql @@ -76,7 +76,7 @@ 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::regclass::text ASC; + ORDER BY inhrelid ASC; EXIT WHEN v_child_table IS NULL; diff --git a/updates/pg_partman--1.0.0--1.1.0.sql b/updates/pg_partman--1.0.0--1.1.0.sql new file mode 100644 index 00000000..fbe6669f --- /dev/null +++ b/updates/pg_partman--1.0.0--1.1.0.sql @@ -0,0 +1,668 @@ +-- 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). +-- Made partition functions quieter. No more notices and just returns number of rows moved. +-- Changed the undo partition functions to remove partitions in the order they were originally created. They were doing it alphabetically before, which could cause an odd order for serial based partitioning (p100 would be before p2). Creation order may not remove them in ascending order of the data at first, which would be ideal, but it makes more sense than alphabetically. +-- Bug fix: undo_partition() could return 0 prematurely if some of the partitions were empty. Will now automatically uninherit/drop any empty partitions and continue on if there are still child tables, not counting them against p_batch_count if given. + + +DROP FUNCTION @extschema@.partition_data_id(text, int, int); +DROP FUNCTION @extschema@.partition_data_time(text, interval, int); + +/* + * Populate the child table(s) of an id-based partition set with old data from the original parent + */ +CREATE FUNCTION partition_data_id(p_parent_table text, p_batch_count int DEFAULT 1, p_batch_interval int DEFAULT NULL) RETURNS bigint + LANGUAGE plpgsql SECURITY DEFINER + AS $$ +DECLARE + +v_control text; +v_last_partition_name text; +v_max_partition_id bigint; +v_min_control bigint; +v_min_partition_id bigint; +v_part_interval bigint; +v_partition_id bigint[]; +v_rowcount bigint; +v_sql text; +v_total_rows bigint := 0; + +BEGIN + +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 NOT FOUND THEN + RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table; +END IF; + +IF p_batch_interval IS NULL OR p_batch_interval > v_part_interval THEN + p_batch_interval := v_part_interval; +END IF; + +FOR i IN 1..p_batch_count LOOP + + EXECUTE 'SELECT min('||v_control||') FROM ONLY '||p_parent_table INTO v_min_control; + IF v_min_control IS NULL THEN + RETURN 0; + END IF; + + v_min_partition_id = v_min_control - (v_min_control % v_part_interval); + + v_partition_id := ARRAY[v_min_partition_id]; +-- RAISE NOTICE 'v_partition_id: %',v_partition_id; + IF (v_min_control + p_batch_interval) >= (v_min_partition_id + v_part_interval) THEN + v_max_partition_id := v_min_partition_id + v_part_interval; + ELSE + v_max_partition_id := v_min_control + p_batch_interval; + END IF; +-- RAISE NOTICE 'v_max_partition_id: %',v_max_partition_id; + + v_sql := 'SELECT @extschema@.create_id_partition('||quote_literal(p_parent_table)||','||quote_literal(v_control)||',' + ||v_part_interval||','||quote_literal(v_partition_id)||')'; +-- RAISE NOTICE 'v_sql: %', v_sql; + EXECUTE v_sql INTO v_last_partition_name; + + v_sql := 'WITH partition_data AS ( + DELETE FROM ONLY '||p_parent_table||' WHERE '||v_control||' >= '||v_min_control|| + ' AND '||v_control||' < '||v_max_partition_id||' RETURNING *) + INSERT INTO '||v_last_partition_name||' SELECT * FROM partition_data'; + +-- RAISE NOTICE 'v_sql: %', v_sql; + EXECUTE v_sql; + + GET DIAGNOSTICS v_rowcount = ROW_COUNT; + v_total_rows := v_total_rows + v_rowcount; + IF v_rowcount = 0 THEN + EXIT; + END IF; + +END LOOP; + +RETURN v_total_rows; + +END +$$; + + +/* + * Populate the child table(s) of a time-based partition set with old data from the original parent + */ +CREATE FUNCTION partition_data_time(p_parent_table text, p_batch_count int DEFAULT 1, p_batch_interval interval DEFAULT NULL) RETURNS bigint + LANGUAGE plpgsql SECURITY DEFINER + AS $$ +DECLARE + +v_control text; +v_datetime_string text; +v_last_partition_name text; +v_max_partition_timestamp timestamp; +v_min_control timestamp; +v_min_partition_timestamp timestamp; +v_part_interval interval; +v_partition_timestamp timestamp[]; +v_rowcount bigint; +v_sql text; +v_total_rows bigint := 0; + +BEGIN + +SELECT part_interval::interval, control, datetime_string +INTO v_part_interval, v_control, v_datetime_string +FROM @extschema@.part_config +WHERE parent_table = p_parent_table +AND (type = 'time-static' OR type = 'time-dynamic'); +IF NOT FOUND THEN + RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table; +END IF; + +IF p_batch_interval IS NULL OR p_batch_interval > v_part_interval THEN + p_batch_interval := v_part_interval; +END IF; + +FOR i IN 1..p_batch_count LOOP + + EXECUTE 'SELECT min('||v_control||') FROM ONLY '||p_parent_table INTO v_min_control; + IF v_min_control IS NULL THEN + RETURN 0; + END IF; + + CASE + WHEN v_part_interval = '15 mins' THEN + v_min_partition_timestamp := date_trunc('hour', v_min_control) + + '15min'::interval * floor(date_part('minute', v_min_control) / 15.0); + WHEN v_part_interval = '30 mins' THEN + v_min_partition_timestamp := date_trunc('hour', v_min_control) + + '30min'::interval * floor(date_part('minute', v_min_control) / 30.0); + WHEN v_part_interval = '1 hour' THEN + v_min_partition_timestamp := date_trunc('hour', v_min_control); + WHEN v_part_interval = '1 day' THEN + v_min_partition_timestamp := date_trunc('day', v_min_control); + WHEN v_part_interval = '1 week' THEN + v_min_partition_timestamp := date_trunc('week', v_min_control); + WHEN v_part_interval = '1 month' THEN + v_min_partition_timestamp := date_trunc('month', v_min_control); + WHEN v_part_interval = '3 months' THEN + v_min_partition_timestamp := date_trunc('quarter', v_min_control); + WHEN v_part_interval = '1 year' THEN + v_min_partition_timestamp := date_trunc('year', v_min_control); + END CASE; + + v_partition_timestamp := ARRAY[v_min_partition_timestamp]; +-- RAISE NOTICE 'v_partition_timestamp: %',v_partition_timestamp; + IF (v_min_control + p_batch_interval) >= (v_min_partition_timestamp + v_part_interval) THEN + v_max_partition_timestamp := v_min_partition_timestamp + v_part_interval; + ELSE + v_max_partition_timestamp := v_min_control + p_batch_interval; + END IF; +-- RAISE NOTICE 'v_max_partition_timestamp: %',v_max_partition_timestamp; + + v_sql := 'SELECT @extschema@.create_time_partition('||quote_literal(p_parent_table)||','||quote_literal(v_control)||',' + ||quote_literal(v_part_interval)||','||quote_literal(v_datetime_string)||','||quote_literal(v_partition_timestamp)||')'; +-- RAISE NOTICE 'v_sql: %', v_sql; + EXECUTE v_sql INTO v_last_partition_name; + + v_sql := 'WITH partition_data AS ( + DELETE FROM ONLY '||p_parent_table||' WHERE '||v_control||' >= '||quote_literal(v_min_control)|| + ' AND '||v_control||' < '||quote_literal(v_max_partition_timestamp)||' RETURNING *) + INSERT INTO '||v_last_partition_name||' SELECT * FROM partition_data'; +-- RAISE NOTICE 'v_sql: %', v_sql; + EXECUTE v_sql; + + GET DIAGNOSTICS v_rowcount = ROW_COUNT; + v_total_rows := v_total_rows + v_rowcount; + IF v_rowcount = 0 THEN + EXIT; + END IF; + +END LOOP; + +RETURN v_total_rows; + +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 inhrelid::regclass INTO v_child_table + FROM pg_catalog.pg_inherits + WHERE inhparent::regclass = p_parent_table::regclass + ORDER BY 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; + +<> +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; + + 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; + <> + 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; + +<> +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; + + 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; + <> + 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 +$$;