Skip to content

Commit

Permalink
v0.4.1 Changed inner workings of privilege management system so it wo…
Browse files Browse the repository at this point in the history
…rks better with large partition sets. See CHANGELOG & pg_partman.md file for more info
  • Loading branch information
keithf4 committed Feb 18, 2013
1 parent 8c68300 commit 0676932
Show file tree
Hide file tree
Showing 16 changed files with 1,261 additions and 99 deletions.
7 changes: 7 additions & 0 deletions 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.
Expand Down
6 changes: 3 additions & 3 deletions 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>"
],
Expand All @@ -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"
}
},
Expand Down
4 changes: 2 additions & 2 deletions README.md
Expand Up @@ -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());
Expand All @@ -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.

Expand Down
11 changes: 5 additions & 6 deletions doc/pg_partman.md
Expand Up @@ -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!

Expand All @@ -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.
Expand Down Expand Up @@ -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*
Expand Down
2 changes: 1 addition & 1 deletion 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
66 changes: 0 additions & 66 deletions sql/functions/apply_grants.sql

This file was deleted.

43 changes: 33 additions & 10 deletions sql/functions/create_id_partition.sql
Expand Up @@ -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;
Expand All @@ -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;
Expand All @@ -46,23 +53,39 @@ 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);
END IF;

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;
Expand Down
43 changes: 33 additions & 10 deletions sql/functions/create_time_partition.sql
Expand Up @@ -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;
Expand All @@ -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';
Expand Down Expand Up @@ -108,23 +115,39 @@ 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);
END IF;

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;
Expand Down

0 comments on commit 0676932

Please sign in to comment.