-- The static partitioning trigger function can now handle partitions based on the configured premake value. For example, the default premake value is 4 so it can now handle data for the current partition, 4 previous partitions and 4 future partitions. Changing the premake value will cause the trigger function to be changed appropriately the next time a partition is automatically created. Except for initial setup, at no time does the automated partitioning system create old partitions (see the create_prev_* functions if you need to do this). If you change the premake value and there is no previous partition for it to put data in, it will go to the parent table. -- create_parent() now accounts for the new static partitioning rules. For time-static, it will create the current partition as well as previous and future partitions equal to the configured premake number (default premake being 4, you will end up with 9 partitions). For id-static, it will only create previous partitions if the resulting rules handle id values greater than zero. So if you're starting from zero you will only have future partitions created, and no previous. -- Constraint now ensures that premake value is greater than zero. -- create_parent() now ensures interval value for serial partitioning is greater than zero. -- Much more extensive pgTAP tests. ALTER TABLE @extschema@.part_config ADD CONSTRAINT positive_premake_check CHECK (premake > 0); /* * Create the trigger function for the parent table of a time-based partition set */ CREATE OR REPLACE FUNCTION create_time_function(p_parent_table text) RETURNS void LANGUAGE plpgsql SECURITY DEFINER AS $$ DECLARE v_control text; v_current_partition_name text; v_current_partition_timestamp timestamp; v_datetime_string text; v_final_partition_timestamp timestamp; v_job_id bigint; v_jobmon_schema text; v_old_search_path text; v_next_partition_name text; v_next_partition_timestamp timestamp; v_part_interval interval; v_premake int; 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'',''@extschema@,'||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 , premake , datetime_string INTO v_type , v_part_interval , v_control , v_premake , v_datetime_string FROM @extschema@.part_config WHERE parent_table = p_parent_table AND (type = 'time-static' OR type = 'time-dynamic'); IF NOT FOUND THEN RAISE EXCEPTION 'ERROR: no config found for %', p_parent_table; END IF; 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 = '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; v_current_partition_name := p_parent_table || '_p' || to_char(v_current_partition_timestamp, v_datetime_string); v_next_partition_timestamp := v_current_partition_timestamp + v_part_interval::interval; v_trig_func := 'CREATE OR REPLACE FUNCTION '||p_parent_table||'_part_trig_func() RETURNS trigger LANGUAGE plpgsql AS $t$ BEGIN IF TG_OP = ''INSERT'' THEN IF NEW.'||v_control||' >= '||quote_literal(v_current_partition_timestamp)||' AND NEW.'||v_control||' < '||quote_literal(v_next_partition_timestamp)|| ' THEN INSERT INTO '||v_current_partition_name||' VALUES (NEW.*); '; FOR i IN 1..v_premake LOOP v_prev_partition_timestamp := v_current_partition_timestamp - (v_part_interval::interval * i); v_next_partition_timestamp := v_current_partition_timestamp + (v_part_interval::interval * i); v_final_partition_timestamp := v_next_partition_timestamp + (v_part_interval::interval); v_prev_partition_name := p_parent_table || '_p' || to_char(v_prev_partition_timestamp, v_datetime_string); v_next_partition_name := p_parent_table || '_p' || to_char(v_next_partition_timestamp, v_datetime_string); v_trig_func := v_trig_func ||' ELSIF NEW.'||v_control||' >= '||quote_literal(v_prev_partition_timestamp)||' AND NEW.'||v_control||' < '|| quote_literal(v_prev_partition_timestamp + v_part_interval::interval)|| ' THEN INSERT INTO '||v_prev_partition_name||' VALUES (NEW.*); ELSIF NEW.'||v_control||' >= '||quote_literal(v_next_partition_timestamp)||' AND NEW.'||v_control||' < '|| quote_literal(v_final_partition_timestamp)|| ' THEN INSERT INTO '||v_next_partition_name||' VALUES (NEW.*); '; END LOOP; v_trig_func := v_trig_func ||' ELSE RETURN NEW; END IF; END IF; RETURN NULL; END $t$;'; 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_final_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$ DECLARE v_count int; v_partition_name text; v_partition_timestamp timestamp; v_schemaname text; v_tablename text; BEGIN IF TG_OP = ''INSERT'' THEN '; CASE WHEN v_part_interval = '15 mins' THEN v_trig_func := v_trig_func||'v_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_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_partition_timestamp := date_trunc(''hour'', NEW.'||v_control||');'; WHEN v_part_interval = '1 day' THEN v_trig_func := v_trig_func||'v_partition_timestamp := date_trunc(''day'', NEW.'||v_control||');'; WHEN v_part_interval = '1 week' 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; v_trig_func := v_trig_func||' v_partition_name := '''||p_parent_table||'_p''|| to_char(v_partition_timestamp, '||quote_literal(v_datetime_string)||'); v_schemaname := split_part(v_partition_name, ''.'', 1); v_tablename := split_part(v_partition_name, ''.'', 2); SELECT count(*) INTO v_count FROM pg_tables WHERE schemaname = v_schemaname AND tablename = v_tablename; IF v_count > 0 THEN EXECUTE ''INSERT INTO ''||v_partition_name||'' VALUES($1.*)'' USING NEW; ELSE RETURN NEW; END IF; END IF; RETURN NULL; END $t$;'; 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'',''@extschema@,'||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 $$; /* * Create the trigger function for the parent table of an id-based partition set */ CREATE OR REPLACE FUNCTION create_id_function(p_parent_table text, p_current_id bigint) RETURNS void LANGUAGE plpgsql SECURITY DEFINER AS $$ DECLARE v_control text; v_current_partition_name text; v_current_partition_id bigint; v_datetime_string text; v_final_partition_id bigint; v_job_id bigint; v_jobmon_schema text; v_last_partition text; v_next_partition_id bigint; v_next_partition_name text; v_old_search_path text; v_part_interval bigint; v_premake int; v_prev_partition_id bigint; v_prev_partition_name text; 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'',''@extschema@,'||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::bigint , control , premake , last_partition INTO v_type , v_part_interval , v_control , v_premake , v_last_partition FROM @extschema@.part_config WHERE parent_table = p_parent_table AND (type = 'id-static' OR type = 'id-dynamic'); 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_next_partition_id := v_current_partition_id + v_part_interval; v_current_partition_name := p_parent_table || '_p' || v_current_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_next_partition_id|| ' THEN INSERT INTO '||v_current_partition_name||' VALUES (NEW.*); '; FOR i IN 1..v_premake LOOP v_prev_partition_id := v_current_partition_id - (v_part_interval * i); v_next_partition_id := v_current_partition_id + (v_part_interval * i); v_final_partition_id := v_next_partition_id + v_part_interval; v_prev_partition_name := p_parent_table || '_p' || v_prev_partition_id::text; v_next_partition_name := p_parent_table || '_p' || v_next_partition_id::text; -- Only make previous partitions if they're starting above zero 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_prev_partition_id + v_part_interval|| ' THEN INSERT INTO '||v_prev_partition_name||' VALUES (NEW.*); '; END IF; v_trig_func := v_trig_func ||' ELSIF NEW.'||v_control||' >= '||v_next_partition_id||' AND NEW.'||v_control||' < '||v_final_partition_id|| ' THEN INSERT INTO '||v_next_partition_name||' VALUES (NEW.*); '; END LOOP; v_trig_func := v_trig_func ||' ELSE RETURN NEW; 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) / '||v_part_interval||') <= '||v_premake||' THEN v_next_partition_name := @extschema@.create_id_partition('||quote_literal(p_parent_table)||', '||quote_literal(v_control)||',' ||v_part_interval||', ARRAY[v_next_partition_id]); UPDATE @extschema@.part_config SET last_partition = v_next_partition_name WHERE parent_table = '||quote_literal(p_parent_table)||'; PERFORM @extschema@.create_id_function('||quote_literal(p_parent_table)||', NEW.'||v_control||'); END IF; END IF; END IF; RETURN NULL; END $t$;'; EXECUTE v_trig_func; IF v_jobmon_schema IS NOT NULL THEN PERFORM update_step(v_step_id, 'OK', 'Added function for current id interval: '||v_current_partition_id||' to '||v_final_partition_id-1); END IF; 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_count int; v_current_partition_id bigint; v_current_partition_name text; v_last_partition text := '||quote_literal(v_last_partition)||'; v_last_partition_id bigint; v_next_partition_id bigint; v_next_partition_name text; v_schemaname text; v_tablename text; BEGIN IF TG_OP = ''INSERT'' THEN v_current_partition_id := NEW.'||v_control||' - (NEW.'||v_control||' % '||v_part_interval||'); v_current_partition_name := '''||p_parent_table||'_p''||v_current_partition_id; IF (NEW.'||v_control||' % '||v_part_interval||') > ('||v_part_interval||' / 2) THEN v_last_partition_id = substring(v_last_partition from char_length('||quote_literal(p_parent_table||'_p')||')+1)::bigint; v_next_partition_id := v_last_partition_id + '||v_part_interval||'; IF NEW.'||v_control||' >= v_next_partition_id THEN RETURN NEW; END IF; IF ((v_next_partition_id - v_current_partition_id) / '||quote_literal(v_part_interval)||') <= '||quote_literal(v_premake)||' THEN v_next_partition_name := @extschema@.create_id_partition('||quote_literal(p_parent_table)||', '||quote_literal(v_control)||',' ||quote_literal(v_part_interval)||', ARRAY[v_next_partition_id]); IF v_next_partition_name IS NOT NULL THEN UPDATE @extschema@.part_config SET last_partition = v_next_partition_name WHERE parent_table = '||quote_literal(p_parent_table)||'; PERFORM @extschema@.create_id_function('||quote_literal(p_parent_table)||', NEW.'||v_control||'); END IF; END IF; END IF; v_schemaname := split_part(v_current_partition_name, ''.'', 1); v_tablename := split_part(v_current_partition_name, ''.'', 2); SELECT count(*) INTO v_count FROM pg_tables WHERE schemaname = v_schemaname AND tablename = v_tablename; IF v_count > 0 THEN EXECUTE ''INSERT INTO ''||v_current_partition_name||'' VALUES($1.*)'' USING NEW; ELSE RETURN NEW; END IF; END IF; RETURN NULL; END $t$;'; 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; ELSE RAISE EXCEPTION 'ERROR: Invalid id 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'',''@extschema@,'||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 $$; /* * Function to turn a table into the parent of a partition set */ CREATE OR REPLACE FUNCTION create_parent(p_parent_table text, p_control text, p_type text, p_interval text, p_premake int DEFAULT 4, p_debug boolean DEFAULT false) RETURNS void LANGUAGE plpgsql SECURITY DEFINER AS $$ 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 bigint; v_notnull boolean; v_starting_partition_id bigint; v_step_id bigint; v_tablename text; v_time_interval interval; BEGIN IF position('.' in p_parent_table) = 0 THEN RAISE EXCEPTION 'Parent table must be schema qualified'; END IF; SELECT tablename INTO v_tablename FROM pg_tables WHERE schemaname || '.' || tablename = p_parent_table; IF v_tablename IS NULL THEN RAISE EXCEPTION 'Please create given parent table first: %', p_parent_table; END IF; SELECT attnotnull INTO v_notnull FROM pg_attribute WHERE attrelid = p_parent_table::regclass AND attname = p_control; IF v_notnull = false THEN RAISE EXCEPTION 'Control column (%) for parent table (%) must be NOT NULL', p_control, p_parent_table; END IF; 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'',''@extschema@,'||v_jobmon_schema||''',''false'')'; END IF; IF v_jobmon_schema IS NOT NULL THEN 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'; WHEN p_interval = 'weekly' THEN v_time_interval = '1 week'; v_datetime_string := 'IYYY"w"IW'; WHEN p_interval = 'daily' THEN v_time_interval = '1 day'; v_datetime_string := 'YYYY_MM_DD'; WHEN p_interval = 'hourly' THEN v_time_interval = '1 hour'; v_datetime_string := 'YYYY_MM_DD_HH24MI'; WHEN p_interval = 'half-hour' THEN v_time_interval = '30 mins'; v_datetime_string := 'YYYY_MM_DD_HH24MI'; WHEN p_interval = 'quarter-hour' THEN v_time_interval = '15 mins'; v_datetime_string := 'YYYY_MM_DD_HH24MI'; ELSE IF p_type = 'id-static' OR p_type = 'id-dynamic' THEN v_id_interval := p_interval::bigint; IF v_id_interval <= 0 THEN RAISE EXCEPTION 'Interval for serial partitioning must be greater than zero'; END IF; ELSE RAISE EXCEPTION 'Invalid interval for time based partitioning: %', p_interval; END IF; END CASE; IF p_type = 'time-static' OR p_type = 'time-dynamic' THEN FOR i IN 0..p_premake LOOP IF i > 0 THEN -- also create previous partitions equal to premake, but avoid duplicating current v_partition_time := array_append(v_partition_time, quote_literal(CURRENT_TIMESTAMP - (v_time_interval*i))::timestamp); END IF; v_partition_time := array_append(v_partition_time, quote_literal(CURRENT_TIMESTAMP + (v_time_interval*i))::timestamp); END LOOP; INSERT INTO @extschema@.part_config (parent_table, type, part_interval, control, premake, datetime_string) VALUES (p_parent_table, p_type, v_time_interval, p_control, p_premake, v_datetime_string); EXECUTE 'SELECT @extschema@.create_time_partition('||quote_literal(p_parent_table)||','||quote_literal(p_control)||',' ||quote_literal(v_time_interval)||','||quote_literal(v_datetime_string)||','||quote_literal(v_partition_time)||')' INTO v_last_partition_name; -- Doing separate update because create function needs parent table in config table for apply_grants() UPDATE @extschema@.part_config SET last_partition = v_last_partition_name WHERE parent_table = p_parent_table; 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 -- 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 -- Only make previous partitions if ID value is less than the starting value and positive IF (v_starting_partition_id - (v_id_interval*i)) > 0 AND (v_starting_partition_id - (v_id_interval*i)) < v_starting_partition_id THEN v_partition_id = array_append(v_partition_id, (v_starting_partition_id - v_id_interval*i)); END IF; v_partition_id = array_append(v_partition_id, (v_id_interval*i) + v_starting_partition_id); END LOOP; INSERT INTO @extschema@.part_config (parent_table, type, part_interval, control, premake) VALUES (p_parent_table, p_type, v_id_interval, p_control, p_premake); EXECUTE 'SELECT @extschema@.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; -- Doing separate update because create function needs parent table in config table for apply_grants() UPDATE @extschema@.part_config SET last_partition = v_last_partition_name WHERE parent_table = p_parent_table; 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 @extschema@.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 v_current_id := COALESCE(v_max, 0); EXECUTE 'SELECT @extschema@.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 @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; EXCEPTION WHEN OTHERS THEN IF v_jobmon_schema IS NOT NULL THEN EXECUTE 'SELECT set_config(''search_path'',''@extschema@,'||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; RAISE EXCEPTION '%', SQLERRM; END $$;