Permalink
Browse files

time-dynamic option now working

  • Loading branch information...
1 parent 7d942bf commit e01634e323de1b280e37c78772bd8959f9532863 @keithf4 committed Sep 9, 2012
Showing with 67 additions and 27 deletions.
  1. +4 −4 doc/pg_partmaint.md
  2. +62 −19 sql/functions/create_time_function.sql
  3. +1 −4 sql/functions/run_maintenance.sql
View
@@ -6,12 +6,12 @@ PostgreSQL Partition Maintenance Extension (pg_partmaint)
* If turning an existing table with data into a partitioned set, please double check all permissions & constraints after the conversion. Constraints should be good, but permissions are not copied. Indexes are not recreated on the new parent either and should not be.
* 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 (time-static is the only one currently supported)
+ * Third column (p_type) is 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.
- > **id-static** - Same functionality as time-static but for a numeric range instead of time.
- > **id-dynamic** - Same functionality as time-dynamic but for a numeric range instead of time.
+ > **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.
+ > **id-static** - Same functionality as time-static but for a numeric range instead of time. (coming soon)
+ > **id-dynamic** - Same functionality as time-dynamic but for a numeric range instead of time. (coming soon)
* Fourth parameter (p_interval) is the time or numeric range interval for each partition. Supported values are:
@@ -33,26 +33,26 @@ IF NOT FOUND THEN
RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table;
END IF;
-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 = '1 year' THEN
- v_current_partition_timestamp := date_trunc('year', CURRENT_TIMESTAMP);
-END CASE;
-
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 = '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;
@@ -89,6 +89,49 @@ ELSIF v_type = 'id-static' THEN
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_counter int;
+ v_new_partition_name text;
+ v_new_partition_timestamp timestamp;
+ v_old_partition_name text;
+ v_old_partition_timestamp timestamp;
+ v_row record;
+ v_where text;
+ BEGIN
+ IF TG_OP = ''INSERT'' THEN
+ ';
+ CASE
+ WHEN v_part_interval = '15 mins' THEN
+ v_trig_func := v_trig_func||'v_new_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_new_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_new_partition_timestamp := date_trunc(''hour'', NEW.'||v_control||');';
+ WHEN v_part_interval = '1 day' THEN
+ v_trig_func := v_trig_func||'v_new_partition_timestamp := date_trunc(''day'', NEW.'||v_control||');';
+ WHEN v_part_interval = '1 week' THEN
+ v_trig_func := v_trig_func||'v_new_partition_timestamp := date_trunc(''week'', NEW.'||v_control||');';
+ WHEN v_part_interval = '1 month' THEN
+ v_trig_func := v_trig_func||'v_new_partition_timestamp := date_trunc(''month'', NEW.'||v_control||');';
+ WHEN v_part_interval = '1 year' THEN
+ v_trig_func := v_trig_func||'v_new_partition_timestamp := date_trunc(''year'', NEW.'||v_control||');';
+ END CASE;
+
+ v_trig_func := v_trig_func||'
+ v_new_partition_name := '''||p_parent_table||'_p''|| to_char(v_new_partition_timestamp, '||quote_literal(v_datetime_string)||');
+
+ EXECUTE ''INSERT INTO ''||v_new_partition_name||'' VALUES($1.*)'' USING NEW;
+ END IF;
+
+ RETURN NULL;
+ END $t$;';
+
+ RAISE NOTICE 'v_trig_func: %',v_trig_func;
+ EXECUTE v_trig_func;
+
ELSIF v_type = 'id-dynamic' THEN
ELSE
@@ -51,12 +51,9 @@ LOOP
v_last_partition_timestamp := to_timestamp(substring(v_row.last_partition from char_length(v_row.parent_table||'_p')+1), v_row.datetime_string);
+ -- Check and see how many premade partitions there are. If it's less than premake in config table, make another
v_premade_count = EXTRACT('epoch' FROM (v_last_partition_timestamp - v_current_partition_timestamp)::interval) / EXTRACT('epoch' FROM v_row.part_interval::interval);
- RAISE NOTICE 'v_premade_count %', v_premade_count;
- -- If it's been longer than the parent table's destinated interval, make the next partition
--- RAISE NOTICE 'It''s been this long: %', (CURRENT_TIMESTAMP - v_current_partition_timestamp)::interval;
--- IF ((CURRENT_TIMESTAMP - v_current_partition_timestamp)::interval >= v_row.part_interval) THEN
IF v_premade_count < v_row.premake THEN
RAISE NOTICE 'Creating next partition';
EXECUTE 'SELECT part.create_next_time_partition('||quote_literal(v_row.parent_table)||')';

0 comments on commit e01634e

Please sign in to comment.