Permalink
Browse files

Added quarterly time partitioning. Fixed bug in run_maintenance. See …

…CHANGELOG for more details.
  • Loading branch information...
1 parent aa577b1 commit 18dbce354adbba375938ef6defa2c293f31df5b7 @keithf4 committed Jan 4, 2013
View
@@ -0,0 +1,11 @@
+0.1.2
+-- Added support for quarterly time partitioning (trickier than it first appeared)
+-- Fixed bug in run_maintenance() that would give an invalid cast to integer error.
+-- Fixed some calls to pg_jobmon that were outside the checks to see if it's actually installed
+-- Properly reset search path back to original before partman functions were run if pg_jobmon is being used
+-- Changed the default premake to 4 instead of 3. This will cause pg_jobmon's default monitoring for 3 consecutive failing jobs to trigger an before the last premade partition is used up.
+-- Added optional jobmon logging to run_maintenance() so that if it fails, pg_jobmon can notify that maintenance didn't work.
+
+
+0.1.1
+-- Only re-create partition functions if a new partition is made.
View
@@ -1,7 +1,7 @@
{
"name": "pg_partman",
"abstract": "Extension to manage partitioned tables by time or ID",
- "version": "0.1.0",
+ "version": "0.1.2",
"maintainer": [
"Keith Fiske <keith@omniti.com>"
],
@@ -22,7 +22,7 @@
"pg_partmaint": {
"file": "sql/pg_partman.sql",
"docfile": "doc/pg_partman.md",
- "version": "0.1.0",
+ "version": "0.1.2",
"abstract": "Extension to manage partitioned tables by time or ID"
}
},
View
@@ -5,7 +5,7 @@ EXTVERSION = $(shell grep default_version $(EXTENSION).control | \
DATA = $(filter-out $(wildcard sql/*--*.sql),$(wildcard sql/*.sql))
DOCS = $(wildcard doc/*.md)
PG_CONFIG = pg_config
-PG91 = $(shell $(PG_CONFIG) --version | grep -qE " 8\.| 9\.0" && echo no || echo yes)
+PG91 = $(shell $(PG_CONFIG) --version | egrep " 8\.| 9\.0" > /dev/null && echo no || echo yes)
ifeq ($(PG91),yes)
all: sql/$(EXTENSION)--$(EXTVERSION).sql
View
@@ -6,29 +6,31 @@ Extension to help make managing time or serial id based table partitioning easie
For this extension, the attributes of the child partitions are all obtained from the original parent. This includes defaults, indexes (primary keys, unique, etc) as well as permissions (permissions not yet inherited. coming soon). 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 gives a more central place to manage things that's a little more natural than a configuration table or using setup functions.
*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 and permissions to parent table so they will propagate to children.
- * First parameter (p_parent_table) is the existing parent table
- * Second paramter (p_control) is the column that the partitioning will be based on. Must be a time based column (integer support for ID partitioning coming soon).
- * Third column (p_type) is one of 4 values to set the partitioning type that will be used
+ * Main function to create a partition set with one parent table and inherited children. Parent table must already exist. Please apply all indexes, constraints and permissions 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_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
> **time-static** - Trigger function inserts only into specifically named partitions (handles data for current partition, 2 partitions ahead and 1 behind). Cannot handle inserts to parent table outside the hard-coded time window. Function is kept up to date by run_maintenance() function. Ideal for high TPS tables that get inserts of new data only.
> **time-dynamic** - Trigger function can insert into any child partition based on the value of the control column. More flexible but not as efficient as time-static. Be aware that if the appropriate partition doesn't yet exist for the data inserted, the insert will fail.
> **id-static** - Same functionality as time-static but for a numeric range instead of time. When the id value has reached 50% of the max value for that partition, it will automatically create the next partition in sequence if it doesn't yet exist. Does NOT require run_maintenance() function to create new partitions.
> **id-dynamic** - Same functionality and limitations as time-dynamic but for a numeric range instead of time. Uses same 50% rule as id-static to create future partitions. Does NOT require run_maintenance() function to create new partitions.
- * Fourth parameter (p_interval) is the time or numeric range interval for each partition. Supported values are:
+ * p_interval - the time or numeric range interval for each partition. Supported values are:
> **yearly** - One partition per year
+ > **quarterly** - One partition per yearly quarter. Partitions are named as YYYYqQ (ex: 2012q4)
> **monthly** - One partition per month
- > **weekly** - One partition per week. Follows ISO week date format (http://en.wikipedia.org/wiki/ISO_week_date). Partitions are named as YYYYwWW (ex: 2012w36).
+ > **weekly** - One partition per week. Follows ISO week date format (http://en.wikipedia.org/wiki/ISO_week_date). Partitions are named as IYYYwIW (ex: 2012w36)
> **daily** - One partition per day
> **hourly** - One partition per hour
> **half-hour** - One partition per 30 minute interval on the half-hour (1200, 1230)
> **quarter-hour** - One partition per 15 minute interval on the quarter-hour (1200, 1215, 1230, 1245)
> **<integer>** - For ID based partitions, the integer value range of that ID that should be set per partition. This is the actual integer value, not text values like time-based partitioning.
- * Fifth paramter (p_premake) is how many additional partitions to always stay ahead of the current partition. Default value is 3. This will keep at minimum 4 partitions made, including the current one. For example, if today was Sept 6, 2012, and premake was set to 4 for a daily partition, then partitions would be made for the 6th as well as the 7th, 8th, 9th and 10th.
- * Sixth parameter (p_debug) is to turn on additional debugging information (not yet working).
+ * p_premake - is how many additional partitions to always stay ahead of the current partition. Default value is 4. This will keep at minimum 5 partitions made, including the current one. For example, if today was Sept 6, 2012, and premake was set to 4 for a daily partition, then partitions would be made for the 6th as well as the 7th, 8th, 9th and 10th.
+ * p_debug - turns on additional debugging information (not yet working).
*run_maintenance()*
* Run this function as a scheduled job (cronjob, etc) to automatically keep time-based partitioning working.
@@ -39,15 +41,15 @@ For this extension, the attributes of the child partitions are all obtained from
*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.
* 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 prevent a failure from causing an extensive rollback.
- * First parameter (p_parent_table) is the existing parent table.
- * Second parameter is how many partitions will be made in a single run of the function. Default value is 1.
+ * p_parent_table - the existing parent table. This is assumed to be where the unpartitioned data is located.
+ * 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.
*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.
* 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 prevent a failure from causing an extensive rollback.
- * First parameter (p_parent_table) is the existing parent table.
- * Second parameter is how many partitions will be made in a single run of the function. Default value is 1.
+ * p_parent_table - the existing parent table. This is assumed to be where the unpartitioned data is located.
+ * 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.
*check_parent() RETURNS SETOF (parent table, count)*
View
@@ -1,3 +1,3 @@
-default_version = '0.1.0'
+default_version = '0.1.2'
comment = 'Extension to manage partitioned tables by time or ID'
relocatable = false
@@ -1,3 +1,6 @@
+/*
+ * Create the next partition in sequence for a time-based partition set
+ */
CREATE FUNCTION create_next_time_partition (p_parent_table text) RETURNS void
LANGUAGE plpgsql
AS $$
@@ -7,10 +10,12 @@ v_control text;
v_datetime_string text;
v_last_partition text;
v_next_partition_timestamp timestamp;
+v_next_year text;
v_part_interval interval;
+v_quarter text;
v_tablename text;
v_type @extschema@.partition_type;
-
+v_year text;
BEGIN
@@ -29,14 +34,33 @@ END IF;
-- Double check that last created partition exists
IF v_last_partition IS NOT NULL THEN
- SELECT tablename INTO v_tablename FROM pg_tables WHERE schemaname || '.' || tablename = p_parent_table;
+ SELECT tablename INTO v_tablename FROM pg_tables WHERE schemaname || '.' || tablename = v_last_partition;
IF v_tablename IS NULL THEN
- RAISE EXCEPTION 'ERROR: previous partition missing. Unable to determine proper next partition name';
+ RAISE EXCEPTION 'ERROR: previous partition table missing. Unable to determine next proper partition in sequence.';
END IF;
+ELSE
+ RAISE EXCEPTION 'ERROR: last known partition missing from config table for parent table %.', p_parent_table;
END IF;
--- pull out datetime portion of last partition's tablename
-v_next_partition_timestamp := to_timestamp(substring(v_last_partition from char_length(p_parent_table||'_p')+1), v_datetime_string) + v_part_interval;
+-- pull out datetime portion of last partition's tablename to make the next one
+IF v_part_interval != '3 months' THEN
+ v_next_partition_timestamp := to_timestamp(substring(v_last_partition from char_length(p_parent_table||'_p')+1), v_datetime_string) + v_part_interval;
+ELSE
+ -- to_timestamp doesn't recognize 'Q' date string formater. Handle it
+ v_year := split_part(substring(v_last_partition from char_length(p_parent_table||'_p')+1), 'q', 1);
+ v_next_year := extract('year' from to_date(v_year, 'YYYY')+'1year'::interval);
+ v_quarter := split_part(substring(v_last_partition from char_length(p_parent_table||'_p')+1), 'q', 2);
+ CASE
+ WHEN v_quarter = '1' THEN
+ v_next_partition_timestamp := to_timestamp(v_year || '-04-01', 'YYYY-MM-DD');
+ WHEN v_quarter = '2' THEN
+ v_next_partition_timestamp := to_timestamp(v_year || '-07-01', 'YYYY-MM-DD');
+ WHEN v_quarter = '3' THEN
+ v_next_partition_timestamp := to_timestamp(v_year || '-10-01', 'YYYY-MM-DD');
+ WHEN v_quarter = '4' THEN
+ v_next_partition_timestamp := to_timestamp(v_next_year || '-01-01', 'YYYY-MM-DD');
+ END CASE;
+END IF;
EXECUTE 'SELECT @extschema@.create_time_partition('||quote_literal(p_parent_table)||','||quote_literal(v_control)||','||quote_literal(v_part_interval)||','
||quote_literal(v_datetime_string)||','||quote_literal(ARRAY[v_next_partition_timestamp])||')' INTO v_last_partition;
@@ -1,4 +1,7 @@
-CREATE FUNCTION create_parent(p_parent_table text, p_control text, p_type @extschema@.partition_type, p_interval text, p_premake int DEFAULT 3, p_debug boolean DEFAULT false) RETURNS void
+/*
+ * Function to turn a table into the parent of a partition set
+ */
+CREATE FUNCTION create_parent(p_parent_table text, p_control text, p_type @extschema@.partition_type, p_interval text, p_premake int DEFAULT 4, p_debug boolean DEFAULT false) RETURNS void
LANGUAGE plpgsql SECURITY DEFINER
AS $$
DECLARE
@@ -34,14 +37,17 @@ IF v_jobmon_schema IS NOT NULL THEN
END IF;
IF v_jobmon_schema IS NOT NULL THEN
- v_job_id := add_job('PARTMON SETUP PARENT: '||p_parent_table);
+ v_job_id := add_job('PARTMAN SETUP PARENT: '||p_parent_table);
v_step_id := add_step(v_job_id, 'Creating initial partitions on new parent table: '||p_parent_table);
END IF;
CASE
WHEN p_interval = 'yearly' THEN
v_time_interval = '1 year';
v_datetime_string := 'YYYY';
+ WHEN p_interval = 'quarterly' THEN
+ v_time_interval = '3 months';
+ v_datetime_string = 'YYYY"q"Q';
WHEN p_interval = 'monthly' THEN
v_time_interval = '1 month';
v_datetime_string := 'YYYY_MM';
@@ -129,9 +135,10 @@ EXECUTE 'SELECT @extschema@.create_trigger('||quote_literal(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);
+ EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;
-PERFORM close_job(v_job_id);
EXCEPTION
WHEN OTHERS THEN
@@ -1,3 +1,6 @@
+/*
+ * Populate the child table(s) of a time-based partition set with old data from the original parent
+ */
CREATE FUNCTION create_prev_time_partition(p_parent_table text, p_batch int DEFAULT 1) RETURNS bigint
LANGUAGE plpgsql SECURITY DEFINER
AS $$
@@ -50,6 +53,8 @@ CASE
v_min_partition_timestamp := date_trunc('week', v_min_control);
WHEN v_part_interval = '1 month' THEN
v_min_partition_timestamp := date_trunc('month', v_min_control);
+ WHEN v_part_interval = '3 months' THEN
+ v_min_partition_timestamp := date_trunc('quarter', v_min_control);
WHEN v_part_interval = '1 year' THEN
v_min_partition_timestamp := date_trunc('year', v_min_control);
END CASE;
@@ -1,3 +1,6 @@
+/*
+ * Create the trigger function for the parent table of a time-based partition set
+ */
CREATE FUNCTION create_time_function(p_parent_table text) RETURNS void
LANGUAGE plpgsql SECURITY DEFINER
AS $$
@@ -65,6 +68,8 @@ IF v_type = 'time-static' 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;
@@ -128,6 +133,8 @@ ELSIF v_type = 'time-dynamic' 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;
@@ -1,3 +1,6 @@
+/*
+ * Function to create a child table in a time-based partition set
+ */
CREATE 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 $$
@@ -9,9 +12,11 @@ v_old_search_path text;
v_partition_name text;
v_partition_timestamp_end timestamp;
v_partition_timestamp_start timestamp;
+v_quarter text;
v_step_id bigint;
v_tablename text;
v_time timestamp;
+v_year text;
BEGIN
@@ -66,6 +71,24 @@ FOREACH v_time IN ARRAY p_partition_times LOOP
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;
@@ -105,7 +128,7 @@ EXCEPTION
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');
- RAISE EXCEPTION '%', SQLERRM;ELSIF v_step_id IS NULL THEN
+ 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'));
Oops, something went wrong. Retry.

0 comments on commit 18dbce3

Please sign in to comment.