Skip to content
Browse files

id-static option now working. New id partition creation is based on t…

…able control column value and does not require run_maintenance()
  • Loading branch information...
1 parent e01634e commit 642f6ea49437243d0f0a0f63da57b6bb1dfa593c @keithf4 committed Sep 11, 2012
View
144 sql/functions/create_id_function.sql
@@ -0,0 +1,144 @@
+CREATE OR REPLACE FUNCTION part.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_last_partition text;
+v_part_interval bigint;
+v_premake int;
+v_prev_partition_name text;
+v_prev_partition_id bigint;
+v_trig_func text;
+v_type text;
+
+
+BEGIN
+
+SELECT type
+ , part_interval::bigint
+ , control
+ , premake
+ , last_partition
+FROM part.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.*);
+ ';
+ -- There
+ 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
+ RAISE EXCEPTION ''ERROR: Attempt to insert data into parent table outside partition trigger boundaries: %'', NEW.'||v_control||';
+ 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) / '||quote_literal(v_part_interval)||') <= '||quote_literal(v_premake)||' THEN
+ v_next_partition_name := part.create_id_partition('||quote_literal(p_parent_table)||', '||quote_literal(v_control)||','
+ ||quote_literal(v_part_interval)||', ARRAY[v_next_partition_id]);
+ UPDATE part.part_config SET last_partition = v_next_partition_name WHERE parent_table = '||quote_literal(p_parent_table)||';
+ PERFORM part.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;
+
+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_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;
+
+ELSE
+ RAISE EXCEPTION 'ERROR: Invalid id partitioning type given: %', v_type;
+END IF;
+
+
+END
+$$;
View
30 sql/functions/create_id_partition.sql
@@ -0,0 +1,30 @@
+CREATE OR REPLACE FUNCTION part.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_partition_name text;
+v_tablename text;
+v_id bigint;
+
+BEGIN
+
+FOREACH v_id IN ARRAY p_partition_ids LOOP
+ v_partition_name := p_parent_table||'_p'||v_id;
+
+ 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 CONSTRAINTS) INHERITS ('||p_parent_table||')';
+ 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)||')';
+
+---- Call post_script() for given parent table
+
+END LOOP;
+
+RETURN v_partition_name;
+
+END
+$$;
View
47 sql/functions/create_next_id_partition.sql
@@ -0,0 +1,47 @@
+CREATE OR REPLACE FUNCTION part.create_next_id_partition (p_parent_table text) RETURNS void
+ LANGUAGE plpgsql
+ AS $$
+DECLARE
+
+v_control text;
+v_datetime_string text;
+v_last_partition text;
+v_next_partition_timestamp timestamp;
+v_part_interval interval;
+v_tablename text;
+v_type part.partition_type;
+
+
+BEGIN
+
+SELECT type
+ , part_interval::interval
+ , control
+ , datetime_string
+ , last_partition
+FROM part.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, v_last_partition;
+IF NOT FOUND THEN
+ RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table;
+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;
+ IF v_tablename IS NULL THEN
+ RAISE EXCEPTION 'ERROR: previous partition missing. Unable to determine proper next partition name';
+ END IF;
+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;
+
+EXECUTE 'SELECT part.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;
+
+UPDATE part.part_config SET last_partition = v_last_partition WHERE parent_table = p_parent_table;
+
+END
+$$;
View
61 sql/functions/create_parent.sql
@@ -3,12 +3,15 @@ CREATE OR REPLACE FUNCTION part.create_parent(p_parent_table text, p_control tex
AS $$
DECLARE
+v_current_id bigint;
v_datetime_string text;
-v_interval interval;
+v_id_interval bigint;
v_last_partition_name text;
v_partition_time timestamp[];
-v_record record;
+v_partition_id bigint[];
+v_max text;
v_tablename text;
+v_time_interval interval;
BEGIN
@@ -17,40 +20,38 @@ SELECT tablename INTO v_tablename FROM pg_tables WHERE schemaname || '.' || tabl
RAISE EXCEPTION 'Please create given parent table first: %', p_parent_table;
END IF;
-IF p_type = 'id-static' OR p_type = 'id-dynamic' THEN
- RAISE EXCEPTION 'ID partitioning not supported yet. Try again later!';
-END IF;
-
EXECUTE 'LOCK TABLE '||p_parent_table||' IN ACCESS EXCLUSIVE MODE';
CASE
WHEN p_interval = 'yearly' THEN
- v_interval = '1 year';
+ v_time_interval = '1 year';
v_datetime_string := 'YYYY';
WHEN p_interval = 'monthly' THEN
- v_interval = '1 month';
+ v_time_interval = '1 month';
v_datetime_string := 'YYYY_MM';
WHEN p_interval = 'weekly' THEN
- v_interval = '1 week';
+ v_time_interval = '1 week';
v_datetime_string := 'IYYY"w"IW';
WHEN p_interval = 'daily' THEN
- v_interval = '1 day';
+ v_time_interval = '1 day';
v_datetime_string := 'YYYY_MM_DD';
WHEN p_interval = 'hourly' THEN
- v_interval = '1 hour';
+ v_time_interval = '1 hour';
v_datetime_string := 'YYYY_MM_DD_HH24MI';
WHEN p_interval = 'half-hour' THEN
- v_interval = '30 mins';
+ v_time_interval = '30 mins';
v_datetime_string := 'YYYY_MM_DD_HH24MI';
WHEN p_interval = 'quarter-hour' THEN
- v_interval = '15 mins';
+ v_time_interval = '15 mins';
v_datetime_string := 'YYYY_MM_DD_HH24MI';
ELSE
- v_interval := p_interval::int;
+ v_id_interval := p_interval::bigint;
END CASE;
-EXECUTE 'SELECT * FROM '||p_parent_table||' LIMIT 1' INTO v_record;
-IF v_record IS NOT NULL THEN
+RAISE NOTICE 'Interval converted';
+
+EXECUTE 'SELECT max('||p_control||')::text FROM '||p_parent_table||' LIMIT 1' INTO v_max;
+IF v_max IS NOT NULL THEN
IF position('.' in p_parent_table) > 0 THEN
v_tablename := substring(p_parent_table from position('.' in p_parent_table)+1);
END IF;
@@ -63,18 +64,38 @@ END IF;
IF p_type = 'time-static' OR p_type = 'time-dynamic' THEN
FOR i IN 0..p_premake LOOP
- v_partition_time := array_append(v_partition_time, quote_literal(CURRENT_TIMESTAMP + (v_interval*i))::timestamp);
+ v_partition_time := array_append(v_partition_time, quote_literal(CURRENT_TIMESTAMP + (v_time_interval*i))::timestamp);
END LOOP;
EXECUTE 'SELECT part.create_time_partition('||quote_literal(p_parent_table)||','||quote_literal(p_control)||','
- ||quote_literal(v_interval)||','||quote_literal(v_datetime_string)||','||quote_literal(v_partition_time)||')' INTO v_last_partition_name;
+ ||quote_literal(v_time_interval)||','||quote_literal(v_datetime_string)||','||quote_literal(v_partition_time)||')' INTO v_last_partition_name;
+
+ INSERT INTO part.part_config (parent_table, type, part_interval, control, premake, datetime_string, last_partition) VALUES
+ (p_parent_table, p_type, v_time_interval, p_control, p_premake, v_datetime_string, v_last_partition_name);
END IF;
-INSERT INTO part.part_config (parent_table, type, part_interval, control, premake, datetime_string, last_partition) VALUES
- (p_parent_table, p_type, v_interval, p_control, p_premake, v_datetime_string, v_last_partition_name);
+IF p_type = 'id-static' OR p_type = 'id-dynamic' THEN
+ FOR i IN 0..p_premake LOOP
+ v_partition_id = array_append(v_partition_id, v_id_interval*i);
+ END LOOP;
+
+ EXECUTE 'SELECT part.create_id_partition('||quote_literal(p_parent_table)||','||quote_literal(p_control)||','
+ ||v_id_interval||','||quote_literal(v_partition_id)||')' INTO v_last_partition_name;
+
+ INSERT INTO part.part_config (parent_table, type, part_interval, control, premake, last_partition) VALUES
+ (p_parent_table, p_type, v_id_interval, p_control, p_premake, v_last_partition_name);
+
+END IF;
IF p_type = 'time-static' OR p_type = 'time-dynamic' THEN
EXECUTE 'SELECT part.create_time_function('||quote_literal(p_parent_table)||')';
+ELSIF p_type = 'id-static' OR p_type = 'id-dynamic' THEN
+ IF v_max IS NOT NULL THEN
+ v_current_id := v_max::bigint;
+ ELSE
+ v_current_id := 0;
+ END IF;
+ EXECUTE 'SELECT part.create_id_function('||quote_literal(p_parent_table)||','||v_current_id||')';
END IF;
EXECUTE 'SELECT part.create_trigger('||quote_literal(p_parent_table)||')';
View
6 sql/functions/create_time_function.sql
@@ -85,8 +85,6 @@ IF v_type = 'time-static' THEN
-- RAISE NOTICE 'v_trig_func: %',v_trig_func;
EXECUTE v_trig_func;
-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$
@@ -132,10 +130,8 @@ ELSIF v_type = 'time-dynamic' THEN
RAISE NOTICE 'v_trig_func: %',v_trig_func;
EXECUTE v_trig_func;
-ELSIF v_type = 'id-dynamic' THEN
-
ELSE
- RAISE EXCEPTION 'ERROR: Invalid partitioning type given: %', v_type;
+ RAISE EXCEPTION 'ERROR: Invalid time partitioning type given: %', v_type;
END IF;
View
2 sql/functions/create_time_partition.sql
@@ -59,7 +59,7 @@ 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 CONSTRAINTS) INHERITS ('||p_parent_table||')';
+EXECUTE 'CREATE TABLE '||v_partition_name||' (LIKE '||p_parent_table||' INCLUDING DEFAULTS INCLUDING CONSTRAINTS) INHERITS ('||p_parent_table||')';
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)||')';

0 comments on commit 642f6ea

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