Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with
or
.
Download ZIP
Browse files

v1.7.1 Added foreign key inheritance support, undo partitioning lockw…

…ait option, & unlogged support
  • Loading branch information...
commit d941cd2c779655d9bd0b0c4ea92c714e93ab8ae2 1 parent 46857e2
@keithf4 authored
View
13 CHANGELOG
@@ -1,3 +1,16 @@
+1.7.1
+-- Foreign keys placed on the parent table are now inherited to child tables.
+ -- Any new partitions created after this update is installed will have the FKs applied to children.
+ -- Existing child partitions will not have FKs applied. See the reapply_foreign_keys.py python script to reapply FKs to all child tables.
+ -- The new apply_foreign_keys() function & reapply_foreign_keys.py script can be applied to any table inheritance set, not just the ones managed by pg_partman.
+ -- See blog post for some more information about partitioning & foreign keys - http://www.keithf4.com/table-partitioning-and-foreign-keys
+-- Unlogged table property on parent table is now automatically inherited to child tables. Note this only applies to newly created child partitions after this update is installed.
+-- Added lockwait options to the undo partition functions (plpgsql & python)
+-- Added the same autovacuum feature & option to undo_partition.py that partition_data.py has.
+-- Made python scripts compatible with python 3
+-- PgTAP tests for unlogged tables and FK inheritance
+
+
1.7.0
-- New configuration option to allow serial partitioning to use run_maintenance() instead of creating next partition via trigger.
-- Use "p_use_run_maintenance" argument to create_parent() to set this during partition creation.
View
6 META.json
@@ -1,7 +1,7 @@
{
"name": "pg_partman",
"abstract": "Extension to manage partitioned tables by time or ID",
- "version": "1.7.0",
+ "version": "1.7.1",
"maintainer": [
"Keith Fiske <keith@omniti.com>"
],
@@ -20,9 +20,9 @@
},
"provides": {
"pg_partman": {
- "file": "sql/pg_partman--1.7.0.sql",
+ "file": "sql/pg_partman--1.7.1.sql",
"docfile": "doc/pg_partman.md",
- "version": "1.7.0",
+ "version": "1.7.1",
"abstract": "Extension to manage partitioned tables by time or ID"
}
},
View
12 bin/check_unique_constraint.py
@@ -36,7 +36,7 @@
cur.close()
cur = conn.cursor()
if not args.quiet:
- print "Dumping out column data to temp file..."
+ print("Dumping out column data to temp file...")
cur.copy_to(fh, args.parent, sep=",", columns=args.column_list.split(","))
conn.rollback()
conn.close()
@@ -44,21 +44,21 @@
total_count = 0
if not args.quiet:
- print "Checking for dupes..."
+ print("Checking for dupes...")
with open(tmp_copy_file.name) as infile:
counts = collections.Counter(l.strip() for l in infile)
for line, count in counts.most_common():
if count > 1:
if not args.simple:
- print str(line) + ": " + str(count)
+ print(str(line) + ": " + str(count))
total_count += count
if args.simple:
if total_count > 0:
- print total_count
+ print(total_count)
elif not args.quiet:
- print total_count
+ print(total_count)
else:
if total_count == 0 and not args.quiet:
- print "No constraint violations found"
+ print("No constraint violations found")
View
20 bin/dump_partition.py
@@ -18,7 +18,7 @@
args = parser.parse_args()
if not os.path.exists(args.output):
- print "Path given by --output (-o) does not exist: " + str(args.output)
+ print("Path given by --output (-o) does not exist: " + str(args.output))
sys.exit(2)
@@ -57,11 +57,11 @@ def perform_dump(result):
processcmd.append(args.dump_database)
if args.verbose:
- print processcmd
+ print(processcmd)
try:
subprocess.check_call(processcmd)
- except subprocess.CalledProcessError, e:
- print "Error in pg_dump command: " + str(e.cmd)
+ except subprocess.CalledProcessError as e:
+ print("Error in pg_dump command: " + str(e.cmd))
sys.exit(2)
return table_name
@@ -77,18 +77,18 @@ def create_hash(table_name):
if not data:
break
shash.update(data)
- except IOError, (ErrorNo, ErrorMsg):
- print "Cannot access dump file for hash creation: " + ErrorMsg
+ except IOError as e:
+ print("Cannot access dump file for hash creation: " + e.strerror)
sys.exit(2)
hash_file = os.path.join(args.output, args.schema + "." + table_name + ".hash")
if args.verbose:
- print "hash_file: " + hash_file
+ print("hash_file: " + hash_file)
try:
with open(hash_file, "w") as fh:
fh.write(shash.hexdigest() + " " + os.path.basename(output_file))
- except IOError, (ErroNo, ErrorMsg):
- print "Unable to write to hash file: " + ErrorMsg
+ except IOError as e:
+ print("Unable to write to hash file: " + e.strerror)
sys.exit(2)
@@ -96,7 +96,7 @@ def drop_table(table_name):
conn = psycopg2.connect(args.connection)
cur = conn.cursor()
sql = "DROP TABLE IF EXISTS " + args.schema + "." + table_name;
- print sql
+ print(sql)
cur.execute(sql)
conn.commit()
cur.close()
View
37 bin/partition_data.py
@@ -39,38 +39,44 @@ def get_partman_schema(conn):
def turn_off_autovacuum(conn, partman_schema):
cur = conn.cursor()
sql = "ALTER TABLE " + args.parent + " SET (autovacuum_enabled = false, toast.autovacuum_enabled = false)"
+ if not args.quiet:
+ print("Attempting to turn off autovacuum for partition set...")
if args.debug:
- print cur.mogrify(sql)
+ print(cur.mogrify(sql))
cur.execute(sql)
sql = "SELECT * FROM " + partman_schema + ".show_partitions(%s)"
if args.debug:
- print cur.mogrify(sql, [args.parent])
+ print(cur.mogrify(sql, [args.parent]))
cur.execute(sql, [args.parent])
result = cur.fetchall()
for r in result:
sql = "ALTER TABLE " + r[0] + " SET (autovacuum_enabled = false, toast.autovacuum_enabled = false)"
if args.debug:
- print cur.mogrify(sql)
+ print(cur.mogrify(sql))
cur.execute(sql)
+ print("\t... Success!")
cur.close()
def reset_autovacuum(conn, table):
cur = conn.cursor()
sql = "ALTER TABLE " + args.parent + " RESET (autovacuum_enabled, toast.autovacuum_enabled)"
+ if not args.quiet:
+ print("Attempting to reset autovacuum for old parent table...")
if args.debug:
- print cur.mogrify(sql)
+ print(cur.mogrify(sql))
cur.execute(sql)
sql = "SELECT * FROM " + partman_schema + ".show_partitions(%s)"
if args.debug:
- print cur.mogrify(sql, [args.parent])
+ print(cur.mogrify(sql, [args.parent]))
cur.execute(sql, [args.parent])
result = cur.fetchall()
for r in result:
sql = "ALTER TABLE " + r[0] + " RESET (autovacuum_enabled, toast.autovacuum_enabled)"
if args.debug:
- print cur.mogrify(sql)
+ print(cur.mogrify(sql))
cur.execute(sql)
+ print("\t... Success!")
cur.close()
@@ -78,9 +84,9 @@ def vacuum_parent(conn):
cur = conn.cursor()
sql = "VACUUM ANALYZE " + args.parent
if args.debug:
- print cur.mogrify(sql)
+ print(cur.mogrify(sql))
if not args.quiet:
- print "Running vacuum analyze on parent table..."
+ print("Running vacuum analyze on parent table...")
cur.execute(sql)
cur.close()
@@ -104,24 +110,24 @@ def partition_data(conn, partman_schema):
else:
li = [args.parent, args.lockwait, args.order]
if args.debug:
- print cur.mogrify(sql, li)
+ print(cur.mogrify(sql, li))
cur.execute(sql, li)
result = cur.fetchone()
if not args.quiet:
if result[0] > 0:
- print "Rows moved: " + str(result[0])
+ print("Rows moved: " + str(result[0]))
elif result[0] == -1:
- print "Unable to obtain lock, trying again"
+ print("Unable to obtain lock, trying again")
+ print(conn.notices[-1])
# if lock wait timeout, do not increment the counter
- if result[0] <> -1:
+ if result[0] != -1:
batch_count += 1
total += result[0]
lockwait_count = 0
else:
lockwait_count += 1
if lockwait_count > args.lockwait_tries:
- print "quitting due to inability to get lock on next rows to be moved"
- print "total rows moved: %d" % total
+ print("Quitting due to inability to get lock on next rows to be moved")
break
# If no rows left or given batch argument limit is reached
if (result[0] == 0) or (args.batch > 0 and batch_count >= int(args.batch)):
@@ -132,7 +138,6 @@ def partition_data(conn, partman_schema):
if __name__ == "__main__":
conn = create_conn()
- cur = conn.cursor()
partman_schema = get_partman_schema(conn)
if not args.autovacuum_on:
@@ -141,7 +146,7 @@ def partition_data(conn, partman_schema):
total = partition_data(conn, partman_schema)
if not args.quiet:
- print "Total rows moved: %d" % total
+ print("Total rows moved: %d" % total)
vacuum_parent(conn)
View
114 bin/reapply_foreign_keys.py
@@ -0,0 +1,114 @@
+#!/usr/bin/env python
+
+import argparse, psycopg2, sys, time
+
+parser = argparse.ArgumentParser(description="This script will reapply the foreign keys on a parent table to all child tables in an inheritance set. Any existing foreign keys on child tables will be dropped in order to match the parent. A commit is done after each foreign key application to avoid excessive contention. Note that this script can work on any inheritance set, not just partition sets managed by pg_partman.")
+parser.add_argument('-p','--parent', required=True, help="Parent table of an already created partition set. (Required)")
+parser.add_argument('-c','--connection', default="host=localhost", help="""Connection string for use by psycopg to connect to your database. Defaults to "host=localhost".""")
+parser.add_argument('-q', '--quiet', action="store_true", help="Switch setting to stop all output during and after partitioning undo.")
+parser.add_argument('--dryrun', action="store_true", help="Show what the script will do without actually running it against the database. Highly recommend reviewing this before running.")
+parser.add_argument('--debug', action="store_true", help="Show additional debugging output")
+args = parser.parse_args()
+
+
+def apply_foreign_keys(conn, child_tables):
+ if not args.quiet:
+ print("Applying foreign keys to child tables...")
+ cur = conn.cursor()
+ for c in child_tables:
+ sql = """SELECT keys.conname
+ , keys.confrelid::regclass::text AS ref_table
+ , '"'||string_agg(att.attname, '","')||'"' AS ref_column
+ , '"'||string_agg(att2.attname, '","')||'"' AS child_column
+ FROM
+ ( SELECT con.conname
+ , unnest(con.conkey) as ref
+ , unnest(con.confkey) as child
+ , con.confrelid
+ , con.conrelid
+ FROM pg_catalog.pg_class c
+ JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
+ JOIN pg_catalog.pg_constraint con ON c.oid = con.conrelid
+ WHERE n.nspname ||'.'|| c.relname = %s
+ AND con.contype = 'f'
+ ORDER BY con.conkey
+ ) keys
+ JOIN pg_catalog.pg_class cl ON cl.oid = keys.confrelid
+ JOIN pg_catalog.pg_attribute att ON att.attrelid = keys.confrelid AND att.attnum = keys.child
+ JOIN pg_catalog.pg_attribute att2 ON att2.attrelid = keys.conrelid AND att2.attnum = keys.ref
+ GROUP BY keys.conname, keys.confrelid""";
+ if args.debug:
+ print(cur.mogrify(sql, [args.parent]))
+ cur.execute(sql, [args.parent])
+ parent_fkeys = cur.fetchall()
+ for pfk in parent_fkeys:
+ alter_sql = "ALTER TABLE " + c[0] + " ADD FOREIGN KEY (" + pfk[3] + ") REFERENCES " + pfk[1] + "(" + pfk[2] + ")"
+ if not args.quiet:
+ print(alter_sql)
+ if not args.dryrun:
+ cur.execute(alter_sql)
+
+
+def create_conn():
+ conn = psycopg2.connect(args.connection)
+ conn.autocommit = True
+ return conn
+
+
+def close_conn(conn):
+ conn.close()
+
+
+def drop_foreign_keys(conn, child_tables):
+ if not args.quiet:
+ print("Dropping current foreign keys on child tables...")
+ cur = conn.cursor()
+ for c in child_tables:
+ sql = """SELECT constraint_name
+ FROM information_schema.table_constraints
+ WHERE table_schema||'.'||table_name = %s AND constraint_type = 'FOREIGN KEY'"""
+ if args.debug:
+ print(cur.mogrify(sql, [ c[0] ]))
+ cur.execute(sql, [ c[0] ])
+ child_fkeys = cur.fetchall()
+ for cfk in child_fkeys:
+ alter_sql = "ALTER TABLE " + c[0] + " DROP CONSTRAINT " + cfk[0]
+ if not args.quiet:
+ print(alter_sql)
+ if not args.dryrun:
+ cur.execute(alter_sql)
+
+
+def get_child_tables(conn, part_schema):
+ if not args.quiet:
+ print("Getting list of child tables...")
+ cur = conn.cursor()
+ sql = "SELECT * FROM " + partman_schema + ".show_partitions(%s)"
+ if args.debug:
+ print(cur.mogrify(sql, [args.parent]))
+ cur.execute(sql, [args.parent])
+ result = cur.fetchall()
+ return result
+
+
+def get_partman_schema(conn):
+ cur = conn.cursor()
+ sql = "SELECT nspname FROM pg_catalog.pg_namespace n, pg_catalog.pg_extension e WHERE e.extname = 'pg_partman' AND e.extnamespace = n.oid"
+ cur.execute(sql)
+ partman_schema = cur.fetchone()[0]
+ cur.close()
+ return partman_schema
+
+
+if __name__ == "__main__":
+ conn = create_conn()
+
+ partman_schema = get_partman_schema(conn)
+ child_tables = get_child_tables(conn, partman_schema)
+
+ drop_foreign_keys(conn, child_tables)
+ apply_foreign_keys(conn, child_tables)
+
+ if not args.quiet:
+ print("Done!")
+ close_conn(conn)
View
189 bin/undo_partition.py
@@ -8,59 +8,162 @@
parser.add_argument('-c','--connection', default="host=localhost", help="""Connection string for use by psycopg to connect to your database. Defaults to "host=localhost".""")
parser.add_argument('-i','--interval', help="Value that is passed on to the undo 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. If -t value is not set, interval cannot be smaller than the partition interval and an entire partition is copied each batch.")
parser.add_argument('-b','--batch', type=int, default=0, help="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.")
-parser.add_argument('-w','--wait', type=float, default=0, help="Cause the script to pause for a given number of seconds between commits (batches).")
parser.add_argument('-d', '--droptable', action="store_true", help="Switch setting for whether to drop child tables when they are empty. Do not set to just uninherit.")
+parser.add_argument('-w','--wait', type=float, default=0, help="Cause the script to pause for a given number of seconds between commits (batches).")
+parser.add_argument('-l','--lockwait', default=0, type=float, help="Have a lock timeout of this many seconds on the data move. If a lock is not obtained, that batch will be tried again.")
+parser.add_argument('--lockwait_tries', default=10, type=int, help="Number of times to allow a lockwait to time out before giving up on the partitioning. Defaults to 10")
+parser.add_argument('--autovacuum_on', action="store_true", help="Turning autovacuum off requires a brief lock to ALTER the table property. Set this option to leave autovacuum on and avoid the lock attempt.")
parser.add_argument('-q', '--quiet', action="store_true", help="Switch setting to stop all output during and after partitioning undo.")
+parser.add_argument('--debug', action="store_true", help="Show additional debugging output")
args = parser.parse_args()
-batch_count = 0
-total = 0
-conn = psycopg2.connect(args.connection)
+def create_conn():
+ conn = psycopg2.connect(args.connection)
+ conn.autocommit = True
+ return conn
+
+
+def close_conn(conn):
+ conn.close()
-cur = conn.cursor()
-sql = "SELECT nspname FROM pg_catalog.pg_namespace n, pg_catalog.pg_extension e WHERE e.extname = 'pg_partman' AND e.extnamespace = n.oid"
-cur.execute(sql)
-partman_schema = cur.fetchone()[0]
-cur.close()
-cur = conn.cursor()
+def get_partman_schema(conn):
+ cur = conn.cursor()
+ sql = "SELECT nspname FROM pg_catalog.pg_namespace n, pg_catalog.pg_extension e WHERE e.extname = 'pg_partman' AND e.extnamespace = n.oid"
+ cur.execute(sql)
+ partman_schema = cur.fetchone()[0]
+ cur.close()
+ return partman_schema
+
+
+def turn_off_autovacuum(conn, partman_schema):
+ cur = conn.cursor()
+ sql = "ALTER TABLE " + args.parent + " SET (autovacuum_enabled = false, toast.autovacuum_enabled = false)"
+ if not args.quiet:
+ print("Attempting to turn off autovacuum for partition set...")
+ if args.debug:
+ print(cur.mogrify(sql))
+ cur.execute(sql)
+ sql = "SELECT * FROM " + partman_schema + ".show_partitions(%s)"
+ if args.debug:
+ print(cur.mogrify(sql, [args.parent]))
+ cur.execute(sql, [args.parent])
+ result = cur.fetchall()
+ for r in result:
+ sql = "ALTER TABLE " + r[0] + " SET (autovacuum_enabled = false, toast.autovacuum_enabled = false)"
+ if args.debug:
+ print(cur.mogrify(sql))
+ cur.execute(sql)
+ print("\t... Success!")
+ cur.close()
+
+
+def reset_autovacuum(conn, table):
+ cur = conn.cursor()
+ sql = "ALTER TABLE " + args.parent + " RESET (autovacuum_enabled, toast.autovacuum_enabled)"
+ if not args.quiet:
+ print("Attempting to reset autovacuum for old parent table...")
+ if args.debug:
+ print(cur.mogrify(sql))
+ cur.execute(sql)
+ sql = "SELECT * FROM " + partman_schema + ".show_partitions(%s)"
+ if args.debug:
+ print(cur.mogrify(sql, [args.parent]))
+ cur.execute(sql, [args.parent])
+ result = cur.fetchall()
+ for r in result:
+ sql = "ALTER TABLE " + r[0] + " RESET (autovacuum_enabled, toast.autovacuum_enabled)"
+ if args.debug:
+ print(cur.mogrify(sql))
+ cur.execute(sql)
+ print("\t... Success!")
+ cur.close()
+
+
+def vacuum_parent(conn):
+ cur = conn.cursor()
+ sql = "VACUUM ANALYZE " + args.parent
+ if args.debug:
+ print(cur.mogrify(sql))
+ if not args.quiet:
+ print("Running vacuum analyze on parent table...")
+ cur.execute(sql)
+ cur.close()
-sql = "SELECT " + partman_schema + ".undo_partition"
-if args.type != None:
- sql += "_" + args.type
-sql += "(%s, p_keep_table := %s"
-if args.interval != None:
- sql += ", p_batch_interval := %s"
-sql += ")"
-# Actual undo sql functions do not drop by default, so fix argument value to match that default
-if args.droptable:
- keep_table = False
-else:
- keep_table = True
+def undo_partition_data(conn, partman_schema):
+ batch_count = 0
+ total = 0
+ lockwait_count = 0
-while True:
+ cur = conn.cursor()
+
+ sql = "SELECT " + partman_schema + ".undo_partition"
+ if args.type != None:
+ sql += "_" + args.type
+ sql += "(%s, p_keep_table := %s"
if args.interval != None:
- li = [args.parent, keep_table, args.interval]
+ sql += ", p_batch_interval := %s"
+ sql += ", p_lock_wait := %s"
+ sql += ")"
+
+ # Actual undo sql functions do not drop by default, so fix argument value to match that default
+ if args.droptable:
+ keep_table = False
else:
- li = [args.parent, keep_table]
-# print cur.mogrify(sql, li)
- cur.execute(sql, li)
- result = cur.fetchone()
- conn.commit()
+ keep_table = True
+
+ while True:
+ if args.interval != None:
+ li = [args.parent, keep_table, args.interval, args.lockwait]
+ else:
+ li = [args.parent, keep_table, args.lockwait]
+ if args.debug:
+ print(cur.mogrify(sql, li))
+ cur.execute(sql, li)
+ result = cur.fetchone()
+ conn.commit()
+ if not args.quiet:
+ if result[0] > 0:
+ print("Rows moved into parent: " + str(result[0]))
+ elif result[0] == -1:
+ print("Unable to obtain lock, trying again (" + str(lockwait_count+1) + ")")
+ print(conn.notices[-1])
+ # if lock wait timeout, do not increment the counter
+ if result[0] != -1:
+ batch_count += 1
+ total += result[0]
+ lockwait_count = 0
+ else:
+ lockwait_count += 1
+ if lockwait_count > args.lockwait_tries:
+ print("Quitting due to inability to get lock on table/rows for migration to parent")
+ break
+ # If no rows left or given batch argument limit is reached
+ if (result[0] == 0) or (args.batch > 0 and batch_count >= int(args.batch)):
+ break
+ if args.wait > 0:
+ time.sleep(args.wait)
+
+ return total
+
+
+if __name__ == "__main__":
+ conn = create_conn()
+ partman_schema = get_partman_schema(conn)
+
+ if not args.autovacuum_on:
+ turn_off_autovacuum(conn, partman_schema)
+
+ total = undo_partition_data(conn, partman_schema)
+
if not args.quiet:
- 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 (args.batch > 0 and batch_count >= int(args.batch)):
- break
- if args.wait > 0:
- time.sleep(float(args.wait))
-
-if not args.quiet:
- print total
-
-cur.close()
-conn.close()
+ print("Total rows moved: %d" % total)
+
+ vacuum_parent(conn)
+
+ if not args.autovacuum_on:
+ reset_autovacuum(conn, partman_schema)
+
+ close_conn(conn)
View
31 doc/pg_partman.md
@@ -9,7 +9,7 @@ If you attempt to insert data into a partition set that contains data for a part
### Child Table Property Inheritance
-For this extension, most of the attributes of the child partitions are all obtained from the original parent. This includes defaults, indexes (primary keys, unique, etc), tablespace, constraints, privileges & ownership. For managing privileges, whenever a new partition is created it will obtain its privilege & ownership information from what the parent has at that time. Previous partition privileges are not changed. If previous partitions require that their privileges be updated, a separate function is available. This is kept as a separate process due to being an expensive operation when the partition set grows larger. The defaults, indexes, tablespace & constraints on the parent are only applied to newly created partitions and are not retroactively set on ones that already existed. While you would not normally create indexes on the parent of a partition set, doing so makes it much easier to manage in this case. There will be no data in the parent table (if everything is working right), so they will not take up any space or have any impact on system performance. Using the parent table as a control to the details of the child tables like this gives a better place to manage things that's a little more natural than a configuration table or using setup functions.
+For this extension, most of the attributes of the child partitions are all obtained from the original parent. This includes defaults, indexes (primary keys, unique, etc), foreign keys, tablespace, constraints, privileges & ownership. This also includes the OID and UNLOGGED table properties. For managing privileges, whenever a new partition is created it will obtain its privilege & ownership information from what the parent has at that time. Previous partition privileges are not changed. If previous partitions require that their privileges be updated, a separate function is available. This is kept as a separate process due to being an expensive operation when the partition set grows larger. The defaults, indexes, tablespace & constraints on the parent are only applied to newly created partitions and are not retroactively set on ones that already existed. While you would not normally create indexes on the parent of a partition set, doing so makes it much easier to manage in this case. There will be no data in the parent table (if everything is working right), so they will not take up any space or have any impact on system performance. Using the parent table as a control to the details of the child tables like this gives a better place to manage things that's a little more natural than a configuration table or using setup functions.
### Retention
@@ -37,7 +37,7 @@ Table inheritance in PostgreSQL does not allow a primary key or unique index/con
### Logging/Monitoring
-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. Jobmon can also be turned on or off individually for each partition set by using the **jobmon** column in the **part_config** table or with the option to create_parent() during initial setup. 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).
+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. Jobmon can also be turned on or off individually for each partition set by using the **jobmon** column in the **part_config** table or with the option to create_parent() during initial setup. Note that if you try to partition pg_jobmon's tables you **MUST** set the option in create_parent() to false, otherwise it will be put into a permanent lockwait since pg_jobmon will be trying to write to the table it's trying to partition. 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).
Extension Objects
-----------------
@@ -172,9 +172,15 @@ quarter-hour - One partition per 15 minute interval on the quarter-hour (1200
* Be aware that for large partition sets, this can be a very long running operation and is why it was made into a separate function to run independently. Only privileges that are different between the parent & child are applied, but it still has to do system catalog lookups and comparisons for every single child partition and all individual privileges on each.
* p_parent_table - parent table of the partition set. Must be schema qualified and match a parent table name already configured in pg_partman.
+*apply_foreign_keys(p_parent_table text, p_child_table text DEFAULT NULL, p_debug boolean DEFAULT false)*
+ * Applies any foreign keys that exist on a parent table in a partition set to all the child tables.
+ * This function is automatically called whenever a new child table is created, so there is no need to manually run it unless you need to fix an existing child table.
+ * If you need to apply this to an entire partition set, see the **reapply_foreign_keys.py** python script. This will commit after every FK creation to avoid contention.
+ * This function can be used on any table inheritance set, not just ones managed by pg_partman.
+
### Destruction Functions
-*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*
+*undo_partition_time(p_parent_table text, p_batch_count int DEFAULT 1, p_batch_interval interval DEFAULT NULL, p_keep_table boolean DEFAULT true, p_lock_wait numeric DEFAULT 0) RETURNS bigint*
* 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 to stop.
@@ -186,9 +192,10 @@ quarter-hour - One partition per 15 minute interval on the quarter-hour (1200
* p_batch_count - an optional argument, this sets how many times to move the amount of data equal to the p_batch_interval argument (or default partition interval if not set) in a single run of the function. Defaults to 1.
* p_batch_interval - an 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_keep_table - an optional argument, setting this to false will cause the old child table to be dropped instead of uninherited after all of it's data has been moved. Note that it takes at least two batches to actually uninherit/drop a table from the set.
+ * p_lock_wait - optional argument, sets how long in seconds to wait for either the table or a row to be unlocked before timing out. Default is to wait forever.
* Returns the number of rows moved to the parent table. Returns zero when all child tables are empty.
-*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*
+*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, p_lock_wait numeric DEFAULT 0) RETURNS bigint*
* 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 to stop.
@@ -200,9 +207,10 @@ quarter-hour - One partition per 15 minute interval on the quarter-hour (1200
* p_batch_count - an optional argument, this sets how many times to move the amount of data equal to the p_batch_interval argument (or default partition interval if not set) in a single run of the function. Defaults to 1.
* p_batch_interval - an 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_keep_table - an optional argument, setting this to false will cause the old child table to be dropped instead of uninherited after all of it's data has been moved. Note that it takes at least two batches to actually uninherit/drop a table from the set (second batch sees it has no more data and drops it).
+ * p_lock_wait - optional argument, sets how long in seconds to wait for either the table or a row to be unlocked before timing out. Default is to wait forever.
* Returns the number of rows moved to the parent table. Returns zero when all child tables are empty.
-*undo_partition(p_parent_table text, p_batch_count int DEFAULT 1, p_keep_table boolean DEFAULT true, p_jobmon boolean DEFAULT true) RETURNS bigint*
+*undo_partition(p_parent_table text, p_batch_count int DEFAULT 1, p_keep_table boolean DEFAULT true, p_jobmon boolean DEFAULT true, p_lock_wait numeric DEFAULT 0) RETURNS bigint
* 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.
@@ -212,6 +220,7 @@ quarter-hour - One partition per 15 minute interval on the quarter-hour (1200
* p_batch_count - an optional argument, this sets how many partitions to copy data from in a single run. Defaults to 1.
* p_keep_table - an optional argument, setting this to false will cause the old child table to be dropped instead of uninherited.
* p_jobmon - an optional paramter to stop undo_partition() from using the pg_jobmon extension to log what it does. Defaults to true if not set.
+ * p_lock_wait - optional argument, sets how long in seconds to wait for either the table or a row to be unlocked before timing out. Default is to wait forever.
* 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, p_retention_schema text DEFAULT NULL) RETURNS int*
@@ -370,6 +379,16 @@ Partition by time in smaller intervals for at most 10 partitions in a single run
* --dryrun: Show what the script will do without actually running it against the database. Highly recommend reviewing this before running.
* --quiet (-q): Turn off all output.
+*reapply_foreign_keys.py*
+ * A python script for redoing the inherited foreign keys for an entire partition set.
+ * All existing foreign keys on all child tables are dropped and the foreign keys that exist on the parent at the time this is run will be applied to all children.
+ * Commits after each foreign key is created to avoid long periods of contention.
+ * --parent (-p) Parent table of an already created partition set. (Required)
+ * --connection (-c) Connection string for use by psycopg to connect to your database. Defaults to "host=localhost".
+ * --quiet (-q ) Switch setting to stop all output during and after partitioning undo.
+ * --dryrun Show what the script will do without actually running it against the database. Highly recommend reviewing this before running.
+ * --debug Show additional debugging output
+
*check_unique_constraints.py*
* Partitioning using inheritance has the shortcoming of not allowing a unique constraint to apply to all tables in the entire partition set without causing large performance issues once the partition set begins to grow very large. This script is used to check that all rows in a partition set are unique for the given columns.
* Note that on very large partition sets this can be an expensive operation to run that can consume a large chunk of storage space. The amount of storage space required is enough to dump out the entire index's column data as a plaintext file.
@@ -380,5 +399,5 @@ Partition by time in smaller intervals for at most 10 partitions in a single run
* --temp (-t): Path to a writable folder that can be used for temp working files. Defaults system temp folder.
* --psql Full path to psql binary if not in current PATH.
* --simple Output a single integer value with the total duplicate count. Use this for monitoring software that requires a simple value to be checked for.
- * --quiet Suppress all output unless there is a constraint violation found.
+ * --quiet (-q) Suppress all output unless there is a constraint violation found.
View
2  pg_partman.control
@@ -1,3 +1,3 @@
-default_version = '1.7.0'
+default_version = '1.7.1'
comment = 'Extension to manage partitioned tables by time or ID'
relocatable = false
View
119 sql/functions/apply_foreign_keys.sql
@@ -0,0 +1,119 @@
+/*
+ * Apply foreign keys that exist on the given parent to the given child table
+ */
+CREATE FUNCTION apply_foreign_keys(p_parent_table text, p_child_table text DEFAULT NULL, p_debug boolean DEFAULT false) RETURNS void
+ LANGUAGE plpgsql
+ AS $$
+DECLARE
+
+v_job_id bigint;
+v_jobmon text;
+v_jobmon_schema text;
+v_old_search_path text;
+v_ref_schema text;
+v_ref_table text;
+v_row record;
+v_schemaname text;
+v_sql text;
+v_step_id bigint;
+v_tablename text;
+
+BEGIN
+
+SELECT jobmon INTO v_jobmon FROM @extschema@.part_config WHERE parent_table = p_parent_table;
+
+IF v_jobmon THEN
+ SELECT nspname INTO v_jobmon_schema FROM pg_catalog.pg_namespace n, pg_catalog.pg_extension e WHERE e.extname = 'pg_jobmon' AND e.extnamespace = n.oid;
+ IF v_jobmon_schema IS NOT NULL THEN
+ SELECT current_setting('search_path') INTO v_old_search_path;
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+ END IF;
+END IF;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ v_job_id := add_job('PARTMAN APPLYING FOREIGN KEYS: '||p_parent_table);
+END IF;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ v_step_id := add_step(v_job_id, 'Checking if target child table exists');
+END IF;
+
+SELECT schemaname, tablename INTO v_schemaname, v_tablename
+FROM pg_catalog.pg_tables
+WHERE schemaname||'.'||tablename = p_child_table;
+
+IF v_tablename IS NULL THEN
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'CRITICAL', 'Target child table ('||v_child_table||') does not exist.');
+ PERFORM fail_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+ END IF;
+ RAISE EXCEPTION 'Target child table (%.%) does not exist.', v_schemaname, v_tablename;
+ RETURN;
+ELSE
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Done');
+ END IF;
+END IF;
+
+FOR v_row IN
+ SELECT keys.conname
+ , keys.confrelid::regclass::text AS ref_table
+ , '"'||string_agg(att.attname, '","')||'"' AS ref_column
+ , '"'||string_agg(att2.attname, '","')||'"' AS child_column
+ FROM
+ ( SELECT con.conname
+ , unnest(con.conkey) as ref
+ , unnest(con.confkey) as child
+ , con.confrelid
+ , con.conrelid
+ FROM pg_catalog.pg_class c
+ JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
+ JOIN pg_catalog.pg_constraint con ON c.oid = con.conrelid
+ WHERE n.nspname ||'.'|| c.relname = p_parent_table
+ AND con.contype = 'f'
+ ORDER BY con.conkey
+ ) keys
+ JOIN pg_catalog.pg_class cl ON cl.oid = keys.confrelid
+ JOIN pg_catalog.pg_attribute att ON att.attrelid = keys.confrelid AND att.attnum = keys.child
+ JOIN pg_catalog.pg_attribute att2 ON att2.attrelid = keys.conrelid AND att2.attnum = keys.ref
+ GROUP BY keys.conname, keys.confrelid
+LOOP
+ SELECT schemaname, tablename INTO v_ref_schema, v_ref_table FROM pg_tables WHERE schemaname||'.'||tablename = v_row.ref_table;
+ v_sql := format('ALTER TABLE %I.%I ADD FOREIGN KEY (%s) REFERENCES %I.%I (%s)',
+ v_schemaname, v_tablename, v_row.child_column, v_ref_schema, v_ref_table, v_row.ref_column);
+
+ IF v_jobmon_schema IS NOT NULL THEN
+ v_step_id := add_step(v_job_id, 'Applying FK: '||v_sql);
+ END IF;
+
+ EXECUTE v_sql;
+
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'FK applied');
+ END IF;
+
+END LOOP;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM close_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+END IF;
+
+EXCEPTION
+ WHEN OTHERS THEN
+ IF v_jobmon_schema IS NOT NULL THEN
+ IF v_job_id IS NULL THEN
+ EXECUTE 'SELECT '||v_jobmon_schema||'.add_job(''PARTMAN APPLYING FOREIGN KEYS: '||p_parent_table||''')' INTO v_job_id;
+ EXECUTE 'SELECT '||v_jobmon_schema||'.add_step('||v_job_id||', ''EXCEPTION before job logging started'')' INTO v_step_id;
+ ELSIF v_step_id IS NULL THEN
+ EXECUTE 'SELECT '||v_jobmon_schema||'.add_step('||v_job_id||', ''EXCEPTION before first step logged'')' INTO v_step_id;
+ END IF;
+ EXECUTE 'SELECT '||v_jobmon_schema||'.update_step('||v_step_id||', ''CRITICAL'', ''ERROR: '||coalesce(SQLERRM,'unknown')||''')';
+ EXECUTE 'SELECT '||v_jobmon_schema||'.fail_job('||v_job_id||')';
+ END IF;
+ RAISE EXCEPTION '%', SQLERRM;
+END
+$$;
+
+
View
13 sql/functions/create_id_partition.sql
@@ -27,6 +27,7 @@ v_revoke text[];
v_sql text;
v_step_id bigint;
v_tablename text;
+v_unlogged char;
BEGIN
@@ -71,8 +72,13 @@ FOREACH v_id IN ARRAY p_partition_ids LOOP
v_step_id := add_step(v_job_id, 'Creating new partition '||v_partition_name||' with interval from '||v_id||' to '||(v_id + v_part_interval)-1);
END IF;
- v_sql := 'CREATE TABLE '||v_partition_name||' (LIKE '||p_parent_table||' INCLUDING DEFAULTS INCLUDING CONSTRAINTS INCLUDING INDEXES INCLUDING STORAGE INCLUDING COMMENTS)';
- SELECT relhasoids INTO v_hasoids FROM pg_class WHERE oid::regclass = p_parent_table::regclass;
+ SELECT relpersistence INTO v_unlogged FROM pg_catalog.pg_class WHERE oid::regclass = p_parent_table::regclass;
+ v_sql := 'CREATE';
+ IF v_unlogged = 'u' THEN
+ v_sql := v_sql || ' UNLOGGED';
+ END IF;
+ v_sql := v_sql || ' TABLE '||v_partition_name||' (LIKE '||p_parent_table||' INCLUDING DEFAULTS INCLUDING CONSTRAINTS INCLUDING INDEXES INCLUDING STORAGE INCLUDING COMMENTS)';
+ SELECT relhasoids INTO v_hasoids FROM pg_catalog.pg_class WHERE oid::regclass = p_parent_table::regclass;
IF v_hasoids IS TRUE THEN
v_sql := v_sql || ' WITH (OIDS)';
END IF;
@@ -111,6 +117,8 @@ FOREACH v_id IN ARRAY p_partition_ids LOOP
EXECUTE 'ALTER TABLE '||v_partition_name||' OWNER TO '||v_parent_owner;
+ PERFORM @extschema@.apply_foreign_keys(quote_ident(v_parent_schema)||'.'||quote_ident(v_parent_tablename), v_partition_name);
+
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
PERFORM close_job(v_job_id);
@@ -144,4 +152,3 @@ EXCEPTION
END
$$;
-
View
12 sql/functions/create_time_partition.sql
@@ -35,6 +35,7 @@ v_tablename text;
v_trunc_value text;
v_time timestamp;
v_type text;
+v_unlogged char;
v_year text;
BEGIN
@@ -118,8 +119,13 @@ FOREACH v_time IN ARRAY p_partition_times LOOP
v_step_id := add_step(v_job_id, 'Creating new partition '||v_partition_name||' with interval from '||v_partition_timestamp_start||' to '||(v_partition_timestamp_end-'1sec'::interval));
END IF;
- v_sql := 'CREATE TABLE '||v_partition_name||' (LIKE '||p_parent_table||' INCLUDING DEFAULTS INCLUDING CONSTRAINTS INCLUDING INDEXES INCLUDING STORAGE INCLUDING COMMENTS)';
- SELECT relhasoids INTO v_hasoids FROM pg_class WHERE oid::regclass = p_parent_table::regclass;
+ SELECT relpersistence INTO v_unlogged FROM pg_catalog.pg_class WHERE oid::regclass = p_parent_table::regclass;
+ v_sql := 'CREATE';
+ IF v_unlogged = 'u' THEN
+ v_sql := v_sql || ' UNLOGGED';
+ END IF;
+ v_sql := v_sql || ' TABLE '||v_partition_name||' (LIKE '||p_parent_table||' INCLUDING DEFAULTS INCLUDING CONSTRAINTS INCLUDING INDEXES INCLUDING STORAGE INCLUDING COMMENTS)';
+ SELECT relhasoids INTO v_hasoids FROM pg_catalog.pg_class WHERE oid::regclass = p_parent_table::regclass;
IF v_hasoids IS TRUE THEN
v_sql := v_sql || ' WITH (OIDS)';
END IF;
@@ -164,6 +170,8 @@ FOREACH v_time IN ARRAY p_partition_times LOOP
EXECUTE 'ALTER TABLE '||v_partition_name||' OWNER TO '||v_parent_owner;
+ PERFORM @extschema@.apply_foreign_keys(quote_ident(v_parent_schema)||'.'||quote_ident(v_parent_tablename), v_partition_name);
+
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
IF v_step_overflow_id IS NOT NULL THEN
View
77 sql/functions/undo_partition.sql
@@ -2,7 +2,7 @@
* Function to undo partitioning.
* Will actually work on any parent/child table set, not just ones created by pg_partman.
*/
-CREATE FUNCTION undo_partition(p_parent_table text, p_batch_count int DEFAULT 1, p_keep_table boolean DEFAULT true, p_jobmon boolean DEFAULT true) RETURNS bigint
+CREATE FUNCTION undo_partition(p_parent_table text, p_batch_count int DEFAULT 1, p_keep_table boolean DEFAULT true, p_jobmon boolean DEFAULT true, p_lock_wait numeric DEFAULT 0) RETURNS bigint
LANGUAGE plpgsql SECURITY DEFINER
AS $$
DECLARE
@@ -15,6 +15,8 @@ v_copy_sql text;
v_function_name text;
v_job_id bigint;
v_jobmon_schema text;
+v_lock_iter int := 1;
+v_lock_obtained boolean := FALSE;
v_old_search_path text;
v_parent_schema text;
v_parent_tablename text;
@@ -52,7 +54,33 @@ UPDATE @extschema@.part_config SET undo_in_progress = true WHERE parent_table =
SELECT schemaname, tablename INTO v_parent_schema, v_parent_tablename FROM pg_tables WHERE schemaname ||'.'|| tablename = p_parent_table;
v_trig_name := @extschema@.check_name_length(p_object_name := v_parent_tablename, p_suffix := '_part_trig');
v_function_name := @extschema@.check_name_length(v_parent_tablename, v_parent_schema, '_part_trig_func', FALSE);
-EXECUTE 'DROP TRIGGER IF EXISTS '||v_trig_name||' ON '||p_parent_table;
+
+SELECT tgname INTO v_trig_name FROM pg_catalog.pg_trigger t WHERE tgname = v_trig_name;
+IF v_trig_name IS NOT NULL THEN
+ -- lockwait for trigger drop
+ IF p_lock_wait > 0 THEN
+ v_lock_iter := 0;
+ WHILE v_lock_iter <= 5 LOOP
+ v_lock_iter := v_lock_iter + 1;
+ BEGIN
+ EXECUTE 'LOCK TABLE ONLY '||p_parent_table||' IN ACCESS EXCLUSIVE MODE NOWAIT';
+ v_lock_obtained := TRUE;
+ EXCEPTION
+ WHEN lock_not_available THEN
+ PERFORM pg_sleep( p_lock_wait / 5.0 );
+ CONTINUE;
+ END;
+ EXIT WHEN v_lock_obtained;
+ END LOOP;
+ IF NOT v_lock_obtained THEN
+ RAISE NOTICE 'Unable to obtain lock on parent table to remove trigger';
+ RETURN -1;
+ END IF;
+ END IF; -- END p_lock_wait IF
+ EXECUTE 'DROP TRIGGER IF EXISTS '||v_trig_name||' ON '||p_parent_table;
+END IF; -- END trigger IF
+v_lock_obtained := FALSE; -- reset for reuse later
+
EXECUTE 'DROP FUNCTION IF EXISTS '||v_function_name||'()';
IF v_jobmon_schema IS NOT NULL THEN
@@ -72,6 +100,29 @@ WHILE v_batch_loop_count < p_batch_count LOOP
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.
+
+ -- lockwait timeout for table drop
+ IF p_lock_wait > 0 THEN
+ v_lock_iter := 0;
+ WHILE v_lock_iter <= 5 LOOP
+ v_lock_iter := v_lock_iter + 1;
+ BEGIN
+ EXECUTE 'LOCK TABLE ONLY '||v_child_table||' IN ACCESS EXCLUSIVE MODE NOWAIT';
+ v_lock_obtained := TRUE;
+ EXCEPTION
+ WHEN lock_not_available THEN
+ PERFORM pg_sleep( p_lock_wait / 5.0 );
+ CONTINUE;
+ END;
+ EXIT WHEN v_lock_obtained;
+ END LOOP;
+ IF NOT v_lock_obtained THEN
+ RAISE NOTICE 'Unable to obtain lock on child table for removal from partition set';
+ RETURN -1;
+ END IF;
+ END IF; -- END p_lock_wait IF
+ v_lock_obtained := FALSE; -- reset for reuse later
+
EXECUTE 'ALTER TABLE '||v_child_table||' NO INHERIT ' || p_parent_table;
IF p_keep_table = false THEN
EXECUTE 'DROP TABLE '||v_child_table;
@@ -91,6 +142,27 @@ WHILE v_batch_loop_count < p_batch_count LOOP
v_step_id := add_step(v_job_id, 'Removing child partition: '||v_child_table);
END IF;
+ -- do some locking with timeout, if required
+ IF p_lock_wait > 0 THEN
+ v_lock_iter := 0;
+ WHILE v_lock_iter <= 5 LOOP
+ v_lock_iter := v_lock_iter + 1;
+ BEGIN
+ EXECUTE 'SELECT * FROM '|| v_child_table ||' FOR UPDATE NOWAIT';
+ v_lock_obtained := TRUE;
+ EXCEPTION
+ WHEN lock_not_available THEN
+ PERFORM pg_sleep( p_lock_wait / 5.0 );
+ CONTINUE;
+ END;
+ EXIT WHEN v_lock_obtained;
+ END LOOP;
+ IF NOT v_lock_obtained THEN
+ RAISE NOTICE 'Unable to obtain lock on batch of rows to move';
+ RETURN -1;
+ END IF;
+ END IF;
+
v_copy_sql := 'INSERT INTO '||p_parent_table||' SELECT * FROM '||v_child_table;
EXECUTE v_copy_sql;
GET DIAGNOSTICS v_rowcount = ROW_COUNT;
@@ -149,3 +221,4 @@ EXCEPTION
END
$$;
+
View
79 sql/functions/undo_partition_id.sql
@@ -1,7 +1,7 @@
/*
* Function to undo id-based partitioning created by this extension
*/
-CREATE 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
+CREATE 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, p_lock_wait numeric DEFAULT 0) RETURNS bigint
LANGUAGE plpgsql SECURITY DEFINER
AS $$
DECLARE
@@ -12,11 +12,14 @@ v_child_loop_total bigint := 0;
v_child_min bigint;
v_child_table text;
v_control text;
+v_exists int;
v_function_name text;
v_inner_loop_count int;
v_job_id bigint;
v_jobmon boolean;
v_jobmon_schema text;
+v_lock_iter int := 1;
+v_lock_obtained boolean := FALSE;
v_move_sql text;
v_old_search_path text;
v_parent_schema text;
@@ -74,7 +77,33 @@ UPDATE @extschema@.part_config SET undo_in_progress = true WHERE parent_table =
SELECT schemaname, tablename INTO v_parent_schema, v_parent_tablename FROM pg_tables WHERE schemaname ||'.'|| tablename = p_parent_table;
v_trig_name := @extschema@.check_name_length(p_object_name := v_parent_tablename, p_suffix := '_part_trig');
v_function_name := @extschema@.check_name_length(v_parent_tablename, v_parent_schema, '_part_trig_func', FALSE);
-EXECUTE 'DROP TRIGGER IF EXISTS '||v_trig_name||' ON '||p_parent_table;
+
+SELECT tgname INTO v_trig_name FROM pg_catalog.pg_trigger t WHERE tgname = v_trig_name;
+IF v_trig_name IS NOT NULL THEN
+ -- lockwait for trigger drop
+ IF p_lock_wait > 0 THEN
+ v_lock_iter := 0;
+ WHILE v_lock_iter <= 5 LOOP
+ v_lock_iter := v_lock_iter + 1;
+ BEGIN
+ EXECUTE 'LOCK TABLE ONLY '||p_parent_table||' IN ACCESS EXCLUSIVE MODE NOWAIT';
+ v_lock_obtained := TRUE;
+ EXCEPTION
+ WHEN lock_not_available THEN
+ PERFORM pg_sleep( p_lock_wait / 5.0 );
+ CONTINUE;
+ END;
+ EXIT WHEN v_lock_obtained;
+ END LOOP;
+ IF NOT v_lock_obtained THEN
+ RAISE NOTICE 'Unable to obtain lock on parent table to remove trigger';
+ RETURN -1;
+ END IF;
+ END IF; -- END p_lock_wait IF
+ EXECUTE 'DROP TRIGGER IF EXISTS '||v_trig_name||' ON '||p_parent_table;
+END IF; -- END trigger IF
+v_lock_obtained := FALSE; -- reset for reuse later
+
EXECUTE 'DROP FUNCTION IF EXISTS '||v_function_name||'()';
IF v_jobmon_schema IS NOT NULL THEN
@@ -99,6 +128,29 @@ WHILE v_batch_loop_count < p_batch_count LOOP
EXECUTE 'SELECT min('||v_control||') FROM '||v_child_table INTO v_child_min;
IF v_child_min IS NULL THEN
-- No rows left in this child table. Remove from partition set.
+
+ -- lockwait timeout for table drop
+ IF p_lock_wait > 0 THEN
+ v_lock_iter := 0;
+ WHILE v_lock_iter <= 5 LOOP
+ v_lock_iter := v_lock_iter + 1;
+ BEGIN
+ EXECUTE 'LOCK TABLE ONLY '||v_child_table||' IN ACCESS EXCLUSIVE MODE NOWAIT';
+ v_lock_obtained := TRUE;
+ EXCEPTION
+ WHEN lock_not_available THEN
+ PERFORM pg_sleep( p_lock_wait / 5.0 );
+ CONTINUE;
+ END;
+ EXIT WHEN v_lock_obtained;
+ END LOOP;
+ IF NOT v_lock_obtained THEN
+ RAISE NOTICE 'Unable to obtain lock on child table for removal from partition set';
+ RETURN -1;
+ END IF;
+ END IF; -- END p_lock_wait IF
+ v_lock_obtained := FALSE; -- reset for reuse later
+
EXECUTE 'ALTER TABLE '||v_child_table||' NO INHERIT ' || p_parent_table;
IF p_keep_table = false THEN
EXECUTE 'DROP TABLE '||v_child_table;
@@ -117,6 +169,29 @@ WHILE v_batch_loop_count < p_batch_count LOOP
v_child_loop_total := 0;
<<inner_child_loop>>
LOOP
+ -- lockwait timeout for row batches
+ IF p_lock_wait > 0 THEN
+ v_lock_iter := 0;
+ WHILE v_lock_iter <= 5 LOOP
+ v_lock_iter := v_lock_iter + 1;
+ BEGIN
+ EXECUTE 'SELECT * FROM ' || v_child_table ||
+ ' WHERE '||v_control||' <= '||quote_literal(v_child_min + (p_batch_interval * v_inner_loop_count))
+ ||' FOR UPDATE NOWAIT';
+ v_lock_obtained := TRUE;
+ EXCEPTION
+ WHEN lock_not_available THEN
+ PERFORM pg_sleep( p_lock_wait / 5.0 );
+ CONTINUE;
+ END;
+ EXIT WHEN v_lock_obtained;
+ END LOOP;
+ IF NOT v_lock_obtained THEN
+ RAISE NOTICE 'Unable to obtain lock on batch of rows to move';
+ RETURN -1;
+ END IF;
+ END IF;
+
-- Get everything from the current child minimum up to the multiples of the given interval
v_move_sql := 'WITH move_data AS (DELETE FROM '||v_child_table||
' WHERE '||v_control||' <= '||quote_literal(v_child_min + (p_batch_interval * v_inner_loop_count))||' RETURNING *)
View
79 sql/functions/undo_partition_time.sql
@@ -1,7 +1,7 @@
/*
* Function to undo time-based partitioning created by this extension
*/
-CREATE 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
+CREATE FUNCTION undo_partition_time(p_parent_table text, p_batch_count int DEFAULT 1, p_batch_interval interval DEFAULT NULL, p_keep_table boolean DEFAULT true, p_lock_wait numeric DEFAULT 0) RETURNS bigint
LANGUAGE plpgsql SECURITY DEFINER
AS $$
DECLARE
@@ -14,6 +14,8 @@ v_child_table text;
v_control text;
v_function_name text;
v_inner_loop_count int;
+v_lock_iter int := 1;
+v_lock_obtained boolean := FALSE;
v_job_id bigint;
v_jobmon boolean;
v_jobmon_schema text;
@@ -74,7 +76,33 @@ UPDATE @extschema@.part_config SET undo_in_progress = true WHERE parent_table =
SELECT schemaname, tablename INTO v_parent_schema, v_parent_tablename FROM pg_tables WHERE schemaname ||'.'|| tablename = p_parent_table;
v_trig_name := @extschema@.check_name_length(p_object_name := v_parent_tablename, p_suffix := '_part_trig');
v_function_name := @extschema@.check_name_length(v_parent_tablename, v_parent_schema, '_part_trig_func', FALSE);
-EXECUTE 'DROP TRIGGER IF EXISTS '||v_trig_name||' ON '||p_parent_table;
+
+SELECT tgname INTO v_trig_name FROM pg_catalog.pg_trigger t WHERE tgname = v_trig_name;
+IF v_trig_name IS NOT NULL THEN
+ -- lockwait for trigger drop
+ IF p_lock_wait > 0 THEN
+ v_lock_iter := 0;
+ WHILE v_lock_iter <= 5 LOOP
+ v_lock_iter := v_lock_iter + 1;
+ BEGIN
+ EXECUTE 'LOCK TABLE ONLY '||p_parent_table||' IN ACCESS EXCLUSIVE MODE NOWAIT';
+ v_lock_obtained := TRUE;
+ EXCEPTION
+ WHEN lock_not_available THEN
+ PERFORM pg_sleep( p_lock_wait / 5.0 );
+ CONTINUE;
+ END;
+ EXIT WHEN v_lock_obtained;
+ END LOOP;
+ IF NOT v_lock_obtained THEN
+ RAISE NOTICE 'Unable to obtain lock on parent table to remove trigger';
+ RETURN -1;
+ END IF;
+ END IF; -- END p_lock_wait IF
+ EXECUTE 'DROP TRIGGER IF EXISTS '||v_trig_name||' ON '||p_parent_table;
+END IF; -- END trigger IF
+v_lock_obtained := FALSE; -- reset for reuse later
+
EXECUTE 'DROP FUNCTION IF EXISTS '||v_function_name||'()';
IF v_jobmon_schema IS NOT NULL THEN
@@ -99,6 +127,29 @@ WHILE v_batch_loop_count < p_batch_count LOOP
EXECUTE 'SELECT min('||v_control||') FROM '||v_child_table INTO v_child_min;
IF v_child_min IS NULL THEN
-- No rows left in this child table. Remove from partition set.
+
+ -- lockwait timeout for table drop
+ IF p_lock_wait > 0 THEN
+ v_lock_iter := 0;
+ WHILE v_lock_iter <= 5 LOOP
+ v_lock_iter := v_lock_iter + 1;
+ BEGIN
+ EXECUTE 'LOCK TABLE ONLY '||v_child_table||' IN ACCESS EXCLUSIVE MODE NOWAIT';
+ v_lock_obtained := TRUE;
+ EXCEPTION
+ WHEN lock_not_available THEN
+ PERFORM pg_sleep( p_lock_wait / 5.0 );
+ CONTINUE;
+ END;
+ EXIT WHEN v_lock_obtained;
+ END LOOP;
+ IF NOT v_lock_obtained THEN
+ RAISE NOTICE 'Unable to obtain lock on child table for removal from partition set';
+ RETURN -1;
+ END IF;
+ END IF; -- END p_lock_wait IF
+ v_lock_obtained := FALSE; -- reset for reuse later
+
EXECUTE 'ALTER TABLE '||v_child_table||' NO INHERIT ' || p_parent_table;
IF p_keep_table = false THEN
EXECUTE 'DROP TABLE '||v_child_table;
@@ -117,6 +168,29 @@ WHILE v_batch_loop_count < p_batch_count LOOP
v_child_loop_total := 0;
<<inner_child_loop>>
LOOP
+ -- do some locking with timeout, if required
+ IF p_lock_wait > 0 THEN
+ v_lock_iter := 0;
+ WHILE v_lock_iter <= 5 LOOP
+ v_lock_iter := v_lock_iter + 1;
+ BEGIN
+ EXECUTE 'SELECT * FROM ' || v_child_table ||
+ ' WHERE '||v_control||' <= '||quote_literal(v_child_min + (p_batch_interval * v_inner_loop_count))
+ ||' FOR UPDATE NOWAIT';
+ v_lock_obtained := TRUE;
+ EXCEPTION
+ WHEN lock_not_available THEN
+ PERFORM pg_sleep( p_lock_wait / 5.0 );
+ CONTINUE;
+ END;
+ EXIT WHEN v_lock_obtained;
+ END LOOP;
+ IF NOT v_lock_obtained THEN
+ RAISE NOTICE 'Unable to obtain lock on batch of rows to move';
+ RETURN -1;
+ END IF;
+ END IF;
+
-- Get everything from the current child minimum up to the multiples of the given interval
v_move_sql := 'WITH move_data AS (DELETE FROM '||v_child_table||
' WHERE '||v_control||' <= '||quote_literal(v_child_min + (p_batch_interval * v_inner_loop_count))||' RETURNING *)
@@ -173,3 +247,4 @@ EXCEPTION
END
$$;
+
View
21 test/test-id-dynamic-run-maint.sql
@@ -1,4 +1,5 @@
-- ########## ID DYNAMIC TESTS ##########
+-- Other tests: Single column Foreign Key
\set ON_ERROR_ROLLBACK 1
\set ON_ERROR_STOP true
@@ -6,13 +7,19 @@
BEGIN;
SELECT set_config('search_path','partman, public',false);
-SELECT plan(104);
+SELECT plan(113);
CREATE SCHEMA partman_test;
CREATE ROLE partman_basic;
CREATE ROLE partman_revoke;
CREATE ROLE partman_owner;
-CREATE TABLE partman_test.id_dynamic_table (col1 int primary key, col2 text, col3 timestamptz DEFAULT now());
+CREATE TABLE partman_test.fk_test_reference (col2 text unique not null);
+INSERT INTO partman_test.fk_test_reference VALUES ('stuff');
+
+CREATE TABLE partman_test.id_dynamic_table (
+ col1 int primary key
+ , col2 text not null default 'stuff' references partman_test.fk_test_reference (col2)
+ , col3 timestamptz DEFAULT now());
INSERT INTO partman_test.id_dynamic_table (col1) VALUES (generate_series(1,9));
GRANT SELECT,INSERT,UPDATE ON partman_test.id_dynamic_table TO partman_basic;
GRANT ALL ON partman_test.id_dynamic_table TO partman_revoke;
@@ -39,6 +46,11 @@ SELECT table_privs_are('partman_test', 'id_dynamic_table_p10', 'partman_revoke',
SELECT table_privs_are('partman_test', 'id_dynamic_table_p20', 'partman_revoke', ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'], 'Check partman_revoke privileges of id_dynamic_table_p20');
SELECT table_privs_are('partman_test', 'id_dynamic_table_p30', 'partman_revoke', ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'], 'Check partman_revoke privileges of id_dynamic_table_p30');
SELECT table_privs_are('partman_test', 'id_dynamic_table_p40', 'partman_revoke', ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'], 'Check partman_revoke privileges of id_dynamic_table_p40');
+SELECT col_is_fk('partman_test', 'id_dynamic_table_p0', 'col2', 'Check that id_dynamic_table_p0 inherited foreign key');
+SELECT col_is_fk('partman_test', 'id_dynamic_table_p10', 'col2', 'Check that id_dynamic_table_p10 inherited foreign key');
+SELECT col_is_fk('partman_test', 'id_dynamic_table_p20', 'col2', 'Check that id_dynamic_table_p20 inherited foreign key');
+SELECT col_is_fk('partman_test', 'id_dynamic_table_p30', 'col2', 'Check that id_dynamic_table_p30 inherited foreign key');
+SELECT col_is_fk('partman_test', 'id_dynamic_table_p40', 'col2', 'Check that id_dynamic_table_p40 inherited foreign key');
SELECT results_eq('SELECT partition_data_id(''partman_test.id_dynamic_table'')::int', ARRAY[9], 'Check that partitioning function returns correct count of rows moved');
SELECT is_empty('SELECT * FROM ONLY partman_test.id_dynamic_table', 'Check that parent table has had data moved to partition');
@@ -61,6 +73,8 @@ SELECT has_table('partman_test', 'id_dynamic_table_p50', 'Check id_dynamic_table
SELECT has_table('partman_test', 'id_dynamic_table_p60', 'Check id_dynamic_table_p60 exists');
SELECT hasnt_table('partman_test', 'id_dynamic_table_p70', 'Check id_dynamic_table_p70 doesn''t exist yet');
SELECT col_is_pk('partman_test', 'id_dynamic_table_p50', ARRAY['col1'], 'Check for primary key in id_dynamic_table_p50');
+SELECT col_is_fk('partman_test', 'id_dynamic_table_p50', 'col2', 'Check that id_dynamic_table_p50 inherited foreign key');
+SELECT col_is_fk('partman_test', 'id_dynamic_table_p60', 'col2', 'Check that id_dynamic_table_p60 inherited foreign key');
SELECT table_privs_are('partman_test', 'id_dynamic_table_p0', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p0');
SELECT table_privs_are('partman_test', 'id_dynamic_table_p10', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p10');
SELECT table_privs_are('partman_test', 'id_dynamic_table_p20', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p20');
@@ -85,6 +99,8 @@ SELECT has_table('partman_test', 'id_dynamic_table_p70', 'Check id_dynamic_table
SELECT hasnt_table('partman_test', 'id_dynamic_table_p80', 'Check id_dynamic_table_p80 doesn''t exists yet');
SELECT col_is_pk('partman_test', 'id_dynamic_table_p60', ARRAY['col1'], 'Check for primary key in id_dynamic_table_p60');
SELECT col_is_pk('partman_test', 'id_dynamic_table_p70', ARRAY['col1'], 'Check for primary key in id_dynamic_table_p70');
+SELECT col_is_fk('partman_test', 'id_dynamic_table_p60', 'col2', 'Check that id_dynamic_table_p60 inherited foreign key');
+SELECT col_is_fk('partman_test', 'id_dynamic_table_p70', 'col2', 'Check that id_dynamic_table_p60 inherited foreign key');
SELECT table_privs_are('partman_test', 'id_dynamic_table_p0', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p0');
SELECT table_privs_are('partman_test', 'id_dynamic_table_p10', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p10');
SELECT table_privs_are('partman_test', 'id_dynamic_table_p20', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p20');
@@ -149,3 +165,4 @@ SELECT is_empty('SELECT * FROM partman_test.id_dynamic_table_p70', 'Check child
SELECT * FROM finish();
ROLLBACK;
+
View
14 test/test-id-dynamic.sql
@@ -1,4 +1,5 @@
-- ########## ID DYNAMIC TESTS ##########
+-- Additional tests: UNLOGGED
\set ON_ERROR_ROLLBACK 1
\set ON_ERROR_STOP true
@@ -6,13 +7,13 @@
BEGIN;
SELECT set_config('search_path','partman, public',false);
-SELECT plan(102);
+SELECT plan(111);
CREATE SCHEMA partman_test;
CREATE ROLE partman_basic;
CREATE ROLE partman_revoke;
CREATE ROLE partman_owner;
-CREATE TABLE partman_test.id_dynamic_table (col1 int primary key, col2 text, col3 timestamptz DEFAULT now());
+CREATE UNLOGGED TABLE partman_test.id_dynamic_table (col1 int primary key, col2 text, col3 timestamptz DEFAULT now());
INSERT INTO partman_test.id_dynamic_table (col1) VALUES (generate_series(1,9));
GRANT SELECT,INSERT,UPDATE ON partman_test.id_dynamic_table TO partman_basic;
GRANT ALL ON partman_test.id_dynamic_table TO partman_revoke;
@@ -39,6 +40,12 @@ SELECT table_privs_are('partman_test', 'id_dynamic_table_p10', 'partman_revoke',
SELECT table_privs_are('partman_test', 'id_dynamic_table_p20', 'partman_revoke', ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'], 'Check partman_revoke privileges of id_dynamic_table_p20');
SELECT table_privs_are('partman_test', 'id_dynamic_table_p30', 'partman_revoke', ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'], 'Check partman_revoke privileges of id_dynamic_table_p30');
SELECT table_privs_are('partman_test', 'id_dynamic_table_p40', 'partman_revoke', ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'], 'Check partman_revoke privileges of id_dynamic_table_p40');
+SELECT results_eq('SELECT relpersistence::text FROM pg_catalog.pg_class WHERE oid::regclass = ''partman_test.id_dynamic_table''::regclass', ARRAY['u'], 'Check that parent table is unlogged');
+SELECT results_eq('SELECT relpersistence::text FROM pg_catalog.pg_class WHERE oid::regclass = ''partman_test.id_dynamic_table_p0''::regclass', ARRAY['u'], 'Check that id_dynamic_table_p0 is unlogged');
+SELECT results_eq('SELECT relpersistence::text FROM pg_catalog.pg_class WHERE oid::regclass = ''partman_test.id_dynamic_table_p10''::regclass', ARRAY['u'], 'Check that id_dynamic_table_p10 is unlogged');
+SELECT results_eq('SELECT relpersistence::text FROM pg_catalog.pg_class WHERE oid::regclass = ''partman_test.id_dynamic_table_p20''::regclass', ARRAY['u'], 'Check that id_dynamic_table_p20 is unlogged');
+SELECT results_eq('SELECT relpersistence::text FROM pg_catalog.pg_class WHERE oid::regclass = ''partman_test.id_dynamic_table_p30''::regclass', ARRAY['u'], 'Check that id_dynamic_table_p30 is unlogged');
+SELECT results_eq('SELECT relpersistence::text FROM pg_catalog.pg_class WHERE oid::regclass = ''partman_test.id_dynamic_table_p40''::regclass', ARRAY['u'], 'Check that id_dynamic_table_p40 is unlogged');
SELECT results_eq('SELECT partition_data_id(''partman_test.id_dynamic_table'')::int', ARRAY[9], 'Check that partitioning function returns correct count of rows moved');
SELECT is_empty('SELECT * FROM ONLY partman_test.id_dynamic_table', 'Check that parent table has had data moved to partition');
@@ -53,6 +60,7 @@ SELECT results_eq('SELECT count(*)::int FROM partman_test.id_dynamic_table_p10',
SELECT results_eq('SELECT count(*)::int FROM partman_test.id_dynamic_table_p20', ARRAY[6], 'Check count from id_dynamic_table_p20');
SELECT has_table('partman_test', 'id_dynamic_table_p50', 'Check id_dynamic_table_p50 exists');
+SELECT results_eq('SELECT relpersistence::text FROM pg_catalog.pg_class WHERE oid::regclass = ''partman_test.id_dynamic_table_p50''::regclass', ARRAY['u'], 'Check that id_dynamic_table_p50 is unlogged');
SELECT hasnt_table('partman_test', 'id_dynamic_table_p60', 'Check id_dynamic_table_p60 doesn''t exists yet');
SELECT col_is_pk('partman_test', 'id_dynamic_table_p50', ARRAY['col1'], 'Check for primary key in id_dynamic_table_p50');
SELECT table_privs_are('partman_test', 'id_dynamic_table_p0', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p0');
@@ -74,7 +82,9 @@ SELECT results_eq('SELECT count(*)::int FROM partman_test.id_dynamic_table_p20',
SELECT results_eq('SELECT count(*)::int FROM partman_test.id_dynamic_table_p30', ARRAY[9], 'Check count from id_dynamic_table_p30');
SELECT has_table('partman_test', 'id_dynamic_table_p60', 'Check id_dynamic_table_p60 exists');
+SELECT results_eq('SELECT relpersistence::text FROM pg_catalog.pg_class WHERE oid::regclass = ''partman_test.id_dynamic_table_p60''::regclass', ARRAY['u'], 'Check that id_dynamic_table_p60 is unlogged');
SELECT has_table('partman_test', 'id_dynamic_table_p70', 'Check id_dynamic_table_p70 exists');
+SELECT results_eq('SELECT relpersistence::text FROM pg_catalog.pg_class WHERE oid::regclass = ''partman_test.id_dynamic_table_p70''::regclass', ARRAY['u'], 'Check that id_dynamic_table_p70 is unlogged');
SELECT hasnt_table('partman_test', 'id_dynamic_table_p80', 'Check id_dynamic_table_p80 doesn''t exists yet');
SELECT col_is_pk('partman_test', 'id_dynamic_table_p60', ARRAY['col1'], 'Check for primary key in id_dynamic_table_p60');
SELECT col_is_pk('partman_test', 'id_dynamic_table_p70', ARRAY['col1'], 'Check for primary key in id_dynamic_table_p70');
View
28 test/test-time-dynamic-yearly.sql
@@ -1,4 +1,5 @@
-- ########## TIME DYNAMIC TESTS ##########
+-- Other tests: Multi-column foreign key
\set ON_ERROR_ROLLBACK 1
\set ON_ERROR_STOP true
@@ -6,13 +7,22 @@
BEGIN;
SELECT set_config('search_path','partman, public',false);
-SELECT plan(83);
+SELECT plan(90);
CREATE SCHEMA partman_test;
CREATE ROLE partman_basic;
CREATE ROLE partman_revoke;
CREATE ROLE partman_owner;
-CREATE TABLE partman_test.time_dynamic_table (col1 int primary key, col2 text, col3 timestamptz NOT NULL DEFAULT now());
+CREATE TABLE partman_test.fk_test_reference (col2 text not null, col4 text not null);
+CREATE UNIQUE INDEX ON partman_test.fk_test_reference(col2, col4);
+INSERT INTO partman_test.fk_test_reference VALUES ('stuff', 'stuff');
+
+CREATE TABLE partman_test.time_dynamic_table (
+ col1 int primary key
+ , col2 text not null default 'stuff'
+ , col3 timestamptz NOT NULL DEFAULT now()
+ , col4 text not null default 'stuff'
+ , FOREIGN KEY (col2, col4) REFERENCES partman_test.fk_test_reference(col2, col4));
INSERT INTO partman_test.time_dynamic_table (col1, col3) VALUES (generate_series(1,10), CURRENT_TIMESTAMP);
GRANT SELECT,INSERT,UPDATE ON partman_test.time_dynamic_table TO partman_basic;
GRANT ALL ON partman_test.time_dynamic_table TO partman_revoke;
@@ -39,6 +49,16 @@ SELECT col_is_pk('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTA
'Check for primary key in time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'3 years'::interval, 'YYYY'));
SELECT col_is_pk('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'4 years'::interval, 'YYYY'), ARRAY['col1'],
'Check for primary key in time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'4 years'::interval, 'YYYY'));
+SELECT col_is_fk('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY'), ARRAY['col2', 'col4'],
+ 'Check for inherited foreign key in time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'1 year'::interval, 'YYYY'));
+SELECT col_is_fk('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'1 year'::interval, 'YYYY'), ARRAY['col2', 'col4'],
+ 'Check for inherited foreign key in time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY'));
+SELECT col_is_fk('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'2 years'::interval, 'YYYY'), ARRAY['col2', 'col4'],
+ 'Check for inherited foreign key in time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'2 years'::interval, 'YYYY'));
+SELECT col_is_fk('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'3 years'::interval, 'YYYY'), ARRAY['col2', 'col4'],
+ 'Check for inherited foreign key in time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'3 years'::interval, 'YYYY'));
+SELECT col_is_fk('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'4 years'::interval, 'YYYY'), ARRAY['col2', 'col4'],
+ 'Check for inherited foreign key in time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'4 years'::interval, 'YYYY'));
SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY'), 'partman_basic',
ARRAY['SELECT','INSERT','UPDATE'],
'Check partman_basic privileges of time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY'));
@@ -95,6 +115,8 @@ SELECT hasnt_table('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMES
'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 years'::interval, 'YYYY')||' exists');
SELECT col_is_pk('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'5 years'::interval, 'YYYY'), ARRAY['col1'],
'Check for primary key in time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'5 years'::interval, 'YYYY'));
+SELECT col_is_fk('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'5 years'::interval, 'YYYY'), ARRAY['col2', 'col4'],
+ 'Check for inherited foreign key in time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'5 years'::interval, 'YYYY'));
SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY'), 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'],
'Check partman_basic privileges of time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY'));
SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'1 year'::interval, 'YYYY'), 'partman_basic',
@@ -124,6 +146,8 @@ SELECT hasnt_table('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMES
'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'7 years'::interval, 'YYYY')||' exists');
SELECT col_is_pk('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 years'::interval, 'YYYY'), ARRAY['col1'],
'Check for primary key in time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 years'::interval, 'YYYY'));
+SELECT col_is_fk('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 years'::interval, 'YYYY'), ARRAY['col2', 'col4'],
+ 'Check for inherited foreign key in time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 years'::interval, 'YYYY'));
SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY'), 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'],
'Check partman_basic privileges of time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY'));
SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'1 year'::interval, 'YYYY'), 'partman_basic',
View
14 test/test-time-static-yearly.sql
@@ -1,4 +1,5 @@
-- ########## TIME STATIC TESTS ##########
+-- Other tests: UNLOGGED
\set ON_ERROR_ROLLBACK 1
\set ON_ERROR_STOP true
@@ -6,14 +7,14 @@
BEGIN;
SELECT set_config('search_path','partman, public',false);
-SELECT plan(129);
+SELECT plan(137);
CREATE SCHEMA partman_test;
CREATE SCHEMA partman_retention_test;
CREATE ROLE partman_basic;
CREATE ROLE partman_revoke;
CREATE ROLE partman_owner;
-CREATE TABLE partman_test.time_static_table (col1 int primary key, col2 text, col3 timestamptz NOT NULL DEFAULT now());
+CREATE UNLOGGED TABLE partman_test.time_static_table (col1 int primary key, col2 text, col3 timestamptz NOT NULL DEFAULT now());
INSERT INTO partman_test.time_static_table (col1, col3) VALUES (generate_series(1,10), CURRENT_TIMESTAMP);
GRANT SELECT,INSERT,UPDATE ON partman_test.time_static_table TO partman_basic;
GRANT ALL ON partman_test.time_static_table TO partman_revoke;
@@ -41,6 +42,13 @@ SELECT has_table('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAM
SELECT hasnt_table('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP-'5 years'::interval, 'YYYY'),
'Check time_static_table_'||to_char(CURRENT_TIMESTAMP-'5 years'::interval, 'YYYY')||' does not exist');
+SELECT results_eq('SELECT relpersistence::text FROM pg_catalog.pg_class WHERE oid::regclass = ''partman_test.time_static_table''::regclass', ARRAY['u'], 'Check that parent table is unlogged');
+SELECT results_eq('SELECT relpersistence::text FROM pg_catalog.pg_class WHERE oid::regclass = ''partman_test.time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY')||'''::regclass', ARRAY['u'], 'Check that partman_test.time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY')||' is unlogged');
+SELECT results_eq('SELECT relpersistence::text FROM pg_catalog.pg_class WHERE oid::regclass = ''partman_test.time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 year'::interval, 'YYYY')||'''::regclass', ARRAY['u'], 'Check that partman_test.time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 year'::interval, 'YYYY')||' is unlogged');
+SELECT results_eq('SELECT relpersistence::text FROM pg_catalog.pg_class WHERE oid::regclass = ''partman_test.time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 years'::interval, 'YYYY')||'''::regclass', ARRAY['u'], 'Check that partman_test.time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 years'::interval, 'YYYY')||' is unlogged');
+SELECT results_eq('SELECT relpersistence::text FROM pg_catalog.pg_class WHERE oid::regclass = ''partman_test.time_static_table_p'||to_char(CURRENT_TIMESTAMP+'3 years'::interval, 'YYYY')||'''::regclass', ARRAY['u'], 'Check that partman_test.time_static_table_p'||to_char(CURRENT_TIMESTAMP+'3 years'::interval, 'YYYY')||' is unlogged');
+SELECT results_eq('SELECT relpersistence::text FROM pg_catalog.pg_class WHERE oid::regclass = ''partman_test.time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 years'::interval, 'YYYY')||'''::regclass', ARRAY['u'], 'Check that partman_test.time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 years'::interval, 'YYYY')||' is unlogged');
+
SELECT col_is_pk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY'), ARRAY['col1'],
'Check for primary key in time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY'));
SELECT col_is_pk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 year'::interval, 'YYYY'), ARRAY['col1'],
@@ -158,6 +166,7 @@ INSERT INTO partman_test.time_static_table (col1, col3) VALUES (generate_series(
SELECT has_table('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'5 years'::interval, 'YYYY'),
'Check time_static_table_'||to_char(CURRENT_TIMESTAMP+'5 years'::interval, 'YYYY')||' exists');
+SELECT results_eq('SELECT relpersistence::text FROM pg_catalog.pg_class WHERE oid::regclass = ''partman_test.time_static_table_p'||to_char(CURRENT_TIMESTAMP+'5 years'::interval, 'YYYY')||'''::regclass', ARRAY['u'], 'Check that partman_test.time_static_table_p'||to_char(CURRENT_TIMESTAMP+'5 years'::interval, 'YYYY')||' is unlogged');
SELECT hasnt_table('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'6 years'::interval, 'YYYY'),
'Check time_static_table_'||to_char(CURRENT_TIMESTAMP+'6 years'::interval, 'YYYY')||' exists');
SELECT col_is_pk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'5 years'::interval, 'YYYY'), ARRAY['col1'],
@@ -212,6 +221,7 @@ SELECT results_eq('SELECT count(*)::int FROM partman_test.time_static_table_p'||
SELECT has_table('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'6 years'::interval, 'YYYY'),
'Check time_static_table_p'||to_char(CURRENT_TIMESTAMP+'6 years'::interval, 'YYYY')||' exists');
+SELECT results_eq('SELECT relpersistence::text FROM pg_catalog.pg_class WHERE oid::regclass = ''partman_test.time_static_table_p'||to_char(CURRENT_TIMESTAMP+'6 years'::interval, 'YYYY')||'''::regclass', ARRAY['u'], 'Check that partman_test.time_static_table_p'||to_char(CURRENT_TIMESTAMP+'6 years'::interval, 'YYYY')||' is unlogged');
SELECT hasnt_table('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'7 years'::interval, 'YYYY'),
'Check time_static_table_p'||to_char(CURRENT_TIMESTAMP+'7 years'::interval, 'YYYY')||' exists');
SELECT col_is_pk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'6 years'::interval, 'YYYY'), ARRAY['col1'],
View
1,259 updates/pg_partman--1.7.0--1.7.1.sql
@@ -0,0 +1,1259 @@
+-- Foreign keys placed on the parent table are now inherited to child tables.
+ -- Any new partitions created after this update is installed will have the FKs applied to children.
+ -- Existing child partitions will not have FKs applied. See the reapply_foreign_keys.py python script to reapply FKs to all child tables.
+ -- The new apply_foreign_keys() function & reapply_foreign_keys.py script can be applied to any table inheritance set, not just the ones managed by pg_partman.
+ -- See blog post for some more information about partitioning & foreign keys - http://www.keithf4.com/table-partitioning-and-foreign-keys
+-- Unlogged table property on parent table is now automatically inherited to child tables. Note this only applies to newly created child partitions after this update is installed.
+-- Added lockwait options to the undo partition functions (plpgsql & python)
+-- Added the same autovacuum feature & option to undo_partition.py that partition_data.py has.
+-- Made python scripts compatible with python 3
+-- PgTAP tests for unlogged tables and FK inheritance
+
+CREATE TEMP TABLE partman_preserve_privs_temp (statement text);
+
+INSERT INTO partman_preserve_privs_temp
+SELECT 'GRANT EXECUTE ON FUNCTION @extschema@.undo_partition_id(text, int, bigint, boolean, numeric) TO '||array_to_string(array_agg(grantee::text), ',')||';'
+FROM information_schema.routine_privileges
+WHERE routine_schema = '@extschema@'
+AND routine_name = 'undo_partition_id';
+
+INSERT INTO partman_preserve_privs_temp
+SELECT 'GRANT EXECUTE ON FUNCTION @extschema@.undo_partition_time(text, int, interval, boolean, numeric) TO '||array_to_string(array_agg(grantee::text), ',')||';'
+FROM information_schema.routine_privileges
+WHERE routine_schema = '@extschema@'
+AND routine_name = 'undo_partition_time';
+
+INSERT INTO partman_preserve_privs_temp
+SELECT 'GRANT EXECUTE ON FUNCTION @extschema@.undo_partition(text, int, boolean, boolean, numeric) TO '||array_to_string(array_agg(grantee::text), ',')||';'
+FROM information_schema.routine_privileges
+WHERE routine_schema = '@extschema@'
+AND routine_name = 'undo_partition';
+
+DROP FUNCTION undo_partition_id(text, int, bigint, boolean);
+DROP FUNCTION undo_partition_time(text, int, interval, boolean);
+DROP FUNCTION undo_partition(text, int, boolean, boolean);
+
+/*
+ * Apply foreign keys that exist on the given parent to the given child table
+ */
+CREATE FUNCTION apply_foreign_keys(p_parent_table text, p_child_table text DEFAULT NULL, p_debug boolean DEFAULT false) RETURNS void
+ LANGUAGE plpgsql
+ AS $$
+DECLARE
+
+v_job_id bigint;
+v_jobmon text;
+v_jobmon_schema text;
+v_old_search_path text;
+v_ref_schema text;
+v_ref_table text;
+v_row record;
+v_schemaname text;
+v_sql text;
+v_step_id bigint;
+v_tablename text;
+
+BEGIN
+
+SELECT jobmon INTO v_jobmon FROM @extschema@.part_config WHERE parent_table = p_parent_table;
+
+IF v_jobmon THEN
+ SELECT nspname INTO v_jobmon_schema FROM pg_catalog.pg_namespace n, pg_catalog.pg_extension e WHERE e.extname = 'pg_jobmon' AND e.extnamespace = n.oid;
+ IF v_jobmon_schema IS NOT NULL THEN
+ SELECT current_setting('search_path') INTO v_old_search_path;
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+ END IF;
+END IF;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ v_job_id := add_job('PARTMAN APPLYING FOREIGN KEYS: '||p_parent_table);
+END IF;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ v_step_id := add_step(v_job_id, 'Checking if target child table exists');
+END IF;
+
+SELECT schemaname, tablename INTO v_schemaname, v_tablename
+FROM pg_catalog.pg_tables
+WHERE schemaname||'.'||tablename = p_child_table;
+
+IF v_tablename IS NULL THEN
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'CRITICAL', 'Target child table ('||v_child_table||') does not exist.');
+ PERFORM fail_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+ END IF;
+ RAISE EXCEPTION 'Target child table (%.%) does not exist.', v_schemaname, v_tablename;
+ RETURN;
+ELSE
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Done');
+ END IF;
+END IF;
+
+FOR v_row IN
+ SELECT keys.conname
+ , keys.confrelid::regclass::text AS ref_table
+ , '"'||string_agg(att.attname, '","')||'"' AS ref_column
+ , '"'||string_agg(att2.attname, '","')||'"' AS child_column
+ FROM
+ ( SELECT con.conname
+ , unnest(con.conkey) as ref
+ , unnest(con.confkey) as child
+ , con.confrelid
+ , con.conrelid
+ FROM pg_catalog.pg_class c
+ JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
+ JOIN pg_catalog.pg_constraint con ON c.oid = con.conrelid
+ WHERE n.nspname ||'.'|| c.relname = p_parent_table
+ AND con.contype = 'f'
+ ORDER BY con.conkey
+ ) keys
+ JOIN pg_catalog.pg_class cl ON cl.oid = keys.confrelid
+ JOIN pg_catalog.pg_attribute att ON att.attrelid = keys.confrelid AND att.attnum = keys.child
+ JOIN pg_catalog.pg_attribute att2 ON att2.attrelid = keys.conrelid AND att2.attnum = keys.ref
+ GROUP BY keys.conname, keys.confrelid
+LOOP
+ SELECT schemaname, tablename INTO v_ref_schema, v_ref_table FROM pg_tables WHERE schemaname||'.'||tablename = v_row.ref_table;
+ v_sql := format('ALTER TABLE %I.%I ADD FOREIGN KEY (%s) REFERENCES %I.%I (%s)',
+ v_schemaname, v_tablename, v_row.child_column, v_ref_schema, v_ref_table, v_row.ref_column);
+
+ IF v_jobmon_schema IS NOT NULL THEN
+ v_step_id := add_step(v_job_id, 'Applying FK: '||v_sql);
+ END IF;
+
+ EXECUTE v_sql;
+
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'FK applied');
+ END IF;
+
+END LOOP;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM close_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+END IF;
+
+EXCEPTION
+ WHEN OTHERS THEN
+ IF v_jobmon_schema IS NOT NULL THEN
+ IF v_job_id IS NULL THEN
+ EXECUTE 'SELECT '||v_jobmon_schema||'.add_job(''PARTMAN APPLYING FOREIGN KEYS: '||p_parent_table||''')' INTO v_job_id;
+ EXECUTE 'SELECT '||v_jobmon_schema||'.add_step('||v_job_id||', ''EXCEPTION before job logging started'')' INTO v_step_id;
+ ELSIF v_step_id IS NULL THEN
+ EXECUTE 'SELECT '||v_jobmon_schema||'.add_step('||v_job_id||', ''EXCEPTION before first step logged'')' INTO v_step_id;
+ END IF;
+ EXECUTE 'SELECT '||v_jobmon_schema||'.update_step('||v_step_id||', ''CRITICAL'', ''ERROR: '||coalesce(SQLERRM,'unknown')||''')';
+ EXECUTE 'SELECT '||v_jobmon_schema||'.fail_job('||v_job_id||')';
+ END IF;
+ RAISE EXCEPTION '%', SQLERRM;
+END
+$$;
+
+
+/*
+ * Function to create id partitions
+ */
+CREATE OR REPLACE FUNCTION create_id_partition (p_parent_table text, p_partition_ids bigint[]) RETURNS text
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_all text[] := ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'];
+v_analyze boolean := FALSE;
+v_control text;
+v_grantees text[];
+v_hasoids boolean;
+v_id bigint;
+v_job_id bigint;
+v_jobmon boolean;
+v_jobmon_schema text;
+v_old_search_path text;
+v_parent_grant record;
+v_parent_owner text;
+v_parent_schema text;
+v_parent_tablename text;
+v_parent_tablespace text;
+v_part_interval bigint;
+v_partition_name text;
+v_revoke text[];
+v_sql text;
+v_step_id bigint;
+v_tablename text;
+v_unlogged char;
+
+BEGIN
+
+SELECT control
+ , part_interval
+ , jobmon
+INTO v_control
+ , v_part_interval
+ , v_jobmon
+FROM @extschema@.part_config
+WHERE parent_table = p_parent_table
+AND (type = 'id-static' OR type = 'id-dynamic');
+
+IF NOT FOUND THEN
+ RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table;
+END IF;
+
+IF v_jobmon THEN
+ SELECT nspname INTO v_jobmon_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'pg_jobmon' AND e.extnamespace = n.oid;
+ IF v_jobmon_schema IS NOT NULL THEN
+ SELECT current_setting('search_path') INTO v_old_search_path;
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+ END IF;
+END IF;
+
+SELECT tableowner, schemaname, tablename, tablespace INTO v_parent_owner, v_parent_schema, v_parent_tablename, v_parent_tablespace FROM pg_tables WHERE schemaname ||'.'|| tablename = p_parent_table;
+
+FOREACH v_id IN ARRAY p_partition_ids LOOP
+ v_partition_name := @extschema@.check_name_length(v_parent_tablename, v_parent_schema, v_id::text, TRUE);
+
+ -- If child table already exists, skip creation
+ SELECT tablename INTO v_tablename FROM pg_catalog.pg_tables WHERE schemaname ||'.'|| tablename = v_partition_name;
+ IF v_tablename IS NOT NULL THEN
+ CONTINUE;
+ END IF;
+
+ -- Ensure analyze is run if a new partition is created. Otherwise if one isn't, will be false and analyze will be skipped
+ v_analyze := TRUE;
+
+ IF v_jobmon_schema IS NOT NULL THEN
+ v_job_id := add_job('PARTMAN CREATE TABLE: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Creating new partition '||v_partition_name||' with interval from '||v_id||' to '||(v_id + v_part_interval)-1);
+ END IF;
+
+ SELECT relpersistence INTO v_unlogged FROM pg_catalog.pg_class WHERE oid::regclass = p_parent_table::regclass;
+ v_sql := 'CREATE';
+ IF v_unlogged = 'u' THEN
+ v_sql := v_sql || ' UNLOGGED';
+ END IF;
+ v_sql := v_sql || ' TABLE '||v_partition_name||' (LIKE '||p_parent_table||' INCLUDING DEFAULTS INCLUDING CONSTRAINTS INCLUDING INDEXES INCLUDING STORAGE INCLUDING COMMENTS)';
+ SELECT relhasoids INTO v_hasoids FROM pg_catalog.pg_class WHERE oid::regclass = p_parent_table::regclass;
+ IF v_hasoids IS TRUE THEN
+ v_sql := v_sql || ' WITH (OIDS)';
+ END IF;
+ EXECUTE v_sql;
+ SELECT tablename INTO v_tablename FROM pg_catalog.pg_tables WHERE schemaname ||'.'|| tablename = v_partition_name;
+ IF v_parent_tablespace IS NOT NULL THEN
+ EXECUTE 'ALTER TABLE '||v_partition_name||' SET TABLESPACE '||v_parent_tablespace;
+ END IF;
+ EXECUTE 'ALTER TABLE '||v_partition_name||' ADD CONSTRAINT '||v_tablename||'_partition_check
+ CHECK ('||v_control||'>='||quote_literal(v_id)||' AND '||v_control||'<'||quote_literal(v_id + v_part_interval)||')';
+ EXECUTE 'ALTER TABLE '||v_partition_name||' INHERIT '||p_parent_table;
+
+ FOR v_parent_grant IN
+ SELECT array_agg(DISTINCT privilege_type::text ORDER BY privilege_type::text) AS types, grantee
+ FROM information_schema.table_privileges
+ WHERE table_schema ||'.'|| table_name = p_parent_table
+ GROUP BY grantee
+ LOOP
+ EXECUTE 'GRANT '||array_to_string(v_parent_grant.types, ',')||' ON '||v_partition_name||' TO '||v_parent_grant.grantee;
+ SELECT array_agg(r) INTO v_revoke FROM (SELECT unnest(v_all) AS r EXCEPT SELECT unnest(v_parent_grant.types)) x;
+ IF v_revoke IS NOT NULL THEN
+ EXECUTE 'REVOKE '||array_to_string(v_revoke, ',')||' ON '||v_partition_name||' FROM '||v_parent_grant.grantee||' CASCADE';
+ END IF;
+ v_grantees := array_append(v_grantees, v_parent_grant.grantee::text);
+ END LOOP;
+ -- Revoke all privileges from roles that have none on the parent
+ IF v_grantees IS NOT NULL THEN
+ SELECT array_agg(r) INTO v_revoke FROM (
+ SELECT DISTINCT grantee::text AS r FROM information_schema.table_privileges WHERE table_schema ||'.'|| table_name = v_partition_name
+ EXCEPT
+ SELECT unnest(v_grantees)) x;
+ IF v_revoke IS NOT NULL THEN
+ EXECUTE 'REVOKE ALL ON '||v_partition_name||' FROM '||array_to_string(v_revoke, ',');
+ END IF;
+ END IF;
+
+ EXECUTE 'ALTER TABLE '||v_partition_name||' OWNER TO '||v_parent_owner;
+
+ PERFORM @extschema@.apply_foreign_keys(quote_ident(v_parent_schema)||'.'||quote_ident(v_parent_tablename), v_partition_name);
+
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Done');
+ PERFORM close_job(v_job_id);
+ END IF;
+
+END LOOP;
+
+IF v_analyze THEN
+ EXECUTE 'ANALYZE '||p_parent_table;
+END IF;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+END IF;
+
+RETURN v_partition_name;
+
+EXCEPTION
+ WHEN OTHERS THEN
+ IF v_jobmon_schema IS NOT NULL THEN
+ IF v_job_id IS NULL THEN
+ EXECUTE 'SELECT '||v_jobmon_schema||'.add_job(''PARTMAN CREATE TABLE: '||p_parent_table||''')' INTO v_job_id;
+ EXECUTE 'SELECT '||v_jobmon_schema||'.add_step('||v_job_id||', ''EXCEPTION before job logging started'')' INTO v_step_id;
+ ELSIF v_step_id IS NULL THEN
+ EXECUTE 'SELECT '||v_jobmon_schema||'.add_step('||v_job_id||', ''EXCEPTION before first step logged'')' INTO v_step_id;
+ END IF;
+ EXECUTE 'SELECT '||v_jobmon_schema||'.update_step('||v_step_id||', ''CRITICAL'', ''ERROR: '||coalesce(SQLERRM,'unknown')||''')';
+ EXECUTE 'SELECT '||v_jobmon_schema||'.fail_job('||v_job_id||')';
+ END IF;
+ RAISE EXCEPTION '%', SQLERRM;
+END
+$$;
+
+
+/*
+ * Function to create a child table in a time-based partition set
+ */
+CREATE OR REPLACE FUNCTION create_time_partition (p_parent_table text, p_partition_times timestamp[])
+RETURNS text
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_all text[] := ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'];
+v_analyze boolean := FALSE;
+v_control text;
+v_grantees text[];
+v_hasoids boolean;
+v_job_id bigint;
+v_jobmon boolean;
+v_jobmon_schema text;
+v_old_search_path text;
+v_parent_grant record;
+v_parent_owner text;
+v_parent_schema text;
+v_parent_tablename text;
+v_partition_name text;
+v_partition_suffix text;
+v_parent_tablespace text;
+v_part_interval interval;
+v_partition_timestamp_end timestamp;
+v_partition_timestamp_start timestamp;
+v_quarter text;
+v_revoke text[];
+v_sql text;
+v_step_id bigint;
+v_step_overflow_id bigint;
+v_tablename text;
+v_trunc_value text;
+v_time timestamp;
+v_type text;
+v_unlogged char;
+v_year text;
+
+BEGIN
+
+SELECT type
+ , control
+ , part_interval
+ , jobmon
+INTO v_type
+ , v_control
+ , v_part_interval
+ , v_jobmon
+FROM @extschema@.part_config
+WHERE parent_table = p_parent_table
+AND (type = 'time-static' OR type = 'time-dynamic' OR type = 'time-custom');
+
+IF NOT FOUND THEN
+ RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table;
+END IF;
+
+IF v_jobmon THEN
+ SELECT nspname INTO v_jobmon_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'pg_jobmon' AND e.extnamespace = n.oid;
+ IF v_jobmon_schema IS NOT NULL THEN
+ SELECT current_setting('search_path') INTO v_old_search_path;
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+ END IF;
+END IF;
+
+SELECT tableowner, schemaname, tablename, tablespace INTO v_parent_owner, v_parent_schema, v_parent_tablename, v_parent_tablespace FROM pg_tables WHERE schemaname ||'.'|| tablename = p_parent_table;
+
+FOREACH v_time IN ARRAY p_partition_times LOOP
+
+ v_partition_suffix := to_char(v_time, 'YYYY');
+ IF v_part_interval < '1 year' AND v_part_interval <> '1 week' THEN
+ v_partition_suffix := v_partition_suffix ||'_'|| to_char(v_time, 'MM');
+ IF v_part_interval < '1 month' AND v_part_interval <> '1 week' THEN
+ v_partition_suffix := v_partition_suffix ||'_'|| to_char(v_time, 'DD');
+ IF v_part_interval < '1 day' THEN
+ v_partition_suffix := v_partition_suffix || '_' || to_char(v_time, 'HH24MI');
+ IF v_part_interval < '1 minute' THEN
+ v_partition_suffix := v_partition_suffix || to_char(v_time, 'SS');
+ END IF; -- end < minute IF
+ END IF; -- end < day IF
+ END IF; -- end < month IF
+ END IF; -- end < year IF
+
+ v_partition_timestamp_start := v_time;
+ BEGIN
+ v_partition_timestamp_end := v_time + v_part_interval;
+ EXCEPTION WHEN datetime_field_overflow THEN
+ RAISE WARNING 'Attempted partition time interval is outside PostgreSQL''s supported time range.
+ Child partition creation after time % skipped', v_time;
+ v_step_overflow_id := add_step(v_job_id, 'Attempted partition time interval is outside PostgreSQL''s supported time range.');
+ PERFORM update_step(v_step_overflow_id, 'CRITICAL', 'Child partition creation after time '||v_time||' skipped');
+ CONTINUE;
+ END;
+
+ IF v_part_interval = '1 week' THEN
+ v_partition_suffix := to_char(v_time, 'IYYY') || 'w' || to_char(v_time, 'IW');
+ END IF;
+
+ -- "Q" is ignored in to_timestamp, so handle special case
+ IF v_part_interval = '3 months' AND (v_type = 'time-static' OR v_type = 'time-dynamic') THEN
+ v_year := to_char(v_time, 'YYYY');
+ v_quarter := to_char(v_time, 'Q');
+ v_partition_suffix := v_year || 'q' || v_quarter;
+ END IF;
+
+ v_partition_name := @extschema@.check_name_length(v_parent_tablename, v_parent_schema, v_partition_suffix, TRUE);
+
+ SELECT tablename INTO v_tablename FROM pg_catalog.pg_tables WHERE schemaname ||'.'|| tablename = v_partition_name;
+ IF v_tablename IS NOT NULL THEN
+ CONTINUE;
+ END IF;
+
+ -- Ensure analyze is run if a new partition is created. Otherwise if one isn't, will be false and analyze will be skipped
+ v_analyze := TRUE;
+
+ IF v_jobmon_schema IS NOT NULL THEN
+ v_job_id := add_job('PARTMAN CREATE TABLE: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Creating new partition '||v_partition_name||' with interval from '||v_partition_timestamp_start||' to '||(v_partition_timestamp_end-'1sec'::interval));
+ END IF;
+
+ SELECT relpersistence INTO v_unlogged FROM pg_catalog.pg_class WHERE oid::regclass = p_parent_table::regclass;
+ v_sql := 'CREATE';
+ IF v_unlogged = 'u' THEN
+ v_sql := v_sql || ' UNLOGGED';
+ END IF;
+ v_sql := v_sql || ' TABLE '||v_partition_name||' (LIKE '||p_parent_table||' INCLUDING DEFAULTS INCLUDING CONSTRAINTS INCLUDING INDEXES INCLUDING STORAGE INCLUDING COMMENTS)';
+ SELECT relhasoids INTO v_hasoids FROM pg_catalog.pg_class WHERE oid::regclass = p_parent_table::regclass;