Permalink
Browse files

Added functions to partition data from previously unpartitioned table…

…. Added function to monitor parent tables for data. New ID based partitions will now start with partition for highest value if data already exists. Changed trigger to only ON INSERT for now. Made partition creation more efficient (shorter lock on parent).
  • Loading branch information...
1 parent c022d2e commit 39b936df3de66969e9e4f406f0137d5b35621f1d @keithf4 committed Oct 1, 2012
View
6 META.json
@@ -11,15 +11,17 @@
"prereqs": {
"runtime": {
"requires": {
- "PostgreSQL": "9.1.0",
+ "PostgreSQL": "9.1.0"
+ },
+ "recommends": {
"pg_jobmon": "0.3.0"
}
}
},
"provides": {
"pg_partmaint": {
"file": "sql/pg_partman.sql",
- "docfile": "doc/partman.md",
+ "docfile": "doc/pg_partman.md",
"version": "0.1.0",
"abstract": "Extension to manage partitioned tables by time or ID"
}
View
4 install.sql
@@ -12,6 +12,8 @@ CREATE SCHEMA part;
\i sql/functions/create_time_function.sql
\i sql/functions/create_time_partition.sql
\i sql/functions/create_trigger.sql
---\i sql/functions/
\i sql/functions/run_maintenance.sql
+\i sql/functions/create_prev_time_partition.sql
+\i sql/functions/create_prev_id_partition.sql
+\i sql/functions/check_parents.sql
View
1 pg_partman.control
@@ -1,4 +1,3 @@
default_version = '0.1.0'
comment = 'Extension to manage partitioned tables by time or ID'
-requires = 'pg_jobmon'
relocatable = false
View
33 sql/functions/check_parent.sql
@@ -0,0 +1,33 @@
+CREATE FUNCTION part.check_parent() RETURNS SETOF part.check_parent_table
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_count bigint = 0;
+v_sql text;
+v_tables record;
+v_trouble part.check_parent_table%rowtype;
+
+BEGIN
+
+FOR v_tables IN
+ SELECT DISTINCT parent_table FROM part.part_config
+LOOP
+
+ v_sql := 'SELECT count(1) AS n FROM ONLY '||v_tables.parent_table;
+ EXECUTE v_sql INTO v_count;
+
+ IF v_count > 0 THEN
+ v_trouble.parent_table := v_tables.parent_table;
+ v_trouble.count := v_count;
+ RETURN NEXT v_trouble;
+ END IF;
+
+ v_count := 0;
+
+END LOOP;
+
+RETURN;
+
+END
+$$;
View
31 sql/functions/check_parents.sql
@@ -1,31 +0,0 @@
-CREATE OR REPLACE FUNCTION part.check_parents() RETURNS record
- LANGUAGE plpgsql SECURITY DEFINER
- AS $$
-DECLARE
-
-v_count bigint = 0;
-v_tables record;
-v_trouble text[];
-
-BEGIN
-
-FOR v_tables IN
- SELECT DISTINCT parent_table FROM part.part_config
-LOOP
-
- SELECT count(1) AS n INTO v_count FROM ONLY v_tables.parent_table;
- --execute v_sql INTO v_count;
-
- IF v_count > 0 THEN
- v_trouble := array_append(v_trouble, v_tables.parent_table);
- v_trouble := array_append(v_trouble, v_count);
- END IF;
-
- v_count := 0;
-
-END LOOP;
-
-RETURN v_trouble;
-
-END
-$$;
View
9 sql/functions/create_id_function.sql
@@ -1,4 +1,4 @@
-CREATE OR REPLACE FUNCTION part.create_id_function(p_parent_table text, p_current_id bigint) RETURNS void
+CREATE FUNCTION part.create_id_function(p_parent_table text, p_current_id bigint) RETURNS void
LANGUAGE plpgsql SECURITY DEFINER
AS $$
DECLARE
@@ -136,10 +136,7 @@ ELSIF v_type = 'id-dynamic' THEN
END IF;
END IF;
END IF;
-
EXECUTE ''INSERT INTO ''||v_current_partition_name||'' VALUES($1.*)'' USING NEW;
-
-
END IF;
RETURN NULL;
@@ -148,7 +145,6 @@ ELSIF v_type = 'id-dynamic' THEN
-- 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;
@@ -176,9 +172,6 @@ EXCEPTION
PERFORM fail_job(v_job_id);
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;
-
RAISE EXCEPTION '%', SQLERRM;
-
-
END
$$;
View
7 sql/functions/create_id_partition.sql
@@ -1,4 +1,4 @@
-CREATE OR REPLACE FUNCTION part.create_id_partition (p_parent_table text, p_control text, p_interval bigint, p_partition_ids bigint[]) RETURNS text
+CREATE 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
@@ -38,9 +38,10 @@ FOREACH v_id IN ARRAY p_partition_ids LOOP
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 INDEXES) INHERITS ('||p_parent_table||')';
+ EXECUTE 'CREATE TABLE '||v_partition_name||' (LIKE '||p_parent_table||' INCLUDING DEFAULTS INCLUDING INDEXES)';
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)||')';
+ EXECUTE 'ALTER TABLE '||v_partition_name||' INHERIT '||p_parent_table;
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
@@ -69,8 +70,6 @@ EXCEPTION
PERFORM fail_job(v_job_id);
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;
-
RAISE EXCEPTION '%', SQLERRM;
-
END
$$;
View
2 sql/functions/create_next_time_partition.sql
@@ -1,4 +1,4 @@
-CREATE OR REPLACE FUNCTION part.create_next_time_partition (p_parent_table text) RETURNS void
+CREATE FUNCTION part.create_next_time_partition (p_parent_table text) RETURNS void
LANGUAGE plpgsql
AS $$
DECLARE
View
21 sql/functions/create_parent.sql
@@ -1,4 +1,4 @@
-CREATE OR REPLACE FUNCTION part.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) RETURNS void
+CREATE FUNCTION part.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) RETURNS void
LANGUAGE plpgsql SECURITY DEFINER
AS $$
DECLARE
@@ -12,7 +12,8 @@ v_last_partition_name text;
v_old_search_path text;
v_partition_time timestamp[];
v_partition_id bigint[];
-v_max text;
+v_max bigint;
+v_starting_partition_id bigint;
v_step_id bigint;
v_tablename text;
v_time_interval interval;
@@ -84,10 +85,11 @@ IF p_type = 'time-static' OR p_type = 'time-dynamic' THEN
END IF;
IF p_type = 'id-static' OR p_type = 'id-dynamic' THEN
- -- EXECUTE 'SELECT COALESCE(max('||p_control||')::text, '0') FROM '||p_parent_table||' LIMIT 1' INTO v_max;
- -- v_max := v_max::bigint;
+ -- If there is already data, start partitioning with the highest current value
+ EXECUTE 'SELECT COALESCE(max('||p_control||')::bigint, 0) FROM '||p_parent_table||' LIMIT 1' INTO v_max;
+ v_starting_partition_id := v_max - (v_max % v_id_interval);
FOR i IN 0..p_premake LOOP
- v_partition_id = array_append(v_partition_id, v_id_interval*i);
+ v_partition_id = array_append(v_partition_id, (v_id_interval*i)+v_starting_partition_id);
END LOOP;
EXECUTE 'SELECT part.create_id_partition('||quote_literal(p_parent_table)||','||quote_literal(p_control)||','
@@ -108,18 +110,12 @@ END IF;
IF p_type = 'time-static' OR p_type = 'time-dynamic' THEN
EXECUTE 'SELECT part.create_time_function('||quote_literal(p_parent_table)||')';
-
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Time function created');
END IF;
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;
+ v_current_id := COALESCE(v_max, 0);
EXECUTE 'SELECT part.create_id_function('||quote_literal(p_parent_table)||','||v_current_id||')';
-
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'ID function created');
END IF;
@@ -151,5 +147,6 @@ EXCEPTION
PERFORM fail_job(v_job_id);
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;
+ RAISE EXCEPTION '%', SQLERRM;
END
$$;
View
68 sql/functions/create_prev_id_partition.sql
@@ -0,0 +1,68 @@
+CREATE FUNCTION part.create_prev_id_partition(p_parent_table text, p_batch int DEFAULT 1) RETURNS bigint
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_control text;
+v_last_partition_name text;
+v_max_partition_id bigint;
+v_min_control bigint;
+v_min_partition_id bigint;
+v_part_interval bigint;
+v_partition_id bigint[];
+v_rowcount bigint;
+v_sql text;
+v_total_rows bigint := 0;
+v_type text;
+
+BEGIN
+
+SELECT type
+ , part_interval::bigint
+ , control
+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;
+IF NOT FOUND THEN
+ RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table;
+END IF;
+
+EXECUTE 'SELECT min('||v_control||') FROM ONLY '||p_parent_table INTO v_min_control;
+IF v_min_control IS NULL THEN
+ RETURN 0;
+END IF;
+
+v_min_partition_id = v_min_control - (v_min_control % v_part_interval);
+
+-- Subtract 1 so that batch count number actually makes sense
+FOR i IN 0..p_batch-1 LOOP
+ v_partition_id := ARRAY[v_min_partition_id + (v_part_interval*i)];
+RAISE NOTICE 'v_partition_id: %',v_partition_id;
+ v_max_partition_id := v_min_partition_id + (v_part_interval*(i+1));
+RAISE NOTICE 'v_max_partition_id: %',v_max_partition_id;
+
+ v_sql := 'SELECT part.create_id_partition('||quote_literal(p_parent_table)||','||quote_literal(v_control)||','
+ ||v_part_interval||','||quote_literal(v_partition_id)||')';
+ RAISE NOTICE 'v_sql: %', v_sql;
+ EXECUTE v_sql INTO v_last_partition_name;
+
+ v_sql := 'WITH partition_data AS (
+ DELETE FROM ONLY '||p_parent_table||' WHERE '||v_control||' >= '||v_min_partition_id||
+ ' AND '||v_control||' < '||v_max_partition_id||' RETURNING *)
+ INSERT INTO '||v_last_partition_name||' SELECT * FROM partition_data';
+ RAISE NOTICE 'v_sql: %', v_sql;
+ EXECUTE v_sql;
+
+ GET DIAGNOSTICS v_rowcount = ROW_COUNT;
+ v_total_rows := v_total_rows + v_rowcount;
+ IF v_rowcount = 0 THEN
+ EXIT;
+ END IF;
+
+END LOOP;
+
+RETURN v_total_rows;
+
+END
+$$;
View
87 sql/functions/create_prev_time_partition.sql
@@ -0,0 +1,87 @@
+CREATE FUNCTION part.create_prev_time_partition(p_parent_table text, p_batch int DEFAULT 1) RETURNS bigint
+ LANGUAGE plpgsql SECURITY DEFINER
+ AS $$
+DECLARE
+
+v_control text;
+v_datetime_string text;
+v_last_partition_name text;
+v_max_partition_timestamp timestamp;
+v_min_control timestamp;
+v_min_partition_timestamp timestamp;
+v_part_interval interval;
+v_partition_timestamp timestamp[];
+v_rowcount bigint;
+v_sql text;
+v_total_rows bigint := 0;
+v_type text;
+
+BEGIN
+
+SELECT type
+ , part_interval::interval
+ , control
+ , datetime_string
+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;
+IF NOT FOUND THEN
+ RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table;
+END IF;
+
+EXECUTE 'SELECT min('||v_control||') FROM ONLY '||p_parent_table INTO v_min_control;
+IF v_min_control IS NULL THEN
+ RETURN 0;
+END IF;
+
+CASE
+ WHEN v_part_interval = '15 mins' THEN
+ v_min_partition_timestamp := date_trunc('hour', v_min_control) +
+ '15min'::interval * floor(date_part('minute', v_min_control) / 15.0);
+ WHEN v_part_interval = '30 mins' THEN
+ v_min_partition_timestamp := date_trunc('hour', v_min_control) +
+ '30min'::interval * floor(date_part('minute', v_min_control) / 30.0);
+ WHEN v_part_interval = '1 hour' THEN
+ v_min_partition_timestamp := date_trunc('hour', v_min_control);
+ WHEN v_part_interval = '1 day' THEN
+ v_min_partition_timestamp := date_trunc('day', v_min_control);
+ WHEN v_part_interval = '1 week' THEN
+ 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 = '1 year' THEN
+ v_min_partition_timestamp := date_trunc('year', v_min_control);
+END CASE;
+
+-- Subtract 1 so that batch count number actually makes sense
+FOR i IN 0..p_batch-1 LOOP
+ v_partition_timestamp := ARRAY[(v_min_partition_timestamp + (v_part_interval*i))::timestamp];
+RAISE NOTICE 'v_partition_timestamp: %',v_partition_timestamp;
+ v_max_partition_timestamp := v_min_partition_timestamp + (v_part_interval*(i+1));
+RAISE NOTICE 'v_max_partition_timestamp: %',v_max_partition_timestamp;
+
+ v_sql := '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(v_partition_timestamp)||')';
+ RAISE NOTICE 'v_sql: %', v_sql;
+ EXECUTE v_sql INTO v_last_partition_name;
+
+ v_sql := 'WITH partition_data AS (
+ DELETE FROM ONLY '||p_parent_table||' WHERE '||v_control||' >= '||quote_literal(v_min_partition_timestamp)||
+ ' AND '||v_control||' < '||quote_literal(v_max_partition_timestamp)||' RETURNING *)
+ INSERT INTO '||v_last_partition_name||' SELECT * FROM partition_data';
+ RAISE NOTICE 'v_sql: %', v_sql;
+ EXECUTE v_sql;
+
+ GET DIAGNOSTICS v_rowcount = ROW_COUNT;
+ v_total_rows := v_total_rows + v_rowcount;
+ IF v_rowcount = 0 THEN
+ EXIT;
+ END IF;
+
+END LOOP;
+
+RETURN v_total_rows;
+
+END
+$$;
View
4 sql/functions/create_time_function.sql
@@ -1,4 +1,4 @@
-CREATE OR REPLACE FUNCTION part.create_time_function(p_parent_table text) RETURNS void
+CREATE FUNCTION part.create_time_function(p_parent_table text) RETURNS void
LANGUAGE plpgsql SECURITY DEFINER
AS $$
DECLARE
@@ -171,8 +171,6 @@ EXCEPTION
PERFORM fail_job(v_job_id);
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;
-
RAISE EXCEPTION '%', SQLERRM;
-
END
$$;
View
11 sql/functions/create_time_partition.sql
@@ -1,4 +1,4 @@
-CREATE OR REPLACE FUNCTION part.create_time_partition (p_parent_table text, p_control text, p_interval interval, p_datetime_string text, p_partition_times timestamp[]) RETURNS text
+CREATE FUNCTION part.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 $$
DECLARE
@@ -80,9 +80,10 @@ FOREACH v_time IN ARRAY p_partition_times LOOP
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 INDEXES) INHERITS ('||p_parent_table||')';
- EXECUTE 'ALTER TABLE '||v_partition_name||' ADD CONSTRAINT '||v_tablename||'_partition_check
+ EXECUTE 'CREATE TABLE '||v_partition_name||' (LIKE '||p_parent_table||' INCLUDING DEFAULTS INCLUDING INDEXES)';
+ 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)||')';
+ EXECUTE 'ALTER TABLE '||v_partition_name||' INHERIT '||p_parent_table;
IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
@@ -104,15 +105,13 @@ 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');
- ELSIF v_step_id IS NULL THEN
+ RAISE EXCEPTION '%', SQLERRM;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
$$;
View
6 sql/functions/create_trigger.sql
@@ -1,4 +1,4 @@
-CREATE OR REPLACE FUNCTION part.create_trigger(p_parent_table text) RETURNS void
+CREATE FUNCTION part.create_trigger(p_parent_table text) RETURNS void
LANGUAGE plpgsql SECURITY DEFINER
AS $$
DECLARE
@@ -13,10 +13,10 @@ IF position('.' in p_parent_table) > 0 THEN
END IF;
-v_trig := 'CREATE TRIGGER '||v_tablename||'_part_trig BEFORE INSERT OR UPDATE OR DELETE ON '||p_parent_table||
+v_trig := 'CREATE TRIGGER '||v_tablename||'_part_trig BEFORE INSERT ON '||p_parent_table||
' FOR EACH ROW EXECUTE PROCEDURE '||p_parent_table||'_part_trig_func()';
-RAISE NOTICE 'v_trig: %', v_trig;
+--RAISE NOTICE 'v_trig: %', v_trig;
EXECUTE v_trig;
END
View
2 sql/functions/run_maintenance.sql
@@ -1,4 +1,4 @@
-CREATE OR REPLACE FUNCTION part.run_maintenance() RETURNS void
+CREATE FUNCTION part.run_maintenance() RETURNS void
LANGUAGE plpgsql SECURITY DEFINER
AS $$
DECLARE
View
2 sql/tables/tables.sql
@@ -4,8 +4,10 @@ CREATE TABLE part.part_config (
part_interval text NOT NULL,
control text NOT NULL,
premake int NOT NULL,
+ retention int,
datetime_string text,
last_partition text,
CONSTRAINT part_config_parent_table_pkey PRIMARY KEY (parent_table)
);
+CREATE INDEX part_config_type_idx ON part.part_config (type);
--SELECT pg_catalog.pg_extension_config_dump('part_config', '');
View
1 sql/types/types.sql
@@ -1 +1,2 @@
CREATE TYPE part.partition_type AS ENUM ('time-static', 'time-dynamic', 'id-static', 'id-dynamic');
+CREATE TYPE part.check_parent_table AS (parent_table text, count bigint);

0 comments on commit 39b936d

Please sign in to comment.