Skip to content
Browse files

v0.3.1 Fixed dynamic partition types to be able to handle inserts for…

… partitions that don't exist
  • Loading branch information...
1 parent 54b3c49 commit c93ac72c36695f8b27d0274c7fb83e19d5bf4e97 @keithf4 committed Jan 16, 2013
View
4 CHANGELOG
@@ -1,3 +1,7 @@
+0.3.1
+-- Added check to dynamic id & time trigger functions to see if target table exists. If it doesn't, insert to parent instead of throwing error. Better than losing data! check_parent() function can monitor for this happening and create_prev_* functions can easily fix it. Thought of having it auto-create the needed partition, but if something is going wrong, that could end up creating a lot of unwanted partitions and be harder to clean up.
+
+
0.3.0
-- Added grants configuration table to propagate permissions to newly created child partitions. Will also apply those permissions to the parent table and all existing child tables whenever a new partition is created. Permissions are only granted, never revoked. See docs for more info.
View
6 META.json
@@ -1,7 +1,7 @@
{
"name": "pg_partman",
"abstract": "Extension to manage partitioned tables by time or ID",
- "version": "0.3.0",
+ "version": "0.3.1",
"maintainer": [
"Keith Fiske <keith@omniti.com>"
],
@@ -20,9 +20,9 @@
},
"provides": {
"pg_partmaint": {
- "file": "sql/pg_partman--0.3.0.sql",
+ "file": "sql/pg_partman--0.3.1.sql",
"docfile": "doc/pg_partman.md",
- "version": "0.3.0",
+ "version": "0.3.1",
"abstract": "Extension to manage partitioned tables by time or ID"
}
},
View
21 doc/pg_partman.md
@@ -12,6 +12,8 @@ I'm trying to find a way to also inherit the permissions from the parent table i
INSERT INTO partman.part_config (parent_table, grants, roles)
VALUES ('my_parent_table', 'INSERT,UPDATE,DELETE', 'role1,role2,role3');
+If you attempt to insert data into a partition set that contains data for a partition that does not exist, that data will be placed into the set's parent table. This is preferred over automatically creating new partitions to match that data since a mistake that is causing non-partitioned data to be inserted could cause a lot of unwanted child tables to be made. The check_parent() function provides monitoring for any data getting inserted into parents and the create_prev_* set of functions can easily partition that data for you if it is valid data. That is much easier than having to clean up potentially hundreds or thousands of unwanted partitions. And also better than throwing an error and losing the data!
+
If you don't need to keep data in older partitions, a retention system is available to automatically drop unneeded child partitions. By default, they are only uninherited not actually dropped, but that can be configured if desired. If the old partitions are kept, dropping their indexes can also be configured to recover disk space. Note that this will also remove any primary key or unique constraints in order to allow the indexes to be dropped. To set the retention policy, enter either an interval or integer value into the **retention** column of the **part_config** table. For time-based partitioning, the interval value will set that any partitions containing data older than that will be dropped. For id-based partitioning, the integer value will set that any partitions with an id value less than the current maximum id value minus the retention value will be dropped. For example, if the current max id is 100 and the retention value is 30, any partitions with id values less than 70 will be dropped. The current maximum id value at the time the drop function is run is always used.
The PG Jobmon extension (https://github.com/omniti-labs/pg_jobmon) is optional and allows auditing and monitoring of partition maintenance. If jobmon is installed and configured properly, it will automatically be used by partman with no additional setup needed. By default, any function that fails to run successfully 3 consecutive times will cause jobmon to raise an alert. This is why the default pre-make value is set to 4 so that an alert will be raised in time for intervention with no additional configuration of jobmon needed. You can of course configure jobmon to alert before (or later) than 3 failures if needed. If you're running partman in a production environment it is HIGHLY recommended to have jobmon installed and some sort of 3rd-party monitoring configured with it to alert when partitioning fails (Nagios, Circonus, etc).
@@ -23,7 +25,7 @@ All functions are run with SECURITY DEFINER, so just ensure that the function ow
*create_parent(p_parent_table text, p_control text, p_type part.partition_type, p_interval text, p_premake int DEFAULT 3, 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 indexes & constraints to parent table so they will propagate to children (permissions not yet propagating; working on it!).
* 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
+ * 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.
* p_type - one of 4 values to set the partitioning type that will be used
@@ -56,39 +58,42 @@ All functions are run with SECURITY DEFINER, so just ensure that the function ow
* Will automatically update the function for **time-static** partitioning to keep the parent table pointing at the correct partitions. When using time-static, run this function more often than the partitioning interval to keep the function running its most efficient. For example, if using quarter-hour, run every 5 minutes; if using daily, run at least twice a day, etc.
*create_prev_time_partition(p_parent_table text, p_batch int DEFAULT 1) RETURNS bigint*
- * This function is used to partition data that may have existed prior to setting up the parent table as a time-based partition set.
+ * This function is used to partition data that may have existed prior to setting up the parent table as a time-based partition set, or to fix data that accidentally gets inserted into the parent.
+ * If the needed partition does not exist, it will automatically be created. If the needed partition already exists, the data will be moved there.
* If you are partitioning a large amount of previous data, it's recommended to run this function with an external script with small batch amounts. This will help avoid transactional locks and prevent a failure from causing an extensive rollback.
- * p_parent_table - the existing parent table. This is assumed to be where the unpartitioned data is located.
+ * p_parent_table - the existing parent table. This is assumed to be where the unpartitioned data is located. MUST be schema qualified, even if in public schema.
* p_batch - how many partitions will be made in a single run of the function. Default value is 1.
* Returns the number of rows that were moved from the parent table to partitions. Returns zero when parent table is empty and partitioning is complete.
*create_prev_id_partition(p_parent_table text, p_batch int DEFAULT 1) RETURNS bigint*
- * This function is used to partition data that may have existed prior to setting up the parent table as a serial id partition set.
+ * This function is used to partition data that may have existed prior to setting up the parent table as a serial id partition set, or to fix data that accidentally gets inserted into the parent.
+ * If the needed partition does not exist, it will automatically be created. If the needed partition already exists, the data will be moved there.
* If you are partitioning a large amount of previous data, it's recommended to run this function with an external script with small batch amounts. This will help avoid transactional locks and prevent a failure from causing an extensive rollback.
- * p_parent_table - the existing parent table. This is assumed to be where the unpartitioned data is located.
+ * p_parent_table - the existing parent table. This is assumed to be where the unpartitioned data is located. MUST be schema qualified, even if in public schema.
* p_batch - how many partitions will be made in a single run of the function. Default value is 1.
* Returns the number of rows that were moved from the parent table to partitions. Returns zero when parent table is empty and partitioning is complete.
-*check_parent() RETURNS SETOF (parent table, count)*
+*check_parent() RETURNS SETOF (parent_table, count)*
* Run this function to monitor that the parent tables of the partition sets that pg_partman manages do not get rows inserted to them.
* Returns a row for each parent table along with the number of rows it contains. Returns zero rows if none found.
*drop_time_partition(p_parent_table text, p_keep_table boolean DEFAULT NULL, p_keep_index boolean DEFAULT NULL)*
* This function is used to drop child tables from a time-based partition set. The table is by default just uninherited and not actually dropped. It is recommended to use the **run_maintenance()** function to manage dropping old child tables and not call it directly unless needed.
- * p_parent_table - the existing parent table of a time-based partition set.
+ * p_parent_table - the existing parent table of a time-based partition set. MUST be schema qualified, even if in public schema.
* p_keep_table - optional parameter to tell partman whether to keep or drop the table in addition to uninheriting it. TRUE means the table will not actually be dropped; FALSE means the table will be dropped. This function will just use the value configured in **part_config** if not explicitly set.
* p_keep_index - optional parameter to tell partman whether to keep or drop the indexes of the child table when it is uninherited. TRUE means the indexes will be kept; FALSE means all indexes will be dropped. This function will just use the value configured in **part_config** if not explicitly set. This option is ignored if p_keep_table is set to FALSE.
*drop_id_partition(p_parent_table text, p_keep_table boolean DEFAULT NULL, p_keep_index boolean DEFAULT NULL)*
* This function is used to drop child tables from an id-based partition set. The table is by default just uninherited and not actually dropped. It is recommended to use the **run_maintenance()** function to manage dropping old child tables and not call it directly unless needed.
- * p_parent_table - the existing parent table of a time-based partition set.
+ * p_parent_table - the existing parent table of a time-based partition set. MUST be schema qualified, even if in public schema.
* p_keep_table - optional parameter to tell partman whether to keep or drop the table in addition to uninheriting it. TRUE means the table will not actually be dropped; FALSE means the table will be dropped. This function will just use the value configured in **part_config** if not explicitly set.
* p_keep_index - optional parameter to tell partman whether to keep or drop the indexes of the child table when it is uninherited. TRUE means the indexes will be kept; FALSE means all indexes will be dropped. This function will just use the value configured in **part_config** if not explicitly set. This option is ignored if p_keep_table is set to FALSE.
*apply_grants(p_parent_table text)*
* This function is used to apply grants that are set in the part_grants table. It is called automatically any time a new partition is made and shouldn't be called directly unless needed.
* It will apply configured grants to the parent table and all child tables every run.
* Grants are only applied, never revoked.
+ * p_parent_table - parent table to apply the grants to. MUST be schema qualified, even if in public schema.
Tables
View
2 pg_partman.control
@@ -1,3 +1,3 @@
-default_version = '0.3.0'
+default_version = '0.3.1'
comment = 'Extension to manage partitioned tables by time or ID'
relocatable = false
View
19 sql/functions/create_id_function.sql
@@ -1,3 +1,6 @@
+/*
+ * Create the trigger function for the parent table of an id-based partition set
+ */
CREATE FUNCTION create_id_function(p_parent_table text, p_current_id bigint) RETURNS void
LANGUAGE plpgsql SECURITY DEFINER
AS $$
@@ -113,20 +116,25 @@ ELSIF v_type = 'id-dynamic' THEN
v_trig_func := 'CREATE OR REPLACE FUNCTION '||p_parent_table||'_part_trig_func() RETURNS trigger LANGUAGE plpgsql AS $t$
DECLARE
+ v_count int;
v_current_partition_id bigint;
v_current_partition_name text;
v_last_partition text := '||quote_literal(v_last_partition)||';
v_last_partition_id bigint;
v_next_partition_id bigint;
v_next_partition_name text;
+ v_schemaname text;
+ v_tablename text;
BEGIN
IF TG_OP = ''INSERT'' THEN
v_current_partition_id := NEW.'||v_control||' - (NEW.'||v_control||' % '||v_part_interval||');
v_current_partition_name := '''||p_parent_table||'_p''||v_current_partition_id;
-
IF (NEW.'||v_control||' % '||v_part_interval||') > ('||v_part_interval||' / 2) THEN
v_last_partition_id = substring(v_last_partition from char_length('||quote_literal(p_parent_table||'_p')||')+1)::bigint;
v_next_partition_id := v_last_partition_id + '||v_part_interval||';
+ IF NEW.'||v_control||' >= v_next_partition_id THEN
+ RETURN NEW;
+ END IF;
IF ((v_next_partition_id - v_current_partition_id) / '||quote_literal(v_part_interval)||') <= '||quote_literal(v_premake)||' THEN
v_next_partition_name := @extschema@.create_id_partition('||quote_literal(p_parent_table)||', '||quote_literal(v_control)||','
||quote_literal(v_part_interval)||', ARRAY[v_next_partition_id]);
@@ -136,7 +144,14 @@ ELSIF v_type = 'id-dynamic' THEN
END IF;
END IF;
END IF;
- EXECUTE ''INSERT INTO ''||v_current_partition_name||'' VALUES($1.*)'' USING NEW;
+ v_schemaname := split_part(v_current_partition_name, ''.'', 1);
+ v_tablename := split_part(v_current_partition_name, ''.'', 2);
+ SELECT count(*) INTO v_count FROM pg_tables WHERE schemaname = v_schemaname AND tablename = v_tablename;
+ IF v_count > 0 THEN
+ EXECUTE ''INSERT INTO ''||v_current_partition_name||'' VALUES($1.*)'' USING NEW;
+ ELSE
+ RETURN NEW;
+ END IF;
END IF;
RETURN NULL;
View
13 sql/functions/create_time_function.sql
@@ -113,8 +113,11 @@ ELSIF v_type = 'time-dynamic' THEN
v_trig_func := 'CREATE OR REPLACE FUNCTION '||p_parent_table||'_part_trig_func() RETURNS trigger LANGUAGE plpgsql AS $t$
DECLARE
+ v_count int;
v_partition_name text;
v_partition_timestamp timestamp;
+ v_schemaname text;
+ v_tablename text;
BEGIN
IF TG_OP = ''INSERT'' THEN
';
@@ -141,8 +144,14 @@ ELSIF v_type = 'time-dynamic' THEN
v_trig_func := v_trig_func||'
v_partition_name := '''||p_parent_table||'_p''|| to_char(v_partition_timestamp, '||quote_literal(v_datetime_string)||');
-
- EXECUTE ''INSERT INTO ''||v_partition_name||'' VALUES($1.*)'' USING NEW;
+ v_schemaname := split_part(v_partition_name, ''.'', 1);
+ v_tablename := split_part(v_partition_name, ''.'', 2);
+ SELECT count(*) INTO v_count FROM pg_tables WHERE schemaname = v_schemaname AND tablename = v_tablename;
+ IF v_count > 0 THEN
+ EXECUTE ''INSERT INTO ''||v_partition_name||'' VALUES($1.*)'' USING NEW;
+ ELSE
+ RETURN NEW;
+ END IF;
END IF;
RETURN NULL;
View
389 updates/pg_partman--0.3.0--0.3.1.sql
@@ -0,0 +1,389 @@
+-- Added check to dynamic id & time trigger functions to see if target table exists. If it doesn't, insert to parent instead of throwing error. Better than losing data! check_parent() function can monitor for this happening and create_prev_* functions can easily fix it. Thought of having it auto-create the needed partition, but if something is going wrong, that could end up creating a lot of unwanted partitions and be harder to clean up.
+
+/*
+ * Create the trigger function for the parent table of a time-based partition set
+ */
+CREATE OR REPLACE FUNCTION create_time_function(p_parent_table text) RETURNS void
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_1st_partition_name text;
+v_1st_partition_timestamp timestamp;
+v_2nd_partition_name text;
+v_2nd_partition_timestamp timestamp;
+v_control text;
+v_current_partition_name text;
+v_current_partition_timestamp timestamp;
+v_datetime_string text;
+v_final_partition_timestamp timestamp;
+v_job_id bigint;
+v_jobmon_schema text;
+v_old_search_path text;
+v_part_interval interval;
+v_prev_partition_name text;
+v_prev_partition_timestamp timestamp;
+v_step_id bigint;
+v_trig_func text;
+v_type 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;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ v_job_id := add_job('PARTMAN CREATE FUNCTION: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Creating partition function for table '||p_parent_table);
+END IF;
+
+SELECT type
+ , part_interval::interval
+ , control
+ , datetime_string
+FROM @extschema@.part_config
+WHERE parent_table = p_parent_table
+AND (type = 'time-static' OR type = 'time-dynamic')
+INTO v_type, v_part_interval, v_control, v_datetime_string;
+IF NOT FOUND THEN
+ RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table;
+END IF;
+
+IF v_type = 'time-static' THEN
+
+ CASE
+ WHEN v_part_interval = '15 mins' THEN
+ v_current_partition_timestamp := date_trunc('hour', CURRENT_TIMESTAMP) +
+ '15min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 15.0);
+ WHEN v_part_interval = '30 mins' THEN
+ v_current_partition_timestamp := date_trunc('hour', CURRENT_TIMESTAMP) +
+ '30min'::interval * floor(date_part('minute', CURRENT_TIMESTAMP) / 30.0);
+ WHEN v_part_interval = '1 hour' THEN
+ v_current_partition_timestamp := date_trunc('hour', CURRENT_TIMESTAMP);
+ WHEN v_part_interval = '1 day' THEN
+ v_current_partition_timestamp := date_trunc('day', CURRENT_TIMESTAMP);
+ WHEN v_part_interval = '1 week' THEN
+ v_current_partition_timestamp := date_trunc('week', CURRENT_TIMESTAMP);
+ WHEN v_part_interval = '1 month' THEN
+ v_current_partition_timestamp := date_trunc('month', CURRENT_TIMESTAMP);
+ WHEN v_part_interval = '3 months' THEN
+ v_current_partition_timestamp := date_trunc('quarter', CURRENT_TIMESTAMP);
+ WHEN v_part_interval = '1 year' THEN
+ v_current_partition_timestamp := date_trunc('year', CURRENT_TIMESTAMP);
+ END CASE;
+
+ v_prev_partition_timestamp := v_current_partition_timestamp - v_part_interval::interval;
+ v_1st_partition_timestamp := v_current_partition_timestamp + v_part_interval::interval;
+ v_2nd_partition_timestamp := v_1st_partition_timestamp + v_part_interval::interval;
+ v_final_partition_timestamp := v_2nd_partition_timestamp + v_part_interval::interval;
+
+ v_prev_partition_name := p_parent_table || '_p' || to_char(v_prev_partition_timestamp, v_datetime_string);
+ v_current_partition_name := p_parent_table || '_p' || to_char(v_current_partition_timestamp, v_datetime_string);
+ v_1st_partition_name := p_parent_table || '_p' || to_char(v_1st_partition_timestamp, v_datetime_string);
+ v_2nd_partition_name := p_parent_table || '_p' || to_char(v_2nd_partition_timestamp, v_datetime_string);
+
+ v_trig_func := 'CREATE OR REPLACE FUNCTION '||p_parent_table||'_part_trig_func() RETURNS trigger LANGUAGE plpgsql AS $t$
+ BEGIN
+ IF TG_OP = ''INSERT'' THEN
+ IF NEW.'||v_control||' >= '||quote_literal(v_current_partition_timestamp)||' AND NEW.'||v_control||' < '||quote_literal(v_1st_partition_timestamp)|| ' THEN
+ INSERT INTO '||v_current_partition_name||' VALUES (NEW.*);
+ ELSIF NEW.'||v_control||' >= '||quote_literal(v_1st_partition_timestamp)||' AND NEW.'||v_control||' < '||quote_literal(v_2nd_partition_timestamp)|| ' THEN
+ INSERT INTO '||v_1st_partition_name||' VALUES (NEW.*);
+ ELSIF NEW.'||v_control||' >= '||quote_literal(v_2nd_partition_timestamp)||' AND NEW.'||v_control||' < '||quote_literal(v_final_partition_timestamp)|| ' THEN
+ INSERT INTO '||v_2nd_partition_name||' VALUES (NEW.*);
+ ELSIF NEW.'||v_control||' >= '||quote_literal(v_prev_partition_timestamp)||' AND NEW.'||v_control||' < '||quote_literal(v_current_partition_timestamp)|| ' THEN
+ INSERT INTO '||v_prev_partition_name||' VALUES (NEW.*);
+ ELSE
+ RETURN NEW;
+ END IF;
+ END IF;
+ RETURN NULL;
+ END $t$;';
+
+-- RAISE NOTICE 'v_trig_func: %',v_trig_func;
+ EXECUTE v_trig_func;
+
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Added function for current time interval: '||v_current_partition_timestamp||' to '||(v_1st_partition_timestamp-'1sec'::interval));
+ END IF;
+
+ELSIF v_type = 'time-dynamic' THEN
+
+ v_trig_func := 'CREATE OR REPLACE FUNCTION '||p_parent_table||'_part_trig_func() RETURNS trigger LANGUAGE plpgsql AS $t$
+ DECLARE
+ v_count int;
+ v_partition_name text;
+ v_partition_timestamp timestamp;
+ v_schemaname text;
+ v_tablename text;
+ BEGIN
+ IF TG_OP = ''INSERT'' THEN
+ ';
+ CASE
+ WHEN v_part_interval = '15 mins' THEN
+ v_trig_func := v_trig_func||'v_partition_timestamp := date_trunc(''hour'', NEW.'||v_control||') +
+ ''15min''::interval * floor(date_part(''minute'', NEW.'||v_control||') / 15.0);';
+ WHEN v_part_interval = '30 mins' THEN
+ v_trig_func := v_trig_func||'v_partition_timestamp := date_trunc(''hour'', NEW.'||v_control||') +
+ ''30min''::interval * floor(date_part(''minute'', NEW.'||v_control||') / 30.0);';
+ WHEN v_part_interval = '1 hour' THEN
+ v_trig_func := v_trig_func||'v_partition_timestamp := date_trunc(''hour'', NEW.'||v_control||');';
+ WHEN v_part_interval = '1 day' THEN
+ v_trig_func := v_trig_func||'v_partition_timestamp := date_trunc(''day'', NEW.'||v_control||');';
+ WHEN v_part_interval = '1 week' THEN
+ v_trig_func := v_trig_func||'v_partition_timestamp := date_trunc(''week'', NEW.'||v_control||');';
+ WHEN v_part_interval = '1 month' THEN
+ v_trig_func := v_trig_func||'v_partition_timestamp := date_trunc(''month'', NEW.'||v_control||');';
+ WHEN v_part_interval = '3 months' THEN
+ v_trig_func := v_trig_func||'v_partition_timestamp := date_trunc(''quarter'', NEW.'||v_control||');';
+ WHEN v_part_interval = '1 year' THEN
+ v_trig_func := v_trig_func||'v_partition_timestamp := date_trunc(''year'', NEW.'||v_control||');';
+ END CASE;
+
+ v_trig_func := v_trig_func||'
+ v_partition_name := '''||p_parent_table||'_p''|| to_char(v_partition_timestamp, '||quote_literal(v_datetime_string)||');
+ v_schemaname := split_part(v_partition_name, ''.'', 1);
+ v_tablename := split_part(v_partition_name, ''.'', 2);
+ SELECT count(*) INTO v_count FROM pg_tables WHERE schemaname = v_schemaname AND tablename = v_tablename;
+ IF v_count > 0 THEN
+ EXECUTE ''INSERT INTO ''||v_partition_name||'' VALUES($1.*)'' USING NEW;
+ ELSE
+ RETURN NEW;
+ END IF;
+ END IF;
+
+ RETURN NULL;
+ END $t$;';
+
+ --RAISE NOTICE 'v_trig_func: %',v_trig_func;
+ EXECUTE v_trig_func;
+
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Added function for dynamic time table: '||p_parent_table);
+ END IF;
+
+ELSE
+ RAISE EXCEPTION 'ERROR: Invalid time partitioning type given: %', v_type;
+END IF;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM close_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+END IF;
+
+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 FUNCTION: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Partition function maintenance for table '||p_parent_table||' failed');
+ ELSIF v_step_id IS NULL THEN
+ v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
+ END IF;
+ PERFORM update_step(v_step_id, '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
+$$;
+
+
+
+/*
+ * Create the trigger function for the parent table of an id-based partition set
+ */
+CREATE OR REPLACE FUNCTION create_id_function(p_parent_table text, p_current_id bigint) RETURNS void
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_1st_partition_name text;
+v_1st_partition_id bigint;
+v_2nd_partition_name text;
+v_2nd_partition_id bigint;
+v_control text;
+v_current_partition_name text;
+v_current_partition_id bigint;
+v_datetime_string text;
+v_final_partition_id bigint;
+v_job_id bigint;
+v_jobmon_schema text;
+v_last_partition text;
+v_old_search_path text;
+v_part_interval bigint;
+v_premake int;
+v_prev_partition_name text;
+v_prev_partition_id bigint;
+v_step_id bigint;
+v_trig_func text;
+v_type 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;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ v_job_id := add_job('PARTMAN CREATE FUNCTION: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Creating partition function for table '||p_parent_table);
+END IF;
+
+SELECT type
+ , part_interval::bigint
+ , control
+ , premake
+ , last_partition
+FROM @extschema@.part_config
+WHERE parent_table = p_parent_table
+AND (type = 'id-static' OR type = 'id-dynamic')
+INTO v_type, v_part_interval, v_control, v_premake, v_last_partition;
+IF NOT FOUND THEN
+ RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table;
+END IF;
+
+IF v_type = 'id-static' THEN
+ v_current_partition_id := p_current_id - (p_current_id % v_part_interval);
+ v_prev_partition_id := v_current_partition_id - v_part_interval;
+ v_1st_partition_id := v_current_partition_id + v_part_interval;
+ v_2nd_partition_id := v_1st_partition_id + v_part_interval;
+ v_final_partition_id := v_2nd_partition_id + v_part_interval;
+
+ v_prev_partition_name := p_parent_table || '_p' || v_prev_partition_id::text;
+ v_current_partition_name := p_parent_table || '_p' || v_current_partition_id::text;
+ v_1st_partition_name := p_parent_table || '_p' || v_1st_partition_id::text;
+ v_2nd_partition_name := p_parent_table || '_p' || v_2nd_partition_id::text;
+
+ v_trig_func := 'CREATE OR REPLACE FUNCTION '||p_parent_table||'_part_trig_func() RETURNS trigger LANGUAGE plpgsql AS $t$
+ DECLARE
+ v_current_partition_id bigint;
+ v_last_partition text := '||quote_literal(v_last_partition)||';
+ v_next_partition_id bigint;
+ v_next_partition_name text;
+ BEGIN
+ IF TG_OP = ''INSERT'' THEN
+ IF NEW.'||v_control||' >= '||v_current_partition_id||' AND NEW.'||v_control||' < '||v_1st_partition_id|| ' THEN
+ INSERT INTO '||v_current_partition_name||' VALUES (NEW.*);
+ ELSIF NEW.'||v_control||' >= '||v_1st_partition_id||' AND NEW.'||v_control||' < '||v_2nd_partition_id|| ' THEN
+ INSERT INTO '||v_1st_partition_name||' VALUES (NEW.*);
+ ELSIF NEW.'||v_control||' >= '||v_2nd_partition_id||' AND NEW.'||v_control||' < '||quote_literal(v_final_partition_id)|| ' THEN
+ INSERT INTO '||v_2nd_partition_name||' VALUES (NEW.*);
+ ';
+ -- If the first partition's function, don't have rule for previous partition
+ IF v_prev_partition_id >= 0 THEN
+ v_trig_func := v_trig_func ||'ELSIF NEW.'||v_control||' >= '||v_prev_partition_id||' AND NEW.'||v_control||' < '||v_current_partition_id|| ' THEN
+ INSERT INTO '||v_prev_partition_name||' VALUES (NEW.*);
+ ';
+ END IF;
+
+ v_trig_func := v_trig_func ||'ELSE
+ RETURN NEW;
+ END IF;
+ v_current_partition_id := NEW.'||v_control||' - (NEW.'||v_control||' % '||v_part_interval||');
+ IF (NEW.'||v_control||' % '||v_part_interval||') > ('||v_part_interval||' / 2) THEN
+ v_next_partition_id := (substring(v_last_partition from char_length('||quote_literal(p_parent_table||'_p')||')+1)::bigint) + '||v_part_interval||';
+ IF ((v_next_partition_id - v_current_partition_id) / '||v_part_interval||') <= '||v_premake||' THEN
+ v_next_partition_name := @extschema@.create_id_partition('||quote_literal(p_parent_table)||', '||quote_literal(v_control)||','
+ ||v_part_interval||', ARRAY[v_next_partition_id]);
+ UPDATE @extschema@.part_config SET last_partition = v_next_partition_name WHERE parent_table = '||quote_literal(p_parent_table)||';
+ PERFORM @extschema@.create_id_function('||quote_literal(p_parent_table)||', NEW.'||v_control||');
+ END IF;
+ END IF;
+ END IF;
+ RETURN NULL;
+ END $t$;';
+
+ --RAISE NOTICE 'v_trig_func: %',v_trig_func;
+ EXECUTE v_trig_func;
+
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Added function for current id interval: '||v_current_partition_id||' to '||v_1st_partition_id-1);
+ END IF;
+
+ELSIF v_type = 'id-dynamic' THEN
+
+ v_trig_func := 'CREATE OR REPLACE FUNCTION '||p_parent_table||'_part_trig_func() RETURNS trigger LANGUAGE plpgsql AS $t$
+ DECLARE
+ v_count int;
+ v_current_partition_id bigint;
+ v_current_partition_name text;
+ v_last_partition text := '||quote_literal(v_last_partition)||';
+ v_last_partition_id bigint;
+ v_next_partition_id bigint;
+ v_next_partition_name text;
+ v_schemaname text;
+ v_tablename text;
+ BEGIN
+ IF TG_OP = ''INSERT'' THEN
+ v_current_partition_id := NEW.'||v_control||' - (NEW.'||v_control||' % '||v_part_interval||');
+ v_current_partition_name := '''||p_parent_table||'_p''||v_current_partition_id;
+ IF (NEW.'||v_control||' % '||v_part_interval||') > ('||v_part_interval||' / 2) THEN
+ v_last_partition_id = substring(v_last_partition from char_length('||quote_literal(p_parent_table||'_p')||')+1)::bigint;
+ v_next_partition_id := v_last_partition_id + '||v_part_interval||';
+ IF NEW.'||v_control||' >= v_next_partition_id THEN
+ RETURN NEW;
+ END IF;
+ IF ((v_next_partition_id - v_current_partition_id) / '||quote_literal(v_part_interval)||') <= '||quote_literal(v_premake)||' THEN
+ v_next_partition_name := @extschema@.create_id_partition('||quote_literal(p_parent_table)||', '||quote_literal(v_control)||','
+ ||quote_literal(v_part_interval)||', ARRAY[v_next_partition_id]);
+ IF v_next_partition_name IS NOT NULL THEN
+ UPDATE @extschema@.part_config SET last_partition = v_next_partition_name WHERE parent_table = '||quote_literal(p_parent_table)||';
+ PERFORM @extschema@.create_id_function('||quote_literal(p_parent_table)||', NEW.'||v_control||');
+ END IF;
+ END IF;
+ END IF;
+ v_schemaname := split_part(v_current_partition_name, ''.'', 1);
+ v_tablename := split_part(v_current_partition_name, ''.'', 2);
+ SELECT count(*) INTO v_count FROM pg_tables WHERE schemaname = v_schemaname AND tablename = v_tablename;
+ IF v_count > 0 THEN
+ EXECUTE ''INSERT INTO ''||v_current_partition_name||'' VALUES($1.*)'' USING NEW;
+ ELSE
+ RETURN NEW;
+ END IF;
+ END IF;
+
+ RETURN NULL;
+ END $t$;';
+
+-- RAISE NOTICE 'v_trig_func: %',v_trig_func;
+ EXECUTE v_trig_func;
+
+ IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM update_step(v_step_id, 'OK', 'Added function for dynamic id table: '||p_parent_table);
+ END IF;
+
+ELSE
+ RAISE EXCEPTION 'ERROR: Invalid id partitioning type given: %', v_type;
+END IF;
+
+IF v_jobmon_schema IS NOT NULL THEN
+ PERFORM close_job(v_job_id);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
+END IF;
+
+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 FUNCTION: '||p_parent_table);
+ v_step_id := add_step(v_job_id, 'Partition function maintenance for table '||p_parent_table||' failed');
+ ELSIF v_step_id IS NULL THEN
+ v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
+ END IF;
+ PERFORM update_step(v_step_id, '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 c93ac72

Please sign in to comment.
Something went wrong with that request. Please try again.