Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with
or
.
Download ZIP
Browse files

v1.0.0 New functions to undo partitioning. Optimization of data parti…

…tioning process. Bug fixes. See CHANGELOG for more details.
  • Loading branch information...
commit 78200bcd1b331df0d1d88250b13a30d3c8bc23e6 1 parent b3d166d
@keithf4 authored
Showing with 7,232 additions and 262 deletions.
  1. +12 −0 CHANGELOG
  2. +3 −3 META.json
  3. +2 −2 README.md
  4. +57 −16 doc/pg_partman.md
  5. +1 −1  pg_partman.control
  6. +9 −11 sql/functions/create_id_function.sql
  7. +0 −68 sql/functions/create_prev_id_partition.sql
  8. +0 −96 sql/functions/create_prev_time_partition.sql
  9. +6 −6 sql/functions/create_time_function.sql
  10. +21 −10 sql/functions/create_time_partition.sql
  11. +77 −0 sql/functions/partition_data_id.sql
  12. +96 −0 sql/functions/partition_data_time.sql
  13. +13 −7 sql/functions/run_maintenance.sql
  14. +124 −0 sql/functions/undo_partition.sql
  15. +166 −0 sql/functions/undo_partition_id.sql
  16. +166 −0 sql/functions/undo_partition_time.sql
  17. +1 −0  sql/tables/tables.sql
  18. +33 −3 test/test-id-dynamic.sql
  19. +26 −2 test/test-id-static-start-100.sql
  20. +26 −3 test/test-id-static.sql
  21. +57 −14 test/{test-time-dynamic.sql → test-time-dynamic-daily.sql}
  22. +386 −0 test/test-time-dynamic-half-hour.sql
  23. +232 −0 test/test-time-dynamic-hourly.sql
  24. +232 −0 test/test-time-dynamic-monthly.sql
  25. +386 −0 test/test-time-dynamic-quarter-hour.sql
  26. +232 −0 test/test-time-dynamic-quarterly.sql
  27. +221 −0 test/test-time-dynamic-weekly.sql
  28. +231 −0 test/test-time-dynamic-yearly.sql
  29. +65 −20 test/{test-time-static.sql → test-time-static-daily.sql}
  30. +595 −0 test/test-time-static-half-hour.sql
  31. +358 −0 test/test-time-static-hourly.sql
  32. +358 −0 test/test-time-static-monthly.sql
  33. +596 −0 test/test-time-static-quarter-hour.sql
  34. +358 −0 test/test-time-static-quarterly.sql
  35. +344 −0 test/test-time-static-weekly.sql
  36. +357 −0 test/test-time-static-yearly.sql
  37. +1,385 −0 updates/pg_partman--0.4.2--1.0.0.sql
View
12 CHANGELOG
@@ -1,3 +1,15 @@
+1.0.0
+-- New functions to undo partitioning. These all either move or copy data from the child tables and put it into the parent. All have an option to allow you either uninherit the child tables (default) or drop them when all their data has been put into the parent.
+ -- undo_partition_time() & undo_partition_id are functions that move the data from the child partitions to the parent tables. Data is deleted from the child table and inserted to the parent. These functions allow smaller interval batches to be given as a parameter and are better able to handle larger partitioning sets.
+ -- undo_partition() can work on an any parent/child table set in PostgreSQL, not just partition sets created by pg_partman. Just pass it the name of the parent table. This method only copies the data out of the child tables instead of deleting it, allowing you to keep all the partitioned data if desired. Because of this it can only process an entire partition at a time and cannot handle batches smaller than the partition interval.
+-- Changed create_prev_id_partition() to partition_data_id() & create_prev_time_partition() to partition_data_time(). This clarifies what these actually do since they don't always create a partition nor is it always necessarily "previous" data.
+-- Changed how the above functions work to move data from parent into partitions. You can now feed them a smaller interval value for the rows that you'd like moved instead of it always moving exactly one entire partition of data. This allows smaller batch sizes when you've got a lot of data even in just one partition. That interval is now the second parameter. A third parameter can tell it how many of those interval batches you'd like to move in a single run of the function. Both of these parameters are optional. If not given, the interval defaults to the partition interval and the batch count is one (so it works exactly like it used to with no parameters but the parent table given).
+-- Partition premake system is now able to catch up if it falls behind for some reason. Also makes it so that if the premake value is increased, within the next few runs it will have that many partitions premade automatically.
+-- Bug fix: create_time_partition() & create_time_function() now handle the "timestamp with time zone" data type much better. Was getting some mismatches in the trigger rules and table constraints when timestamptz was in use on server not running in UTC/GMT time. Would cause constraint violations during data insert at certain time boundaries. If you ran into this issue, there are two ways to fix it: 1) Manually recreate the constraints for the most recent partitions and any future partitions already created. You may have to move some data around as well. 2) Use the new undo functions to move all the data back into the parent table and then repartition again using the partition_data_* functions. This will fix the issue for all partitions.
+-- Bug fix: Determining how many partitions to premake in run_maintenance() is now more accurate. Previous date math would occasionally premake 1 extra partition depending on the time differences. This can still occur with weekly partitioning due to differing month lengths (especially February) and daylight savings. Doesn't hurt anything and will self-correct.
+-- Much more complete pgTAP test suite.
+
+
0.4.2
-- The static partitioning trigger function can now handle partitions based on the configured premake value. For example, the default premake value is 4 so it can now handle data for the current partition, 4 previous partitions and 4 future partitions. Changing the premake value will cause the trigger function to be changed appropriately the next time a partition is automatically created. Except for initial setup, at no time does the automated partitioning system create old partitions (see the create_prev_* functions if you need to do this). If you change the premake value and there is no previous partition for it to put data in, it will go to the parent table.
-- create_parent() now accounts for the new static partitioning rules. For time-static, it will create the current partition as well as previous and future partitions equal to the configured premake number (default premake being 4, you will end up with 9 partitions). For id-static, it will only create previous partitions if the resulting rules handle id values greater than zero. So if you're starting from zero you will only have future partitions created, and no previous.
View
6 META.json
@@ -1,7 +1,7 @@
{
"name": "pg_partman",
"abstract": "Extension to manage partitioned tables by time or ID",
- "version": "0.4.2",
+ "version": "1.0.0",
"maintainer": [
"Keith Fiske <keith@omniti.com>"
],
@@ -20,9 +20,9 @@
},
"provides": {
"pg_partmaint": {
- "file": "sql/pg_partman--0.4.2.sql",
+ "file": "sql/pg_partman--1.0.0.sql",
"docfile": "doc/pg_partman.md",
- "version": "0.4.2",
+ "version": "1.0.0",
"abstract": "Extension to manage partitioned tables by time or ID"
}
},
View
4 README.md
@@ -23,7 +23,7 @@ Functions must either be run as a superuser or you can set the ownership of the
UPGRADE
-------
-Make sure all the upgrade scripts for the version you have installed up to the most recent version are in the $BASEDIR/share/extension folder.
+Make sure all the upgrade scripts for the version you have installed up to the most recent version are in the $/share/extension folder.
ALTER EXTENSION pg_partman UPDATE TO '<latest version>';
@@ -44,7 +44,7 @@ This will turn your table into a parent table and premake 4 future partitions an
This should be enough to get you started. Please see the pg_partman.md file in the doc folder for more information on the types of partitioning supported and what the parameters in the create_parent() function mean.
LICENSE AND COPYRIGHT
--------------------
+---------------------
PG Partition Manager (pg_partman) is released under the PostgreSQL License, a liberal Open Source license, similar to the BSD or MIT licenses.
View
73 doc/pg_partman.md
@@ -3,11 +3,11 @@ PostgreSQL Partition Manager Extension (pg_partman)
About
-----
-pg_partman is an extension to help make managing time or serial id based table partitioning easier.
+pg_partman is an extension to help make managing time or serial id based table partitioning easier. Currenly the trigger functions only handle inserts to the parent table. Updates that would move a value from one partition to another are not yet supported.
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), 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 & constraints on the parent are only applied to newly created partitions and are not retroactively set on ones that already existed. And 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.
-If you attempt to insert data into a partition set that contains data for a partition that does not exist, that data will be placed into the set's parent table. This is preferred over automatically creating new partitions to match that data since a mistake that is causing non-partitioned data to be inserted could cause a lot of unwanted child tables to be made. The check_parent() function provides monitoring for any data getting inserted into parents and the create_prev_* set of functions can easily partition that data for you if it is valid data. That is much easier than having to clean up potentially hundreds or thousands of unwanted partitions. And also better than throwing an error and losing the data!
+If you attempt to insert data into a partition set that contains data for a partition that does not exist, that data will be placed into the set's parent table. This is preferred over automatically creating new partitions to match that data since a mistake that is causing non-partitioned data to be inserted could cause a lot of unwanted child tables to be made. The check_parent() function provides monitoring for any data getting inserted into parents and the partition_data_* set of functions can easily partition that data for you if it is valid data. That is much easier than having to clean up potentially hundreds or thousands of unwanted partitions. And also better than throwing an error and losing the data!
If you don't need to keep data in older partitions, a retention system is available to automatically drop unneeded child partitions. By default, they are only uninherited not actually dropped, but that can be configured if desired. If the old partitions are kept, dropping their indexes can also be configured to recover disk space. Note that this will also remove any primary key or unique constraints in order to allow the indexes to be dropped. To set the retention policy, enter either an interval or integer value into the **retention** column of the **part_config** table. For time-based partitioning, the interval value will set that any partitions containing data older than that will be dropped. For id-based partitioning, the integer value will set that any partitions with an id value less than the current maximum id value minus the retention value will be dropped. For example, if the current max id is 100 and the retention value is 30, any partitions with id values less than 70 will be dropped. The current maximum id value at the time the drop function is run is always used.
@@ -25,8 +25,8 @@ A superuser must be used to run these functions in order to set privileges & own
* p_type - one of 4 values to set the partitioning type that will be used
> **time-static** - Trigger function inserts only into specifically named partitions. The the number of partitions managed behind and ahead of the current one is determined by the **premake** config value (default of 4 means data for 4 previous and 4 future partitions are handled automatically). *Beware setting the premake value too high as that will lessen the efficiency of this partitioning method.* Inserts to parent table outside the hard-coded time window will go to the parent. Trigger function is kept up to date by run_maintenance() function. Ideal for high TPS tables that get inserts of new data only.
- > **time-dynamic** - Trigger function can insert into any child partition based on the value of the control column. More flexible but not as efficient as time-static. Be aware that if the appropriate partition doesn't yet exist for the data inserted, data gets inserted to the parent.
- > **id-static** - Same functionality and use of the premake value as time-static but for a numeric range instead of time. When the id value has reached 50% of the max value for that partition, it will automatically create the next partition in sequence if it doesn't yet exist. Does NOT require run_maintenance() function to create new partitions. Only supports id values greater than or equal to zero.
+ > **time-dynamic** - Trigger function can insert into any existing child partition based on the value of the control column at the time of insertion. More flexible but not as efficient as time-static.
+ > **id-static** - Same functionality and use of the premake value as time-static but for a numeric range instead of time. When the id value reaches 50% of the max value for that partition, it will automatically create the next partition in sequence if it doesn't yet exist. Does NOT require run_maintenance() function to create new partitions. Only supports id values greater than or equal to zero.
> **id-dynamic** - Same functionality and limitations as time-dynamic but for a numeric range instead of time. Uses same 50% rule as id-static to create future partitions. Does NOT require run_maintenance() function to create new partitions. Only supports id values greater than or equal to zero.
* p_interval - the time or numeric range interval for each partition. Supported values are:
@@ -41,31 +41,31 @@ A superuser must be used to run these functions in order to set privileges & own
> **quarter-hour** - One partition per 15 minute interval on the quarter-hour (1200, 1215, 1230, 1245)
> **<integer>** - For ID based partitions, the integer value range of the ID that should be set per partition. This is the actual integer value, not text values like time-based partitioning. Must be greater than zero.
- * p_premake - is how many additional partitions to always stay ahead of the current partition. Default value is 4. This will keep at minimum 5 partitions made, including the current one. For example, if today was Sept 6, 2012, and premake was set to 4 for a daily partition, then partitions would be made for the 6th as well as the 7th, 8th, 9th and 10th. As stated above, this value also determines how many partitions outside of the current one the static partitioning trigger function will handle.
+ * p_premake - is how many additional partitions to always stay ahead of the current partition. Default value is 4. This will keep at minimum 5 partitions made, including the current one. For example, if today was Sept 6, 2012, and premake was set to 4 for a daily partition, then partitions would be made for the 6th as well as the 7th, 8th, 9th and 10th. As stated above, this value also determines how many partitions outside of the current one the static partitioning trigger function will handle (behind & ahead). Note that weekly partitioning may occasionally cause an extra partition to be premade due to differing month lengths and daylight savings (on non-UTC systems). This won't hurt anything and will self-correct. If partitioning ever falls behind the premake value, normal running of run_maintenance() and data insertion to id-based tables should automatically catch things up.
* p_debug - turns on additional debugging information (not yet working).
*run_maintenance()*
- * Run this function as a scheduled job (cronjob, etc) to automatically keep time-based partitioning working.
- * Run this function as a scheduled job to automatically drop child tables and/or indexes if the retention options are configured.
+ * Run this function as a scheduled job (cronjob, etc) to automatically keep time-based partitioning working and/or use the partition retention system.
* Every run checks all tables listed in the **part_config** table with the types **time-static** and **time-dynamic** to pre-make child tables (not needed for id-based partitioning).
* Every run checks all tables of all types listed in the **part_config** table with a value in the **retention** column and drops tables as needed (see **About** and config table below).
- * Will automatically pre-create the new partition, keeping ahead by the number set as the **premake**.
* Will automatically update the function for **time-static** partitioning to keep the parent table pointing at the correct partitions. When using time-static, run this function more often than the partitioning interval to keep the function running its most efficient. For example, if using quarter-hour, run every 5 minutes; if using daily, run at least twice a day, etc.
-*create_prev_time_partition(p_parent_table text, p_batch int DEFAULT 1) RETURNS bigint*
+*partition_data_time(p_parent_table text, p_batch_interval interval DEFAULT NULL, p_batch_count int DEFAULT 1) RETURNS bigint*
* This function is used to partition data that may have existed prior to setting up the parent table as a time-based partition set, or to fix data that accidentally gets inserted into the parent.
* If the needed partition does not exist, it will automatically be created. If the needed partition already exists, the data will be moved there.
- * If you are partitioning a large amount of previous data, it's recommended to run this function with an external script with small batch amounts. This will help avoid transactional locks and prevent a failure from causing an extensive rollback.
+ * If you are trying to partition a large amount of previous data automatically, it is recommended to run this function with an external script and appropriate batch settings. This will help avoid transactional locks and prevent a failure from causing an extensive rollback.
* p_parent_table - the existing parent table. This is assumed to be where the unpartitioned data is located. MUST be schema qualified, even if in public schema.
- * p_batch - how many partitions will be made in a single run of the function. Default value is 1.
+ * p_batch_interval - optional argument, a time interval of how much of the data to move. This can be smaller than the partition interval, allowing for very large sized partitions to be broken up into smaller commit batches. Defaults to the configured partition interval if not given or if you give an interval larger than the partition interval.
+ * p_batch_count - optional argument, how many times to run the batch_interval in a single call of this function. Default value is 1.
* Returns the number of rows that were moved from the parent table to partitions. Returns zero when parent table is empty and partitioning is complete.
-*create_prev_id_partition(p_parent_table text, p_batch int DEFAULT 1) RETURNS bigint*
+*partition_data_id(p_parent_table text, p_batch_interval int DEFAULT NULL, p_batch_count int DEFAULT 1) RETURNS bigint*
* This function is used to partition data that may have existed prior to setting up the parent table as a serial id partition set, or to fix data that accidentally gets inserted into the parent.
* If the needed partition does not exist, it will automatically be created. If the needed partition already exists, the data will be moved there.
- * If you are partitioning a large amount of previous data, it's recommended to run this function with an external script with small batch amounts. This will help avoid transactional locks and prevent a failure from causing an extensive rollback.
+ * If you are trying to partition a large amount of previous data automatically, it is recommended to run this function with an external script and appropriate batch settings. This will help avoid transactional locks and prevent a failure from causing an extensive rollback.
* p_parent_table - the existing parent table. This is assumed to be where the unpartitioned data is located. MUST be schema qualified, even if in public schema.
- * p_batch - how many partitions will be made in a single run of the function. Default value is 1.
+ * p_batch_interval - optional argument, an integer amount representing an interval of how much of the data to move. This can be smaller than the partition interval, allowing for very large sized partitions to be broken up into smaller commit batches. Defaults to the configured partition interval if not given or if you give an interval larger than the partition interval.
+ * p_batch_count - optional argument, how many times to run the batch_interval in a single call of this function. Default value is 1.
* Returns the number of rows that were moved from the parent table to partitions. Returns zero when parent table is empty and partitioning is complete.
*check_parent() RETURNS SETOF (parent_table, count)*
@@ -73,13 +73,13 @@ A superuser must be used to run these functions in order to set privileges & own
* Returns a row for each parent table along with the number of rows it contains. Returns zero rows if none found.
*drop_time_partition(p_parent_table text, p_keep_table boolean DEFAULT NULL, p_keep_index boolean DEFAULT NULL)*
- * This function is used to drop child tables from a time-based partition set. The table is by default just uninherited and not actually dropped. It is recommended to use the **run_maintenance()** function to manage dropping old child tables and not call it directly unless needed.
+ * This function is used to drop child tables from a time-based partition set. By default, the table is just uninherited and not actually dropped. It is recommended to use the **run_maintenance()** function to manage dropping old child tables and not call it directly unless needed.
* p_parent_table - the existing parent table of a time-based partition set. MUST be schema qualified, even if in public schema.
* p_keep_table - optional parameter to tell partman whether to keep or drop the table in addition to uninheriting it. TRUE means the table will not actually be dropped; FALSE means the table will be dropped. This function will just use the value configured in **part_config** if not explicitly set.
* p_keep_index - optional parameter to tell partman whether to keep or drop the indexes of the child table when it is uninherited. TRUE means the indexes will be kept; FALSE means all indexes will be dropped. This function will just use the value configured in **part_config** if not explicitly set. This option is ignored if p_keep_table is set to FALSE.
*drop_id_partition(p_parent_table text, p_keep_table boolean DEFAULT NULL, p_keep_index boolean DEFAULT NULL)*
- * This function is used to drop child tables from an id-based partition set. The table is by default just uninherited and not actually dropped. It is recommended to use the **run_maintenance()** function to manage dropping old child tables and not call it directly unless needed.
+ * This function is used to drop child tables from an id-based partition set. By default, the table just uninherited and not actually dropped. It is recommended to use the **run_maintenance()** function to manage dropping old child tables and not call it directly unless needed.
* p_parent_table - the existing parent table of a time-based partition set. MUST be schema qualified, even if in public schema.
* p_keep_table - optional parameter to tell partman whether to keep or drop the table in addition to uninheriting it. TRUE means the table will not actually be dropped; FALSE means the table will be dropped. This function will just use the value configured in **part_config** if not explicitly set.
* p_keep_index - optional parameter to tell partman whether to keep or drop the indexes of the child table when it is uninherited. TRUE means the indexes will be kept; FALSE means all indexes will be dropped. This function will just use the value configured in **part_config** if not explicitly set. This option is ignored if p_keep_table is set to FALSE.
@@ -91,6 +91,45 @@ A superuser must be used to run these functions in order to set privileges & own
* 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.
+*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 a time-based partition set created by pg_partman. This function MOVES the data from existing child partitions to the parent table.
+ * When this function is run, the trigger on the parent table & the trigger function are immediately dropped (if they still exist). This means any further writes are done to the parent.
+ * When this function is run, the **undo_in_progress** column in the configuration table is set. This causes all partition creation and retention management by the run_maintenance() function to stop.
+ * If you are trying to un-partition a large amount of data automatically, it is recommended to run this function with an external script and appropriate batch settings. This will help avoid transactional locks and prevent a failure from causing an extensive rollback.
+ * By default, partitions are not DROPPED, they are UNINHERITED. This leave previous child tables as empty, independent tables.
+ * Without setting either batch argument manually, each run of the function will move all the data from a single partition into the parent.
+ * Once all child tables have been uninherited/dropped, the configuration data is removed from pg_partman automatically.
+ * p_parent_table - parent table of the partition set. Must be schema qualified and match a parent table name already configured in pg_partman.
+ * 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 ininherit/drop a table from the set.
+ * Returns the number of rows moved to the parent table. Returns zero when child tables are all 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 an id-based partition set created by pg_partman. This function MOVES the data from existing child partitions to the parent table.
+ * When this function is run, the trigger on the parent table & the trigger function are immediately dropped (if they still exist). This means any further writes are done to the parent.
+ * When this function is run, the **undo_in_progress** column in the configuration table is set. This causes all partition creation and retention management by the run_maintenance() function to stop.
+ * If you are trying to un-partition a large amount of data automatically, it is recommended to run this function with an external script and appropriate batch settings. This will help avoid transactional locks and prevent a failure from causing an extensive rollback.
+ * By default, partitions are not DROPPED, they are UNINHERITED. This leave previous child tables as empty, independent tables.
+ * Without setting either batch argument manually, each run of the function will move all the data from a single partition into the parent.
+ * Once all child tables have been uninherited/dropped, the configuration data is removed from pg_partman automatically.
+ * p_parent_table - parent table of the partition set. Must be schema qualified and match a parent table name already configured in pg_partman.
+ * 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 ininherit/drop a table from the set (second batch sees it has no more data and drops it).
+ * Returns the number of rows moved to the parent table. Returns zero when child tables are all empty.
+
+*undo_partition(p_parent_table text, p_batch_count int DEFAULT 1, p_keep_table boolean DEFAULT true) 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.
+ * If you are trying to un-partition a large amount of data automatically, it is recommended to run this function with an external script and appropriate batch settings. This will help avoid transactional locks and prevent a failure from causing an extensive rollback.
+ * By default, partitions are not DROPPED, they are UNINHERITED. This leave previous child tables exactly as they were but no longer inherited from the parent.
+ * p_parent_table - parent table of the partition set. Must be schema qualified but does NOT have to be managed by pg_partman.
+ * p_batch_count - an optional argument, this sets how many partitions to copy data from in a single run. Defaults to 1.
+ * p_keep_table - an optional argument, setting this to false will cause the old child table to be dropped instead of uninherited.
+ * Returns the number of rows moved to the parent table. Returns zero when child tables are all empty.
+
Tables
------
*part_config*
@@ -114,3 +153,5 @@ Tables
Default is TRUE. Set to FALSE to have the child table's indexes dropped when it is uninherited.
datetime_string - For time-based partitioning, this is the datetime format string used when naming child partitions.
last_partition - Tracks the last successfully created partition and used to determine the next one.
+ undo_in_progress - Set by the undo_partition functions whenever they are run. If true, This causes all partition creation
+ and retention management by the run_maintenance() function to stop. Default is false.
View
2  pg_partman.control
@@ -1,3 +1,3 @@
-default_version = '0.4.2'
+default_version = '1.0.0'
comment = 'Extension to manage partitioned tables by time or ID'
relocatable = false
View
20 sql/functions/create_id_function.sql
@@ -96,12 +96,13 @@ IF v_type = 'id-static' THEN
v_current_partition_id := NEW.'||v_control||' - (NEW.'||v_control||' % '||v_part_interval||');
IF (NEW.'||v_control||' % '||v_part_interval||') > ('||v_part_interval||' / 2) THEN
v_next_partition_id := (substring(v_last_partition from char_length('||quote_literal(p_parent_table||'_p')||')+1)::bigint) + '||v_part_interval||';
- IF ((v_next_partition_id - v_current_partition_id) / '||v_part_interval||') <= '||v_premake||' THEN
+ WHILE ((v_next_partition_id - v_current_partition_id) / '||v_part_interval||') <= '||v_premake||' LOOP
v_next_partition_name := @extschema@.create_id_partition('||quote_literal(p_parent_table)||', '||quote_literal(v_control)||','
||v_part_interval||', ARRAY[v_next_partition_id]);
UPDATE @extschema@.part_config SET last_partition = v_next_partition_name WHERE parent_table = '||quote_literal(p_parent_table)||';
PERFORM @extschema@.create_id_function('||quote_literal(p_parent_table)||', NEW.'||v_control||');
- END IF;
+ v_next_partition_id := v_next_partition_id + '||v_part_interval||';
+ END LOOP;
END IF;
END IF;
RETURN NULL;
@@ -114,7 +115,7 @@ IF v_type = 'id-static' THEN
END IF;
ELSIF v_type = 'id-dynamic' THEN
-
+ -- The return inside the partition creation check is there to keep really high ID values from creating new partitions.
v_trig_func := 'CREATE OR REPLACE FUNCTION '||p_parent_table||'_part_trig_func() RETURNS trigger LANGUAGE plpgsql AS $t$
DECLARE
v_count int;
@@ -124,8 +125,6 @@ ELSIF v_type = 'id-dynamic' THEN
v_last_partition_id bigint;
v_next_partition_id bigint;
v_next_partition_name text;
- v_schemaname text;
- v_tablename text;
BEGIN
IF TG_OP = ''INSERT'' THEN
v_current_partition_id := NEW.'||v_control||' - (NEW.'||v_control||' % '||v_part_interval||');
@@ -136,18 +135,17 @@ ELSIF v_type = 'id-dynamic' THEN
IF NEW.'||v_control||' >= v_next_partition_id THEN
RETURN NEW;
END IF;
- IF ((v_next_partition_id - v_current_partition_id) / '||quote_literal(v_part_interval)||') <= '||quote_literal(v_premake)||' THEN
+ WHILE ((v_next_partition_id - v_current_partition_id) / '||v_part_interval||') <= '||v_premake||' LOOP
v_next_partition_name := @extschema@.create_id_partition('||quote_literal(p_parent_table)||', '||quote_literal(v_control)||','
||quote_literal(v_part_interval)||', ARRAY[v_next_partition_id]);
IF v_next_partition_name IS NOT NULL THEN
UPDATE @extschema@.part_config SET last_partition = v_next_partition_name WHERE parent_table = '||quote_literal(p_parent_table)||';
PERFORM @extschema@.create_id_function('||quote_literal(p_parent_table)||', NEW.'||v_control||');
END IF;
- END IF;
+ v_next_partition_id := v_next_partition_id + '||v_part_interval||';
+ END LOOP;
END IF;
- v_schemaname := split_part(v_current_partition_name, ''.'', 1);
- v_tablename := split_part(v_current_partition_name, ''.'', 2);
- SELECT count(*) INTO v_count FROM pg_tables WHERE schemaname = v_schemaname AND tablename = v_tablename;
+ SELECT count(*) INTO v_count FROM pg_tables WHERE schemaname ||''.''|| tablename = v_current_partition_name;
IF v_count > 0 THEN
EXECUTE ''INSERT INTO ''||v_current_partition_name||'' VALUES($1.*)'' USING NEW;
ELSE
@@ -183,7 +181,7 @@ EXCEPTION
ELSIF v_step_id IS NULL THEN
v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
END IF;
- PERFORM update_step(v_step_id, 'BAD', 'ERROR: '||coalesce(SQLERRM,'unknown'));
+ PERFORM update_step(v_step_id, 'CRITICAL', 'ERROR: '||coalesce(SQLERRM,'unknown'));
PERFORM fail_job(v_job_id);
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;
View
68 sql/functions/create_prev_id_partition.sql
@@ -1,68 +0,0 @@
-CREATE FUNCTION create_prev_id_partition(p_parent_table text, p_batch int DEFAULT 1) RETURNS bigint
- LANGUAGE plpgsql SECURITY DEFINER
- AS $$
-DECLARE
-
-v_control text;
-v_last_partition_name text;
-v_max_partition_id bigint;
-v_min_control bigint;
-v_min_partition_id bigint;
-v_part_interval bigint;
-v_partition_id bigint[];
-v_rowcount bigint;
-v_sql text;
-v_total_rows bigint := 0;
-v_type text;
-
-BEGIN
-
-SELECT type
- , part_interval::bigint
- , control
-FROM @extschema@.part_config
-WHERE parent_table = p_parent_table
-AND (type = 'id-static' OR type = 'id-dynamic')
-INTO v_type, v_part_interval, v_control;
-IF NOT FOUND THEN
- RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table;
-END IF;
-
-EXECUTE 'SELECT min('||v_control||') FROM ONLY '||p_parent_table INTO v_min_control;
-IF v_min_control IS NULL THEN
- RETURN 0;
-END IF;
-
-v_min_partition_id = v_min_control - (v_min_control % v_part_interval);
-
--- Subtract 1 so that batch count number actually makes sense
-FOR i IN 0..p_batch-1 LOOP
- v_partition_id := ARRAY[v_min_partition_id + (v_part_interval*i)];
-RAISE NOTICE 'v_partition_id: %',v_partition_id;
- v_max_partition_id := v_min_partition_id + (v_part_interval*(i+1));
-RAISE NOTICE 'v_max_partition_id: %',v_max_partition_id;
-
- v_sql := 'SELECT @extschema@.create_id_partition('||quote_literal(p_parent_table)||','||quote_literal(v_control)||','
- ||v_part_interval||','||quote_literal(v_partition_id)||')';
- RAISE NOTICE 'v_sql: %', v_sql;
- EXECUTE v_sql INTO v_last_partition_name;
-
- v_sql := 'WITH partition_data AS (
- DELETE FROM ONLY '||p_parent_table||' WHERE '||v_control||' >= '||v_min_partition_id||
- ' AND '||v_control||' < '||v_max_partition_id||' RETURNING *)
- INSERT INTO '||v_last_partition_name||' SELECT * FROM partition_data';
- RAISE NOTICE 'v_sql: %', v_sql;
- EXECUTE v_sql;
-
- GET DIAGNOSTICS v_rowcount = ROW_COUNT;
- v_total_rows := v_total_rows + v_rowcount;
- IF v_rowcount = 0 THEN
- EXIT;
- END IF;
-
-END LOOP;
-
-RETURN v_total_rows;
-
-END
-$$;
View
96 sql/functions/create_prev_time_partition.sql
@@ -1,96 +0,0 @@
-/*
- * Populate the child table(s) of a time-based partition set with old data from the original parent
- */
-CREATE FUNCTION create_prev_time_partition(p_parent_table text, p_batch int DEFAULT 1) RETURNS bigint
- LANGUAGE plpgsql SECURITY DEFINER
- AS $$
-DECLARE
-
-v_control text;
-v_datetime_string text;
-v_last_partition_name text;
-v_max_partition_timestamp timestamp;
-v_min_control timestamp;
-v_min_partition_timestamp timestamp;
-v_part_interval interval;
-v_partition_timestamp timestamp[];
-v_rowcount bigint;
-v_sql text;
-v_total_rows bigint := 0;
-v_type text;
-
-BEGIN
-
-SELECT type
- , part_interval::interval
- , control
- , datetime_string
-FROM @extschema@.part_config
-WHERE parent_table = p_parent_table
-AND (type = 'time-static' OR type = 'time-dynamic')
-INTO v_type, v_part_interval, v_control, v_datetime_string;
-IF NOT FOUND THEN
- RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table;
-END IF;
-
-EXECUTE 'SELECT min('||v_control||') FROM ONLY '||p_parent_table INTO v_min_control;
-IF v_min_control IS NULL THEN
- RETURN 0;
-END IF;
-
-CASE
- WHEN v_part_interval = '15 mins' THEN
- v_min_partition_timestamp := date_trunc('hour', v_min_control) +
- '15min'::interval * floor(date_part('minute', v_min_control) / 15.0);
- WHEN v_part_interval = '30 mins' THEN
- v_min_partition_timestamp := date_trunc('hour', v_min_control) +
- '30min'::interval * floor(date_part('minute', v_min_control) / 30.0);
- WHEN v_part_interval = '1 hour' THEN
- v_min_partition_timestamp := date_trunc('hour', v_min_control);
- WHEN v_part_interval = '1 day' THEN
- v_min_partition_timestamp := date_trunc('day', v_min_control);
- WHEN v_part_interval = '1 week' THEN
- v_min_partition_timestamp := date_trunc('week', v_min_control);
- WHEN v_part_interval = '1 month' THEN
- v_min_partition_timestamp := date_trunc('month', v_min_control);
- WHEN v_part_interval = '3 months' THEN
- v_min_partition_timestamp := date_trunc('quarter', v_min_control);
- WHEN v_part_interval = '1 year' THEN
- v_min_partition_timestamp := date_trunc('year', v_min_control);
-END CASE;
-
--- Subtract 1 so that batch count number actually makes sense
-FOR i IN 0..p_batch-1 LOOP
- v_partition_timestamp := ARRAY[(v_min_partition_timestamp + (v_part_interval*i))::timestamp];
-RAISE NOTICE 'v_partition_timestamp: %',v_partition_timestamp;
- v_max_partition_timestamp := v_min_partition_timestamp + (v_part_interval*(i+1));
-RAISE NOTICE 'v_max_partition_timestamp: %',v_max_partition_timestamp;
-
- v_sql := 'SELECT @extschema@.create_time_partition('||quote_literal(p_parent_table)||','||quote_literal(v_control)||','
- ||quote_literal(v_part_interval)||','||quote_literal(v_datetime_string)||','||quote_literal(v_partition_timestamp)||')';
- RAISE NOTICE 'v_sql: %', v_sql;
- EXECUTE v_sql INTO v_last_partition_name;
-
- -- create_time_partition() already checks to see if the partition exists and skips creation if it does.
- -- So this function will still work with already existing partitions to get all data moved out of parent table up to and including when
- -- pg_partman was used to set up partitioning.
-
- v_sql := 'WITH partition_data AS (
- DELETE FROM ONLY '||p_parent_table||' WHERE '||v_control||' >= '||quote_literal(v_min_partition_timestamp)||
- ' AND '||v_control||' < '||quote_literal(v_max_partition_timestamp)||' RETURNING *)
- INSERT INTO '||v_last_partition_name||' SELECT * FROM partition_data';
- RAISE NOTICE 'v_sql: %', v_sql;
- EXECUTE v_sql;
-
- GET DIAGNOSTICS v_rowcount = ROW_COUNT;
- v_total_rows := v_total_rows + v_rowcount;
- IF v_rowcount = 0 THEN
- EXIT;
- END IF;
-
-END LOOP;
-
-RETURN v_total_rows;
-
-END
-$$;
View
12 sql/functions/create_time_function.sql
@@ -8,18 +8,18 @@ DECLARE
v_control text;
v_current_partition_name text;
-v_current_partition_timestamp timestamp;
+v_current_partition_timestamp timestamptz;
v_datetime_string text;
-v_final_partition_timestamp timestamp;
+v_final_partition_timestamp timestamptz;
v_job_id bigint;
v_jobmon_schema text;
v_old_search_path text;
v_next_partition_name text;
-v_next_partition_timestamp timestamp;
+v_next_partition_timestamp timestamptz;
v_part_interval interval;
v_premake int;
v_prev_partition_name text;
-v_prev_partition_timestamp timestamp;
+v_prev_partition_timestamp timestamptz;
v_step_id bigint;
v_trig_func text;
v_type text;
@@ -122,7 +122,7 @@ ELSIF v_type = 'time-dynamic' THEN
DECLARE
v_count int;
v_partition_name text;
- v_partition_timestamp timestamp;
+ v_partition_timestamp timestamptz;
v_schemaname text;
v_tablename text;
BEGIN
@@ -189,7 +189,7 @@ EXCEPTION
ELSIF v_step_id IS NULL THEN
v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
END IF;
- PERFORM update_step(v_step_id, 'BAD', 'ERROR: '||coalesce(SQLERRM,'unknown'));
+ PERFORM update_step(v_step_id, 'CRITICAL', 'ERROR: '||coalesce(SQLERRM,'unknown'));
PERFORM fail_job(v_job_id);
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;
View
31 sql/functions/create_time_partition.sql
@@ -20,6 +20,7 @@ v_quarter text;
v_revoke text[];
v_step_id bigint;
v_tablename text;
+v_trunc_value text;
v_time timestamp;
v_year text;
@@ -39,17 +40,21 @@ FOREACH v_time IN ARRAY p_partition_times LOOP
IF p_interval = '1 year' OR p_interval = '1 month' OR p_interval = '1 day' OR p_interval = '1 hour' OR p_interval = '30 mins' OR p_interval = '15 mins' THEN
v_partition_name := v_partition_name || to_char(v_time, 'YYYY');
-
+ v_trunc_value := 'year';
+
IF p_interval = '1 month' OR p_interval = '1 day' OR p_interval = '1 hour' OR p_interval = '30 mins' OR p_interval = '15 mins' THEN
v_partition_name := v_partition_name || '_' || to_char(v_time, 'MM');
+ v_trunc_value := 'month';
IF p_interval = '1 day' OR p_interval = '1 hour' OR p_interval = '30 mins' OR p_interval = '15 mins' THEN
v_partition_name := v_partition_name || '_' || to_char(v_time, 'DD');
+ v_trunc_value := 'day';
IF p_interval = '1 hour' OR p_interval = '30 mins' OR p_interval = '15 mins' THEN
v_partition_name := v_partition_name || '_' || to_char(v_time, 'HH24');
IF p_interval <> '30 mins' AND p_interval <> '15 mins' THEN
v_partition_name := v_partition_name || '00';
+ v_trunc_value := 'hour';
ELSIF p_interval = '15 mins' THEN
IF date_part('minute', v_time) < 15 THEN
v_partition_name := v_partition_name || '00';
@@ -60,40 +65,46 @@ FOREACH v_time IN ARRAY p_partition_times LOOP
ELSE
v_partition_name := v_partition_name || '45';
END IF;
+ v_trunc_value := 'minute';
ELSIF p_interval = '30 mins' THEN
IF date_part('minute', v_time) < 30 THEN
v_partition_name := v_partition_name || '00';
ELSE
v_partition_name := v_partition_name || '30';
END IF;
+ v_trunc_value := 'minute';
END IF;
END IF; -- end hour IF
END IF; -- end day IF
END IF; -- end month IF
ELSIF p_interval = '1 week' THEN
v_partition_name := v_partition_name || to_char(v_time, 'IYYY') || 'w' || to_char(v_time, 'IW');
+ v_trunc_value := 'week';
END IF; -- end year/week IF
- -- pull out datetime portion of last partition's tablename
- v_partition_timestamp_start := to_timestamp(substring(v_partition_name from char_length(p_parent_table||'_p')+1), p_datetime_string);
- v_partition_timestamp_end := to_timestamp(substring(v_partition_name from char_length(p_parent_table||'_p')+1), p_datetime_string) + p_interval;
+ -- pull out datetime portion of last partition's tablename if it matched one of the above partitioning intervals
+ IF v_trunc_value IS NOT NULL THEN
+ v_partition_timestamp_start := date_trunc(v_trunc_value, to_timestamp(substring(v_partition_name from char_length(p_parent_table||'_p')+1), p_datetime_string));
+ v_partition_timestamp_end := date_trunc(v_trunc_value, to_timestamp(substring(v_partition_name from char_length(p_parent_table||'_p')+1), p_datetime_string) + p_interval);
+ END IF;
-- "Q" is ignored in to_timestamp, so handle special case
IF p_interval = '3 months' THEN
v_year := to_char(v_time, 'YYYY');
v_quarter := to_char(v_time, 'Q');
v_partition_name := v_partition_name || v_year || 'q' || v_quarter;
+ v_trunc_value := 'quarter';
CASE
WHEN v_quarter = '1' THEN
- v_partition_timestamp_start := to_timestamp(v_year || '-01-01', 'YYYY-MM-DD');
+ v_partition_timestamp_start := date_trunc(v_trunc_value, to_timestamp(v_year || '-01-01', 'YYYY-MM-DD'));
WHEN v_quarter = '2' THEN
- v_partition_timestamp_start := to_timestamp(v_year || '-04-01', 'YYYY-MM-DD');
+ v_partition_timestamp_start := date_trunc(v_trunc_value, to_timestamp(v_year || '-04-01', 'YYYY-MM-DD'));
WHEN v_quarter = '3' THEN
- v_partition_timestamp_start := to_timestamp(v_year || '-07-01', 'YYYY-MM-DD');
+ v_partition_timestamp_start := date_trunc(v_trunc_value, to_timestamp(v_year || '-07-01', 'YYYY-MM-DD'));
WHEN v_quarter = '4' THEN
- v_partition_timestamp_start := to_timestamp(v_year || '-10-01', 'YYYY-MM-DD');
+ v_partition_timestamp_start := date_trunc(v_trunc_value, to_timestamp(v_year || '-10-01', 'YYYY-MM-DD'));
END CASE;
- v_partition_timestamp_end := v_partition_timestamp_start + p_interval;
+ v_partition_timestamp_end := date_trunc(v_trunc_value, (v_partition_timestamp_start + p_interval));
END IF;
SELECT schemaname ||'.'|| tablename INTO v_tablename FROM pg_catalog.pg_tables WHERE schemaname ||'.'|| tablename = v_partition_name;
@@ -164,7 +175,7 @@ EXCEPTION
ELSIF v_step_id IS NULL THEN
v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
END IF;
- PERFORM update_step(v_step_id, 'BAD', 'ERROR: '||coalesce(SQLERRM,'unknown'));
+ PERFORM update_step(v_step_id, 'CRITICAL', 'ERROR: '||coalesce(SQLERRM,'unknown'));
PERFORM fail_job(v_job_id);
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;
View
77 sql/functions/partition_data_id.sql
@@ -0,0 +1,77 @@
+/*
+ * Populate the child table(s) of an id-based partition set with old data from the original parent
+ */
+CREATE FUNCTION partition_data_id(p_parent_table text, p_batch_interval int DEFAULT NULL, p_batch_count int DEFAULT 1) RETURNS bigint
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_control text;
+v_last_partition_name text;
+v_max_partition_id bigint;
+v_min_control bigint;
+v_min_partition_id bigint;
+v_part_interval bigint;
+v_partition_id bigint[];
+v_rowcount bigint;
+v_sql text;
+v_total_rows bigint := 0;
+
+BEGIN
+
+SELECT part_interval::bigint, control
+INTO v_part_interval, v_control
+FROM @extschema@.part_config
+WHERE parent_table = p_parent_table
+AND (type = 'id-static' OR type = 'id-dynamic');
+IF NOT FOUND THEN
+ RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table;
+END IF;
+
+IF p_batch_interval IS NULL OR p_batch_interval > v_part_interval THEN
+ p_batch_interval := v_part_interval;
+END IF;
+
+FOR i IN 1..p_batch_count LOOP
+
+ EXECUTE 'SELECT min('||v_control||') FROM ONLY '||p_parent_table INTO v_min_control;
+ IF v_min_control IS NULL THEN
+ RETURN 0;
+ END IF;
+
+ v_min_partition_id = v_min_control - (v_min_control % v_part_interval);
+
+ v_partition_id := ARRAY[v_min_partition_id];
+ RAISE NOTICE 'v_partition_id: %',v_partition_id;
+ IF (v_min_control + p_batch_interval) >= (v_min_partition_id + v_part_interval) THEN
+ v_max_partition_id := v_min_partition_id + v_part_interval;
+ ELSE
+ v_max_partition_id := v_min_control + p_batch_interval;
+ END IF;
+ RAISE NOTICE 'v_max_partition_id: %',v_max_partition_id;
+
+ v_sql := 'SELECT @extschema@.create_id_partition('||quote_literal(p_parent_table)||','||quote_literal(v_control)||','
+ ||v_part_interval||','||quote_literal(v_partition_id)||')';
+ RAISE NOTICE 'v_sql: %', v_sql;
+ EXECUTE v_sql INTO v_last_partition_name;
+
+ v_sql := 'WITH partition_data AS (
+ DELETE FROM ONLY '||p_parent_table||' WHERE '||v_control||' >= '||v_min_control||
+ ' AND '||v_control||' < '||v_max_partition_id||' RETURNING *)
+ INSERT INTO '||v_last_partition_name||' SELECT * FROM partition_data';
+
+ RAISE NOTICE 'v_sql: %', v_sql;
+ EXECUTE v_sql;
+
+ GET DIAGNOSTICS v_rowcount = ROW_COUNT;
+ v_total_rows := v_total_rows + v_rowcount;
+ IF v_rowcount = 0 THEN
+ EXIT;
+ END IF;
+
+END LOOP;
+
+RETURN v_total_rows;
+
+END
+$$;
View
96 sql/functions/partition_data_time.sql
@@ -0,0 +1,96 @@
+/*
+ * Populate the child table(s) of a time-based partition set with old data from the original parent
+ */
+CREATE FUNCTION partition_data_time(p_parent_table text, p_batch_interval interval DEFAULT NULL, p_batch_count int DEFAULT 1) RETURNS bigint
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_control text;
+v_datetime_string text;
+v_last_partition_name text;
+v_max_partition_timestamp timestamp;
+v_min_control timestamp;
+v_min_partition_timestamp timestamp;
+v_part_interval interval;
+v_partition_timestamp timestamp[];
+v_rowcount bigint;
+v_sql text;
+v_total_rows bigint := 0;
+
+BEGIN
+
+SELECT part_interval::interval, control, datetime_string
+INTO v_part_interval, v_control, v_datetime_string
+FROM @extschema@.part_config
+WHERE parent_table = p_parent_table
+AND (type = 'time-static' OR type = 'time-dynamic');
+IF NOT FOUND THEN
+ RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table;
+END IF;
+
+IF p_batch_interval IS NULL OR p_batch_interval > v_part_interval THEN
+ p_batch_interval := v_part_interval;
+END IF;
+
+FOR i IN 1..p_batch_count LOOP
+
+ EXECUTE 'SELECT min('||v_control||') FROM ONLY '||p_parent_table INTO v_min_control;
+ IF v_min_control IS NULL THEN
+ RETURN 0;
+ END IF;
+
+ CASE
+ WHEN v_part_interval = '15 mins' THEN
+ v_min_partition_timestamp := date_trunc('hour', v_min_control) +
+ '15min'::interval * floor(date_part('minute', v_min_control) / 15.0);
+ WHEN v_part_interval = '30 mins' THEN
+ v_min_partition_timestamp := date_trunc('hour', v_min_control) +
+ '30min'::interval * floor(date_part('minute', v_min_control) / 30.0);
+ WHEN v_part_interval = '1 hour' THEN
+ v_min_partition_timestamp := date_trunc('hour', v_min_control);
+ WHEN v_part_interval = '1 day' THEN
+ v_min_partition_timestamp := date_trunc('day', v_min_control);
+ WHEN v_part_interval = '1 week' THEN
+ v_min_partition_timestamp := date_trunc('week', v_min_control);
+ WHEN v_part_interval = '1 month' THEN
+ v_min_partition_timestamp := date_trunc('month', v_min_control);
+ WHEN v_part_interval = '3 months' THEN
+ v_min_partition_timestamp := date_trunc('quarter', v_min_control);
+ WHEN v_part_interval = '1 year' THEN
+ v_min_partition_timestamp := date_trunc('year', v_min_control);
+ END CASE;
+
+ v_partition_timestamp := ARRAY[v_min_partition_timestamp];
+ RAISE NOTICE 'v_partition_timestamp: %',v_partition_timestamp;
+ IF (v_min_control + p_batch_interval) >= (v_min_partition_timestamp + v_part_interval) THEN
+ v_max_partition_timestamp := v_min_partition_timestamp + v_part_interval;
+ ELSE
+ v_max_partition_timestamp := v_min_control + p_batch_interval;
+ END IF;
+ RAISE NOTICE 'v_max_partition_timestamp: %',v_max_partition_timestamp;
+
+ v_sql := 'SELECT @extschema@.create_time_partition('||quote_literal(p_parent_table)||','||quote_literal(v_control)||','
+ ||quote_literal(v_part_interval)||','||quote_literal(v_datetime_string)||','||quote_literal(v_partition_timestamp)||')';
+ RAISE NOTICE 'v_sql: %', v_sql;
+ EXECUTE v_sql INTO v_last_partition_name;
+
+ v_sql := 'WITH partition_data AS (
+ DELETE FROM ONLY '||p_parent_table||' WHERE '||v_control||' >= '||quote_literal(v_min_control)||
+ ' AND '||v_control||' < '||quote_literal(v_max_partition_timestamp)||' RETURNING *)
+ INSERT INTO '||v_last_partition_name||' SELECT * FROM partition_data';
+ RAISE NOTICE 'v_sql: %', v_sql;
+ EXECUTE v_sql;
+
+ GET DIAGNOSTICS v_rowcount = ROW_COUNT;
+ v_total_rows := v_total_rows + v_rowcount;
+ IF v_rowcount = 0 THEN
+ EXIT;
+ END IF;
+
+END LOOP;
+
+RETURN v_total_rows;
+
+END
+$$;
View
20 sql/functions/run_maintenance.sql
@@ -1,6 +1,6 @@
/*
- * Function to manage pre-creation of the next partitions in a time-based partition set
- * Also manages dropping old partitions if the retention option is set
+ * Function to manage pre-creation of the next partitions in a time-based partition set.
+ * Also manages dropping old partitions if the retention option is set.
*/
CREATE FUNCTION run_maintenance() RETURNS void
LANGUAGE plpgsql SECURITY DEFINER
@@ -49,8 +49,11 @@ SELECT parent_table
, premake
, datetime_string
, last_partition
+ , undo_in_progress
FROM @extschema@.part_config WHERE type = 'time-static' OR type = 'time-dynamic'
LOOP
+
+ CONTINUE WHEN v_row.undo_in_progress;
CASE
WHEN v_row.part_interval = '15 mins' THEN
@@ -92,26 +95,29 @@ LOOP
END IF;
-- Check and see how many premade partitions there are. If it's less than premake in config table, make another
- v_premade_count = EXTRACT('epoch' FROM (v_last_partition_timestamp - v_current_partition_timestamp)::interval) / EXTRACT('epoch' FROM v_row.part_interval::interval);
+ v_premade_count = EXTRACT('epoch' FROM age(v_last_partition_timestamp, v_current_partition_timestamp)) / EXTRACT('epoch' FROM v_row.part_interval::interval);
- IF v_premade_count < v_row.premake THEN
+ -- Loop premaking until config setting is met. Allows it to catch up if it fell behind or if premake changed.
+ WHILE v_premade_count < v_row.premake LOOP
EXECUTE 'SELECT @extschema@.create_next_time_partition('||quote_literal(v_row.parent_table)||')';
v_create_count := v_create_count + 1;
IF v_row.type = 'time-static' THEN
EXECUTE 'SELECT @extschema@.create_time_function('||quote_literal(v_row.parent_table)||')';
END IF;
- END IF;
+ v_last_partition_timestamp := v_last_partition_timestamp + v_row.part_interval;
+ v_premade_count = EXTRACT('epoch' FROM age(v_last_partition_timestamp, v_current_partition_timestamp)) / EXTRACT('epoch' FROM v_row.part_interval::interval);
+ END LOOP;
END LOOP; -- end of creation loop
-- Manage dropping old partitions if retention option is set
FOR v_row IN
- SELECT parent_table FROM @extschema@.part_config WHERE retention IS NOT NULL AND (type = 'time-static' OR type = 'time-dynamic')
+ SELECT parent_table FROM @extschema@.part_config WHERE retention IS NOT NULL AND undo_in_progress = false AND (type = 'time-static' OR type = 'time-dynamic')
LOOP
v_drop_count := v_drop_count + @extschema@.drop_time_partition(v_row.parent_table);
END LOOP;
FOR v_row IN
- SELECT parent_table FROM @extschema@.part_config WHERE retention IS NOT NULL AND (type = 'id-static' OR type = 'id-dynamic')
+ SELECT parent_table FROM @extschema@.part_config WHERE retention IS NOT NULL AND undo_in_progress = false AND (type = 'id-static' OR type = 'id-dynamic')
LOOP
v_drop_count := v_drop_count + @extschema@.drop_id_partition(v_row.parent_table);
END LOOP;
View
124 sql/functions/undo_partition.sql
@@ -0,0 +1,124 @@
+/*
+ * 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) RETURNS bigint
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_adv_lock boolean;
+v_child_table text;
+v_copy_sql text;
+v_job_id bigint;
+v_jobmon_schema text;
+v_old_search_path text;
+v_part_interval interval;
+v_rowcount bigint;
+v_step_id bigint;
+v_tablename text;
+v_total bigint := 0;
+v_undo_count int := 0;
+
+BEGIN
+
+v_adv_lock := pg_try_advisory_lock(hashtext('pg_partman undo_partition'));
+IF v_adv_lock = 'false' THEN
+ RAISE NOTICE 'undo_partition already running.';
+ RETURN 0;
+END IF;
+
+SELECT nspname INTO v_jobmon_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'pg_jobmon' AND e.extnamespace = n.oid;
+IF v_jobmon_schema IS NOT NULL THEN
+ SELECT current_setting('search_path') INTO v_old_search_path;
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+END IF;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ v_job_id := add_job('PARTMAN UNDO PARTITIONING: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Undoing partitioning for table '||p_parent_table);
+END IF;
+
+-- Stops new time partitons from being made as well as stopping child tables from being dropped if they were configured with a retention period.
+UPDATE @extschema@.part_config SET undo_in_progress = true WHERE parent_table = p_parent_table;
+-- Stop data going into child tables and stop new id partitions from being made.
+v_tablename := substring(p_parent_table from position('.' in p_parent_table)+1);
+EXECUTE 'DROP TRIGGER IF EXISTS '||v_tablename||'_part_trig ON '||p_parent_table;
+EXECUTE 'DROP FUNCTION IF EXISTS '||p_parent_table||'_part_trig_func()';
+
+IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Stopped partition creation process. Removed trigger & trigger function');
+END IF;
+
+FOR i IN 1..p_batch_count LOOP
+ SELECT inhrelid::regclass INTO v_child_table
+ FROM pg_catalog.pg_inherits
+ WHERE inhparent::regclass = p_parent_table::regclass
+ ORDER BY inhrelid::regclass::text ASC;
+
+ EXIT WHEN v_child_table IS NULL;
+
+ IF v_jobmon_schema IS NOT NULL THEN
+ v_step_id := add_step(v_job_id, 'Removing child partition: '||v_child_table);
+ END IF;
+
+ v_copy_sql := 'INSERT INTO '||p_parent_table||' SELECT * FROM '||v_child_table;
+ EXECUTE v_copy_sql;
+ GET DIAGNOSTICS v_rowcount = ROW_COUNT;
+ v_total := v_total + v_rowcount;
+
+ EXECUTE 'ALTER TABLE '||v_child_table||' NO INHERIT ' || p_parent_table;
+ IF p_keep_table = false THEN
+ EXECUTE 'DROP TABLE '||v_child_table;
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Child table DROPPED. Moved '||v_rowcount||' rows to parent');
+ END IF;
+ ELSE
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Child table UNINHERITED, not DROPPED. Copied '||v_rowcount||' rows to parent');
+ END IF;
+ END IF;
+ v_undo_count := v_undo_count + 1;
+END LOOP;
+
+IF v_undo_count = 0 THEN
+ -- FOR loop never ran, so there's no child tables left.
+ DELETE FROM @extschema@.part_config WHERE parent_table = p_parent_table;
+ IF v_jobmon_schema IS NOT NULL THEN
+ v_step_id := add_step(v_job_id, 'Removing config from pg_partman (if it existed)');
+ PERFORM update_step(v_step_id, 'OK', 'Done');
+ END IF;
+END IF;
+
+RAISE NOTICE 'Copied % row(s) from % child table(s) to the parent: %', v_total, v_undo_count, p_parent_table;
+IF v_jobmon_schema IS NOT NULL THEN
+ v_step_id := add_step(v_job_id, 'Final stats');
+ PERFORM update_step(v_step_id, 'OK', 'Copied '||v_total||' row(s) from '||v_undo_count||' child table(s) to the parent');
+END IF;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM close_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+END IF;
+
+PERFORM pg_advisory_unlock(hashtext('pg_partman undo_partition'));
+
+RETURN v_total;
+
+EXCEPTION
+ WHEN OTHERS THEN
+ IF v_jobmon_schema IS NOT NULL THEN
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+ IF v_job_id IS NULL THEN
+ v_job_id := add_job('PARTMAN UNDO PARTITIONING: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Partition function maintenance for table '||p_parent_table||' failed');
+ ELSIF v_step_id IS NULL THEN
+ v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
+ END IF;
+ PERFORM update_step(v_step_id, 'CRITICAL', 'ERROR: '||coalesce(SQLERRM,'unknown'));
+ PERFORM fail_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+ END IF;
+ RAISE EXCEPTION '%', SQLERRM;
+END
+$$;
View
166 sql/functions/undo_partition_id.sql
@@ -0,0 +1,166 @@
+/*
+ * 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
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_adv_lock boolean;
+v_batch_loop_count int := 0;
+v_child_loop_total bigint := 0;
+v_child_min bigint;
+v_child_table text;
+v_control text;
+v_inner_loop_count int;
+v_job_id bigint;
+v_jobmon_schema text;
+v_move_sql text;
+v_old_search_path text;
+v_part_interval bigint;
+v_row record;
+v_rowcount bigint;
+v_step_id bigint;
+v_tablename text;
+v_total bigint := 0;
+v_undo_count int := 0;
+
+BEGIN
+
+v_adv_lock := pg_try_advisory_lock(hashtext('pg_partman undo_id_partition'));
+IF v_adv_lock = 'false' THEN
+ RAISE NOTICE 'undo_id_partition already running.';
+ RETURN 0;
+END IF;
+
+SELECT part_interval::bigint
+ , control
+INTO v_part_interval
+ , v_control
+FROM @extschema@.part_config
+WHERE parent_table = p_parent_table
+AND (type = 'id-static' OR type = 'id-dynamic');
+
+IF v_part_interval IS NULL THEN
+ RAISE EXCEPTION 'Configuration for given parent table not found: %', p_parent_table;
+END IF;
+
+SELECT nspname INTO v_jobmon_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'pg_jobmon' AND e.extnamespace = n.oid;
+IF v_jobmon_schema IS NOT NULL THEN
+ SELECT current_setting('search_path') INTO v_old_search_path;
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+END IF;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ v_job_id := add_job('PARTMAN UNDO PARTITIONING: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Undoing partitioning for table '||p_parent_table);
+END IF;
+
+IF p_batch_interval IS NULL THEN
+ p_batch_interval := v_part_interval;
+END IF;
+
+-- Stops new time partitons from being made as well as stopping child tables from being dropped if they were configured with a retention period.
+UPDATE @extschema@.part_config SET undo_in_progress = true WHERE parent_table = p_parent_table;
+-- Stop data going into child tables and stop new id partitions from being made.
+v_tablename := substring(p_parent_table from position('.' in p_parent_table)+1);
+EXECUTE 'DROP TRIGGER IF EXISTS '||v_tablename||'_part_trig ON '||p_parent_table;
+EXECUTE 'DROP FUNCTION IF EXISTS '||p_parent_table||'_part_trig_func()';
+
+IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Stopped partition creation process. Removed trigger & trigger function');
+END IF;
+
+<<outer_child_loop>>
+WHILE v_batch_loop_count < p_batch_count LOOP
+ SELECT inhrelid::regclass INTO v_child_table
+ FROM pg_catalog.pg_inherits
+ WHERE inhparent::regclass = p_parent_table::regclass
+ ORDER BY inhrelid::regclass::text ASC;
+
+ EXIT WHEN v_child_table IS NULL;
+
+ IF v_jobmon_schema IS NOT NULL THEN
+ v_step_id := add_step(v_job_id, 'Removing child partition: '||v_child_table);
+ END IF;
+
+ EXECUTE 'SELECT min('||v_control||') FROM '||v_child_table INTO v_child_min;
+ IF v_child_min IS NULL THEN
+ -- No rows left in this child table. Remove from partition set.
+ EXECUTE 'ALTER TABLE '||v_child_table||' NO INHERIT ' || p_parent_table;
+ IF p_keep_table = false THEN
+ EXECUTE 'DROP TABLE '||v_child_table;
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Child table DROPPED. Moved '||v_child_loop_total||' rows to parent');
+ END IF;
+ ELSE
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Child table UNINHERITED, not DROPPED. Moved '||v_child_loop_total||' rows to parent');
+ END IF;
+ END IF;
+ v_undo_count := v_undo_count + 1;
+ CONTINUE outer_child_loop;
+ END IF;
+ v_inner_loop_count := 1;
+ v_child_loop_total := 0;
+ <<inner_child_loop>>
+ LOOP
+ -- Get everything from the current child minimum up to the multiples of the given interval
+ v_move_sql := 'WITH move_data AS (DELETE FROM '||v_child_table||
+ ' WHERE '||v_control||' <= '||quote_literal(v_child_min + (p_batch_interval * v_inner_loop_count))||' RETURNING *)
+ INSERT INTO '||p_parent_table||' SELECT * FROM move_data';
+ EXECUTE v_move_sql;
+ GET DIAGNOSTICS v_rowcount = ROW_COUNT;
+ v_total := v_total + v_rowcount;
+ v_child_loop_total := v_child_loop_total + v_rowcount;
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Moved '||v_child_loop_total||' rows to parent.');
+ END IF;
+ EXIT inner_child_loop WHEN v_rowcount = 0; -- exit before loop incr if table is empty
+ v_inner_loop_count := v_inner_loop_count + 1;
+ v_batch_loop_count := v_batch_loop_count + 1;
+ EXIT outer_child_loop WHEN v_batch_loop_count >= p_batch_count; -- Exit outer FOR loop if p_batch_count is reached
+ END LOOP inner_child_loop;
+END LOOP outer_child_loop;
+
+IF v_batch_loop_count < p_batch_count THEN
+ -- FOR loop never ran, so there's no child tables left.
+ DELETE FROM @extschema@.part_config WHERE parent_table = p_parent_table;
+ IF v_jobmon_schema IS NOT NULL THEN
+ v_step_id := add_step(v_job_id, 'Removing config from pg_partman');
+ PERFORM update_step(v_step_id, 'OK', 'Done');
+ END IF;
+END IF;
+
+RAISE NOTICE 'Copied % row(s) to the parent. Removed % partitions.', v_total, v_undo_count;
+IF v_jobmon_schema IS NOT NULL THEN
+ v_step_id := add_step(v_job_id, 'Final stats');
+ PERFORM update_step(v_step_id, 'OK', 'Copied '||v_total||' row(s) to the parent. Removed '||v_undo_count||' partitions.');
+END IF;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM close_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+END IF;
+
+PERFORM pg_advisory_unlock(hashtext('pg_partman undo_id_partition'));
+
+RETURN v_total;
+
+EXCEPTION
+ WHEN OTHERS THEN
+ IF v_jobmon_schema IS NOT NULL THEN
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+ IF v_job_id IS NULL THEN
+ v_job_id := add_job('PARTMAN UNDO PARTITIONING: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Partition function maintenance for table '||p_parent_table||' failed');
+ ELSIF v_step_id IS NULL THEN
+ v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
+ END IF;
+ PERFORM update_step(v_step_id, 'CRITICAL', 'ERROR: '||coalesce(SQLERRM,'unknown'));
+ PERFORM fail_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+ END IF;
+ RAISE EXCEPTION '%', SQLERRM;
+END
+$$;
View
166 sql/functions/undo_partition_time.sql
@@ -0,0 +1,166 @@
+/*
+ * 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
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_adv_lock boolean;
+v_batch_loop_count int := 0;
+v_child_min timestamptz;
+v_child_loop_total bigint := 0;
+v_child_table text;
+v_control text;
+v_inner_loop_count int;
+v_job_id bigint;
+v_jobmon_schema text;
+v_move_sql text;
+v_old_search_path text;
+v_part_interval interval;
+v_row record;
+v_rowcount bigint;
+v_step_id bigint;
+v_tablename text;
+v_total bigint := 0;
+v_undo_count int := 0;
+
+BEGIN
+
+v_adv_lock := pg_try_advisory_lock(hashtext('pg_partman undo_time_partition'));
+IF v_adv_lock = 'false' THEN
+ RAISE NOTICE 'undo_time_partition already running.';
+ RETURN 0;
+END IF;
+
+SELECT part_interval::interval
+ , control
+INTO v_part_interval
+ , v_control
+FROM @extschema@.part_config
+WHERE parent_table = p_parent_table
+AND (type = 'time-static' OR type = 'time-dynamic');
+
+IF v_part_interval IS NULL THEN
+ RAISE EXCEPTION 'Configuration for given parent table not found: %', p_parent_table;
+END IF;
+
+SELECT nspname INTO v_jobmon_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'pg_jobmon' AND e.extnamespace = n.oid;
+IF v_jobmon_schema IS NOT NULL THEN
+ SELECT current_setting('search_path') INTO v_old_search_path;
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+END IF;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ v_job_id := add_job('PARTMAN UNDO PARTITIONING: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Undoing partitioning for table '||p_parent_table);
+END IF;
+
+IF p_batch_interval IS NULL THEN
+ p_batch_interval := v_part_interval;
+END IF;
+
+-- Stops new time partitons from being made as well as stopping child tables from being dropped if they were configured with a retention period.
+UPDATE @extschema@.part_config SET undo_in_progress = true WHERE parent_table = p_parent_table;
+-- Stop data going into child tables and stop new id partitions from being made.
+v_tablename := substring(p_parent_table from position('.' in p_parent_table)+1);
+EXECUTE 'DROP TRIGGER IF EXISTS '||v_tablename||'_part_trig ON '||p_parent_table;
+EXECUTE 'DROP FUNCTION IF EXISTS '||p_parent_table||'_part_trig_func()';
+
+IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Stopped partition creation process. Removed trigger & trigger function');
+END IF;
+
+<<outer_child_loop>>
+WHILE v_batch_loop_count < p_batch_count LOOP
+ SELECT inhrelid::regclass INTO v_child_table
+ FROM pg_catalog.pg_inherits
+ WHERE inhparent::regclass = p_parent_table::regclass
+ ORDER BY inhrelid::regclass::text ASC;
+
+ EXIT WHEN v_child_table IS NULL;
+
+ IF v_jobmon_schema IS NOT NULL THEN
+ v_step_id := add_step(v_job_id, 'Removing child partition: '||v_child_table);
+ END IF;
+
+ EXECUTE 'SELECT min('||v_control||') FROM '||v_child_table INTO v_child_min;
+ IF v_child_min IS NULL THEN
+ -- No rows left in this child table. Remove from partition set.
+ EXECUTE 'ALTER TABLE '||v_child_table||' NO INHERIT ' || p_parent_table;
+ IF p_keep_table = false THEN
+ EXECUTE 'DROP TABLE '||v_child_table;
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Child table DROPPED. Moved '||v_child_loop_total||' rows to parent');
+ END IF;
+ ELSE
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Child table UNINHERITED, not DROPPED. Moved '||v_child_loop_total||' rows to parent');
+ END IF;
+ END IF;
+ v_undo_count := v_undo_count + 1;
+ CONTINUE outer_child_loop;
+ END IF;
+ v_inner_loop_count := 1;
+ v_child_loop_total := 0;
+ <<inner_child_loop>>
+ LOOP
+ -- Get everything from the current child minimum up to the multiples of the given interval
+ v_move_sql := 'WITH move_data AS (DELETE FROM '||v_child_table||
+ ' WHERE '||v_control||' <= '||quote_literal(v_child_min + (p_batch_interval * v_inner_loop_count))||' RETURNING *)
+ INSERT INTO '||p_parent_table||' SELECT * FROM move_data';
+ EXECUTE v_move_sql;
+ GET DIAGNOSTICS v_rowcount = ROW_COUNT;
+ v_total := v_total + v_rowcount;
+ v_child_loop_total := v_child_loop_total + v_rowcount;
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Moved '||v_child_loop_total||' rows to parent.');
+ END IF;
+ EXIT inner_child_loop WHEN v_rowcount = 0; -- exit before loop incr if table is empty
+ v_inner_loop_count := v_inner_loop_count + 1;
+ v_batch_loop_count := v_batch_loop_count + 1;
+ EXIT outer_child_loop WHEN v_batch_loop_count >= p_batch_count; -- Exit outer FOR loop if p_batch_count is reached
+ END LOOP inner_child_loop;
+END LOOP outer_child_loop;
+
+IF v_batch_loop_count < p_batch_count THEN
+ -- FOR loop never ran, so there's no child tables left.
+ DELETE FROM @extschema@.part_config WHERE parent_table = p_parent_table;
+ IF v_jobmon_schema IS NOT NULL THEN
+ v_step_id := add_step(v_job_id, 'Removing config from pg_partman');
+ PERFORM update_step(v_step_id, 'OK', 'Done');
+ END IF;
+END IF;
+
+RAISE NOTICE 'Copied % row(s) to the parent. Removed % partitions.', v_total, v_undo_count;
+IF v_jobmon_schema IS NOT NULL THEN
+ v_step_id := add_step(v_job_id, 'Final stats');
+ PERFORM update_step(v_step_id, 'OK', 'Copied '||v_total||' row(s) to the parent. Removed '||v_undo_count||' partitions.');
+END IF;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM close_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+END IF;
+
+PERFORM pg_advisory_unlock(hashtext('pg_partman undo_time_partition'));
+
+RETURN v_total;
+
+EXCEPTION
+ WHEN OTHERS THEN
+ IF v_jobmon_schema IS NOT NULL THEN
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+ IF v_job_id IS NULL THEN
+ v_job_id := add_job('PARTMAN UNDO PARTITIONING: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Partition function maintenance for table '||p_parent_table||' failed');
+ ELSIF v_step_id IS NULL THEN
+ v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
+ END IF;
+ PERFORM update_step(v_step_id, 'CRITICAL', 'ERROR: '||coalesce(SQLERRM,'unknown'));
+ PERFORM fail_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+ END IF;
+ RAISE EXCEPTION '%', SQLERRM;
+END
+$$;
View
1  sql/tables/tables.sql
@@ -9,6 +9,7 @@ CREATE TABLE part_config (
retention_keep_index boolean NOT NULL DEFAULT true,
datetime_string text,
last_partition text,
+ undo_in_progress boolean NOT NULL DEFAULT false,
CONSTRAINT part_config_parent_table_pkey PRIMARY KEY (parent_table),
CONSTRAINT part_config_type_check CHECK (@extschema@.check_partition_type(type)),
CONSTRAINT positive_premake_check CHECK (premake > 0)
View
36 test/test-id-dynamic.sql
@@ -6,7 +6,7 @@
BEGIN;
SELECT set_config('search_path','partman, tap',false);
-SELECT plan(73);
+SELECT plan(101);
CREATE SCHEMA partman_test;
CREATE ROLE partman_basic;
CREATE ROLE partman_revoke;
@@ -40,7 +40,7 @@ SELECT table_privs_are('partman_test', 'id_dynamic_table_p20', 'partman_revoke',
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 create_prev_id_partition('partman_test.id_dynamic_table');
+SELECT partition_data_id('partman_test.id_dynamic_table');
SELECT is_empty('SELECT * FROM ONLY partman_test.id_dynamic_table', 'Check that parent table has had data moved to partition');
SELECT results_eq('SELECT count(*)::int FROM partman_test.id_dynamic_table', ARRAY[9], 'Check count from parent table');
SELECT results_eq('SELECT count(*)::int FROM partman_test.id_dynamic_table_p0', ARRAY[9], 'Check count from id_dynamic_table_p0');
@@ -69,6 +69,7 @@ ALTER TABLE partman_test.id_dynamic_table OWNER TO partman_owner;
INSERT INTO partman_test.id_dynamic_table (col1) VALUES (generate_series(26,38));
SELECT is_empty('SELECT * FROM ONLY partman_test.id_dynamic_table', 'Check that parent table has had no data inserted to it');
+SELECT results_eq('SELECT count(*)::int FROM partman_test.id_dynamic_table', ARRAY[38], 'Check count from id_dynamic_table');
SELECT results_eq('SELECT count(*)::int FROM partman_test.id_dynamic_table_p20', ARRAY[10], 'Check count from 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');
@@ -86,9 +87,10 @@ SELECT table_privs_are('partman_test', 'id_dynamic_table_p50', 'partman_basic',
SELECT table_privs_are('partman_test', 'id_dynamic_table_p50', 'partman_revoke', ARRAY['SELECT'], 'Check partman_revoke privileges of id_dynamic_table_p50');
SELECT table_privs_are('partman_test', 'id_dynamic_table_p60', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_dynamic_table_p60');
SELECT table_privs_are('partman_test', 'id_dynamic_table_p70', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_dynamic_table_p70');
--- Currently unable to test that all privileges have been revoked. Sent in request to pgtap developer.
SELECT table_owner_is ('partman_test', 'id_dynamic_table_p60', 'partman_owner', 'Check that ownership change worked for id_dynamic_table_p60');
SELECT table_owner_is ('partman_test', 'id_dynamic_table_p70', 'partman_owner', 'Check that ownership change worked for id_dynamic_table_p70');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p60', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_dynamic_table_p60');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p70', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_dynamic_table_p70');
INSERT INTO partman_test.id_dynamic_table (col1) VALUES (generate_series(200,210));
SELECT results_eq('SELECT count(*)::int FROM ONLY partman_test.id_dynamic_table', ARRAY[11], 'Check that data outside trigger scope goes to parent');
@@ -102,6 +104,14 @@ SELECT table_privs_are('partman_test', 'id_dynamic_table_p40', 'partman_basic',
SELECT table_privs_are('partman_test', 'id_dynamic_table_p50', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_dynamic_table_p50');
SELECT table_privs_are('partman_test', 'id_dynamic_table_p60', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_dynamic_table_p60');
SELECT table_privs_are('partman_test', 'id_dynamic_table_p70', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_dynamic_table_p70');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p0', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_dynamic_table_p0');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p10', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_dynamic_table_p10');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p20', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_dynamic_table_p20');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p30', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_dynamic_table_p30');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p40', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_dynamic_table_p40');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p50', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_dynamic_table_p50');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p60', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_dynamic_table_p60');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p70', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_dynamic_table_p70');
SELECT table_owner_is ('partman_test', 'id_dynamic_table_p0', 'partman_owner', 'Check that ownership change worked for id_dynamic_table_p0');
SELECT table_owner_is ('partman_test', 'id_dynamic_table_p10', 'partman_owner', 'Check that ownership change worked for id_dynamic_table_p10');
SELECT table_owner_is ('partman_test', 'id_dynamic_table_p20', 'partman_owner', 'Check that ownership change worked for id_dynamic_table_p20');
@@ -111,5 +121,25 @@ SELECT table_owner_is ('partman_test', 'id_dynamic_table_p50', 'partman_owner',
SELECT table_owner_is ('partman_test', 'id_dynamic_table_p60', 'partman_owner', 'Check that ownership change worked for id_dynamic_table_p60');
SELECT table_owner_is ('partman_test', 'id_dynamic_table_p70', 'partman_owner', 'Check that ownership change worked for id_dynamic_table_p70');
+SELECT undo_partition_id('partman_test.id_dynamic_table', 10);
+SELECT results_eq('SELECT count(*)::int FROM ONLY partman_test.id_dynamic_table', ARRAY[49], 'Check count from parent table after undo');
+SELECT has_table('partman_test', 'id_dynamic_table_p0', 'Check id_dynamic_table_p0 still exists');
+SELECT is_empty('SELECT * FROM partman_test.id_dynamic_table_p0', 'Check child table had its data removed id_dynamic_table_p0');
+SELECT has_table('partman_test', 'id_dynamic_table_p10', 'Check id_dynamic_table_p10 still exists');
+SELECT is_empty('SELECT * FROM partman_test.id_dynamic_table_p10', 'Check child table had its data removed id_dynamic_table_p10');
+SELECT has_table('partman_test', 'id_dynamic_table_p20', 'Check id_dynamic_table_p20 still exists');
+SELECT is_empty('SELECT * FROM partman_test.id_dynamic_table_p20', 'Check child table had its data removed id_dynamic_table_p20');
+SELECT has_table('partman_test', 'id_dynamic_table_p30', 'Check id_dynamic_table_p30 still exists');
+SELECT is_empty('SELECT * FROM partman_test.id_dynamic_table_p30', 'Check child table had its data removed id_dynamic_table_p30');
+SELECT has_table('partman_test', 'id_dynamic_table_p40', 'Check id_dynamic_table_p40 still exists');
+SELECT is_empty('SELECT * FROM partman_test.id_dynamic_table_p40', 'Check child table had its data removed id_dynamic_table_p40');
+SELECT has_table('partman_test', 'id_dynamic_table_p50', 'Check id_dynamic_table_p50 still exists');
+SELECT is_empty('SELECT * FROM partman_test.id_dynamic_table_p50', 'Check child table had its data removed id_dynamic_table_p50');
+SELECT has_table('partman_test', 'id_dynamic_table_p60', 'Check id_dynamic_table_p60 still exists');
+SELECT is_empty('SELECT * FROM partman_test.id_dynamic_table_p60', 'Check child table had its data removed id_dynamic_table_p60');
+SELECT has_table('partman_test', 'id_dynamic_table_p70', 'Check id_dynamic_table_p70 still exists');
+SELECT is_empty('SELECT * FROM partman_test.id_dynamic_table_p70', 'Check child table had its data removed id_dynamic_table_p70');
+
+
SELECT * FROM finish();
ROLLBACK;
View
28 test/test-id-static-start-100.sql
@@ -6,7 +6,7 @@
BEGIN;
SELECT set_config('search_path','partman, tap',false);
-SELECT plan(54);
+SELECT plan(76);
CREATE SCHEMA partman_test;
CREATE ROLE partman_basic;
CREATE ROLE partman_owner;
@@ -46,7 +46,7 @@ SELECT table_privs_are('partman_test', 'id_static_table_p80', 'partman_basic', A
SELECT table_privs_are('partman_test', 'id_static_table_p70', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_static_table_p70');
SELECT table_privs_are('partman_test', 'id_static_table_p60', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_static_table_p60');
-SELECT create_prev_id_partition('partman_test.id_static_table');
+SELECT partition_data_id('partman_test.id_static_table');
SELECT is_empty('SELECT * FROM ONLY partman_test.id_static_table', 'Check that parent table has had data moved to partition');
SELECT results_eq('SELECT count(*)::int FROM partman_test.id_static_table', ARRAY[10], 'Check count from parent table');
SELECT results_eq('SELECT count(*)::int FROM partman_test.id_static_table_p100', ARRAY[10], 'Check count from id_static_table_p100');
@@ -78,5 +78,29 @@ SELECT results_eq('SELECT count(*)::int FROM partman_test.id_static_table_p130',
SELECT results_eq('SELECT count(*)::int FROM partman_test.id_static_table_p140', ARRAY[6], 'Check count from id_static_table_p140');
SELECT is_empty('SELECT * FROM partman_test.id_static_table_p150', 'Check that next is empty');
+SELECT undo_partition('partman_test.id_static_table', 20);
+SELECT results_eq('SELECT count(*)::int FROM ONLY partman_test.id_static_table', ARRAY[86], 'Check count from parent table after undo');
+SELECT has_table('partman_test', 'id_static_table_p60', 'Check id_static_table_p60 still exists');
+SELECT has_table('partman_test', 'id_static_table_p70', 'Check id_static_table_p70 still exists');
+SELECT has_table('partman_test', 'id_static_table_p80', 'Check id_static_table_p80 still exists');
+SELECT has_table('partman_test', 'id_static_table_p90', 'Check id_static_table_p90 still exists');
+SELECT has_table('partman_test', 'id_static_table_p100', 'Check id_static_table_p100 still exists');
+SELECT has_table('partman_test', 'id_static_table_p110', 'Check id_static_table_p110 still exists');
+SELECT has_table('partman_test', 'id_static_table_p120', 'Check id_static_table_p120 still exists');
+SELECT has_table('partman_test', 'id_static_table_p130', 'Check id_static_table_p130 still exists');
+SELECT has_table('partman_test', 'id_static_table_p140', 'Check id_static_table_p140 still exists');
+SELECT has_table('partman_test', 'id_static_table_p150', 'Check id_static_table_p140 still exists');
+SELECT has_table('partman_test', 'id_static_table_p160', 'Check id_static_table_p140 still exists');
+SELECT has_table('partman_test', 'id_static_table_p170', 'Check id_static_table_p140 still exists');
+SELECT results_eq('SELECT count(*)::int FROM partman_test.id_static_table_p60', ARRAY[10], 'Check count from id_static_table_p60');
+SELECT results_eq('SELECT count(*)::int FROM partman_test.id_static_table_p70', ARRAY[10], 'Check count from id_static_table_p70');
+SELECT results_eq('SELECT count(*)::int FROM partman_test.id_static_table_p80', ARRAY[10], 'Check count from id_static_table_p80');
+SELECT results_eq('SELECT count(*)::int FROM partman_test.id_static_table_p90', ARRAY[10], 'Check count from id_static_table_p90');
+SELECT results_eq('SELECT count(*)::int FROM partman_test.id_static_table_p100', ARRAY[10], 'Check count from id_static_table_p100');
+SELECT results_eq('SELECT count(*)::int FROM partman_test.id_static_table_p110', ARRAY[10], 'Check count from id_static_table_p110');
+SELECT results_eq('SELECT count(*)::int FROM partman_test.id_static_table_p120', ARRAY[10], 'Check count from id_static_table_p120');
+SELECT results_eq('SELECT count(*)::int FROM partman_test.id_static_table_p130', ARRAY[10], 'Check count from id_static_table_p130');
+SELECT results_eq('SELECT count(*)::int FROM partman_test.id_static_table_p140', ARRAY[6], 'Check count from id_static_table_p140');
+
SELECT * FROM finish();
ROLLBACK;
View
29 test/test-id-static.sql
@@ -6,7 +6,7 @@
BEGIN;
SELECT set_config('search_path','partman, tap',false);
-SELECT plan(82);
+SELECT plan(104);
CREATE SCHEMA partman_test;
CREATE ROLE partman_basic;
CREATE ROLE partman_revoke;
@@ -40,7 +40,7 @@ SELECT table_privs_are('partman_test', 'id_static_table_p20', 'partman_revoke',
SELECT table_privs_are('partman_test', 'id_static_table_p30', 'partman_revoke', ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'], 'Check partman_revoke privileges of id_static_table_p30');
SELECT table_privs_are('partman_test', 'id_static_table_p40', 'partman_revoke', ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'], 'Check partman_revoke privileges of id_static_table_p40');
-SELECT create_prev_id_partition('partman_test.id_static_table');
+SELECT partition_data_id('partman_test.id_static_table');
SELECT is_empty('SELECT * FROM ONLY partman_test.id_static_table', 'Check that parent table has had data moved to partition');
SELECT results_eq('SELECT count(*)::int FROM partman_test.id_static_table', ARRAY[9], 'Check count from parent table');
SELECT results_eq('SELECT count(*)::int FROM partman_test.id_static_table_p0', ARRAY[9], 'Check count from id_static_table_p0');
@@ -92,7 +92,9 @@ SELECT table_privs_are('partman_test', 'id_static_table_p60', 'partman_basic', A
SELECT table_privs_are('partman_test', 'id_static_table_p70', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_static_table_p70');
SELECT table_privs_are('partman_test', 'id_static_table_p80', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_static_table_p80');
SELECT table_privs_are('partman_test', 'id_static_table_p50', 'partman_revoke', ARRAY['SELECT'], 'Check partman_revoke privileges of id_static_table_p50');
--- Currently unable to test that all privileges have been revoked. Sent in request to pgtap developer.
+SELECT table_privs_are('partman_test', 'id_static_table_p60', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_static_table_p60');
+SELECT table_privs_are('partman_test', 'id_static_table_p70', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_static_table_p70');
+SELECT table_privs_are('partman_test', 'id_static_table_p80', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_static_table_p80');
SELECT table_owner_is ('partman_test', 'id_static_table_p60', 'partman_owner', 'Check that ownership change worked for id_static_table_p60');
SELECT table_owner_is ('partman_test', 'id_static_table_p70', 'partman_owner', 'Check that ownership change worked for id_static_table_p70');
SELECT table_owner_is ('partman_test', 'id_static_table_p80', 'partman_owner', 'Check that ownership change worked for id_static_table_p80');
@@ -110,6 +112,15 @@ SELECT table_privs_are('partman_test', 'id_static_table_p50', 'partman_basic', A
SELECT table_privs_are('partman_test', 'id_static_table_p60', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_static_table_p60');
SELECT table_privs_are('partman_test', 'id_static_table_p70', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_static_table_p70');
SELECT table_privs_are('partman_test', 'id_static_table_p80', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_static_table_p80');
+SELECT table_privs_are('partman_test', 'id_static_table_p0', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_static_table_p0');
+SELECT table_privs_are('partman_test', 'id_static_table_p10', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_static_table_p10');
+SELECT table_privs_are('partman_test', 'id_static_table_p20', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_static_table_p20');
+SELECT table_privs_are('partman_test', 'id_static_table_p30', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_static_table_p30');
+SELECT table_privs_are('partman_test', 'id_static_table_p40', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_static_table_p40');
+SELECT table_privs_are('partman_test', 'id_static_table_p50', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_static_table_p50');
+SELECT table_privs_are('partman_test', 'id_static_table_p60', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_static_table_p60');
+SELECT table_privs_are('partman_test', 'id_static_table_p70', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_static_table_p70');
+SELECT table_privs_are('partman_test', 'id_static_table_p80', 'partman_revoke', '{}'::text[], 'Check partman_revoke has no privileges on id_static_table_p80');
SELECT table_owner_is ('partman_test', 'id_static_table_p0', 'partman_owner', 'Check that ownership change worked for id_static_table_p0');
SELECT table_owner_is ('partman_test', 'id_static_table_p10', 'partman_owner', 'Check that ownership change worked for id_static_table_p10');
SELECT table_owner_is ('partman_test', 'id_static_table_p20', 'partman_owner', 'Check that ownership change worked for id_static_table_p20');
@@ -120,5 +131,17 @@ SELECT table_owner_is ('partman_test', 'id_static_table_p60', 'partman_owner', '
SELECT table_owner_is ('partman_test', 'id_static_table_p70', 'partman_owner', 'Check that ownership change worked for id_static_table_p70');
SELECT table_owner_is ('partman_test', 'id_static_table_p80', 'partman_owner', 'Check that ownership change worked for id_static_table_p80');
+SELECT undo_partition_id('partman_test.id_static_table', 10, p_keep_table := false);
+SELECT results_eq('SELECT count(*)::int FROM ONLY partman_test.id_static_table', ARRAY[66], 'Check count from parent table after undo');
+SELECT hasnt_table('partman_test', 'id_static_table_p0', 'Check id_static_table_p0 doesn''t exists anymore');
+SELECT hasnt_table('partman_test', 'id_static_table_p10', 'Check id_static_table_p10 doesn''t exists anymore');
+SELECT hasnt_table('partman_test', 'id_static_table_p20', 'Check id_static_table_p20 doesn''t exists anymore');
+SELECT hasnt_table('partman_test', 'id_static_table_p30', 'Check id_static_table_p30 doesn''t exists anymore');
+SELECT hasnt_table('partman_test', 'id_static_table_p40', 'Check id_static_table_p40 doesn''t exists anymore');
+SELECT hasnt_table('partman_test', 'id_static_table_p50', 'Check id_static_table_p50 doesn''t exists anymore');
+SELECT hasnt_table('partman_test', 'id_static_table_p60', 'Check id_static_table_p60 doesn''t exists anymore');
+SELECT hasnt_table('partman_test', 'id_static_table_p70', 'Check id_static_table_p70 doesn''t exists anymore');
+SELECT hasnt_table('partman_test', 'id_static_table_p80', 'Check id_static_table_p80 doesn''t exists anymore');
+
SELECT * FROM finish();
ROLLBACK;
View
71 test/test-time-dynamic.sql → test/test-time-dynamic-daily.sql
@@ -6,7 +6,7 @@
BEGIN;
SELECT set_config('search_path','partman, tap',false);
-SELECT plan(61);
+SELECT plan(82);
CREATE SCHEMA partman_test;
CREATE ROLE partman_basic;
CREATE ROLE partman_revoke;
@@ -18,17 +18,17 @@ GRANT SELECT,INSERT,UPDATE ON partman_test.time_dynamic_table TO partman_basic;
GRANT ALL ON partman_test.time_dynamic_table TO partman_revoke;
SELECT create_parent('partman_test.time_dynamic_table', 'col3', 'time-dynamic', 'daily');
-SELECT has_table('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'), 'Check time_dynamic_table_'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD')||' exists');
+SELECT has_table('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'), 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD')||' exists');
SELECT has_table('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'),
- 'Check time_dynamic_table_'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD')||' exists');
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD')||' exists');
SELECT has_table('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'),
- 'Check time_dynamic_table_'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD')||' exists');
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD')||' exists');
SELECT has_table('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'),
- 'Check time_dynamic_table_'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD')||' exists');
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD')||' exists');
SELECT has_table('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'),
- 'Check time_dynamic_table_'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD')||' exists');
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD')||' exists');
SELECT hasnt_table('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'),
- 'Check time_dynamic_table_'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD')||' exists');
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD')||' exists');
SELECT col_is_pk('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'), ARRAY['col1'],
'Check for primary key in time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'));
SELECT col_is_pk('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'), ARRAY['col1'],
@@ -56,7 +56,7 @@ SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_T
'Check partman_basic privileges of time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'));
SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'), 'partman_revoke',
ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'],
- 'Check partman_revoke privileges of time_dynamic_table_'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'));
+ 'Check partman_revoke privileges of time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'));
SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'), 'partman_revoke',
ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'],
'Check partman_revoke privileges of time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'));
@@ -70,7 +70,7 @@ SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_T
ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'],
'Check partman_revoke privileges of time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'));
-SELECT create_prev_time_partition('partman_test.time_dynamic_table');
+SELECT partition_data_time('partman_test.time_dynamic_table');
SELECT is_empty('SELECT * FROM ONLY partman_test.time_dynamic_table', 'Check that parent table has had data moved to partition');
SELECT results_eq('SELECT count(*)::int FROM partman_test.time_dynamic_table', ARRAY[10], 'Check count from parent table');
SELECT results_eq('SELECT count(*)::int FROM partman_test.time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'),
@@ -81,6 +81,7 @@ INSERT INTO partman_test.time_dynamic_table (col1, col3) VALUES (generate_series
INSERT INTO partman_test.time_dynamic_table (col1, col3) VALUES (generate_series(21,25), CURRENT_TIMESTAMP + '2 days'::interval);
SELECT is_empty('SELECT * FROM ONLY partman_test.time_dynamic_table', 'Check that parent table has had no data inserted to it');
+SELECT results_eq('SELECT count(*)::int FROM partman_test.time_dynamic_table', ARRAY[25], 'Check count from time_dynamic_table');
SELECT results_eq('SELECT count(*)::int FROM partman_test.time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'),
ARRAY[10], 'Check count from time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'));
SELECT results_eq('SELECT count(*)::int FROM partman_test.time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'),
@@ -89,9 +90,9 @@ SELECT results_eq('SELECT count(*)::int FROM partman_test.time_dynamic_table_p'|
UPDATE part_config SET premake = 5 WHERE parent_table = 'partman_test.time_dynamic_table';
SELECT run_maintenance();
SELECT has_table('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'),
- 'Check time_dynamic_table_'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD')||' exists');
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD')||' exists');
SELECT hasnt_table('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'),
- 'Check time_dynamic_table_'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD')||' exists');
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD')||' exists');
SELECT col_is_pk('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'), ARRAY['col1'],
'Check for primary key in time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'));
SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'), 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'],
@@ -118,9 +119,9 @@ ALTER TABLE partman_test.time_dynamic_table OWNER TO partman_owner;
UPDATE part_config SET premake = 6 WHERE parent_table = 'partman_test.time_dynamic_table';
SELECT run_maintenance();
SELECT has_table('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'),
- 'Check time_dynamic_table_'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD')||' exists');
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD')||' exists');
SELECT hasnt_table('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'7 days'::interval, 'YYYY_MM_DD'),
- 'Check time_dynamic_table_'||to_char(CURRENT_TIMESTAMP+'7 days'::interval, 'YYYY_MM_DD')||' exists');
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'7 days'::interval, 'YYYY_MM_DD')||' exists');
SELECT col_is_pk('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'), ARRAY['col1'],
'Check for primary key in time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'));
SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'), 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'],
@@ -139,10 +140,11 @@ SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_T
'Check partman_basic privileges of time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'));
SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'), 'partman_revoke',
ARRAY['SELECT'], 'Check partman_revoke privileges of time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'), 'partman_revoke',
+ '{}'::text[], 'Check partman_revoke privileges of time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'));
SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'), 'partman_basic',
ARRAY['SELECT','INSERT','UPDATE', 'DELETE'],
'Check partman_basic privileges of time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'));
--- Currently unable to test that all privileges have been revoked. Sent in request to pgtap developer.
SELECT table_owner_is ('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'), 'partman_owner',
'Check that ownership change worked for time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'));
@@ -168,6 +170,22 @@ SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_T
SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'), 'partman_basic',
ARRAY['SELECT','INSERT','UPDATE', 'DELETE'],
'Check partman_basic privileges of time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'));
+
+SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'), 'partman_revoke',
+ '{}'::text[], 'Check partman_revoke privileges of time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'), 'partman_revoke',
+ '{}'::text[], 'Check partman_revoke privileges of time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'), 'partman_revoke',
+ '{}'::text[], 'Check partman_revoke privileges of time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'), 'partman_revoke',
+ '{}'::text[], 'Check partman_revoke privileges of time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'), 'partman_revoke',
+ '{}'::text[], 'Check partman_revoke privileges of time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'), 'partman_revoke',
+ '{}'::text[], 'Check partman_revoke privileges of time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'), 'partman_revoke',
+ '{}'::text[], 'Check partman_revoke privileges of time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'));
+
SELECT table_owner_is ('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'), 'partman_owner',
'Check that ownership change worked for time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'));
SELECT table_owner_is ('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'), 'partman_owner',
@@ -183,6 +201,31 @@ SELECT table_owner_is ('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_T
SELECT table_owner_is ('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'), 'partman_owner',
'Check that ownership change worked for time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'));
+SELECT undo_partition_time('partman_test.time_dynamic_table', 20);
+SELECT has_table('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'),
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD')||' still exists');
+SELECT is_empty('SELECT * FROM partman_test.time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'),
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD')||' is empty');
+SELECT has_table('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'),
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD')||' still exists');
+SELECT is_empty('SELECT * FROM partman_test.time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'),
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD')||' is empty');
+SELECT has_table('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'),
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD')||' still exists');
+SELECT is_empty('SELECT * FROM partman_test.time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'),
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD')||' is empty');
+SELECT has_table('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'),
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD')||' still exists');
+SELECT is_empty('SELECT * FROM partman_test.time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'),
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD')||' is empty');
+SELECT has_table('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'),
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD')||' still exists');
+SELECT is_empty('SELECT * FROM partman_test.time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'),
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD')||' is empty');
+SELECT has_table('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'),
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD')||' still exists');
+SELECT is_empty('SELECT * FROM partman_test.time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'),
+ 'Check time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD')||' is empty');
SELECT * FROM finish();
View
386 test/test-time-dynamic-half-hour.sql
@@ -0,0 +1,386 @@
+-- ########## TIME DYNAMIC TESTS ##########
+
+\set ON_ERROR_ROLLBACK 1
+\set ON_ERROR_STOP true
+
+BEGIN;
+SELECT set_config('search_path','partman, tap',false);
+
+SELECT plan(82);
+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());
+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;
+
+SELECT create_parent('partman_test.time_dynamic_table', 'col3', 'time-dynamic', 'half-hour');
+SELECT has_table('partman_test', 'time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0), 'YYYY_MM_DD_HH24MI'), 'Check time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0), 'YYYY_MM_DD_HH24MI')||' exists');
+SELECT has_table('partman_test', 'time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'30 mins'::interval, 'YYYY_MM_DD_HH24MI'),
+ 'Check time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'30 mins'::interval, 'YYYY_MM_DD_HH24MI')||' exists');
+SELECT has_table('partman_test', 'time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'60 mins'::interval, 'YYYY_MM_DD_HH24MI'),
+ 'Check time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'60 mins'::interval, 'YYYY_MM_DD_HH24MI')||' exists');
+SELECT has_table('partman_test', 'time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'90 mins'::interval, 'YYYY_MM_DD_HH24MI'),
+ 'Check time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'90 mins'::interval, 'YYYY_MM_DD_HH24MI')||' exists');
+SELECT has_table('partman_test', 'time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'120 mins'::interval, 'YYYY_MM_DD_HH24MI'),
+ 'Check time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'120 mins'::interval, 'YYYY_MM_DD_HH24MI')||' exists');
+SELECT hasnt_table('partman_test', 'time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'150 mins'::interval, 'YYYY_MM_DD_HH24MI'),
+ 'Check time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'150 mins'::interval, 'YYYY_MM_DD_HH24MI')||' exists');
+SELECT col_is_pk('partman_test', 'time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0), 'YYYY_MM_DD_HH24MI'), ARRAY['col1'],
+ 'Check for primary key in time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0), 'YYYY_MM_DD_HH24MI'));
+SELECT col_is_pk('partman_test', 'time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'30 mins'::interval, 'YYYY_MM_DD_HH24MI'), ARRAY['col1'],
+ 'Check for primary key in time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'30 mins'::interval, 'YYYY_MM_DD_HH24MI'));
+SELECT col_is_pk('partman_test', 'time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'60 mins'::interval, 'YYYY_MM_DD_HH24MI'), ARRAY['col1'],
+ 'Check for primary key in time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'60 mins'::interval, 'YYYY_MM_DD_HH24MI'));
+SELECT col_is_pk('partman_test', 'time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'90 mins'::interval, 'YYYY_MM_DD_HH24MI'), ARRAY['col1'],
+ 'Check for primary key in time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'90 mins'::interval, 'YYYY_MM_DD_HH24MI'));
+SELECT col_is_pk('partman_test', 'time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'120 mins'::interval, 'YYYY_MM_DD_HH24MI'), ARRAY['col1'],
+ 'Check for primary key in time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'120 mins'::interval, 'YYYY_MM_DD_HH24MI'));
+SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0), 'YYYY_MM_DD_HH24MI'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic privileges of time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0), 'YYYY_MM_DD_HH24MI'));
+SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'30 mins'::interval, 'YYYY_MM_DD_HH24MI'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic privileges of time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'30 mins'::interval, 'YYYY_MM_DD_HH24MI'));
+SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'60 mins'::interval, 'YYYY_MM_DD_HH24MI'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic privileges of time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'60 mins'::interval, 'YYYY_MM_DD_HH24MI'));
+SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0)+'90 mins'::interval, 'YYYY_MM_DD_HH24MI'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic privileges of time_dynamic_table_p'||to_char(date_trunc('hour', CURRENT_TIMESTAMP