Permalink
Browse files

v0.4.1 Changed inner workings of privilege management system so it wo…

…rks better with large partition sets. See CHANGELOG & pg_partman.md file for more info
  • Loading branch information...
1 parent 8c68300 commit 06769323fedd14d57985002e166dc860016fcec1 @keithf4 committed Feb 18, 2013
View
7 CHANGELOG
@@ -1,3 +1,10 @@
+0.4.1
+-- Changed the privilege management system to apply the current parent's privileges only to new child tables at the time they're created. No longer re-applies privileges to existing child tables. When partition sets grew large, this was causing serious performance problems and was too expensive an operation to run every time a child was created.
+-- Dropped apply_grants() function. New child table privileges are now managed by the partition creation functions themselves.
+-- Created reapply_privileges() function to reset the privileges of all child tables in a given partition set. Uses the given parent's privileges at the time the function is run. All new grants will be set and all that don't exist will be revoked. Ownership will be updated if it has changed.
+-- First round of pgTAP tests.
+
+
0.4.0
-- No separate configuration required for setting privileges on child tables anymore. Grants config table has been dropped. Please apply the grants you need to the parent table and they will be set for all children using that. Note that unlike before, privilges that don't exist on the parent will now be revoked from all child tables.
-- create_parent() now enforces that a given parent table be schema qualified. Ensures that a custom search_path doesn't affect the wrong table by accident.
View
6 META.json
@@ -1,7 +1,7 @@
{
"name": "pg_partman",
"abstract": "Extension to manage partitioned tables by time or ID",
- "version": "0.4.0",
+ "version": "0.4.1",
"maintainer": [
"Keith Fiske <keith@omniti.com>"
],
@@ -20,9 +20,9 @@
},
"provides": {
"pg_partmaint": {
- "file": "sql/pg_partman--0.4.0.sql",
+ "file": "sql/pg_partman--0.4.1.sql",
"docfile": "doc/pg_partman.md",
- "version": "0.4.0",
+ "version": "0.4.1",
"abstract": "Extension to manage partitioned tables by time or ID"
}
},
View
4 README.md
@@ -29,7 +29,7 @@ Make sure all the upgrade scripts for the version you have installed up to the m
EXAMPLE
-------
-First create a parent table with an appropriate column type for the partitioning you will do. Here's one with a columns that can be used for either
+First create a parent table with an appropriate column type for the partitioning type you will do. Apply all defaults, indexes, constraints, privileges & ownership to the parent table and they will be inherited to newly created child tables automatically (not already existing partitions). Here's one with columns that can be used for either
CREATE schema test;
CREATE TABLE test.part_test (col1 serial, col2 text, col3 timestamptz DEFAULT now());
@@ -38,7 +38,7 @@ If you're looking to do time-based partitioning, and will only be inserting new
SELECT part.create_parent('test.part_test', 'col3', 'time-static', 'daily');
-This will turn your table into a parent table and premake 4 future partitions. To make new partitions for time-based partitioning, run the run_maintenance() function. Ideally, you'd run this as a cronjob to keep new partitions premade in preparation of new data.
+This will turn your table into a parent table and premake 4 future partitions. To make new partitions for time-based partitioning, use the run_maintenance() function. Ideally, you'd run this as a cronjob to keep new partitions premade in preparation of new data.
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.
View
11 doc/pg_partman.md
@@ -5,7 +5,7 @@ About
-----
pg_partman is an extension to help make managing time or serial id based table partitioning easier.
-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, note that whenever a new partition is created, all child tables have their privileges reset to what the parent has at that time. All current grants are applied and any that the child had that don't match the parent anymore are revoked (with CASCADE option to ensure it doesn't fail the revoke). 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.
+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!
@@ -18,7 +18,7 @@ Functions
A superuser must be used to run these functions in order to set privileges & ownership properly in all cases. All are set with SECURITY DEFINER, so if you cannot have a superuser running them just assign a superuser role as the owner.
*create_parent(p_parent_table text, p_control text, p_type part.partition_type, p_interval text, p_premake int DEFAULT 4, p_debug boolean DEFAULT false)*
- * Main function to create a partition set with one parent table and inherited children. Parent table must already exist. Please apply all defaults, indexes, constraints, privileges & ownership to parent table so they will propagate to children (permissions not yet propagating; working on it!).
+ * Main function to create a partition set with one parent table and inherited children. Parent table must already exist. Please apply all defaults, indexes, constraints, privileges & ownership to parent table so they will propagate to children.
* An ACCESS EXCLUSIVE lock is taken on the parent table during the running of this function. No data is moved when running this function, so lock should be brief.
* p_parent_table - the existing parent table. MUST be schema qualified, even if in public schema.
* p_control - the column that the partitioning will be based on. Must be a time or integer based column.
@@ -84,14 +84,13 @@ A superuser must be used to run these functions in order to set privileges & own
* 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.
-*apply_grants(p_parent_table text)*
- * This function is used to apply ownership & grants on all child tables based on what the parent table has set. It is called automatically any time a new partition is made.
- * This function can be called separately if you need to apply privilege changes before the next partition in the set is made.
+*reapply_privileges(p_parent_table text)*
+ * This function is used to reapply ownership & grants on all child tables based on what the parent table has set.
* Privileges that the parent table has will be granted to all child tables and privilges that the parent does not have will be revoked (with CASCADE).
* Privilges that are checked for are SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, & TRIGGER.
+ * 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 match a parent table name already configured in pg_partman.
-
Tables
------
*part_config*
View
2 pg_partman.control
@@ -1,3 +1,3 @@
-default_version = '0.4.0'
+default_version = '0.4.1'
comment = 'Extension to manage partitioned tables by time or ID'
relocatable = false
View
66 sql/functions/apply_grants.sql
@@ -1,66 +0,0 @@
-/*
- * Function to apply ownership & privileges on child tables using parent table as reference
- */
-CREATE FUNCTION apply_grants(p_parent_table text) RETURNS void
- LANGUAGE plpgsql SECURITY DEFINER
- AS $$
-DECLARE
-
-v_all text[] := ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'];
-v_child_table text;
-v_count int := 0;
-v_grant text;
-v_grantees text[];
-v_owner text;
-v_owner_sql text;
-v_revoke text[];
-v_revoke_sql text;
-v_row record;
-v_sql text;
-
-BEGIN
-
-SELECT count(parent_table) INTO v_count FROM @extschema@.part_config WHERE parent_table = p_parent_table;
-IF v_count = 0 THEN
- RAISE EXCEPTION 'Given table is not managed by this extention: %', p_parent_table;
-END IF;
-
-SELECT tableowner INTO v_owner FROM pg_tables WHERE schemaname ||'.'|| tablename = p_parent_table;
-
-FOR v_child_table IN
- SELECT inhrelid::regclass FROM pg_catalog.pg_inherits WHERE inhparent::regclass = p_parent_table::regclass ORDER BY inhrelid::regclass ASC
-LOOP
- v_grantees := NULL;
- FOR v_row IN
- SELECT array_agg(privilege_type::text) AS types, grantee
- FROM information_schema.table_privileges
- WHERE table_schema ||'.'|| table_name = p_parent_table
- GROUP BY grantee
- LOOP
- EXECUTE 'GRANT '||array_to_string(v_row.types, ',')||' ON '||v_child_table||' TO '||v_row.grantee;
-
- SELECT array_agg(r) INTO v_revoke FROM (SELECT unnest(v_all) AS r EXCEPT SELECT unnest(v_row.types)) x;
- IF v_revoke IS NOT NULL THEN
- EXECUTE 'REVOKE '||array_to_string(v_revoke, ',')||' ON '||v_child_table||' FROM '||v_row.grantee||' CASCADE';
- END IF;
-
- v_grantees := array_append(v_grantees, v_row.grantee::text);
- END LOOP;
-
- -- Revoke all privileges from roles that have none on the parent
- IF v_grantees IS NOT NULL THEN
- SELECT array_agg(r) INTO v_revoke FROM (
- SELECT DISTINCT grantee::text AS r FROM information_schema.table_privileges WHERE table_schema ||'.'|| table_name = v_child_table
- EXCEPT
- SELECT unnest(v_grantees)) x;
- IF v_revoke IS NOT NULL THEN
- EXECUTE 'REVOKE ALL ON '||v_child_table||' FROM '||array_to_string(v_revoke, ',');
- END IF;
- END IF;
-
- EXECUTE 'ALTER TABLE '||v_child_table||' OWNER TO '||v_owner;
-
-END LOOP;
-
-END
-$$;
View
43 sql/functions/create_id_partition.sql
@@ -6,10 +6,15 @@ CREATE FUNCTION create_id_partition (p_parent_table text, p_control text, p_inte
AS $$
DECLARE
+v_all text[] := ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'];
+v_grantees text[];
v_job_id bigint;
v_jobmon_schema text;
v_old_search_path text;
+v_parent_grant record;
+v_parent_owner text;
v_partition_name text;
+v_revoke text[];
v_step_id bigint;
v_tablename text;
v_id bigint;
@@ -22,6 +27,8 @@ IF v_jobmon_schema IS NOT NULL THEN
EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
END IF;
+SELECT tableowner INTO v_parent_owner FROM pg_tables WHERE schemaname ||'.'|| tablename = p_parent_table;
+
FOREACH v_id IN ARRAY p_partition_ids LOOP
v_partition_name := p_parent_table||'_p'||v_id;
@@ -46,6 +53,32 @@ FOREACH v_id IN ARRAY p_partition_ids LOOP
CHECK ('||p_control||'>='||quote_literal(v_id)||' AND '||p_control||'<'||quote_literal(v_id + p_interval)||')';
EXECUTE 'ALTER TABLE '||v_partition_name||' INHERIT '||p_parent_table;
+ FOR v_parent_grant IN
+ SELECT array_agg(DISTINCT privilege_type::text ORDER BY privilege_type::text) AS types, grantee
+ FROM information_schema.table_privileges
+ WHERE table_schema ||'.'|| table_name = p_parent_table
+ GROUP BY grantee
+ LOOP
+ EXECUTE 'GRANT '||array_to_string(v_parent_grant.types, ',')||' ON '||v_partition_name||' TO '||v_parent_grant.grantee;
+ SELECT array_agg(r) INTO v_revoke FROM (SELECT unnest(v_all) AS r EXCEPT SELECT unnest(v_parent_grant.types)) x;
+ IF v_revoke IS NOT NULL THEN
+ EXECUTE 'REVOKE '||array_to_string(v_revoke, ',')||' ON '||v_partition_name||' FROM '||v_parent_grant.grantee||' CASCADE';
+ END IF;
+ v_grantees := array_append(v_grantees, v_parent_grant.grantee::text);
+ END LOOP;
+ -- Revoke all privileges from roles that have none on the parent
+ IF v_grantees IS NOT NULL THEN
+ SELECT array_agg(r) INTO v_revoke FROM (
+ SELECT DISTINCT grantee::text AS r FROM information_schema.table_privileges WHERE table_schema ||'.'|| table_name = v_partition_name
+ EXCEPT
+ SELECT unnest(v_grantees)) x;
+ IF v_revoke IS NOT NULL THEN
+ EXECUTE 'REVOKE ALL ON '||v_partition_name||' FROM '||array_to_string(v_revoke, ',');
+ END IF;
+ END IF;
+
+ EXECUTE 'ALTER TABLE '||v_partition_name||' OWNER TO '||v_parent_owner;
+
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
PERFORM close_job(v_job_id);
@@ -54,16 +87,6 @@ FOREACH v_id IN ARRAY p_partition_ids LOOP
END LOOP;
IF v_jobmon_schema IS NOT NULL THEN
- v_job_id := add_job('PARTMAN APPLYING GRANTS: '||p_parent_table);
- v_step_id := add_step(v_job_id, 'Looping through all child tables applying privileges of the parent');
-END IF;
-PERFORM @extschema@.apply_grants(p_parent_table);
-IF v_jobmon_schema IS NOT NULL THEN
- PERFORM update_step(v_step_id, 'OK', 'Done');
- PERFORM close_job(v_job_id);
-END IF;
-
-IF v_jobmon_schema IS NOT NULL THEN
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;
View
43 sql/functions/create_time_partition.sql
@@ -6,13 +6,18 @@ CREATE FUNCTION create_time_partition (p_parent_table text, p_control text, p_in
AS $$
DECLARE
+v_all text[] := ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'];
+v_grantees text[];
v_job_id bigint;
v_jobmon_schema text;
v_old_search_path text;
+v_parent_grant record;
+v_parent_owner text;
v_partition_name text;
v_partition_timestamp_end timestamp;
v_partition_timestamp_start timestamp;
v_quarter text;
+v_revoke text[];
v_step_id bigint;
v_tablename text;
v_time timestamp;
@@ -26,6 +31,8 @@ IF v_jobmon_schema IS NOT NULL THEN
EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
END IF;
+SELECT tableowner INTO v_parent_owner FROM pg_tables WHERE schemaname ||'.'|| tablename = p_parent_table;
+
FOREACH v_time IN ARRAY p_partition_times LOOP
v_partition_name := p_parent_table || '_p';
@@ -108,6 +115,32 @@ FOREACH v_time IN ARRAY p_partition_times LOOP
CHECK ('||p_control||'>='||quote_literal(v_partition_timestamp_start)||' AND '||p_control||'<'||quote_literal(v_partition_timestamp_end)||')';
EXECUTE 'ALTER TABLE '||v_partition_name||' INHERIT '||p_parent_table;
+ FOR v_parent_grant IN
+ SELECT array_agg(DISTINCT privilege_type::text ORDER BY privilege_type::text) AS types, grantee
+ FROM information_schema.table_privileges
+ WHERE table_schema ||'.'|| table_name = p_parent_table
+ GROUP BY grantee
+ LOOP
+ EXECUTE 'GRANT '||array_to_string(v_parent_grant.types, ',')||' ON '||v_partition_name||' TO '||v_parent_grant.grantee;
+ SELECT array_agg(r) INTO v_revoke FROM (SELECT unnest(v_all) AS r EXCEPT SELECT unnest(v_parent_grant.types)) x;
+ IF v_revoke IS NOT NULL THEN
+ EXECUTE 'REVOKE '||array_to_string(v_revoke, ',')||' ON '||v_partition_name||' FROM '||v_parent_grant.grantee||' CASCADE';
+ END IF;
+ v_grantees := array_append(v_grantees, v_parent_grant.grantee::text);
+ END LOOP;
+ -- Revoke all privileges from roles that have none on the parent
+ IF v_grantees IS NOT NULL THEN
+ SELECT array_agg(r) INTO v_revoke FROM (
+ SELECT DISTINCT grantee::text AS r FROM information_schema.table_privileges WHERE table_schema ||'.'|| table_name = v_partition_name
+ EXCEPT
+ SELECT unnest(v_grantees)) x;
+ IF v_revoke IS NOT NULL THEN
+ EXECUTE 'REVOKE ALL ON '||v_partition_name||' FROM '||array_to_string(v_revoke, ',');
+ END IF;
+ END IF;
+
+ EXECUTE 'ALTER TABLE '||v_partition_name||' OWNER TO '||v_parent_owner;
+
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
PERFORM close_job(v_job_id);
@@ -116,16 +149,6 @@ FOREACH v_time IN ARRAY p_partition_times LOOP
END LOOP;
IF v_jobmon_schema IS NOT NULL THEN
- v_job_id := add_job('PARTMAN APPLYING GRANTS: '||p_parent_table);
- v_step_id := add_step(v_job_id, 'Looping through all child tables applying privileges of the parent');
-END IF;
-PERFORM @extschema@.apply_grants(p_parent_table);
-IF v_jobmon_schema IS NOT NULL THEN
- PERFORM update_step(v_step_id, 'OK', 'Done');
- PERFORM close_job(v_job_id);
-END IF;
-
-IF v_jobmon_schema IS NOT NULL THEN
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;
View
126 sql/functions/reapply_privileges.sql
@@ -0,0 +1,126 @@
+/*
+ * Function to re-apply ownership & privileges on all child tables in a partition set using parent table as reference
+ */
+CREATE FUNCTION reapply_privileges(p_parent_table text) RETURNS void
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_all text[] := ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'];
+v_child_owner text;
+v_child_table text;
+v_child_grant record;
+v_count int;
+v_grant text;
+v_grantees text[];
+v_job_id bigint;
+v_jobmon_schema text;
+v_match boolean;
+v_old_search_path text;
+v_parent_owner text;
+v_owner_sql text;
+v_revoke text[];
+v_parent_grant record;
+v_sql text;
+v_step_id bigint;
+
+BEGIN
+
+SELECT count(*) INTO v_count FROM @extschema@.part_config WHERE parent_table = p_parent_table;
+IF v_count = 0 THEN
+ RAISE EXCEPTION 'Given table is not managed by this extention: %', p_parent_table;
+END IF;
+
+SELECT nspname INTO v_jobmon_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'pg_jobmon' AND e.extnamespace = n.oid;
+IF v_jobmon_schema IS NOT NULL THEN
+ SELECT current_setting('search_path') INTO v_old_search_path;
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+END IF;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ v_job_id := add_job('PARTMAN RE-APPLYING PRIVILEGES TO ALL CHILD TABLES OF: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Setting new child table privileges');
+END IF;
+
+SELECT tableowner INTO v_parent_owner FROM pg_tables WHERE schemaname ||'.'|| tablename = p_parent_table;
+
+FOR v_child_table IN
+ SELECT inhrelid::regclass FROM pg_catalog.pg_inherits WHERE inhparent::regclass = p_parent_table::regclass ORDER BY inhrelid::regclass ASC
+LOOP
+ PERFORM update_step(v_step_id, 'PENDING', 'Currently on child partition in ascending order: '||v_child_table);
+ v_grantees := NULL;
+ FOR v_parent_grant IN
+ SELECT array_agg(DISTINCT privilege_type::text ORDER BY privilege_type::text) AS types, grantee
+ FROM information_schema.table_privileges
+ WHERE table_schema ||'.'|| table_name = p_parent_table
+ GROUP BY grantee
+ LOOP
+ -- Compare parent & child grants. Don't re-apply if it already exists
+ v_match := false;
+ FOR v_child_grant IN
+ SELECT array_agg(DISTINCT privilege_type::text ORDER BY privilege_type::text) AS types, grantee
+ FROM information_schema.table_privileges
+ WHERE table_schema ||'.'|| table_name = v_child_table
+ GROUP BY grantee
+ LOOP
+ IF v_parent_grant.types = v_child_grant.types AND v_parent_grant.grantee = v_child_grant.grantee THEN
+ v_match := true;
+ END IF;
+ END LOOP;
+
+ IF v_match = false THEN
+ EXECUTE 'GRANT '||array_to_string(v_parent_grant.types, ',')||' ON '||v_child_table||' TO '||v_parent_grant.grantee;
+ SELECT array_agg(r) INTO v_revoke FROM (SELECT unnest(v_all) AS r EXCEPT SELECT unnest(v_parent_grant.types)) x;
+ IF v_revoke IS NOT NULL THEN
+ EXECUTE 'REVOKE '||array_to_string(v_revoke, ',')||' ON '||v_child_table||' FROM '||v_parent_grant.grantee||' CASCADE';
+ END IF;
+ END IF;
+
+ v_grantees := array_append(v_grantees, v_parent_grant.grantee::text);
+
+ END LOOP;
+
+ -- Revoke all privileges from roles that have none on the parent
+ IF v_grantees IS NOT NULL THEN
+ SELECT array_agg(r) INTO v_revoke FROM (
+ SELECT DISTINCT grantee::text AS r FROM information_schema.table_privileges WHERE table_schema ||'.'|| table_name = v_child_table
+ EXCEPT
+ SELECT unnest(v_grantees)) x;
+ IF v_revoke IS NOT NULL THEN
+ EXECUTE 'REVOKE ALL ON '||v_child_table||' FROM '||array_to_string(v_revoke, ',');
+ END IF;
+ END IF;
+
+ SELECT tableowner INTO v_child_owner FROM pg_tables WHERE schemaname ||'.'|| tablename = v_child_table;
+ IF v_parent_owner <> v_child_owner THEN
+ EXECUTE 'ALTER TABLE '||v_child_table||' OWNER TO '||v_parent_owner;
+ END IF;
+
+END LOOP;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Done');
+ PERFORM close_job(v_job_id);
+END IF;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+END IF;
+
+EXCEPTION
+ WHEN OTHERS THEN
+ IF v_jobmon_schema IS NOT NULL THEN
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+ IF v_job_id IS NULL THEN
+ v_job_id := add_job('PARTMAN CREATE TABLE: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Partition maintenance for table '||p_parent_table||' failed');
+ ELSIF v_step_id IS NULL THEN
+ v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
+ END IF;
+ PERFORM update_step(v_step_id, 'BAD', 'ERROR: '||coalesce(SQLERRM,'unknown'));
+ PERFORM fail_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+ END IF;
+ RAISE EXCEPTION '%', SQLERRM;
+END
+$$;
View
1 sql/types/types.sql
@@ -1,3 +1,2 @@
-CREATE TYPE partition_type AS ENUM ('time-static', 'time-dynamic', 'id-static', 'id-dynamic');
CREATE TYPE check_parent_table AS (parent_table text, count bigint);
View
21 test/README_test.md
@@ -0,0 +1,21 @@
+pg_partman Test Suite
+=====================
+
+The pgTAP testing suite is used to provide an extensive and easily maintainable set of tests. Please see the pgTAP home page for more details on its installation and use.
+
+http://pgTAP.org/
+
+Tests assume that the required extensions have been installed in the following schemas:
+
+ pg_partman: partman
+ pgTAP: tap
+
+If you've installed any of the above extensions in a different schema and would like to run the test suite, simply change the configuration option found at the top of each testing file to match your setup. If you've also installed pg_jobmon, be aware that the logging of the tests cannot be rolled back and any failures will be picked up by the monitoring in the jobmon extension.
+
+ SELECT set_config('search_path','partman, tap',false);
+
+Once that's done, it's best to use the **pg_prove** script that pgTAP comes with to run all the tests. I like using the -o -f -v options to get more useful feedback.
+
+ pg_prove -o -f -v /path/to/partman/test/*.sql
+
+The tests must be run by a superuser since roles & schemas are created & dropped as part of the test. There is a separate test script for each of the partitioning types. The tests are not required to run pg_partman, so if you don't feel safe doing this you don't need to run the tests. But if you are running into problems and report any issues without a clear explanation of what is wrong, I will ask that you run the test suite so you can try and narrow down where the problem may be. You are free to look through to tests to see exactly what they're doing. Everything is run inside a transaction that is rolled back, so it should not change anything (except jobmon logging as mentioned).
View
115 test/id-dynamic-test.sql
@@ -0,0 +1,115 @@
+-- ########## ID DYNAMIC TESTS ##########
+
+\set ON_ERROR_ROLLBACK 1
+\set ON_ERROR_STOP true
+
+BEGIN;
+SELECT set_config('search_path','partman, tap',false);
+
+SELECT plan(73);
+CREATE SCHEMA partman_test;
+CREATE ROLE partman_basic;
+CREATE ROLE partman_revoke;
+CREATE ROLE partman_owner;
+
+CREATE TABLE partman_test.id_dynamic_table (col1 int primary key, col2 text, col3 timestamptz DEFAULT now());
+INSERT INTO partman_test.id_dynamic_table (col1) VALUES (generate_series(1,9));
+GRANT SELECT,INSERT,UPDATE ON partman_test.id_dynamic_table TO partman_basic;
+GRANT ALL ON partman_test.id_dynamic_table TO partman_revoke;
+
+SELECT create_parent('partman_test.id_dynamic_table', 'col1', 'id-dynamic', '10');
+SELECT has_table('partman_test', 'id_dynamic_table_p0', 'Check id_dynamic_table_p0 exists');
+SELECT has_table('partman_test', 'id_dynamic_table_p10', 'Check id_dynamic_table_p10 exists');
+SELECT has_table('partman_test', 'id_dynamic_table_p20', 'Check id_dynamic_table_p20 exists');
+SELECT has_table('partman_test', 'id_dynamic_table_p30', 'Check id_dynamic_table_p30 exists');
+SELECT has_table('partman_test', 'id_dynamic_table_p40', 'Check id_dynamic_table_p40 exists');
+SELECT hasnt_table('partman_test', 'id_dynamic_table_p50', 'Check id_dynamic_table_p50 doesn''t exists yet');
+SELECT col_is_pk('partman_test', 'id_dynamic_table_p0', ARRAY['col1'], 'Check for primary key in id_dynamic_table_p0');
+SELECT col_is_pk('partman_test', 'id_dynamic_table_p10', ARRAY['col1'], 'Check for primary key in id_dynamic_table_p10');
+SELECT col_is_pk('partman_test', 'id_dynamic_table_p20', ARRAY['col1'], 'Check for primary key in id_dynamic_table_p20');
+SELECT col_is_pk('partman_test', 'id_dynamic_table_p30', ARRAY['col1'], 'Check for primary key in id_dynamic_table_p30');
+SELECT col_is_pk('partman_test', 'id_dynamic_table_p40', ARRAY['col1'], 'Check for primary key in id_dynamic_table_p40');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p0', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p0');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p10', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p10');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p20', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p20');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p30', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p30');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p40', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p40');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p0', 'partman_revoke', ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'], 'Check partman_revoke privileges of id_dynamic_table_p0');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p10', 'partman_revoke', ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'], 'Check partman_revoke privileges of id_dynamic_table_p10');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p20', 'partman_revoke', ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'], 'Check partman_revoke privileges of id_dynamic_table_p20');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p30', 'partman_revoke', ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'], 'Check partman_revoke privileges of id_dynamic_table_p30');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p40', 'partman_revoke', ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'], 'Check partman_revoke privileges of id_dynamic_table_p40');
+
+SELECT create_prev_id_partition('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');
+
+REVOKE INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER ON partman_test.id_dynamic_table FROM partman_revoke;
+INSERT INTO partman_test.id_dynamic_table (col1) VALUES (generate_series(10,25));
+
+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_p10', ARRAY[10], 'Check count from id_dynamic_table_p10');
+SELECT results_eq('SELECT count(*)::int FROM partman_test.id_dynamic_table_p20', ARRAY[6], 'Check count from id_dynamic_table_p20');
+
+SELECT has_table('partman_test', 'id_dynamic_table_p50', 'Check id_dynamic_table_p50 exists');
+SELECT hasnt_table('partman_test', 'id_dynamic_table_p60', 'Check id_dynamic_table_p60 doesn''t exists yet');
+SELECT col_is_pk('partman_test', 'id_dynamic_table_p50', ARRAY['col1'], 'Check for primary key in id_dynamic_table_p50');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p0', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p0');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p10', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p10');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p20', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p20');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p30', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p30');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p40', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p40');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p50', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p50');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p50', 'partman_revoke', ARRAY['SELECT'], 'Check partman_revoke privileges of id_dynamic_table_p50');
+
+GRANT DELETE ON partman_test.id_dynamic_table TO partman_basic;
+REVOKE ALL ON partman_test.id_dynamic_table FROM partman_revoke;
+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_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');
+
+SELECT has_table('partman_test', 'id_dynamic_table_p60', 'Check id_dynamic_table_p60 exists');
+SELECT has_table('partman_test', 'id_dynamic_table_p70', 'Check id_dynamic_table_p70 exists');
+SELECT hasnt_table('partman_test', 'id_dynamic_table_p80', 'Check id_dynamic_table_p80 doesn''t exists yet');
+SELECT col_is_pk('partman_test', 'id_dynamic_table_p60', ARRAY['col1'], 'Check for primary key in id_dynamic_table_p60');
+SELECT col_is_pk('partman_test', 'id_dynamic_table_p70', ARRAY['col1'], 'Check for primary key in id_dynamic_table_p70');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p0', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p0');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p10', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p10');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p20', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p20');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p30', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p30');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p40', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p40');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p50', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_dynamic_table_p50');
+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');
+
+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');
+
+SELECT reapply_privileges('partman_test.id_dynamic_table');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p0', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_dynamic_table_p0');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p10', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_dynamic_table_p10');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p20', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_dynamic_table_p20');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p30', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_dynamic_table_p30');
+SELECT table_privs_are('partman_test', 'id_dynamic_table_p40', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_dynamic_table_p40');
+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_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');
+SELECT table_owner_is ('partman_test', 'id_dynamic_table_p30', 'partman_owner', 'Check that ownership change worked for id_dynamic_table_p30');
+SELECT table_owner_is ('partman_test', 'id_dynamic_table_p40', 'partman_owner', 'Check that ownership change worked for id_dynamic_table_p40');
+SELECT table_owner_is ('partman_test', 'id_dynamic_table_p50', 'partman_owner', 'Check that ownership change worked for id_dynamic_table_p50');
+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 * FROM finish();
+ROLLBACK;
View
115 test/id-static-test.sql
@@ -0,0 +1,115 @@
+-- ########## ID STATIC TESTS ##########
+
+\set ON_ERROR_ROLLBACK 1
+\set ON_ERROR_STOP true
+
+BEGIN;
+SELECT set_config('search_path','partman, tap',false);
+
+SELECT plan(73);
+CREATE SCHEMA partman_test;
+CREATE ROLE partman_basic;
+CREATE ROLE partman_revoke;
+CREATE ROLE partman_owner;
+
+CREATE TABLE partman_test.id_static_table (col1 int primary key, col2 text, col3 timestamptz DEFAULT now());
+INSERT INTO partman_test.id_static_table (col1) VALUES (generate_series(1,9));
+GRANT SELECT,INSERT,UPDATE ON partman_test.id_static_table TO partman_basic;
+GRANT ALL ON partman_test.id_static_table TO partman_revoke;
+
+SELECT create_parent('partman_test.id_static_table', 'col1', 'id-static', '10');
+SELECT has_table('partman_test', 'id_static_table_p0', 'Check id_static_table_p0 exists');
+SELECT has_table('partman_test', 'id_static_table_p10', 'Check id_static_table_p10 exists');
+SELECT has_table('partman_test', 'id_static_table_p20', 'Check id_static_table_p20 exists');
+SELECT has_table('partman_test', 'id_static_table_p30', 'Check id_static_table_p30 exists');
+SELECT has_table('partman_test', 'id_static_table_p40', 'Check id_static_table_p40 exists');
+SELECT hasnt_table('partman_test', 'id_static_table_p50', 'Check id_static_table_p50 doesn''t exists yet');
+SELECT col_is_pk('partman_test', 'id_static_table_p0', ARRAY['col1'], 'Check for primary key in id_static_table_p0');
+SELECT col_is_pk('partman_test', 'id_static_table_p10', ARRAY['col1'], 'Check for primary key in id_static_table_p10');
+SELECT col_is_pk('partman_test', 'id_static_table_p20', ARRAY['col1'], 'Check for primary key in id_static_table_p20');
+SELECT col_is_pk('partman_test', 'id_static_table_p30', ARRAY['col1'], 'Check for primary key in id_static_table_p30');
+SELECT col_is_pk('partman_test', 'id_static_table_p40', ARRAY['col1'], 'Check for primary key in id_static_table_p40');
+SELECT table_privs_are('partman_test', 'id_static_table_p0', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_static_table_p0');
+SELECT table_privs_are('partman_test', 'id_static_table_p10', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_static_table_p10');
+SELECT table_privs_are('partman_test', 'id_static_table_p20', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_static_table_p20');
+SELECT table_privs_are('partman_test', 'id_static_table_p30', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_static_table_p30');
+SELECT table_privs_are('partman_test', 'id_static_table_p40', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_static_table_p40');
+SELECT table_privs_are('partman_test', 'id_static_table_p0', 'partman_revoke', ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'], 'Check partman_revoke privileges of id_static_table_p0');
+SELECT table_privs_are('partman_test', 'id_static_table_p10', 'partman_revoke', ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'], 'Check partman_revoke privileges of id_static_table_p10');
+SELECT table_privs_are('partman_test', 'id_static_table_p20', 'partman_revoke', ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'], 'Check partman_revoke privileges of id_static_table_p20');
+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 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');
+
+REVOKE INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER ON partman_test.id_static_table FROM partman_revoke;
+INSERT INTO partman_test.id_static_table (col1) VALUES (generate_series(10,25));
+
+SELECT is_empty('SELECT * FROM ONLY partman_test.id_static_table', 'Check that parent table has had no data inserted to it');
+SELECT results_eq('SELECT count(*)::int FROM partman_test.id_static_table_p10', ARRAY[10], 'Check count from id_static_table_p10');
+SELECT results_eq('SELECT count(*)::int FROM partman_test.id_static_table_p20', ARRAY[6], 'Check count from id_static_table_p20');
+
+SELECT has_table('partman_test', 'id_static_table_p50', 'Check id_static_table_p50 exists');
+SELECT hasnt_table('partman_test', 'id_static_table_p60', 'Check id_static_table_p60 doesn''t exists yet');
+SELECT col_is_pk('partman_test', 'id_static_table_p50', ARRAY['col1'], 'Check for primary key in id_static_table_p50');
+SELECT table_privs_are('partman_test', 'id_static_table_p0', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_static_table_p0');
+SELECT table_privs_are('partman_test', 'id_static_table_p10', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_static_table_p10');
+SELECT table_privs_are('partman_test', 'id_static_table_p20', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_static_table_p20');
+SELECT table_privs_are('partman_test', 'id_static_table_p30', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_static_table_p30');
+SELECT table_privs_are('partman_test', 'id_static_table_p40', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_static_table_p40');
+SELECT table_privs_are('partman_test', 'id_static_table_p50', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_static_table_p50');
+SELECT table_privs_are('partman_test', 'id_static_table_p50', 'partman_revoke', ARRAY['SELECT'], 'Check partman_revoke privileges of id_static_table_p50');
+
+GRANT DELETE ON partman_test.id_static_table TO partman_basic;
+REVOKE ALL ON partman_test.id_static_table FROM partman_revoke;
+ALTER TABLE partman_test.id_static_table OWNER TO partman_owner;
+INSERT INTO partman_test.id_static_table (col1) VALUES (generate_series(26,38));
+
+SELECT is_empty('SELECT * FROM ONLY partman_test.id_static_table', 'Check that parent table has had no data inserted to it');
+SELECT results_eq('SELECT count(*)::int FROM partman_test.id_static_table_p20', ARRAY[10], 'Check count from id_static_table_p20');
+SELECT results_eq('SELECT count(*)::int FROM partman_test.id_static_table_p30', ARRAY[9], 'Check count from id_static_table_p30');
+
+SELECT has_table('partman_test', 'id_static_table_p60', 'Check id_static_table_p60 exists');
+SELECT has_table('partman_test', 'id_static_table_p70', 'Check id_static_table_p70 exists');
+SELECT hasnt_table('partman_test', 'id_static_table_p80', 'Check id_static_table_p80 doesn''t exists yet');
+SELECT col_is_pk('partman_test', 'id_static_table_p60', ARRAY['col1'], 'Check for primary key in id_static_table_p60');
+SELECT col_is_pk('partman_test', 'id_static_table_p70', ARRAY['col1'], 'Check for primary key in id_static_table_p70');
+SELECT table_privs_are('partman_test', 'id_static_table_p0', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_static_table_p0');
+SELECT table_privs_are('partman_test', 'id_static_table_p10', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_static_table_p10');
+SELECT table_privs_are('partman_test', 'id_static_table_p20', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_static_table_p20');
+SELECT table_privs_are('partman_test', 'id_static_table_p30', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_static_table_p30');
+SELECT table_privs_are('partman_test', 'id_static_table_p40', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_static_table_p40');
+SELECT table_privs_are('partman_test', 'id_static_table_p50', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'], 'Check partman_basic privileges of id_static_table_p50');
+SELECT table_privs_are('partman_test', 'id_static_table_p50', 'partman_revoke', ARRAY['SELECT'], 'Check partman_revoke privileges of id_static_table_p50');
+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');
+-- Currently unable to test that all privileges have been revoked. Sent in request to pgtap developer.
+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');
+
+INSERT INTO partman_test.id_static_table (col1) VALUES (generate_series(200,210));
+SELECT results_eq('SELECT count(*)::int FROM ONLY partman_test.id_static_table', ARRAY[11], 'Check that data outside trigger scope goes to parent');
+
+SELECT reapply_privileges('partman_test.id_static_table');
+SELECT table_privs_are('partman_test', 'id_static_table_p0', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_static_table_p0');
+SELECT table_privs_are('partman_test', 'id_static_table_p10', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_static_table_p10');
+SELECT table_privs_are('partman_test', 'id_static_table_p20', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_static_table_p20');
+SELECT table_privs_are('partman_test', 'id_static_table_p30', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_static_table_p30');
+SELECT table_privs_are('partman_test', 'id_static_table_p40', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_static_table_p40');
+SELECT table_privs_are('partman_test', 'id_static_table_p50', 'partman_basic', ARRAY['SELECT','INSERT','UPDATE','DELETE'], 'Check partman_basic privileges of id_static_table_p50');
+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_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');
+SELECT table_owner_is ('partman_test', 'id_static_table_p30', 'partman_owner', 'Check that ownership change worked for id_static_table_p30');
+SELECT table_owner_is ('partman_test', 'id_static_table_p40', 'partman_owner', 'Check that ownership change worked for id_static_table_p40');
+SELECT table_owner_is ('partman_test', 'id_static_table_p50', 'partman_owner', 'Check that ownership change worked for id_static_table_p50');
+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 * FROM finish();
+ROLLBACK;
View
189 test/time-dynamic.test.sql
@@ -0,0 +1,189 @@
+-- ########## TIME DYNAMIC TESTS ##########
+
+\set ON_ERROR_ROLLBACK 1
+\set ON_ERROR_STOP true
+
+BEGIN;
+SELECT set_config('search_path','partman, tap',false);
+
+SELECT plan(61);
+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', '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+'1 day'::interval, 'YYYY_MM_DD'),
+ 'Check time_dynamic_table_'||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');
+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');
+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');
+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');
+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'],
+ 'Check for primary key in time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'));
+SELECT col_is_pk('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'), ARRAY['col1'],
+ 'Check for primary key in time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'));
+SELECT col_is_pk('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'), ARRAY['col1'],
+ 'Check for primary key in time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'));
+SELECT col_is_pk('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'), ARRAY['col1'],
+ 'Check for primary key in 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_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic 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_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic 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_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic 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_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic 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_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ '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'));
+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'));
+SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::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+'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',
+ ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'],
+ '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',
+ 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 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'),
+ ARRAY[10], 'Check count from time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'));
+
+REVOKE INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER ON partman_test.time_dynamic_table FROM partman_revoke;
+INSERT INTO partman_test.time_dynamic_table (col1, col3) VALUES (generate_series(11,20), CURRENT_TIMESTAMP + '1 day'::interval);
+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_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'),
+ ARRAY[5], 'Check count from time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'));
+
+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');
+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');
+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'],
+ 'Check partman_basic 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_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic 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_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic 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_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic 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_basic',
+ARRAY['SELECT','INSERT','UPDATE'],
+ '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'));
+
+GRANT DELETE ON partman_test.time_dynamic_table TO partman_basic;
+REVOKE ALL ON partman_test.time_dynamic_table FROM partman_revoke;
+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');
+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');
+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'],
+ 'Check partman_basic 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_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic 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_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic 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_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic 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_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ '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_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'));
+
+INSERT INTO partman_test.time_dynamic_table (col1, col3) VALUES (generate_series(200,210), CURRENT_TIMESTAMP + '20 days'::interval);
+SELECT results_eq('SELECT count(*)::int FROM ONLY partman_test.time_dynamic_table', ARRAY[11], 'Check that data outside trigger scope goes to parent');
+
+SELECT reapply_privileges('partman_test.time_dynamic_table');
+SELECT table_privs_are('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE', 'DELETE'],
+ 'Check partman_basic 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_basic',
+ ARRAY['SELECT','INSERT','UPDATE', 'DELETE'],
+ 'Check partman_basic 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_basic',
+ ARRAY['SELECT','INSERT','UPDATE', 'DELETE'],
+ 'Check partman_basic 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_basic',
+ ARRAY['SELECT','INSERT','UPDATE', 'DELETE'],
+ 'Check partman_basic 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_basic',
+ ARRAY['SELECT','INSERT','UPDATE', 'DELETE'],
+ '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+'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_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',
+ 'Check that ownership change worked for time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'));
+SELECT table_owner_is ('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'), 'partman_owner',
+ 'Check that ownership change worked for time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'));
+SELECT table_owner_is ('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'), 'partman_owner',
+ 'Check that ownership change worked for time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'));
+SELECT table_owner_is ('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'), 'partman_owner',
+ 'Check that ownership change worked for time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'));
+SELECT table_owner_is ('partman_test', 'time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'), 'partman_owner',
+ 'Check that ownership change worked for time_dynamic_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'));
+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 * FROM finish();
+ROLLBACK;
View
189 test/time-static.test.sql
@@ -0,0 +1,189 @@
+-- ########## TIME STATIC TESTS ##########
+
+\set ON_ERROR_ROLLBACK 1
+\set ON_ERROR_STOP true
+
+BEGIN;
+SELECT set_config('search_path','partman, tap',false);
+
+SELECT plan(61);
+CREATE SCHEMA partman_test;
+CREATE ROLE partman_basic;
+CREATE ROLE partman_revoke;
+CREATE ROLE partman_owner;
+
+CREATE TABLE partman_test.time_static_table (col1 int primary key, col2 text, col3 timestamptz NOT NULL DEFAULT now());
+INSERT INTO partman_test.time_static_table (col1, col3) VALUES (generate_series(1,10), CURRENT_TIMESTAMP);
+GRANT SELECT,INSERT,UPDATE ON partman_test.time_static_table TO partman_basic;
+GRANT ALL ON partman_test.time_static_table TO partman_revoke;
+
+SELECT create_parent('partman_test.time_static_table', 'col3', 'time-static', 'daily');
+SELECT has_table('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'), 'Check time_static_table_'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD')||' exists');
+SELECT has_table('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'),
+ 'Check time_static_table_'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD')||' exists');
+SELECT has_table('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'),
+ 'Check time_static_table_'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD')||' exists');
+SELECT has_table('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'),
+ 'Check time_static_table_'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD')||' exists');
+SELECT has_table('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'),
+ 'Check time_static_table_'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD')||' exists');
+SELECT hasnt_table('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'),
+ 'Check time_static_table_'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD')||' exists');
+SELECT col_is_pk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'), ARRAY['col1'],
+ 'Check for primary key in time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'));
+SELECT col_is_pk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'), ARRAY['col1'],
+ 'Check for primary key in time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'));
+SELECT col_is_pk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'), ARRAY['col1'],
+ 'Check for primary key in time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'));
+SELECT col_is_pk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'), ARRAY['col1'],
+ 'Check for primary key in time_static_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'));
+SELECT col_is_pk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'), ARRAY['col1'],
+ 'Check for primary key in time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_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_static_table_'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_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_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'), 'partman_revoke',
+ ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'],
+ 'Check partman_revoke privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'), 'partman_revoke',
+ ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'],
+ 'Check partman_revoke privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'), 'partman_revoke',
+ ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'],
+ 'Check partman_revoke privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'));
+
+SELECT create_prev_time_partition('partman_test.time_static_table');
+SELECT is_empty('SELECT * FROM ONLY partman_test.time_static_table', 'Check that parent table has had data moved to partition');
+SELECT results_eq('SELECT count(*)::int FROM partman_test.time_static_table', ARRAY[10], 'Check count from parent table');
+SELECT results_eq('SELECT count(*)::int FROM partman_test.time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'),
+ ARRAY[10], 'Check count from time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'));
+
+REVOKE INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER ON partman_test.time_static_table FROM partman_revoke;
+INSERT INTO partman_test.time_static_table (col1, col3) VALUES (generate_series(11,20), CURRENT_TIMESTAMP + '1 day'::interval);
+INSERT INTO partman_test.time_static_table (col1, col3) VALUES (generate_series(21,25), CURRENT_TIMESTAMP + '2 days'::interval);
+
+SELECT is_empty('SELECT * FROM ONLY partman_test.time_static_table', 'Check that parent table has had no data inserted to it');
+SELECT results_eq('SELECT count(*)::int FROM partman_test.time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'),
+ ARRAY[10], 'Check count from time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'));
+SELECT results_eq('SELECT count(*)::int FROM partman_test.time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'),
+ ARRAY[5], 'Check count from time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'));
+
+UPDATE part_config SET premake = 5 WHERE parent_table = 'partman_test.time_static_table';
+SELECT run_maintenance();
+SELECT has_table('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'),
+ 'Check time_static_table_'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD')||' exists');
+SELECT hasnt_table('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'),
+ 'Check time_static_table_'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD')||' exists');
+SELECT col_is_pk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'), ARRAY['col1'],
+ 'Check for primary key in time_static_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'), 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'), 'partman_basic',
+ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'), 'partman_revoke',
+ ARRAY['SELECT'], 'Check partman_revoke privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'));
+
+GRANT DELETE ON partman_test.time_static_table TO partman_basic;
+REVOKE ALL ON partman_test.time_static_table FROM partman_revoke;
+ALTER TABLE partman_test.time_static_table OWNER TO partman_owner;
+
+UPDATE part_config SET premake = 6 WHERE parent_table = 'partman_test.time_static_table';
+SELECT run_maintenance();
+SELECT has_table('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'),
+ 'Check time_static_table_'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD')||' exists');
+SELECT hasnt_table('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'7 days'::interval, 'YYYY_MM_DD'),
+ 'Check time_static_table_'||to_char(CURRENT_TIMESTAMP+'7 days'::interval, 'YYYY_MM_DD')||' exists');
+SELECT col_is_pk('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'), ARRAY['col1'],
+ 'Check for primary key in time_static_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'), 'partman_basic', ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE'],
+ 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'), 'partman_revoke',
+ ARRAY['SELECT'], 'Check partman_revoke privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_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_static_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_static_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'), 'partman_owner',
+ 'Check that ownership change worked for time_static_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'));
+
+INSERT INTO partman_test.time_static_table (col1, col3) VALUES (generate_series(200,210), CURRENT_TIMESTAMP + '20 days'::interval);
+SELECT results_eq('SELECT count(*)::int FROM ONLY partman_test.time_static_table', ARRAY[11], 'Check that data outside trigger scope goes to parent');
+
+SELECT reapply_privileges('partman_test.time_static_table');
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE', 'DELETE'],
+ 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE', 'DELETE'],
+ 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE', 'DELETE'],
+ 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE', 'DELETE'],
+ 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'), 'partman_basic',
+ ARRAY['SELECT','INSERT','UPDATE', 'DELETE'],
+ 'Check partman_basic privileges of time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'));
+SELECT table_privs_are('partman_test', 'time_static_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_static_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'));
+SELECT table_owner_is ('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'), 'partman_owner',
+ 'Check that ownership change worked for time_static_table_p'||to_char(CURRENT_TIMESTAMP, 'YYYY_MM_DD'));
+SELECT table_owner_is ('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'), 'partman_owner',
+ 'Check that ownership change worked for time_static_table_p'||to_char(CURRENT_TIMESTAMP+'1 day'::interval, 'YYYY_MM_DD'));
+SELECT table_owner_is ('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'), 'partman_owner',
+ 'Check that ownership change worked for time_static_table_p'||to_char(CURRENT_TIMESTAMP+'2 days'::interval, 'YYYY_MM_DD'));
+SELECT table_owner_is ('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'), 'partman_owner',
+ 'Check that ownership change worked for time_static_table_p'||to_char(CURRENT_TIMESTAMP+'3 days'::interval, 'YYYY_MM_DD'));
+SELECT table_owner_is ('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'), 'partman_owner',
+ 'Check that ownership change worked for time_static_table_p'||to_char(CURRENT_TIMESTAMP+'4 days'::interval, 'YYYY_MM_DD'));
+SELECT table_owner_is ('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'), 'partman_owner',
+ 'Check that ownership change worked for time_static_table_p'||to_char(CURRENT_TIMESTAMP+'5 days'::interval, 'YYYY_MM_DD'));
+SELECT table_owner_is ('partman_test', 'time_static_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'), 'partman_owner',
+ 'Check that ownership change worked for time_static_table_p'||to_char(CURRENT_TIMESTAMP+'6 days'::interval, 'YYYY_MM_DD'));
+
+
+
+SELECT * FROM finish();
+ROLLBACK;
View
422 updates/pg_partman--0.4.0--0.4.1.sql
@@ -0,0 +1,422 @@
+-- Changed the privilege management system to apply the current parent's privileges only to new child tables at the time they're created. No longer re-applies privileges to existing child tables. When partition sets grew large, this was causing serious performance problems and was too expensive an operation to run every time a child was created.
+-- Dropped apply_grants() function. New child table privileges are now managed by the partition creation functions themselves.
+-- Created reapply_privileges() function to reset the privileges of all child tables in a given partition set. Uses the given parent's privileges at the time the function is run. All new grants will be set and all that don't exist will be revoked. Ownership will be updated if it has changed.
+-- First round of pgTAP tests.
+
+DROP FUNCTION apply_grants(text);
+DROP TYPE IF EXISTS @extschema@.partition_type;
+
+/*
+ * Function to re-apply ownership & privileges on all child tables in a partition set using parent table as reference
+ */
+CREATE FUNCTION reapply_privileges(p_parent_table text) RETURNS void
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_all text[] := ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'];
+v_child_owner text;
+v_child_table text;
+v_child_grant record;
+v_count int;
+v_grant text;
+v_grantees text[];
+v_job_id bigint;
+v_jobmon_schema text;
+v_match boolean;
+v_old_search_path text;
+v_parent_owner text;
+v_owner_sql text;
+v_revoke text[];
+v_parent_grant record;
+v_sql text;
+v_step_id bigint;
+
+BEGIN
+
+SELECT count(*) INTO v_count FROM @extschema@.part_config WHERE parent_table = p_parent_table;
+IF v_count = 0 THEN
+ RAISE EXCEPTION 'Given table is not managed by this extention: %', p_parent_table;
+END IF;
+
+SELECT nspname INTO v_jobmon_schema FROM pg_namespace n, pg_extension e WHERE e.extname = 'pg_jobmon' AND e.extnamespace = n.oid;
+IF v_jobmon_schema IS NOT NULL THEN
+ SELECT current_setting('search_path') INTO v_old_search_path;
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+END IF;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ v_job_id := add_job('PARTMAN RE-APPLYING PRIVILEGES TO ALL CHILD TABLES OF: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Setting new child table privileges');
+END IF;
+
+SELECT tableowner INTO v_parent_owner FROM pg_tables WHERE schemaname ||'.'|| tablename = p_parent_table;
+
+FOR v_child_table IN
+ SELECT inhrelid::regclass FROM pg_catalog.pg_inherits WHERE inhparent::regclass = p_parent_table::regclass ORDER BY inhrelid::regclass ASC
+LOOP
+ PERFORM update_step(v_step_id, 'PENDING', 'Currently on child partition in ascending order: '||v_child_table);
+ v_grantees := NULL;
+ FOR v_parent_grant IN
+ SELECT array_agg(DISTINCT privilege_type::text ORDER BY privilege_type::text) AS types, grantee
+ FROM information_schema.table_privileges
+ WHERE table_schema ||'.'|| table_name = p_parent_table
+ GROUP BY grantee
+ LOOP
+ -- Compare parent & child grants. Don't re-apply if it already exists
+ v_match := false;
+ FOR v_child_grant IN
+ SELECT array_agg(DISTINCT privilege_type::text ORDER BY privilege_type::text) AS types, grantee
+ FROM information_schema.table_privileges
+ WHERE table_schema ||'.'|| table_name = v_child_table
+ GROUP BY grantee
+ LOOP
+ IF v_parent_grant.types = v_child_grant.types AND v_parent_grant.grantee = v_child_grant.grantee THEN
+ v_match := true;
+ END IF;
+ END LOOP;
+
+ IF v_match = false THEN
+ EXECUTE 'GRANT '||array_to_string(v_parent_grant.types, ',')||' ON '||v_child_table||' TO '||v_parent_grant.grantee;
+ SELECT array_agg(r) INTO v_revoke FROM (SELECT unnest(v_all) AS r EXCEPT SELECT unnest(v_parent_grant.types)) x;
+ IF v_revoke IS NOT NULL THEN
+ EXECUTE 'REVOKE '||array_to_string(v_revoke, ',')||' ON '||v_child_table||' FROM '||v_parent_grant.grantee||' CASCADE';
+ END IF;
+ END IF;
+
+ v_grantees := array_append(v_grantees, v_parent_grant.grantee::text);
+
+ END LOOP;
+
+ -- Revoke all privileges from roles that have none on the parent
+ IF v_grantees IS NOT NULL THEN
+ SELECT array_agg(r) INTO v_revoke FROM (
+ SELECT DISTINCT grantee::text AS r FROM information_schema.table_privileges WHERE table_schema ||'.'|| table_name = v_child_table
+ EXCEPT
+ SELECT unnest(v_grantees)) x;
+ IF v_revoke IS NOT NULL THEN
+ EXECUTE 'REVOKE ALL ON '||v_child_table||' FROM '||array_to_string(v_revoke, ',');
+ END IF;
+ END IF;
+
+ SELECT tableowner INTO v_child_owner FROM pg_tables WHERE schemaname ||'.'|| tablename = v_child_table;
+ IF v_parent_owner <> v_child_owner THEN
+ EXECUTE 'ALTER TABLE '||v_child_table||' OWNER TO '||v_parent_owner;
+ END IF;
+
+END LOOP;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Done');
+ PERFORM close_job(v_job_id);
+END IF;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+END IF;
+
+EXCEPTION
+ WHEN OTHERS THEN
+ IF v_jobmon_schema IS NOT NULL THEN
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+ IF v_job_id IS NULL THEN
+ v_job_id := add_job('PARTMAN CREATE TABLE: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Partition maintenance for table '||p_parent_table||' failed');
+ ELSIF v_step_id IS NULL THEN
+ v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
+ END IF;
+ PERFORM update_step(v_step_id, 'BAD', 'ERROR: '||coalesce(SQLERRM,'unknown'));
+ PERFORM fail_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+ END IF;
+ RAISE EXCEPTION '%', SQLERRM;
+END
+$$;
+
+
+/*
+ * Function to create id partitions
+ */
+CREATE OR REPLACE FUNCTION create_id_partition (p_parent_table text, p_control text, p_interval bigint, p_partition_ids bigint[]) RETURNS text
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_all text[] := ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'];
+v_grantees text[];
+v_job_id bigint;
+v_jobmon_schema text;
+v_old_search_path text;
+v_parent_grant record;
+v_parent_owner text;
+v_partition_name text;
+v_revoke text[];
+v_step_id bigint;
+v_tablename text;
+v_id bigint;
+
+BEGIN
+
+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;
+
+SELECT tableowner INTO v_parent_owner FROM pg_tables WHERE schemaname ||'.'|| tablename = p_parent_table;
+
+FOREACH v_id IN ARRAY p_partition_ids LOOP
+
+ v_partition_name := p_parent_table||'_p'||v_id;
+
+ SELECT schemaname ||'.'|| tablename INTO v_tablename FROM pg_catalog.pg_tables WHERE schemaname ||'.'|| tablename = v_partition_name;
+
+ IF v_tablename IS NOT NULL THEN
+ CONTINUE;
+ END IF;
+
+ IF v_jobmon_schema IS NOT NULL THEN
+ v_job_id := add_job('PARTMAN CREATE TABLE: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Creating new partition '||v_partition_name||' with interval from '||v_id||' to '||(v_id + p_interval)-1);
+ END IF;
+
+ IF position('.' in p_parent_table) > 0 THEN
+ v_tablename := substring(v_partition_name from position('.' in v_partition_name)+1);
+ END IF;
+
+ EXECUTE 'CREATE TABLE '||v_partition_name||' (LIKE '||p_parent_table||' INCLUDING DEFAULTS INCLUDING INDEXES)';
+ EXECUTE 'ALTER TABLE '||v_partition_name||' ADD CONSTRAINT '||v_tablename||'_partition_check
+ CHECK ('||p_control||'>='||quote_literal(v_id)||' AND '||p_control||'<'||quote_literal(v_id + p_interval)||')';
+ EXECUTE 'ALTER TABLE '||v_partition_name||' INHERIT '||p_parent_table;
+
+ FOR v_parent_grant IN
+ SELECT array_agg(DISTINCT privilege_type::text ORDER BY privilege_type::text) AS types, grantee
+ FROM information_schema.table_privileges
+ WHERE table_schema ||'.'|| table_name = p_parent_table
+ GROUP BY grantee
+ LOOP
+ EXECUTE 'GRANT '||array_to_string(v_parent_grant.types, ',')||' ON '||v_partition_name||' TO '||v_parent_grant.grantee;
+ SELECT array_agg(r) INTO v_revoke FROM (SELECT unnest(v_all) AS r EXCEPT SELECT unnest(v_parent_grant.types)) x;
+ IF v_revoke IS NOT NULL THEN
+ EXECUTE 'REVOKE '||array_to_string(v_revoke, ',')||' ON '||v_partition_name||' FROM '||v_parent_grant.grantee||' CASCADE';
+ END IF;
+ v_grantees := array_append(v_grantees, v_parent_grant.grantee::text);
+ END LOOP;
+ -- Revoke all privileges from roles that have none on the parent
+ IF v_grantees IS NOT NULL THEN
+ SELECT array_agg(r) INTO v_revoke FROM (
+ SELECT DISTINCT grantee::text AS r FROM information_schema.table_privileges WHERE table_schema ||'.'|| table_name = v_partition_name
+ EXCEPT
+ SELECT unnest(v_grantees)) x;
+ IF v_revoke IS NOT NULL THEN
+ EXECUTE 'REVOKE ALL ON '||v_partition_name||' FROM '||array_to_string(v_revoke, ',');
+ END IF;
+ END IF;
+
+ EXECUTE 'ALTER TABLE '||v_partition_name||' OWNER TO '||v_parent_owner;
+
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Done');
+ PERFORM close_job(v_job_id);
+ END IF;
+
+END LOOP;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+END IF;
+
+RETURN v_partition_name;
+
+EXCEPTION
+ WHEN OTHERS THEN
+ IF v_jobmon_schema IS NOT NULL THEN
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+ IF v_job_id IS NULL THEN
+ v_job_id := add_job('PARTMAN CREATE TABLE: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Partition maintenance for table '||p_parent_table||' failed');
+ ELSIF v_step_id IS NULL THEN
+ v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
+ END IF;
+ PERFORM update_step(v_step_id, 'BAD', 'ERROR: '||coalesce(SQLERRM,'unknown'));
+ PERFORM fail_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+ END IF;
+ RAISE EXCEPTION '%', SQLERRM;
+END
+$$;
+
+
+/*
+ * Function to create a child table in a time-based partition set
+ */
+CREATE OR REPLACE FUNCTION create_time_partition (p_parent_table text, p_control text, p_interval interval, p_datetime_string text, p_partition_times timestamp[]) RETURNS text
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_all text[] := ARRAY['SELECT', 'INSERT', 'UPDATE', 'DELETE', 'TRUNCATE', 'REFERENCES', 'TRIGGER'];
+v_grantees text[];
+v_job_id bigint;
+v_jobmon_schema text;
+v_old_search_path text;
+v_parent_grant record;
+v_parent_owner text;
+v_partition_name text;
+v_partition_timestamp_end timestamp;
+v_partition_timestamp_start timestamp;
+v_quarter text;
+v_revoke text[];
+v_step_id bigint;
+v_tablename text;
+v_time timestamp;
+v_year text;
+
+BEGIN
+
+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;
+
+SELECT tableowner INTO v_parent_owner FROM pg_tables WHERE schemaname ||'.'|| tablename = p_parent_table;
+
+FOREACH v_time IN ARRAY p_partition_times LOOP
+
+ v_partition_name := p_parent_table || '_p';
+
+ 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');
+
+ 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');
+
+ 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');
+
+ 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';
+ ELSIF p_interval = '15 mins' THEN
+ IF date_part('minute', v_time) < 15 THEN
+ v_partition_name := v_partition_name || '00';
+ ELSIF date_part('minute', v_time) >= 15 AND date_part('minute', v_time) < 30 THEN
+ v_partition_name := v_partition_name || '15';
+ ELSIF date_part('minute', v_time) >= 30 AND date_part('minute', v_time) < 45 THEN
+ v_partition_name := v_partition_name || '30';
+ ELSE
+ v_partition_name := v_partition_name || '45';
+ END IF;
+ 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;
+ 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');
+ 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;
+
+ -- "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;
+ CASE
+ WHEN v_quarter = '1' THEN
+ v_partition_timestamp_start := 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');
+ WHEN v_quarter = '3' THEN
+ v_partition_timestamp_start := 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');
+ END CASE;
+ v_partition_timestamp_end := 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;
+ IF v_tablename IS NOT NULL THEN
+ CONTINUE;
+ END IF;
+
+ IF v_jobmon_schema IS NOT NULL THEN
+ v_job_id := add_job('PARTMAN CREATE TABLE: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Creating new partition '||v_partition_name||' with interval from '||v_partition_timestamp_start||' to '||(v_partition_timestamp_end-'1sec'::interval));
+ END IF;
+
+ IF position('.' in p_parent_table) > 0 THEN
+ v_tablename := substring(v_partition_name from position('.' in v_partition_name)+1);
+ END IF;
+
+ EXECUTE 'CREATE TABLE '||v_partition_name||' (LIKE '||p_parent_table||' INCLUDING DEFAULTS INCLUDING INDEXES)';
+ EXECUTE 'ALTER TABLE '||v_partition_name||' ADD CONSTRAINT '||v_tablename||'_partition_check
+ CHECK ('||p_control||'>='||quote_literal(v_partition_timestamp_start)||' AND '||p_control||'<'||quote_literal(v_partition_timestamp_end)||')';
+ EXECUTE 'ALTER TABLE '||v_partition_name||' INHERIT '||p_parent_table;
+
+ FOR v_parent_grant IN
+ SELECT array_agg(DISTINCT privilege_type::text ORDER BY privilege_type::text) AS types, grantee
+ FROM information_schema.table_privileges
+ WHERE table_schema ||'.'|| table_name = p_parent_table
+ GROUP BY grantee
+ LOOP
+ EXECUTE 'GRANT '||array_to_string(v_parent_grant.types, ',')||' ON '||v_partition_name||' TO '||v_parent_grant.grantee;
+ SELECT array_agg(r) INTO v_revoke FROM (SELECT unnest(v_all) AS r EXCEPT SELECT unnest(v_parent_grant.types)) x;
+ IF v_revoke IS NOT NULL THEN
+ EXECUTE 'REVOKE '||array_to_string(v_revoke, ',')||' ON '||v_partition_name||' FROM '||v_parent_grant.grantee||' CASCADE';
+ END IF;
+ v_grantees := array_append(v_grantees, v_parent_grant.grantee::text);
+ END LOOP;
+ -- Revoke all privileges from roles that have none on the parent
+ IF v_grantees IS NOT NULL THEN
+ SELECT array_agg(r) INTO v_revoke FROM (
+ SELECT DISTINCT grantee::text AS r FROM information_schema.table_privileges WHERE table_schema ||'.'|| table_name = v_partition_name
+ EXCEPT
+ SELECT unnest(v_grantees)) x;
+ IF v_revoke IS NOT NULL THEN
+ EXECUTE 'REVOKE ALL ON '||v_partition_name||' FROM '||array_to_string(v_revoke, ',');
+ END IF;
+ END IF;
+
+ EXECUTE 'ALTER TABLE '||v_partition_name||' OWNER TO '||v_parent_owner;
+
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Done');
+ PERFORM close_job(v_job_id);
+ END IF;
+
+END LOOP;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+END IF;
+
+RETURN v_partition_name;
+
+EXCEPTION
+ WHEN OTHERS THEN
+ IF v_jobmon_schema IS NOT NULL THEN
+ EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||v_jobmon_schema||''',''false'')';
+ IF v_job_id IS NULL THEN
+ v_job_id := add_job('PARTMAN CREATE TABLE: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Partition maintenance for table '||p_parent_table||' failed');
+ ELSIF v_step_id IS NULL THEN
+ v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
+ END IF;
+ PERFORM update_step(v_step_id, 'BAD', 'ERROR: '||coalesce(SQLERRM,'unknown'));
+ PERFORM fail_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+ END IF;
+ RAISE EXCEPTION '%', SQLERRM;
+END
+$$;

0 comments on commit 0676932

Please sign in to comment.