Skip to content

Commit

Permalink
More pg_jobmon integration. Now working in create_parent and time-bas…
Browse files Browse the repository at this point in the history
…ed partition functions
  • Loading branch information
keithf4 committed Sep 18, 2012
1 parent 5610dcd commit c022d2e
Show file tree
Hide file tree
Showing 5 changed files with 158 additions and 20 deletions.
9 changes: 3 additions & 6 deletions sql/functions/create_id_function.sql
Original file line number Diff line number Diff line change
Expand Up @@ -34,7 +34,7 @@ IF v_jobmon_schema IS NOT NULL THEN
END IF;

IF v_jobmon_schema IS NOT NULL THEN
v_job_id := add_job('PARTMON CREATE FUNCTION: '||p_parent_table);
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;

Expand Down Expand Up @@ -159,9 +159,6 @@ END IF;

IF v_jobmon_schema IS NOT NULL THEN
PERFORM close_job(v_job_id);
END IF;

IF v_jobmon_schema IS NOT NULL THEN
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;

Expand All @@ -170,8 +167,8 @@ EXCEPTION
IF v_jobmon_schema IS NOT NULL THEN
EXECUTE 'SELECT set_config(''search_path'',''part,'||v_jobmon_schema||''',''false'')';
IF v_job_id IS NULL THEN
v_job_id := add_job('PARTMON CREATE FUNCTION: '||p_parent_table);
v_step_id := add_step(v_job_id, 'Partition function maintenance for table '||p_parent_table||'failed');
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;
Expand Down
6 changes: 3 additions & 3 deletions sql/functions/create_id_partition.sql
Original file line number Diff line number Diff line change
Expand Up @@ -30,7 +30,7 @@ FOREACH v_id IN ARRAY p_partition_ids LOOP
END IF;

IF v_jobmon_schema IS NOT NULL THEN
v_job_id := add_job('PARTMON CREATE TABLE: '||p_parent_table);
v_job_id := add_job('PARTMAN CREATE TABLE: '||p_parent_table);
v_step_id := add_step(v_job_id, 'Creating new partition '||v_partition_name||' with interval from '||v_id||' to '||(v_id + p_interval)-1);
END IF;

Expand Down Expand Up @@ -60,8 +60,8 @@ EXCEPTION
IF v_jobmon_schema IS NOT NULL THEN
EXECUTE 'SELECT set_config(''search_path'',''part,'||v_jobmon_schema||''',''false'')';
IF v_job_id IS NULL THEN
v_job_id := add_job('PARTMON CREATE TABLE: '||p_parent_table);
v_step_id := add_step(v_job_id, 'Partition maintenance for table'||p_parent_table||'failed');
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
v_step_id := add_step(v_job_id, 'EXCEPTION before first step logged');
END IF;
Expand Down
67 changes: 61 additions & 6 deletions sql/functions/create_parent.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,10 +6,14 @@ DECLARE
v_current_id bigint;
v_datetime_string text;
v_id_interval bigint;
v_job_id bigint;
v_jobmon_schema text;
v_last_partition_name text;
v_old_search_path text;
v_partition_time timestamp[];
v_partition_id bigint[];
v_max text;
v_step_id bigint;
v_tablename text;
v_time_interval interval;

Expand All @@ -22,6 +26,17 @@ SELECT tablename INTO v_tablename FROM pg_tables WHERE schemaname || '.' || tabl

EXECUTE 'LOCK TABLE '||p_parent_table||' IN ACCESS EXCLUSIVE MODE';

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'',''part,'||v_jobmon_schema||''',''false'')';
END IF;

IF v_jobmon_schema IS NOT NULL THEN
v_job_id := add_job('PARTMON 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';
Expand Down Expand Up @@ -52,8 +67,6 @@ CASE
END IF;
END CASE;

EXECUTE 'SELECT max('||p_control||')::text FROM '||p_parent_table||' LIMIT 1' INTO v_max;

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_time_interval*i))::timestamp);
Expand All @@ -64,9 +77,15 @@ IF p_type = 'time-static' OR p_type = 'time-dynamic' THEN

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);

IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Time partitions premade: '||p_premake);
END IF;
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;
FOR i IN 0..p_premake LOOP
v_partition_id = array_append(v_partition_id, v_id_interval*i);
END LOOP;
Expand All @@ -76,25 +95,61 @@ IF p_type = 'id-static' OR p_type = 'id-dynamic' THEN

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);

IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'ID partitions premade: '||p_premake);
END IF;

END IF;

IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, 'Creating partition function');
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;
EXECUTE 'SELECT part.create_id_function('||quote_literal(p_parent_table)||','||v_current_id||')';
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;
END IF;

IF v_jobmon_schema IS NOT NULL THEN
v_step_id := add_step(v_job_id, 'Creating partition trigger');
END IF;

EXECUTE 'SELECT part.create_trigger('||quote_literal(p_parent_table)||')';

IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
END IF;

PERFORM close_job(v_job_id);

EXCEPTION
-- Catch if the conversion of the p_interval parameter to an integer doesn't work
WHEN invalid_text_representation THEN
RAISE EXCEPTION 'Check interval parameter to ensure it is a valid integer value for serial partitioning: %', SQLERRM;
WHEN OTHERS THEN
IF v_jobmon_schema IS NOT NULL THEN
EXECUTE 'SELECT set_config(''search_path'',''part,'||v_jobmon_schema||''',''false'')';
IF v_job_id IS NULL THEN
v_job_id := add_job('PARTMAN CREATE PARENT: '||p_parent_table);
v_step_id := add_step(v_job_id, 'Partition creation 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;
END
$$;
52 changes: 48 additions & 4 deletions sql/functions/create_time_function.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,24 +3,39 @@ CREATE OR REPLACE FUNCTION part.create_time_function(p_parent_table text) RETURN
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_1st_partition_name text;
v_1st_partition_timestamp timestamp;
v_2nd_partition_name text;
v_2nd_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'',''part,'||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
Expand Down Expand Up @@ -85,6 +100,10 @@ IF v_type = 'time-static' 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 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$
Expand Down Expand Up @@ -125,10 +144,35 @@ ELSIF v_type = 'time-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 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'',''part,'||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
$$;
44 changes: 43 additions & 1 deletion sql/functions/create_time_partition.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,15 +3,26 @@ CREATE OR REPLACE FUNCTION part.create_time_partition (p_parent_table text, p_co
AS $$
DECLARE

v_job_id bigint;
v_jobmon_schema text;
v_old_search_path text;
v_partition_name text;
v_partition_timestamp_end timestamp;
v_partition_timestamp_start timestamp;
v_step_id bigint;
v_tablename text;
v_time timestamp;

BEGIN

FOREACH v_time IN ARRAY p_partition_times LOOP
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'',''part,'||v_jobmon_schema||''',''false'')';
END IF;

FOREACH v_time IN ARRAY p_partition_times LOOP

v_partition_name := p_parent_table || '_p';

IF p_interval = '1 year' OR p_interval = '1 month' OR p_interval = '1 day' OR p_interval = '1 hour' OR p_interval = '30 mins' OR p_interval = '15 mins' THEN
Expand Down Expand Up @@ -60,6 +71,11 @@ FOREACH v_time IN ARRAY p_partition_times LOOP
CONTINUE;
END IF;

IF v_jobmon_schema IS NOT NULL THEN
v_job_id := add_job('PARTMAN CREATE TABLE: '||p_parent_table);
v_step_id := add_step(v_job_id, 'Creating new partition '||v_partition_name||' with interval from '||v_partition_timestamp_start||' to '||(v_partition_timestamp_end-'1sec'::interval));
END IF;

IF position('.' in p_parent_table) > 0 THEN
v_tablename := substring(v_partition_name from position('.' in v_partition_name)+1);
END IF;
Expand All @@ -68,9 +84,35 @@ FOREACH v_time IN ARRAY p_partition_times LOOP
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)||')';

IF v_jobmon_schema IS NOT NULL THEN
PERFORM update_step(v_step_id, 'OK', 'Done');
PERFORM close_job(v_job_id);
END IF;

END LOOP;

IF v_jobmon_schema IS NOT NULL THEN
EXECUTE 'SELECT set_config(''search_path'','''||v_old_search_path||''',''false'')';
END IF;

RETURN v_partition_name;

EXCEPTION
WHEN OTHERS THEN
IF v_jobmon_schema IS NOT NULL THEN
EXECUTE 'SELECT set_config(''search_path'',''part,'||v_jobmon_schema||''',''false'')';
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
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 c022d2e

Please sign in to comment.