CREATE TEMP TABLE partman_preserve_privs_temp (statement text); INSERT INTO partman_preserve_privs_temp SELECT 'GRANT EXECUTE ON FUNCTION @extschema@.partition_data_time(text, int, interval, numeric, text, boolean, text, text[], boolean) TO '||array_to_string(array_agg('"'||grantee::text||'"'), ',')||';' FROM information_schema.routine_privileges WHERE routine_schema = '@extschema@' AND routine_name = 'partition_data_time' AND grantee != 'PUBLIC'; INSERT INTO partman_preserve_privs_temp SELECT 'GRANT EXECUTE ON FUNCTION @extschema@.partition_data_id(text, int, bigint, numeric, text, boolean, text, text[], boolean) TO '||array_to_string(array_agg('"'||grantee::text||'"'), ',')||';' FROM information_schema.routine_privileges WHERE routine_schema = '@extschema@' AND routine_name = 'partition_data_id' AND grantee != 'PUBLIC'; INSERT INTO partman_preserve_privs_temp SELECT 'GRANT EXECUTE ON FUNCTION @extschema@.create_parent(text, text, text, text, text, int, text, boolean, text, text[], text, boolean, text, boolean, text, text, bigint) TO '||array_to_string(array_agg('"'||grantee::text||'"'), ',')||';' FROM information_schema.routine_privileges WHERE routine_schema = '@extschema@' AND routine_name = 'create_parent' AND grantee != 'PUBLIC'; INSERT INTO partman_preserve_privs_temp SELECT 'GRANT EXECUTE ON FUNCTION @extschema@.show_partition_info(text, text, text, boolean) TO '||array_to_string(array_agg('"'||grantee::text||'"'), ',')||';' FROM information_schema.routine_privileges WHERE routine_schema = '@extschema@' AND routine_name = 'show_partition_info' AND grantee != 'PUBLIC'; ALTER TABLE @extschema@.part_config ADD COLUMN async_partitioning_in_progress text; DROP FUNCTION @extschema@.partition_data_time(text, int, interval, numeric, text, boolean, text, text[]); DROP FUNCTION @extschema@.partition_data_id(text, int, bigint, numeric, text, boolean, text, text[]); DROP FUNCTION @extschema@.create_parent(text, text, text, text, text, int, text, boolean, text, text[], text, boolean, text, boolean, text, text); DROP FUNCTION @extschema@.show_partition_info(text, text, text); CREATE PROCEDURE @extschema@.partition_data_async ( p_parent_table text , p_loop_count int DEFAULT NULL , p_interval text DEFAULT NULL , p_lock_wait int DEFAULT 0 , p_lock_wait_tries int DEFAULT 10 , p_wait int DEFAULT 1 , p_order text DEFAULT 'ASC' , p_ignored_columns text[] DEFAULT NULL , p_quiet boolean DEFAULT false ) LANGUAGE plpgsql AS $$ DECLARE v_adv_lock boolean; v_analyze boolean; v_async_partitioning_in_progress text; v_column_list_filtered text; v_control text; v_control_type text; v_default_batch_max_timestamp timestamptz; v_default_batch_min_timestamp timestamptz; v_default_interval text; v_default_schemaname text; v_default_tablename text; v_epoch text; v_lock_iter int; v_lock_obtained boolean := FALSE; v_loop_count int := 0; v_parent_schemaname text; v_parent_tablename text; v_partition_expression text; v_run_cleanup boolean; v_sql text; v_target_child_max_timestamp timestamptz; v_target_child_min_timestamp timestamptz; v_target_child_schemaname text; v_target_child_tablename text; v_temp_batch_min_timestamp timestamptz; v_temp_count int; v_temp_exists text; v_temp_storage_table text; BEGIN v_adv_lock := pg_try_advisory_xact_lock(hashtext('pg_partman partition_data_async'), hashtext(p_parent_table)); IF v_adv_lock = 'false' THEN RAISE NOTICE 'Partman partition_data_async already running for given parent table: %.', p_parent_table; RETURN; END IF; SELECT control, epoch, partition_interval, async_partitioning_in_progress INTO v_control, v_epoch, v_default_interval, v_async_partitioning_in_progress FROM @extschema@.part_config WHERE parent_table = p_parent_table; IF NOT FOUND THEN RAISE EXCEPTION 'ERROR: No entry in part_config found for given table: %', p_parent_table; END IF; SELECT n.nspname, c.relname INTO v_parent_schemaname, v_parent_tablename FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = split_part(p_parent_table, '.', 1)::name AND c.relname = split_part(p_parent_table, '.', 2)::name; IF v_parent_tablename IS NULL THEN RAISE EXCEPTION 'Unable to find given parent table in system catalogs. Ensure it is schema qualified: %', p_parent_table; END IF; IF p_order <> 'ASC' THEN RAISE EXCEPTION 'Async partitioning currently only supports going in ascending order for data migration'; END IF; SELECT general_type INTO v_control_type FROM @extschema@.check_control_type(v_parent_schemaname, v_parent_tablename, v_control); IF v_control_type = 'id' AND v_epoch <> 'none' THEN v_control_type := 'time'; ELSIF v_control_type != 'time' THEN RAISE EXCEPTION 'Asyncronous partitioning currently only works with time-based partitioning. ID/Integer/UUID support is in development'; END IF; SELECT n.nspname::text, c.relname::text INTO v_default_schemaname, v_default_tablename FROM pg_catalog.pg_inherits h JOIN pg_catalog.pg_class c ON c.oid = h.inhrelid JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE h.inhparent = format('%I.%I', v_parent_schemaname, v_parent_tablename)::regclass AND pg_get_expr(relpartbound, c.oid) = 'DEFAULT'; IF v_default_tablename IS NULL THEN RAISE EXCEPTION 'Default table not found for given partition set: %', p_parent_table; END IF; v_temp_storage_table := format('%I.%I', v_parent_schemaname, 'partman_tmp_storage_' || v_parent_tablename ); -- Generate filtered column list to use in SELECT/INSERT statements below. Allows for exclusion of GENERATED (or any other desired) columns. -- TODO turn this into a function along with the full column list in other functions SELECT string_agg(quote_ident(attname), ',') INTO v_column_list_filtered FROM pg_catalog.pg_attribute a JOIN pg_catalog.pg_class c ON a.attrelid = c.oid JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = v_default_schemaname AND c.relname = v_default_tablename AND a.attnum > 0 AND a.attisdropped = false AND attname <> ALL(COALESCE(p_ignored_columns, ARRAY[]::text[])); IF v_control_type = 'time' THEN IF p_interval::interval >= v_default_interval::interval THEN RAISE EXCEPTION 'The given interval (%) is greater than or equal to this partition set''s default interval (%). Please use a non-async partitioning function or procedure for a much simpler process to partition your data', p_interval, v_default_interval; END IF; --TODO turn this into a function v_partition_expression := CASE WHEN v_epoch = 'seconds' THEN format('to_timestamp(%I)', v_control) WHEN v_epoch = 'milliseconds' THEN format('to_timestamp((%I/1000)::float)', v_control) WHEN v_epoch = 'microseconds' THEN format('to_timestamp((%I/1000000)::float)', v_control) WHEN v_epoch = 'nanoseconds' THEN format('to_timestamp((%I/1000000000)::float)', v_control) ELSE format('%I', v_control) END; EXECUTE format('SELECT min(%s) FROM ONLY %I.%I', v_partition_expression, v_default_schemaname, v_default_tablename) INTO v_default_batch_min_timestamp; RAISE DEBUG 'partition_data_async: v_default_batch_min_timestamp: %', v_default_batch_min_timestamp; SELECT format('%I.%I)', n.nspname, c.relname) INTO v_temp_exists FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = v_parent_schemaname AND c.relname = 'partman_tmp_storage_' || v_parent_tablename; IF v_default_batch_min_timestamp IS NOT NULL THEN -- only need to do this stuff once v_run_cleanup := true; IF v_temp_exists IS NOT NULL AND v_async_partitioning_in_progress IS NULL THEN RAISE EXCEPTION 'Found an already existing temporary storage table (%) for managing async partitioning for the partition set given: %. However this partition set was not marked as being in progress for an existing async partitioning operation. This is an unexpected condition and means a previous async partitioning operation may not have been completed properly. Please review the contents of the given temporary working table and make sure there is no data missing from the partition set before proceeding with further partitioning operations.', v_temp_exists, p_parent_table; ELSE v_sql := format ('CREATE TABLE IF NOT EXISTS %s (LIKE %I.%I INCLUDING INDEXES)', v_temp_storage_table, v_parent_schemaname, v_parent_tablename); RAISE DEBUG 'partition_data_async: v_sql: %', v_sql; EXECUTE v_sql; END IF; ELSE RAISE NOTICE 'No data found in target partition set default table: %', p_parent_table; RETURN; END IF; <> WHILE (v_default_batch_min_timestamp IS NOT NULL OR v_async_partitioning_in_progress IS NOT NULL) LOOP IF v_async_partitioning_in_progress IS NOT NULL THEN v_target_child_min_timestamp := v_async_partitioning_in_progress::timestamptz; v_target_child_max_timestamp := v_target_child_min_timestamp + v_default_interval::interval; ELSE v_async_partitioning_in_progress := v_target_child_min_timestamp::text; END IF; UPDATE @extschema@.part_config SET async_partitioning_in_progress = v_target_child_min_timestamp::text WHERE parent_table = p_parent_table; v_default_batch_max_timestamp := v_default_batch_min_timestamp + p_interval::interval; RAISE DEBUG 'partiton_data_async: before first condition in loop - v_target_child_min_timestamp: %, v_target_child_max_timestamp: %, v_default_batch_max_timestamp: %, v_default_batch_min_timestamp: %', v_target_child_min_timestamp, v_target_child_max_timestamp, v_default_batch_max_timestamp, v_default_batch_min_timestamp; IF v_target_child_min_timestamp IS NOT NULL AND v_target_child_max_timestamp IS NOT NULL AND v_target_child_tablename IS NOT NULL THEN IF v_default_batch_min_timestamp >= v_target_child_max_timestamp OR v_default_batch_min_timestamp IS NULL THEN /* If first condition is true, there should be no data left in the default that would fit in the current target child table due to actions below to reset the batch max value. This should then allow the child table to be created. OR if second condition is true and default_batch_min is NULL there still stuff left in the temp table to clean up */ -- Get temp table minimum to start loop v_temp_batch_min_timestamp := NULL; -- Just to be sure EXECUTE format('SELECT min(%s) FROM ONLY %s', v_partition_expression, v_temp_storage_table) INTO v_temp_batch_min_timestamp; RAISE DEBUG 'partition_data_async: before loop to move data out of temp - v_temp_batch_min_timestamp: %', v_temp_batch_min_timestamp; v_analyze := @extschema@.create_partition_time(p_parent_table, ARRAY[v_target_child_min_timestamp]); WHILE v_temp_batch_min_timestamp IS NOT NULL LOOP -- start batch transaction to move data from temp to real child table v_sql := format('WITH partition_data AS ( DELETE FROM %1$s WHERE %2$s >= %3$L AND %2$s < %4$L RETURNING *) INSERT INTO %5$I.%6$I (%7$s) SELECT %7$s FROM partition_data' , v_temp_storage_table , v_partition_expression , v_temp_batch_min_timestamp , v_temp_batch_min_timestamp + p_interval::interval , v_target_child_schemaname , v_target_child_tablename , v_column_list_filtered); RAISE DEBUG 'partition_data_async | move data from temp to real child: %', v_sql; EXECUTE v_sql; v_loop_count := v_loop_count + 1; COMMIT; -- end batch transaction to move data from temp to real child table EXECUTE format('SELECT min(%s) FROM ONLY %s', v_partition_expression, v_temp_storage_table) INTO v_temp_batch_min_timestamp; RAISE DEBUG 'partition_data_async: inside loop to move data out of temp - v_temp_batch_min_timestamp: %', v_temp_batch_min_timestamp; EXIT WHEN p_loop_count > 0 AND v_loop_count >= p_loop_count; END LOOP; -- End inner loop to move data out of temp to real child table IF v_temp_batch_min_timestamp IS NULL THEN v_target_child_max_timestamp := NULL; v_target_child_min_timestamp := NULL; v_target_child_schemaname := NULL; v_target_child_tablename := NULL; -- If all batches for a given child have been completed, ensure async mode has been disabled UPDATE @extschema@.part_config SET async_partitioning_in_progress = NULL WHERE parent_table = p_parent_table; v_async_partitioning_in_progress := NULL; END IF; EXIT outer_loop WHEN p_loop_count > 0 AND v_loop_count >= p_loop_count; CONTINUE outer_loop; ELSIF v_default_batch_max_timestamp >= v_target_child_max_timestamp THEN v_default_batch_max_timestamp := v_target_child_max_timestamp; END IF; IF p_lock_wait > 0 THEN v_lock_iter := 0; WHILE v_lock_iter <= 5 LOOP v_lock_iter := v_lock_iter + 1; RAISE DEBUG 'lock wait: v_lock_iter: %, v_lock_obtained: %', v_lock_iter, v_lock_obtained; BEGIN EXECUTE format('SELECT %s FROM ONLY %I.%I WHERE %s >= %L AND %4$s < %6$L FOR UPDATE NOWAIT' , v_column_list_filtered , v_default_schemaname , v_default_tablename , v_partition_expression , v_default_batch_min_timestamp , v_default_batch_max_timestamp); v_lock_obtained := TRUE; EXCEPTION WHEN lock_not_available THEN PERFORM pg_sleep( p_lock_wait / 5.0 ); CONTINUE; END; EXIT WHEN v_lock_obtained; END LOOP; IF NOT v_lock_obtained THEN RAISE EXCEPTION 'Quitting due to inability to get lock on next batch of rows to be moved'; END IF; END IF; -- start batch transaction to move data from default to temp EXECUTE format('WITH partition_data AS ( DELETE FROM %1$I.%2$I WHERE %3$s >= %4$L AND %3$s < %5$L RETURNING *) INSERT INTO %6$s (%7$s) SELECT %7$s FROM partition_data' , v_default_schemaname , v_default_tablename , v_partition_expression , v_default_batch_min_timestamp , v_default_batch_max_timestamp , v_temp_storage_table , v_column_list_filtered); COMMIT; -- end batch transaction to move data from default to temp v_loop_count := v_loop_count + 1; ELSE -- Only set these if target child table has yet to be determined or one was just created and these were reset EXECUTE format('SELECT min(%s) FROM ONLY %s', v_partition_expression, v_temp_storage_table) INTO v_temp_batch_min_timestamp; RAISE DEBUG 'partition_data_async: v_temp_batch_min_timestamp: %, v_target_child_min_timestamp: %, v_target_child_max_timestamp: %', v_temp_batch_min_timestamp, v_target_child_min_timestamp, v_target_child_max_timestamp; IF v_temp_batch_min_timestamp IS NOT NULL THEN SELECT partition_schema, partition_table INTO v_target_child_schemaname, v_target_child_tablename FROM @extschema@.show_partition_name(p_parent_table, v_temp_batch_min_timestamp::text); ELSE SELECT partition_schema, partition_table INTO v_target_child_schemaname, v_target_child_tablename FROM @extschema@.show_partition_name(p_parent_table, v_default_batch_min_timestamp::text); END IF; RAISE DEBUG 'partition_data_async: v_target_child_schemaname: %, v_target_child_tablename: % ', v_target_child_schemaname, v_target_child_tablename; SELECT child_start_time, child_end_time INTO v_target_child_min_timestamp, v_target_child_max_timestamp FROM @extschema@.show_partition_info(v_target_child_tablename, p_parent_table := p_parent_table, p_table_exists := FALSE); END IF; EXECUTE format('SELECT min(%s) FROM ONLY %I.%I', v_partition_expression, v_default_schemaname, v_default_tablename) INTO v_default_batch_min_timestamp; IF p_loop_count > 0 AND v_loop_count >= p_loop_count THEN EXIT; END IF; END LOOP outer_loop; -- end outer loop to move data from default to temp ELSIF v_control_type = 'id' THEN -- Under development -- ELSE RAISE EXCEPTION 'partition_data_async: Unknown control type encountered: %. Please report this error with how you got to this code path.', v_control_type; END IF; IF v_run_cleanup THEN IF v_async_partitioning_in_progress IS NULL THEN v_sql := format ('DROP TABLE IF EXISTS %s', v_temp_storage_table); RAISE DEBUG 'partition_data_async: v_sql %', v_sql; EXECUTE v_sql; END IF; END IF; END $$; CREATE OR REPLACE PROCEDURE @extschema@.partition_data_proc ( p_parent_table text , p_loop_count int DEFAULT NULL , p_interval text DEFAULT NULL , p_lock_wait int DEFAULT 0 , p_lock_wait_tries int DEFAULT 10 , p_wait int DEFAULT 1 , p_order text DEFAULT 'ASC' , p_source_table text DEFAULT NULL , p_ignored_columns text[] DEFAULT NULL , p_quiet boolean DEFAULT false ) LANGUAGE plpgsql AS $$ DECLARE v_adv_lock boolean; v_control text; v_control_type text; v_epoch text; v_is_autovac_off boolean := false; v_lockwait_count int := 0; v_loop_count int := 0; v_parent_schemaname text; v_parent_tablename text; v_rows_moved bigint; v_source_schemaname text; v_source_tablename text; v_sql text; v_total bigint := 0; BEGIN v_adv_lock := pg_try_advisory_xact_lock(hashtext('pg_partman partition_data_proc'), hashtext(p_parent_table)); IF v_adv_lock = 'false' THEN RAISE NOTICE 'Partman partition_data_proc already running for given parent table: %.', p_parent_table; RETURN; END IF; SELECT control, epoch INTO v_control, v_epoch FROM @extschema@.part_config WHERE parent_table = p_parent_table; IF NOT FOUND THEN RAISE EXCEPTION 'ERROR: No entry in part_config found for given table: %', p_parent_table; END IF; SELECT n.nspname, c.relname INTO v_parent_schemaname, v_parent_tablename FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = split_part(p_parent_table, '.', 1)::name AND c.relname = split_part(p_parent_table, '.', 2)::name; IF v_parent_tablename IS NULL THEN RAISE EXCEPTION 'Unable to find given parent table in system catalogs. Ensure it is schema qualified: %', p_parent_table; END IF; IF p_source_table IS NOT NULL THEN SELECT n.nspname, c.relname INTO v_source_schemaname, v_source_tablename FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = split_part(p_source_table, '.', 1)::name AND c.relname = split_part(p_source_table, '.', 2)::name; IF v_source_tablename IS NULL THEN RAISE EXCEPTION 'Unable to find given source table in system catalogs. Ensure it is schema qualified: %', p_source_table; END IF; END IF; SELECT general_type INTO v_control_type FROM @extschema@.check_control_type(v_parent_schemaname, v_parent_tablename, v_control); IF v_control_type = 'id' AND v_epoch <> 'none' THEN v_control_type := 'time'; END IF; /* -- Currently no way to catch exception and reset autovac settings back to normal. Until I can do that, leaving this feature out for now -- Leaving the functions to turn off/reset in to let people do that manually if desired IF p_autovacuum_on = false THEN -- Add this parameter back to definition when this is working -- Turn off autovac for parent, source table if set, and all child tables v_is_autovac_off := @extschema@.autovacuum_off(v_parent_schemaname, v_parent_tablename, v_source_schema, v_source_tablename); COMMIT; END IF; */ v_sql := format('SELECT %s.partition_data_%s (p_parent_table := %L , p_lock_wait := %L , p_order := %L , p_analyze := false' , '@extschema@', v_control_type, p_parent_table, p_lock_wait, p_order); IF p_interval IS NOT NULL THEN v_sql := v_sql || format(', p_batch_interval := %L', p_interval); END IF; IF p_source_table IS NOT NULL THEN v_sql := v_sql || format(', p_source_table := %L', p_source_table); END IF; IF p_ignored_columns IS NOT NULL THEN v_sql := v_sql || format(', p_ignored_columns := %L', p_ignored_columns); END IF; v_sql := v_sql || ')'; RAISE DEBUG 'partition_data sql: %', v_sql; LOOP EXECUTE v_sql INTO v_rows_moved; -- If lock wait timeout, do not increment the counter IF v_rows_moved != -1 THEN v_loop_count := v_loop_count + 1; v_total := v_total + v_rows_moved; v_lockwait_count := 0; ELSE v_lockwait_count := v_lockwait_count + 1; IF v_lockwait_count > p_lock_wait_tries THEN RAISE EXCEPTION 'Quitting due to inability to get lock on next batch of rows to be moved'; END IF; END IF; IF p_quiet = false THEN IF v_rows_moved > 0 THEN RAISE NOTICE 'Loop: %, Rows moved: %', v_loop_count, v_rows_moved; ELSIF v_rows_moved = -1 THEN RAISE NOTICE 'Unable to obtain row locks for data to be moved. Trying again...'; END IF; END IF; -- If no rows left or given loop argument limit is reached IF v_rows_moved = 0 OR (p_loop_count > 0 AND v_loop_count >= p_loop_count) THEN EXIT; END IF; COMMIT; PERFORM pg_sleep(p_wait); RAISE DEBUG 'v_rows_moved: %, v_loop_count: %, v_total: %, v_lockwait_count: %, p_wait: %', p_wait, v_rows_moved, v_loop_count, v_total, v_lockwait_count; END LOOP; /* IF v_is_autovac_off = true THEN -- Reset autovac back to default if it was turned off by this procedure PERFORM @extschema@.autovacuum_reset(v_parent_schemaname, v_parent_tablename, v_source_schema, v_source_tablename); COMMIT; END IF; */ IF p_quiet = false THEN RAISE NOTICE 'Total rows moved: %', v_total; END IF; RAISE NOTICE 'Ensure to VACUUM ANALYZE the parent (and source table if used) after partitioning data'; /* Leaving here until I can figure out what's wrong with procedures and exception handling EXCEPTION WHEN QUERY_CANCELED THEN ROLLBACK; -- Reset autovac back to default if it was turned off by this procedure IF v_is_autovac_off = true THEN PERFORM @extschema@.autovacuum_reset(v_parent_schema, v_parent_tablename, v_source_schema, v_source_tablename); END IF; RAISE EXCEPTION '%', SQLERRM; WHEN OTHERS THEN ROLLBACK; -- Reset autovac back to default if it was turned off by this procedure IF v_is_autovac_off = true THEN PERFORM @extschema@.autovacuum_reset(v_parent_schema, v_parent_tablename, v_source_schema, v_source_tablename); END IF; RAISE EXCEPTION '%', SQLERRM; */ END; $$; CREATE FUNCTION @extschema@.partition_data_time( p_parent_table text , p_batch_count int DEFAULT 1 , p_batch_interval interval DEFAULT NULL , p_lock_wait numeric DEFAULT 0 , p_order text DEFAULT 'ASC' , p_analyze boolean DEFAULT true , p_source_table text DEFAULT NULL , p_ignored_columns text[] DEFAULT NULL , p_override_system_value boolean DEFAULT false ) RETURNS bigint LANGUAGE plpgsql AS $$ DECLARE v_analyze boolean := FALSE; v_async_rowcount int; v_column_list_filtered text; v_column_list_full text; v_control text; v_control_type text; v_datetime_string text; v_current_partition_name text; v_default_exists boolean; v_default_schemaname text; v_default_tablename text; v_epoch text; v_last_partition text; v_lock_iter int := 1; v_lock_obtained boolean := FALSE; v_max_partition_timestamp timestamptz; v_min_partition_timestamp timestamptz; v_override_statement text; v_parent_schemaname text; v_parent_tablename text; v_partition_expression text; v_partition_interval interval; v_partition_suffix text; v_partition_timestamp timestamptz[]; v_source_schemaname text; v_source_tablename text; v_rowcount bigint; v_start_control timestamptz; v_temp_storage_table text; v_time_encoder text; v_time_decoder text; v_total_rows bigint := 0; BEGIN /* * Populate the child table(s) of a time-based partition set with data from the default or a source table */ SELECT partition_interval::interval , control , time_encoder , time_decoder , datetime_string , epoch INTO v_partition_interval , v_control , v_time_encoder , v_time_decoder , v_datetime_string , v_epoch FROM @extschema@.part_config WHERE parent_table = p_parent_table; IF NOT FOUND THEN RAISE EXCEPTION 'ERROR: No entry in part_config found for given table: %', p_parent_table; END IF; --TODO this was setting parent table as source back during trigger-based. -- Probably don't need to do that anymore and can simplify this without needing to preserve the parent table names since those -- will never be the source -- TODO Also do this for ID partitioning SELECT schemaname, tablename INTO v_source_schemaname, v_source_tablename FROM pg_catalog.pg_tables WHERE schemaname = split_part(p_parent_table, '.', 1)::name AND tablename = split_part(p_parent_table, '.', 2)::name; -- Preserve real parent tablename for use below v_parent_schemaname := v_source_schemaname; v_parent_tablename := v_source_tablename; SELECT general_type INTO v_control_type FROM @extschema@.check_control_type(v_source_schemaname, v_source_tablename, v_control); IF v_control_type <> 'time' THEN IF (v_control_type = 'id' AND v_epoch = 'none') OR v_control_type NOT IN ('text', 'id', 'uuid') OR (v_control_type IN ('text', 'uuid') AND v_time_encoder IS NULL) THEN RAISE EXCEPTION 'Cannot run on partition set without time based control column, an epoch flag set with an id column or time_encoder set with text column. Found control: %, epoch: %, time_encoder: %s', v_control_type, v_epoch, v_time_encoder; END IF; END IF; SELECT n.nspname::text, c.relname::text INTO v_default_schemaname, v_default_tablename FROM pg_catalog.pg_inherits h JOIN pg_catalog.pg_class c ON c.oid = h.inhrelid JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE h.inhparent = format('%I.%I', v_source_schemaname, v_source_tablename)::regclass AND pg_get_expr(relpartbound, c.oid) = 'DEFAULT'; -- Replace the parent variables with the source variables if using source table for child table data IF p_source_table IS NOT NULL THEN -- Set source table to user given source table instead of default table v_source_schemaname := NULL; v_source_tablename := NULL; SELECT schemaname, tablename INTO v_source_schemaname, v_source_tablename FROM pg_catalog.pg_tables WHERE schemaname = split_part(p_source_table, '.', 1)::name AND tablename = split_part(p_source_table, '.', 2)::name; IF v_default_tablename IS NOT NULL THEN -- Cannot set source parameter to default. Otherwise things get put into a weird loop since data is getting put back into where it was just pulled out IF v_default_schemaname = v_source_schemaname AND v_default_tablename = v_source_tablename THEN RAISE EXCEPTION 'Cannot set p_source_table to the same value as the default table for this partition set. If you are moving data out of the default, please leave p_source_table unset and data will be moved out of the default table automatically.'; END IF; END IF; IF v_source_tablename IS NULL THEN RAISE EXCEPTION 'Given source table does not exist in system catalogs: %', p_source_table; END IF; ELSE IF p_batch_interval IS NOT NULL AND p_batch_interval != v_partition_interval THEN -- This is true because all data for a given child table must be moved out of the default partition before the child table can be created. -- So cannot create the child table when only some of the data has been moved out of the default partition. RAISE EXCEPTION 'If any interval smaller than the partition interval must be used for moving data out of the default, please use the partition_data_async() procedure.'; END IF; -- Set source table to default table if p_source_table is not set, and it exists -- Otherwise just return with a DEBUG that no data source exists IF v_default_tablename IS NOT NULL THEN v_source_schemaname := v_default_schemaname; v_source_tablename := v_default_tablename; v_default_exists := true; v_temp_storage_table := format('%I', 'partman_temp_data_storage'); EXECUTE format ('CREATE TEMP TABLE IF NOT EXISTS %s (LIKE %I.%I INCLUDING INDEXES) ON COMMIT DROP', v_temp_storage_table, v_source_schemaname, v_source_tablename); ELSE RAISE DEBUG 'No default table found when partition_data_time() was called'; RETURN v_total_rows; END IF; END IF; IF p_batch_interval IS NULL OR p_batch_interval > v_partition_interval THEN p_batch_interval := v_partition_interval; END IF; SELECT partition_tablename INTO v_last_partition FROM @extschema@.show_partitions(p_parent_table, 'DESC') LIMIT 1; v_partition_expression := CASE WHEN v_epoch = 'seconds' THEN format('to_timestamp(%I)', v_control) WHEN v_epoch = 'milliseconds' THEN format('to_timestamp((%I/1000)::float)', v_control) WHEN v_epoch = 'microseconds' THEN format('to_timestamp((%I/1000000)::float)', v_control) WHEN v_epoch = 'nanoseconds' THEN format('to_timestamp((%I/1000000000)::float)', v_control) ELSE format('%I', v_control) END; -- Generate filtered column list to use in SELECT/INSERT statements below. Allows for exclusion of GENERATED (or any other desired) columns. SELECT string_agg(quote_ident(attname), ',') INTO v_column_list_filtered FROM pg_catalog.pg_attribute a JOIN pg_catalog.pg_class c ON a.attrelid = c.oid JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = v_source_schemaname AND c.relname = v_source_tablename AND a.attnum > 0 AND a.attisdropped = false AND attname <> ALL(COALESCE(p_ignored_columns, ARRAY[]::text[])); -- Generate full column list to use in SELECT/INSERT statements below when temp table is in use SELECT string_agg(quote_ident(attname), ',') INTO v_column_list_full FROM pg_catalog.pg_attribute a JOIN pg_catalog.pg_class c ON a.attrelid = c.oid JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = v_source_schemaname AND c.relname = v_source_tablename AND a.attnum > 0 AND a.attisdropped = false; FOR i IN 1..p_batch_count LOOP IF v_time_decoder IS NULL THEN IF p_order = 'ASC' THEN EXECUTE format('SELECT min(%s) FROM ONLY %I.%I', v_partition_expression, v_source_schemaname, v_source_tablename) INTO v_start_control; ELSIF p_order = 'DESC' THEN EXECUTE format('SELECT max(%s) FROM ONLY %I.%I', v_partition_expression, v_source_schemaname, v_source_tablename) INTO v_start_control; ELSE RAISE EXCEPTION 'Invalid value for p_order. Must be ASC or DESC'; END IF; ELSE -- Currently time decoder function must take a text parameter. See if this can be more flexible in the future IF p_order = 'ASC' THEN EXECUTE format('SELECT min(%s(%s::text)) FROM ONLY %I.%I', v_time_decoder, v_partition_expression, v_source_schemaname, v_source_tablename) INTO v_start_control; ELSIF p_order = 'DESC' THEN EXECUTE format('SELECT max(%s(%s::text)) FROM ONLY %I.%I', v_time_decoder, v_partition_expression, v_source_schemaname, v_source_tablename) INTO v_start_control; ELSE RAISE EXCEPTION 'Invalid value for p_order. Must be ASC or DESC'; END IF; END IF; IF v_start_control IS NULL THEN EXIT; END IF; SELECT child_start_time INTO v_min_partition_timestamp FROM @extschema@.show_partition_info(v_parent_schemaname||'.'||v_last_partition , v_partition_interval::text , p_parent_table); v_max_partition_timestamp := v_min_partition_timestamp + v_partition_interval; LOOP IF v_start_control >= v_min_partition_timestamp AND v_start_control < v_max_partition_timestamp THEN EXIT; ELSE BEGIN IF v_start_control >= v_max_partition_timestamp THEN -- Keep going forward in time, checking if child partition time interval encompasses the current v_start_control value v_min_partition_timestamp := v_max_partition_timestamp; v_max_partition_timestamp := v_max_partition_timestamp + v_partition_interval; ELSE -- Keep going backwards in time, checking if child partition time interval encompasses the current v_start_control value v_max_partition_timestamp := v_min_partition_timestamp; v_min_partition_timestamp := v_min_partition_timestamp - v_partition_interval; END IF; EXCEPTION WHEN datetime_field_overflow THEN RAISE EXCEPTION 'Attempted partition time interval is outside PostgreSQL''s supported time range. Unable to create partition with interval before timestamp % ', v_min_partition_timestamp; END; END IF; END LOOP; v_partition_timestamp := ARRAY[v_min_partition_timestamp]; IF p_order = 'ASC' THEN -- Ensure batch interval given as parameter doesn't cause maximum to overflow the current partition maximum IF (v_start_control + p_batch_interval) >= (v_min_partition_timestamp + v_partition_interval) THEN v_max_partition_timestamp := v_min_partition_timestamp + v_partition_interval; ELSE v_max_partition_timestamp := v_start_control + p_batch_interval; END IF; ELSIF p_order = 'DESC' THEN -- Must be greater than max value still in parent table since query below grabs < max v_max_partition_timestamp := v_min_partition_timestamp + v_partition_interval; -- Ensure batch interval given as parameter doesn't cause minimum to underflow current partition minimum IF (v_start_control - p_batch_interval) >= v_min_partition_timestamp THEN v_min_partition_timestamp = v_start_control - p_batch_interval; END IF; ELSE RAISE EXCEPTION 'Invalid value for p_order. Must be ASC or DESC'; END IF; -- do some locking with timeout, if required IF p_lock_wait > 0 THEN v_lock_iter := 0; WHILE v_lock_iter <= 5 LOOP v_lock_iter := v_lock_iter + 1; BEGIN EXECUTE format('SELECT * FROM ONLY %I.%I WHERE %s >= %L AND %4$s < %6$L FOR UPDATE NOWAIT' , v_source_schemaname , v_source_tablename , v_partition_expression , v_min_partition_timestamp , v_max_partition_timestamp); v_lock_obtained := TRUE; EXCEPTION WHEN lock_not_available THEN PERFORM pg_sleep( p_lock_wait / 5.0 ); CONTINUE; END; EXIT WHEN v_lock_obtained; END LOOP; IF NOT v_lock_obtained THEN RETURN -1; END IF; END IF; -- This suffix generation code is in create_partition_time() as well v_partition_suffix := to_char(v_min_partition_timestamp, v_datetime_string); v_current_partition_name := @extschema@.check_name_length(v_parent_tablename, v_partition_suffix, TRUE); IF p_override_system_value THEN v_override_statement = ' OVERRIDING SYSTEM VALUE '; ELSE v_override_statement = ' '; END IF; IF v_default_exists THEN -- Child tables cannot be created if data that belongs to it exists in the default -- Have to move data out to temporary location, create child table, then move it back -- Temp table created above to avoid excessive temp creation in loop -- Must use full column list here since the temp table cannot have generated/identity values for defaults. -- This allows for all scenarios where some people may want newly generated values and others may not. -- Those that want them are handled by the filtered column list when moving to the real table IF v_time_encoder IS NULL THEN EXECUTE format('WITH partition_data AS ( DELETE FROM %1$I.%2$I WHERE %3$s >= %4$L AND %3$s < %5$L RETURNING *) INSERT INTO %6$s (%7$s) SELECT %7$s FROM partition_data' , v_source_schemaname , v_source_tablename , v_partition_expression , v_min_partition_timestamp , v_max_partition_timestamp , v_temp_storage_table , v_column_list_full); ELSE EXECUTE format('WITH partition_data AS ( DELETE FROM %1$I.%2$I WHERE %8$s(%3$s::text) >= %4$L AND %8$s(%3$s::text) < %5$L RETURNING *) INSERT INTO %6$s (%7$s) SELECT %7$s FROM partition_data' , v_source_schemaname , v_source_tablename , v_partition_expression , v_min_partition_timestamp , v_max_partition_timestamp , v_temp_storage_table , v_column_list_full , v_time_decoder); END IF; -- Set analyze to true if a table is created v_analyze := @extschema@.create_partition_time(p_parent_table, v_partition_timestamp); EXECUTE format('WITH partition_data AS ( DELETE FROM %s RETURNING *) INSERT INTO %I.%I (%4$s) %5$s SELECT %4$s FROM partition_data' , v_temp_storage_table , v_parent_schemaname , v_current_partition_name , v_column_list_filtered , v_override_statement); ELSE -- Set analyze to true if a table is created v_analyze := @extschema@.create_partition_time(p_parent_table, v_partition_timestamp); IF v_time_encoder IS NULL THEN EXECUTE format('WITH partition_data AS ( DELETE FROM ONLY %I.%I WHERE %s >= %L AND %3$s < %5$L RETURNING *) INSERT INTO %6$I.%7$I (%8$s) %9$s SELECT %8$s FROM partition_data' , v_source_schemaname , v_source_tablename , v_partition_expression , v_min_partition_timestamp , v_max_partition_timestamp , v_parent_schemaname , v_current_partition_name , v_column_list_filtered , v_override_statement); ELSE EXECUTE format('WITH partition_data AS ( DELETE FROM ONLY %I.%I WHERE %10$s(%3$s::text) >= %L AND %10$s(%3$s::text) < %5$L RETURNING *) INSERT INTO %6$I.%7$I (%8$s) %9$s SELECT %8$s FROM partition_data' , v_source_schemaname , v_source_tablename , v_partition_expression , v_min_partition_timestamp , v_max_partition_timestamp , v_parent_schemaname , v_current_partition_name , v_column_list_filtered , v_override_statement , v_time_decoder); END IF; END IF; GET DIAGNOSTICS v_rowcount = ROW_COUNT; v_total_rows := v_total_rows + v_rowcount; IF v_rowcount = 0 THEN EXIT; END IF; END LOOP; -- v_analyze is a local check if a new table is made. -- p_analyze is a parameter to say whether to run the analyze at all. Used by create_parent() to avoid long exclusive lock or run_maintenence() to avoid long creation runs. IF v_analyze AND p_analyze THEN RAISE DEBUG 'partiton_data_time: Begin analyze of %.%', v_parent_schemaname, v_parent_tablename; EXECUTE format('ANALYZE %I.%I', v_parent_schemaname, v_parent_tablename); RAISE DEBUG 'partiton_data_time: End analyze of %.%', v_parent_schemaname, v_parent_tablename; END IF; RETURN v_total_rows; END $$; CREATE FUNCTION @extschema@.partition_data_id( p_parent_table text , p_batch_count int DEFAULT 1 , p_batch_interval bigint DEFAULT NULL , p_lock_wait numeric DEFAULT 0 , p_order text DEFAULT 'ASC' , p_analyze boolean DEFAULT true , p_source_table text DEFAULT NULL , p_ignored_columns text[] DEFAULT NULL , p_override_system_value boolean DEFAULT false ) RETURNS bigint LANGUAGE plpgsql AS $$ DECLARE v_analyze boolean := FALSE; v_column_list_filtered text; v_column_list_full text; v_control text; v_control_type text; v_current_partition_name text; v_default_exists boolean; v_default_schemaname text; v_default_tablename text; v_epoch text; v_lock_iter int := 1; v_lock_obtained boolean := FALSE; v_max_partition_id bigint; v_min_partition_id bigint; v_override_statement text; v_parent_schemaname text; v_parent_tablename text; v_partition_interval bigint; v_partition_id bigint[]; v_rowcount bigint; v_source_schemaname text; v_source_tablename text; v_sql text; v_start_control bigint; v_total_rows bigint := 0; BEGIN /* * Populate the child table(s) of an id-based partition set with data from the default or other given source */ SELECT partition_interval::bigint , control , epoch INTO v_partition_interval , v_control , v_epoch FROM @extschema@.part_config WHERE parent_table = p_parent_table; IF NOT FOUND THEN RAISE EXCEPTION 'ERROR: No entry in part_config found for given table: %', p_parent_table; END IF; SELECT schemaname, tablename INTO v_source_schemaname, v_source_tablename FROM pg_catalog.pg_tables WHERE schemaname = split_part(p_parent_table, '.', 1)::name AND tablename = split_part(p_parent_table, '.', 2)::name; -- Preserve given parent tablename for use below v_parent_schemaname := v_source_schemaname; v_parent_tablename := v_source_tablename; SELECT general_type INTO v_control_type FROM @extschema@.check_control_type(v_source_schemaname, v_source_tablename, v_control); IF v_control_type <> 'id' OR (v_control_type = 'id' AND v_epoch <> 'none') THEN RAISE EXCEPTION 'Control column for given partition set is not id/serial based or epoch flag is set for time-based partitioning.'; END IF; IF p_source_table IS NOT NULL THEN -- Set source table to user given source table instead of parent table v_source_schemaname := NULL; v_source_tablename := NULL; SELECT schemaname, tablename INTO v_source_schemaname, v_source_tablename FROM pg_catalog.pg_tables WHERE schemaname = split_part(p_source_table, '.', 1)::name AND tablename = split_part(p_source_table, '.', 2)::name; IF v_source_tablename IS NULL THEN RAISE EXCEPTION 'Given source table does not exist in system catalogs: %', p_source_table; END IF; ELSE IF p_batch_interval IS NOT NULL AND p_batch_interval != v_partition_interval THEN -- This is true because all data for a given child table must be moved out of the default partition before the child table can be created. -- So cannot create the child table when only some of the data has been moved out of the default partition. RAISE EXCEPTION 'Custom intervals are not allowed when moving data out of the DEFAULT partition. Please leave p_interval/p_batch_interval parameters unset or NULL to allow use of partition set''s default partitioning interval.'; END IF; -- Set source table to default table if p_source_table is not set, and it exists -- Otherwise just return with a DEBUG that no data source exists SELECT n.nspname::text, c.relname::text INTO v_default_schemaname, v_default_tablename FROM pg_catalog.pg_inherits h JOIN pg_catalog.pg_class c ON c.oid = h.inhrelid JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE h.inhparent = format('%I.%I', v_source_schemaname, v_source_tablename)::regclass AND pg_get_expr(relpartbound, c.oid) = 'DEFAULT'; IF v_default_tablename IS NOT NULL THEN v_source_schemaname := v_default_schemaname; v_source_tablename := v_default_tablename; v_default_exists := true; EXECUTE format ('CREATE TEMP TABLE IF NOT EXISTS partman_temp_data_storage (LIKE %I.%I INCLUDING DEFAULTS INCLUDING INDEXES) ON COMMIT DROP', v_source_schemaname, v_source_tablename); ELSE RAISE DEBUG 'No default table found when partition_data_id() was called'; RETURN v_total_rows; END IF; END IF; IF p_batch_interval IS NULL OR p_batch_interval > v_partition_interval THEN p_batch_interval := v_partition_interval; END IF; -- Generate filtered column list to use in SELECT/INSERT statements below. Allows for exclusion of GENERATED (or any other desired) columns. SELECT string_agg(quote_ident(attname), ',') INTO v_column_list_filtered FROM pg_catalog.pg_attribute a JOIN pg_catalog.pg_class c ON a.attrelid = c.oid JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = v_source_schemaname AND c.relname = v_source_tablename AND a.attnum > 0 AND a.attisdropped = false AND attname <> ALL(COALESCE(p_ignored_columns, ARRAY[]::text[])); -- Generate full column list to use in SELECT/INSERT statements below when temp table is in use SELECT string_agg(quote_ident(attname), ',') INTO v_column_list_full FROM pg_catalog.pg_attribute a JOIN pg_catalog.pg_class c ON a.attrelid = c.oid JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = v_source_schemaname AND c.relname = v_source_tablename AND a.attnum > 0 AND a.attisdropped = false; FOR i IN 1..p_batch_count LOOP IF p_order = 'ASC' THEN EXECUTE format('SELECT min(%I) FROM ONLY %I.%I', v_control, v_source_schemaname, v_source_tablename) INTO v_start_control; IF v_start_control IS NULL THEN EXIT; END IF; v_min_partition_id = v_start_control - (v_start_control % v_partition_interval); v_partition_id := ARRAY[v_min_partition_id]; -- Check if custom batch interval overflows current partition maximum IF (v_start_control + p_batch_interval) >= (v_min_partition_id + v_partition_interval) THEN v_max_partition_id := v_min_partition_id + v_partition_interval; ELSE v_max_partition_id := v_start_control + p_batch_interval; END IF; ELSIF p_order = 'DESC' THEN EXECUTE format('SELECT max(%I) FROM ONLY %I.%I', v_control, v_source_schemaname, v_source_tablename) INTO v_start_control; IF v_start_control IS NULL THEN EXIT; END IF; v_min_partition_id = v_start_control - (v_start_control % v_partition_interval); -- Must be greater than max value still in parent table since query below grabs < max v_max_partition_id := v_min_partition_id + v_partition_interval; v_partition_id := ARRAY[v_min_partition_id]; -- Make sure minimum doesn't underflow current partition minimum IF (v_start_control - p_batch_interval) >= v_min_partition_id THEN v_min_partition_id = v_start_control - p_batch_interval; END IF; ELSE RAISE EXCEPTION 'Invalid value for p_order. Must be ASC or DESC'; END IF; -- do some locking with timeout, if required IF p_lock_wait > 0 THEN v_lock_iter := 0; WHILE v_lock_iter <= 5 LOOP v_lock_iter := v_lock_iter + 1; BEGIN v_sql := format('SELECT * FROM ONLY %I.%I WHERE %I >= %s AND %I < %s FOR UPDATE NOWAIT' , v_source_schemaname , v_source_tablename , v_control , v_min_partition_id , v_control , v_max_partition_id); EXECUTE v_sql; v_lock_obtained := TRUE; EXCEPTION WHEN lock_not_available THEN PERFORM pg_sleep( p_lock_wait / 5.0 ); CONTINUE; END; EXIT WHEN v_lock_obtained; END LOOP; IF NOT v_lock_obtained THEN RETURN -1; END IF; END IF; v_current_partition_name := @extschema@.check_name_length(COALESCE(v_parent_tablename), v_min_partition_id::text, TRUE); IF p_override_system_value THEN v_override_statement = ' OVERRIDING SYSTEM VALUE '; ELSE v_override_statement = ' '; END IF; IF v_default_exists THEN -- Child tables cannot be created if data that belongs to it exists in the default -- Have to move data out to temporary location, create child table, then move it back -- Temp table created above to avoid excessive temp creation in loop -- Must use full column list here since the temp table cannot have generated/identity values for defaults. -- This allows for all scenarios where some people may want newly generated values and others may not. -- Those that want them are handled by the filtered column list when moving to the real table EXECUTE format('WITH partition_data AS ( DELETE FROM %1$I.%2$I WHERE %3$I >= %4$s AND %3$I < %5$s RETURNING *) INSERT INTO partman_temp_data_storage (%6$s) SELECT %6$s FROM partition_data' , v_source_schemaname , v_source_tablename , v_control , v_min_partition_id , v_max_partition_id , v_column_list_full); -- Set analyze to true if a table is created v_analyze := @extschema@.create_partition_id(p_parent_table, v_partition_id); EXECUTE format('WITH partition_data AS ( DELETE FROM partman_temp_data_storage RETURNING *) INSERT INTO %1$I.%2$I (%3$s) %4$s SELECT %3$s FROM partition_data' , v_parent_schemaname , v_current_partition_name , v_column_list_filtered , v_override_statement); ELSE -- Set analyze to true if a table is created v_analyze := @extschema@.create_partition_id(p_parent_table, v_partition_id); EXECUTE format('WITH partition_data AS ( DELETE FROM ONLY %1$I.%2$I WHERE %3$I >= %4$s AND %3$I < %5$s RETURNING *) INSERT INTO %6$I.%7$I (%8$s) %9$s SELECT %8$s FROM partition_data' , v_source_schemaname , v_source_tablename , v_control , v_min_partition_id , v_max_partition_id , v_parent_schemaname , v_current_partition_name , v_column_list_filtered , v_override_statement); END IF; GET DIAGNOSTICS v_rowcount = ROW_COUNT; v_total_rows := v_total_rows + v_rowcount; IF v_rowcount = 0 THEN EXIT; END IF; END LOOP; -- v_analyze is a local check if a new table is made. -- p_analyze is a parameter to say whether to run the analyze at all. Used by create_parent() to avoid long exclusive lock or run_maintenence() to avoid long creation runs. IF v_analyze AND p_analyze THEN RAISE DEBUG 'partiton_data_time: Begin analyze of %.%', v_parent_schemaname, v_parent_tablename; EXECUTE format('ANALYZE %I.%I', v_parent_schemaname, v_parent_tablename); RAISE DEBUG 'partiton_data_time: End analyze of %.%', v_parent_schemaname, v_parent_tablename; END IF; RETURN v_total_rows; END $$; CREATE FUNCTION @extschema@.create_parent( p_parent_table text , p_control text , p_interval text , p_type text DEFAULT 'range' , p_epoch text DEFAULT 'none' , p_premake int DEFAULT 4 , p_start_partition text DEFAULT NULL , p_default_table boolean DEFAULT true , p_automatic_maintenance text DEFAULT 'on' , p_constraint_cols text[] DEFAULT NULL , p_template_table text DEFAULT NULL , p_jobmon boolean DEFAULT true , p_date_trunc_interval text DEFAULT NULL , p_control_not_null boolean DEFAULT true , p_time_encoder text DEFAULT NULL , p_time_decoder text DEFAULT NULL , p_offset_id bigint DEFAULT 0 ) RETURNS boolean LANGUAGE plpgsql AS $$ DECLARE ex_context text; ex_detail text; ex_hint text; ex_message text; v_base_timestamp timestamptz; v_count int := 1; v_control_type text; v_control_exact_type text; v_datetime_string text; v_default_partition text; v_higher_control_type text; v_higher_parent_control text; v_higher_parent_epoch text; v_higher_parent_schema text := split_part(p_parent_table, '.', 1); v_higher_parent_table text := split_part(p_parent_table, '.', 2); v_id_interval bigint; v_inherit_privileges boolean := false; -- This is false by default so initial partition set creation doesn't require superuser. v_job_id bigint; v_jobmon_schema text; v_last_partition_created boolean; v_max bigint; v_notnull boolean; v_new_search_path text; v_old_search_path text; v_parent_owner text; v_parent_partition_id bigint; v_parent_partition_timestamp timestamptz; v_parent_schemaname text; v_parent_tablename text; v_parent_tablespace name; v_part_col text; v_part_type text; v_partattrs smallint[]; v_partition_time timestamptz; v_partition_time_array timestamptz[]; v_partition_id_array bigint[]; v_partstrat char; v_row record; v_sql text; v_start_time timestamptz; v_starting_partition_id bigint; v_step_id bigint; v_step_overflow_id bigint; v_success boolean := false; v_template_schema text; v_template_tablename text; v_time_interval interval; v_top_parent_schema text := split_part(p_parent_table, '.', 1); v_top_parent_table text := split_part(p_parent_table, '.', 2); v_unlogged char; BEGIN /* * Function to turn a table into the parent of a partition set */ IF array_length(string_to_array(p_parent_table, '.'), 1) < 2 THEN RAISE EXCEPTION 'Parent table must be schema qualified'; ELSIF array_length(string_to_array(p_parent_table, '.'), 1) > 2 THEN RAISE EXCEPTION 'pg_partman does not support objects with periods in their names'; END IF; IF p_interval = 'yearly' OR p_interval = 'quarterly' OR p_interval = 'monthly' OR p_interval = 'weekly' OR p_interval = 'daily' OR p_interval = 'hourly' OR p_interval = 'half-hour' OR p_interval = 'quarter-hour' THEN RAISE EXCEPTION 'Special partition interval values from old pg_partman versions (%) are no longer supported. Please use a supported interval time value from core PostgreSQL (https://www.postgresql.org/docs/current/datatype-datetime.html#DATATYPE-INTERVAL-INPUT)', p_interval; END IF; SELECT n.nspname , c.relname , t.spcname INTO v_parent_schemaname , v_parent_tablename , v_parent_tablespace FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid LEFT OUTER JOIN pg_catalog.pg_tablespace t ON c.reltablespace = t.oid WHERE n.nspname = split_part(p_parent_table, '.', 1)::name AND c.relname = split_part(p_parent_table, '.', 2)::name; IF v_parent_tablename IS NULL THEN RAISE EXCEPTION 'Unable to find given parent table in system catalogs. Please create parent table first: %', p_parent_table; END IF; SELECT attnotnull INTO v_notnull FROM pg_catalog.pg_attribute a JOIN pg_catalog.pg_class c ON a.attrelid = c.oid JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE c.relname = v_parent_tablename::name AND n.nspname = v_parent_schemaname::name AND a.attname = p_control::name; IF (v_notnull IS NULL) THEN RAISE EXCEPTION 'Control column given (%) for parent table (%) does not exist', p_control, p_parent_table; ELSIF (v_notnull = false and p_control_not_null = true) THEN RAISE EXCEPTION 'Control column given (%) for parent table (%) must be set to NOT NULL', p_control, p_parent_table; END IF; SELECT general_type, exact_type INTO v_control_type, v_control_exact_type FROM @extschema@.check_control_type(v_parent_schemaname, v_parent_tablename, p_control); IF v_control_type IS NULL THEN RAISE EXCEPTION 'pg_partman only supports partitioning of data types that are integer, numeric, date/timestamp or specially encoded text. Supplied column is of type %', v_control_exact_type; END IF; IF (p_epoch <> 'none' AND v_control_type <> 'id') THEN RAISE EXCEPTION 'p_epoch can only be used with an integer based control column'; END IF; IF NOT @extschema@.check_partition_type(p_type) THEN RAISE EXCEPTION '% is not a valid partitioning type for pg_partman', p_type; END IF; IF current_setting('server_version_num')::int < 140000 THEN RAISE EXCEPTION 'pg_partman requires PostgreSQL 14 or greater'; END IF; -- Check if given parent table has been already set up as a partitioned table SELECT p.partstrat , p.partattrs INTO v_partstrat , v_partattrs FROM pg_catalog.pg_partitioned_table p JOIN pg_catalog.pg_class c ON p.partrelid = c.oid JOIN pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = v_parent_schemaname::name AND c.relname = v_parent_tablename::name; IF v_partstrat NOT IN ('r', 'l') OR v_partstrat IS NULL THEN RAISE EXCEPTION 'You must have created the given parent table as ranged or list partitioned already. Ex: CREATE TABLE ... PARTITION BY [RANGE|LIST] ...)'; END IF; IF array_length(v_partattrs, 1) > 1 THEN RAISE NOTICE 'pg_partman only supports single column partitioning at this time. Found % columns in given parent definition.', array_length(v_partattrs, 1); END IF; SELECT a.attname, t.typname INTO v_part_col, v_part_type FROM pg_attribute a JOIN pg_class c ON a.attrelid = c.oid JOIN pg_namespace n ON c.relnamespace = n.oid JOIN pg_type t ON a.atttypid = t.oid WHERE n.nspname = v_parent_schemaname::name AND c.relname = v_parent_tablename::name AND attnum IN (SELECT unnest(partattrs) FROM pg_partitioned_table p WHERE a.attrelid = p.partrelid); IF p_control <> v_part_col OR v_control_exact_type <> v_part_type THEN RAISE EXCEPTION 'Control column and type given in arguments (%, %) does not match the control column and type of the given partition set (%, %)', p_control, v_control_exact_type, v_part_col, v_part_type; END IF; -- Check that control column is a usable type for pg_partman. IF v_control_type NOT IN ('time', 'id', 'text', 'uuid') THEN RAISE EXCEPTION 'Only date/time, text/uuid or integer types are allowed for the control column.'; ELSIF v_control_type IN ('text', 'uuid') AND (p_time_encoder IS NULL OR p_time_decoder IS NULL) THEN RAISE EXCEPTION 'p_time_encoder and p_time_decoder needs to be set for text/uuid type control column.'; ELSIF v_control_type NOT IN ('text', 'uuid') AND (p_time_encoder IS NOT NULL OR p_time_decoder IS NOT NULL) THEN RAISE EXCEPTION 'p_time_encoder and p_time_decoder can only be used with text/uuid type control column.'; END IF; -- Table to handle properties not managed by core PostgreSQL yet IF p_template_table IS NULL THEN v_template_schema := '@extschema@'; v_template_tablename := @extschema@.check_name_length('template_'||v_parent_schemaname||'_'||v_parent_tablename); EXECUTE format('CREATE TABLE IF NOT EXISTS %I.%I (LIKE %I.%I)', v_template_schema, v_template_tablename, v_parent_schemaname, v_parent_tablename); SELECT pg_get_userbyid(c.relowner) INTO v_parent_owner FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = v_parent_schemaname::name AND c.relname = v_parent_tablename::name; EXECUTE format('ALTER TABLE %s.%I OWNER TO %I' , '@extschema@' , v_template_tablename , v_parent_owner); ELSIF lower(p_template_table) IN ('false', 'f') THEN v_template_schema := NULL; v_template_tablename := NULL; RAISE DEBUG 'create_parent(): parent_table: %, skipped template table creation', p_parent_table; ELSE SELECT n.nspname, c.relname INTO v_template_schema, v_template_tablename FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = split_part(p_template_table, '.', 1)::name AND c.relname = split_part(p_template_table, '.', 2)::name; IF v_template_tablename IS NULL THEN RAISE EXCEPTION 'Unable to find given template table in system catalogs (%). Please create template table first or leave parameter NULL to have a default one created for you.', p_parent_table; END IF; END IF; SELECT current_setting('search_path') INTO v_old_search_path; IF length(v_old_search_path) > 0 THEN v_new_search_path := '@extschema@,pg_temp,'||v_old_search_path; ELSE v_new_search_path := '@extschema@,pg_temp'; END IF; IF p_jobmon THEN SELECT nspname INTO v_jobmon_schema FROM pg_catalog.pg_namespace n, pg_catalog.pg_extension e WHERE e.extname = 'pg_jobmon'::name AND e.extnamespace = n.oid; IF v_jobmon_schema IS NOT NULL THEN v_new_search_path := format('%s,%s',v_jobmon_schema, v_new_search_path); END IF; END IF; EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_new_search_path, 'false'); EXECUTE format('LOCK TABLE %I.%I IN ACCESS EXCLUSIVE MODE', v_parent_schemaname, v_parent_tablename); IF v_jobmon_schema IS NOT NULL THEN v_job_id := add_job(format('PARTMAN SETUP PARENT: %s', p_parent_table)); v_step_id := add_step(v_job_id, format('Creating initial partitions on new parent table: %s', p_parent_table)); END IF; -- If this parent table has siblings that are also partitioned (subpartitions), ensure this parent gets added to part_config_sub table so future maintenance will subpartition it -- Just doing in a loop to avoid having to assign a bunch of variables (should only run once, if at all; constraint should enforce only one value.) FOR v_row IN WITH parent_table AS ( SELECT h.inhparent AS parent_oid FROM pg_catalog.pg_inherits h JOIN pg_catalog.pg_class c ON h.inhrelid = c.oid JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE c.relname = v_parent_tablename::name AND n.nspname = v_parent_schemaname::name ), sibling_children AS ( SELECT i.inhrelid::regclass::text AS tablename FROM pg_inherits i JOIN parent_table p ON i.inhparent = p.parent_oid ) -- This column list must be kept consistent between: -- create_parent, check_subpart_sameconfig, create_partition_id, create_partition_time, dump_partitioned_table_definition and table definition SELECT DISTINCT a.sub_control , a.sub_partition_interval , a.sub_partition_type , a.sub_premake , a.sub_automatic_maintenance , a.sub_template_table , a.sub_retention , a.sub_retention_schema , a.sub_retention_keep_index , a.sub_retention_keep_table , a.sub_epoch , a.sub_constraint_cols , a.sub_optimize_constraint , a.sub_infinite_time_partitions , a.sub_jobmon , a.sub_inherit_privileges , a.sub_constraint_valid , a.sub_date_trunc_interval , a.sub_ignore_default_data , a.sub_default_table , a.sub_retention_keep_publication FROM @extschema@.part_config_sub a JOIN sibling_children b on a.sub_parent = b.tablename LIMIT 1 LOOP INSERT INTO @extschema@.part_config_sub ( sub_parent , sub_partition_type , sub_control , sub_partition_interval , sub_constraint_cols , sub_premake , sub_retention , sub_retention_schema , sub_retention_keep_table , sub_retention_keep_index , sub_automatic_maintenance , sub_epoch , sub_optimize_constraint , sub_infinite_time_partitions , sub_jobmon , sub_template_table , sub_inherit_privileges , sub_constraint_valid , sub_date_trunc_interval , sub_ignore_default_data , sub_retention_keep_publication) VALUES ( p_parent_table , v_row.sub_partition_type , v_row.sub_control , v_row.sub_partition_interval , v_row.sub_constraint_cols , v_row.sub_premake , v_row.sub_retention , v_row.sub_retention_schema , v_row.sub_retention_keep_index , v_row.sub_retention_keep_table , v_row.sub_automatic_maintenance , v_row.sub_epoch , v_row.sub_optimize_constraint , v_row.sub_infinite_time_partitions , v_row.sub_jobmon , v_row.sub_template_table , v_row.sub_inherit_privileges , v_row.sub_constraint_valid , v_row.sub_date_trunc_interval , v_row.sub_ignore_default_data , v_row.sub_retention_keep_publication); -- Set this equal to sibling configs so that newly created child table -- privileges are set properly below during initial setup. -- This setting is special because it applies immediately to the new child -- tables of a given parent, not just during maintenance like most other settings. v_inherit_privileges = v_row.sub_inherit_privileges; END LOOP; IF v_control_type IN ('time', 'text', 'uuid') OR (v_control_type = 'id' AND p_epoch <> 'none') THEN v_time_interval := p_interval::interval; IF v_time_interval < '1 second'::interval THEN RAISE EXCEPTION 'Partitioning interval must be 1 second or greater'; END IF; -- First partition is either the min premake or p_start_partition v_start_time := COALESCE(p_start_partition::timestamptz, CURRENT_TIMESTAMP - (v_time_interval * p_premake)); SELECT base_timestamp, datetime_string INTO v_base_timestamp, v_datetime_string FROM @extschema@.calculate_time_partition_info(v_time_interval, v_start_time, p_date_trunc_interval); RAISE DEBUG 'create_parent(): parent_table: %, v_base_timestamp: %', p_parent_table, v_base_timestamp; v_partition_time_array := array_append(v_partition_time_array, v_base_timestamp); LOOP -- If current loop value is less than or equal to the value of the max premake, add time to array. IF (v_base_timestamp + (v_time_interval * v_count)) < (CURRENT_TIMESTAMP + (v_time_interval * p_premake)) THEN BEGIN v_partition_time := (v_base_timestamp + (v_time_interval * v_count))::timestamptz; v_partition_time_array := array_append(v_partition_time_array, v_partition_time); EXCEPTION WHEN datetime_field_overflow THEN RAISE WARNING 'Attempted partition time interval is outside PostgreSQL''s supported time range. Child partition creation after time % skipped', v_partition_time; v_step_overflow_id := add_step(v_job_id, 'Attempted partition time interval is outside PostgreSQL''s supported time range.'); PERFORM update_step(v_step_overflow_id, 'CRITICAL', 'Child partition creation after time '||v_partition_time||' skipped'); CONTINUE; END; ELSE EXIT; -- all needed partitions added to array. Exit the loop. END IF; v_count := v_count + 1; END LOOP; INSERT INTO @extschema@.part_config ( parent_table , partition_type , partition_interval , epoch , control , premake , time_encoder , time_decoder , constraint_cols , datetime_string , automatic_maintenance , jobmon , template_table , inherit_privileges , date_trunc_interval) VALUES ( p_parent_table , p_type , v_time_interval , p_epoch , p_control , p_premake , p_time_encoder , p_time_decoder , p_constraint_cols , v_datetime_string , p_automatic_maintenance , p_jobmon , v_template_schema||'.'||v_template_tablename , v_inherit_privileges , p_date_trunc_interval); RAISE DEBUG 'create_parent: v_partition_time_array: %', v_partition_time_array; v_last_partition_created := @extschema@.create_partition_time(p_parent_table, v_partition_time_array); IF v_last_partition_created = false THEN -- This can happen with subpartitioning when future or past partitions prevent child creation because they're out of range of the parent -- First see if this parent is a subpartition managed by pg_partman WITH top_oid AS ( SELECT i.inhparent AS top_parent_oid FROM pg_catalog.pg_inherits i JOIN pg_catalog.pg_class c ON c.oid = i.inhrelid JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace WHERE c.relname = v_parent_tablename::name AND n.nspname = v_parent_schemaname::name ) SELECT n.nspname, c.relname INTO v_top_parent_schema, v_top_parent_table FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace JOIN top_oid t ON c.oid = t.top_parent_oid JOIN @extschema@.part_config p ON p.parent_table = n.nspname||'.'||c.relname; IF v_top_parent_table IS NOT NULL THEN -- If so create the lowest possible partition that is within the boundary of the parent SELECT child_start_time INTO v_parent_partition_timestamp FROM @extschema@.show_partition_info(p_parent_table, p_parent_table := v_top_parent_schema||'.'||v_top_parent_table); IF v_base_timestamp >= v_parent_partition_timestamp THEN WHILE v_base_timestamp >= v_parent_partition_timestamp LOOP v_base_timestamp := v_base_timestamp - v_time_interval; END LOOP; v_base_timestamp := v_base_timestamp + v_time_interval; -- add one back since while loop set it one lower than is needed ELSIF v_base_timestamp < v_parent_partition_timestamp THEN WHILE v_base_timestamp < v_parent_partition_timestamp LOOP v_base_timestamp := v_base_timestamp + v_time_interval; END LOOP; -- Don't need to remove one since new starting time will fit in top parent interval END IF; v_partition_time_array := NULL; v_partition_time_array := array_append(v_partition_time_array, v_base_timestamp); v_last_partition_created := @extschema@.create_partition_time(p_parent_table, v_partition_time_array); ELSE RAISE WARNING 'No child tables created. Check that all child tables did not already exist and may not have been part of partition set. Given parent has still been configured with pg_partman, but may not have expected children. Please review schema and config to confirm things are ok.'; IF v_jobmon_schema IS NOT NULL THEN PERFORM update_step(v_step_id, 'OK', 'Done'); IF v_step_overflow_id IS NOT NULL THEN PERFORM fail_job(v_job_id); ELSE PERFORM close_job(v_job_id); END IF; END IF; EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false'); RETURN v_success; END IF; END IF; -- End v_last_partition IF IF v_jobmon_schema IS NOT NULL THEN PERFORM update_step(v_step_id, 'OK', format('Time partitions premade: %s', p_premake)); END IF; END IF; IF v_control_type = 'id' AND p_epoch = 'none' THEN v_id_interval := p_interval::bigint; IF v_id_interval < 2 AND p_type != 'list' THEN RAISE EXCEPTION 'Interval for range partitioning must be greater than or equal to 2. Use LIST partitioning for single value partitions. (Values given: p_interval: %, p_type: %)', p_interval, p_type; END IF; -- Check if parent table is a subpartition of an already existing id partition set managed by pg_partman. WHILE v_higher_parent_table IS NOT NULL LOOP -- initially set in DECLARE WITH top_oid AS ( SELECT i.inhparent AS top_parent_oid FROM pg_catalog.pg_inherits i JOIN pg_catalog.pg_class c ON c.oid = i.inhrelid JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace WHERE n.nspname = v_higher_parent_schema::name AND c.relname = v_higher_parent_table::name ) SELECT n.nspname, c.relname, p.control, p.epoch INTO v_higher_parent_schema, v_higher_parent_table, v_higher_parent_control, v_higher_parent_epoch FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace JOIN top_oid t ON c.oid = t.top_parent_oid JOIN @extschema@.part_config p ON p.parent_table = n.nspname||'.'||c.relname; IF v_higher_parent_table IS NOT NULL THEN SELECT general_type INTO v_higher_control_type FROM @extschema@.check_control_type(v_higher_parent_schema, v_higher_parent_table, v_higher_parent_control); IF v_higher_control_type <> 'id' or (v_higher_control_type = 'id' AND v_higher_parent_epoch <> 'none') THEN -- The parent above the p_parent_table parameter is not partitioned by ID -- so don't check for max values in parents that aren't partitioned by ID. -- This avoids missing child tables in subpartition sets that have differing ID data EXIT; END IF; -- v_top_parent initially set in DECLARE v_top_parent_schema := v_higher_parent_schema; v_top_parent_table := v_higher_parent_table; END IF; END LOOP; -- If custom start partition is set, use that. -- If custom start is not set and there is already data, start partitioning with the highest current value and ensure it's grabbed from highest top parent table IF p_start_partition IS NOT NULL THEN v_max := p_start_partition::bigint; ELSE v_sql := format('SELECT COALESCE(trunc(max(%I))::bigint, 0) FROM %I.%I LIMIT 1' , p_control , v_top_parent_schema , v_top_parent_table); EXECUTE v_sql INTO v_max; END IF; v_starting_partition_id := ((v_max - (v_max % v_id_interval)) + p_offset_id); FOR i IN 0..p_premake LOOP -- Only make previous partitions if ID value is less than the starting value and positive (and custom start partition wasn't set) IF p_start_partition IS NULL AND (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 = array_append(v_partition_id_array, (v_starting_partition_id - v_id_interval*i)); END IF; v_partition_id_array = array_append(v_partition_id_array, (v_id_interval*i) + v_starting_partition_id); END LOOP; INSERT INTO @extschema@.part_config ( parent_table , partition_type , partition_interval , control , premake , constraint_cols , automatic_maintenance , jobmon , template_table , inherit_privileges , date_trunc_interval) VALUES ( p_parent_table , p_type , v_id_interval , p_control , p_premake , p_constraint_cols , p_automatic_maintenance , p_jobmon , v_template_schema||'.'||v_template_tablename , v_inherit_privileges , p_date_trunc_interval); v_last_partition_created := @extschema@.create_partition_id(p_parent_table, v_partition_id_array); IF v_last_partition_created = false THEN -- This can happen with subpartitioning when future or past partitions prevent child creation because they're out of range of the parent -- See if it's actually a subpartition of a parent id partition WITH top_oid AS ( SELECT i.inhparent AS top_parent_oid FROM pg_catalog.pg_inherits i JOIN pg_catalog.pg_class c ON c.oid = i.inhrelid JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace WHERE c.relname = v_parent_tablename::name AND n.nspname = v_parent_schemaname::name ) SELECT n.nspname||'.'||c.relname INTO v_top_parent_table FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace JOIN top_oid t ON c.oid = t.top_parent_oid JOIN @extschema@.part_config p ON p.parent_table = n.nspname||'.'||c.relname; IF v_top_parent_table IS NOT NULL THEN -- Create the lowest possible partition that is within the boundary of the parent SELECT child_start_id INTO v_parent_partition_id FROM @extschema@.show_partition_info(p_parent_table, p_parent_table := v_top_parent_table); IF v_starting_partition_id >= v_parent_partition_id THEN WHILE v_starting_partition_id >= v_parent_partition_id LOOP v_starting_partition_id := v_starting_partition_id - v_id_interval; END LOOP; v_starting_partition_id := v_starting_partition_id + v_id_interval; -- add one back since while loop set it one lower than is needed ELSIF v_starting_partition_id < v_parent_partition_id THEN WHILE v_starting_partition_id < v_parent_partition_id LOOP v_starting_partition_id := v_starting_partition_id + v_id_interval; END LOOP; -- Don't need to remove one since new starting id will fit in top parent interval END IF; v_partition_id_array = NULL; v_partition_id_array = array_append(v_partition_id_array, v_starting_partition_id); v_last_partition_created := @extschema@.create_partition_id(p_parent_table, v_partition_id_array); ELSE -- Currently unknown edge case if code gets here RAISE WARNING 'No child tables created. Check that all child tables did not already exist and may not have been part of partition set. Given parent has still been configured with pg_partman, but may not have expected children. Please review schema and config to confirm things are ok.'; IF v_jobmon_schema IS NOT NULL THEN PERFORM update_step(v_step_id, 'OK', 'Done'); IF v_step_overflow_id IS NOT NULL THEN PERFORM fail_job(v_job_id); ELSE PERFORM close_job(v_job_id); END IF; END IF; EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false'); RETURN v_success; END IF; END IF; -- End v_last_partition_created IF END IF; -- End IF id IF p_default_table THEN -- Add default partition v_default_partition := @extschema@.check_name_length(v_parent_tablename, '_default', FALSE); v_sql := 'CREATE'; -- Same INCLUDING list is used in create_partition_*(). INDEXES is handled when partition is attached if it's supported. v_sql := v_sql || format(' TABLE IF NOT EXISTS %I.%I (LIKE %I.%I INCLUDING COMMENTS INCLUDING COMPRESSION INCLUDING CONSTRAINTS INCLUDING DEFAULTS INCLUDING GENERATED INCLUDING STATISTICS INCLUDING STORAGE)' , v_parent_schemaname, v_default_partition, v_parent_schemaname, v_parent_tablename); IF v_parent_tablespace IS NOT NULL THEN v_sql := format('%s TABLESPACE %I ', v_sql, v_parent_tablespace); END IF; EXECUTE v_sql; v_sql := format('ALTER TABLE %I.%I ATTACH PARTITION %I.%I DEFAULT' , v_parent_schemaname, v_parent_tablename, v_parent_schemaname, v_default_partition); EXECUTE v_sql; PERFORM @extschema@.inherit_replica_identity(v_parent_schemaname, v_parent_tablename, v_default_partition); -- Manage template inherited properties IF v_template_tablename IS NOT NULL THEN PERFORM @extschema@.inherit_template_properties(p_parent_table, v_parent_schemaname, v_default_partition); END IF; END IF; IF v_jobmon_schema IS NOT NULL THEN PERFORM update_step(v_step_id, 'OK', 'Done'); IF v_step_overflow_id IS NOT NULL THEN PERFORM fail_job(v_job_id); ELSE PERFORM close_job(v_job_id); END IF; END IF; EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false'); v_success := true; RETURN v_success; EXCEPTION WHEN OTHERS THEN GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, ex_context = PG_EXCEPTION_CONTEXT, ex_detail = PG_EXCEPTION_DETAIL, ex_hint = PG_EXCEPTION_HINT; IF v_jobmon_schema IS NOT NULL THEN IF v_job_id IS NULL THEN EXECUTE format('SELECT %I.add_job(''PARTMAN CREATE PARENT: %s'')', v_jobmon_schema, p_parent_table) INTO v_job_id; EXECUTE format('SELECT %I.add_step(%s, ''Partition creation for table '||p_parent_table||' failed'')', v_jobmon_schema, v_job_id, p_parent_table) INTO v_step_id; ELSIF v_step_id IS NULL THEN EXECUTE format('SELECT %I.add_step(%s, ''EXCEPTION before first step logged'')', v_jobmon_schema, v_job_id) INTO v_step_id; END IF; EXECUTE format('SELECT %I.update_step(%s, ''CRITICAL'', %L)', v_jobmon_schema, v_step_id, 'ERROR: '||coalesce(SQLERRM,'unknown')); EXECUTE format('SELECT %I.fail_job(%s)', v_jobmon_schema, v_job_id); END IF; RAISE EXCEPTION '% CONTEXT: % DETAIL: % HINT: %', ex_message, ex_context, ex_detail, ex_hint; END $$; CREATE FUNCTION @extschema@.show_partition_info( p_child_table text , p_partition_interval text DEFAULT NULL , p_parent_table text DEFAULT NULL , p_table_exists boolean DEFAULT true , OUT child_start_time timestamptz , OUT child_end_time timestamptz , OUT child_start_id bigint , OUT child_end_id bigint , OUT suffix text ) RETURNS record LANGUAGE plpgsql STABLE AS $$ DECLARE v_child_schemaname text; v_child_tablename text; v_control text; v_control_type text; v_time_encoder text; v_time_decoder text; v_epoch text; v_exact_control_type text; v_parent_schemaname text; v_parent_table text; v_parent_tablename text; v_partstrat char; v_partition_interval text; v_start_string text; v_suffix_position int; BEGIN /* * Show the data boundaries for a given child table as well as the suffix that will be used. * Passing the parent table argument slightly improves performance by avoiding a catalog lookup. * Passing an interval lets you set one different than the default configured one if desired. */ IF p_parent_table IS NULL THEN IF p_table_exists = FALSE THEN RAISE EXCEPTION 'If given child table does not exist (p_table_exists = false), then the p_parent_table parameter must be set'; END IF; SELECT n.nspname||'.'|| c.relname INTO v_parent_table FROM pg_catalog.pg_inherits h JOIN pg_catalog.pg_class c ON c.oid = h.inhparent JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE h.inhrelid::regclass = p_child_table::regclass; ELSE v_parent_table := p_parent_table; END IF; SELECT n.nspname, c.relname INTO v_parent_schemaname, v_parent_tablename FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = split_part(v_parent_table, '.', 1)::name AND c.relname = split_part(v_parent_table, '.', 2)::name; IF v_parent_tablename IS NULL THEN RAISE EXCEPTION 'Unable to find given parent table in system catalogs. Ensure it is schema qualified: %', p_parent_table; END IF; SELECT time_encoder, time_decoder INTO v_time_encoder, v_time_decoder FROM @extschema@.part_config WHERE parent_table = v_parent_table; IF p_partition_interval IS NULL THEN SELECT control, partition_interval, epoch INTO v_control, v_partition_interval, v_epoch FROM @extschema@.part_config WHERE parent_table = v_parent_table; ELSE v_partition_interval := p_partition_interval; SELECT control, epoch INTO v_control, v_epoch FROM @extschema@.part_config WHERE parent_table = v_parent_table; END IF; IF v_control IS NULL THEN RAISE EXCEPTION 'Parent table of given child not managed by pg_partman: %', v_parent_table; END IF; SELECT p.partstrat INTO v_partstrat FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid JOIN pg_catalog.pg_partitioned_table p ON c.oid = p.partrelid WHERE n.nspname = v_parent_schemaname::name AND c.relname = v_parent_tablename::name; IF p_table_exists THEN SELECT n.nspname, c.relname INTO v_child_schemaname, v_child_tablename FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = split_part(p_child_table, '.', 1)::name AND c.relname = split_part(p_child_table, '.', 2)::name; IF v_child_tablename IS NULL THEN IF p_parent_table IS NOT NULL THEN RAISE EXCEPTION 'Child table given does not exist (%) for given parent table (%)', p_child_table, p_parent_table; ELSE RAISE EXCEPTION 'Child table given does not exist (%)', p_child_table; END IF; END IF; -- Look at actual partition bounds in catalog and pull values from there. IF v_partstrat = 'r' THEN SELECT (regexp_match(pg_get_expr(c.relpartbound, c.oid, true) , $REGEX$\(([^)]+)\) TO \(([^)]+)\)$REGEX$))[1]::text INTO v_start_string FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE c.relname = v_child_tablename AND n.nspname = v_child_schemaname; ELSIF v_partstrat = 'l' THEN SELECT (regexp_match(pg_get_expr(c.relpartbound, c.oid, true) , $REGEX$FOR VALUES IN \(([^)]+)\)$REGEX$))[1]::text INTO v_start_string FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE c.relname = v_child_tablename AND n.nspname = v_child_schemaname; ELSE RAISE EXCEPTION 'partman functions only work with list partitioning with integers and ranged partitioning with time or integers. Found partition strategy "%" for given partition set', v_partstrat; END IF; ELSE v_child_tablename := split_part(p_child_table, '.', 1); v_child_schemaname := split_part(p_child_table, '.', 2); v_suffix_position := (length(v_child_tablename) - position('p_' in reverse(v_child_tablename))) + 2; v_start_string := substring(v_child_tablename from v_suffix_position); END IF; SELECT general_type, exact_type INTO v_control_type, v_exact_control_type FROM @extschema@.check_control_type(v_parent_schemaname, v_parent_tablename, v_control); RAISE DEBUG 'show_partition_info: v_child_schemaname: %, v_child_tablename: %, v_control_type: %, v_exact_control_type: %', v_child_schemaname, v_child_tablename, v_control_type, v_exact_control_type; IF v_control_type IN ('time', 'text', 'uuid') OR (v_control_type = 'id' AND v_epoch <> 'none') THEN IF v_control_type = 'time' THEN child_start_time := v_start_string::timestamptz; ELSIF v_control_type IN ('text', 'uuid') THEN EXECUTE format('SELECT %s(%s)', v_time_decoder, v_start_string) INTO child_start_time; ELSIF (v_control_type = 'id' AND v_epoch <> 'none') THEN -- bigint data type is stored as a single-quoted string in the partition expression. Must strip quotes for valid type-cast. v_start_string := trim(BOTH '''' FROM v_start_string); IF v_epoch = 'seconds' THEN child_start_time := to_timestamp(v_start_string::double precision); ELSIF v_epoch = 'milliseconds' THEN child_start_time := to_timestamp((v_start_string::double precision) / 1000); ELSIF v_epoch = 'microseconds' THEN child_start_time := to_timestamp((v_start_string::double precision) / 1000000); ELSIF v_epoch = 'nanoseconds' THEN child_start_time := to_timestamp((v_start_string::double precision) / 1000000000); END IF; ELSE RAISE EXCEPTION 'Unexpected code path in show_partition_info(). Please report this bug with the configuration that lead to it.'; END IF; child_end_time := (child_start_time + v_partition_interval::interval); SELECT to_char(base_timestamp, datetime_string) INTO suffix FROM @extschema@.calculate_time_partition_info(v_partition_interval::interval, child_start_time); ELSIF v_control_type = 'id' THEN IF v_exact_control_type IN ('int8', 'int4', 'int2') THEN -- Have to do a trim here because of inconsistency in quoting different integer types. Ex: bigint boundary values are quoted but int values are not child_start_id := trim(BOTH $QUOTE$''$QUOTE$ FROM v_start_string)::bigint; ELSIF v_exact_control_type = 'numeric' THEN -- cast to numeric then trunc to get rid of decimal without rounding child_start_id := trunc(trim(BOTH $QUOTE$''$QUOTE$ FROM v_start_string)::numeric)::bigint; END IF; child_end_id := (child_start_id + v_partition_interval::bigint) - 1; ELSE RAISE EXCEPTION 'Invalid partition type encountered in show_partition_info()'; END IF; RETURN; END $$; CREATE OR REPLACE FUNCTION @extschema@.show_partition_name( p_parent_table text, p_value text , OUT partition_schema text , OUT partition_table text , OUT suffix_timestamp timestamptz , OUT suffix_id bigint , OUT table_exists boolean ) RETURNS record LANGUAGE plpgsql STABLE AS $$ DECLARE v_child_end_time timestamptz; v_child_exists text; v_child_larger boolean := false; v_child_smaller boolean := false; v_child_start_time timestamptz; v_control text; v_time_encoder text; v_control_type text; v_datetime_string text; v_epoch text; v_given_timestamp timestamptz; v_parent_schemaname text; v_parent_tablename text; v_partition_interval text; v_row record; v_type text; BEGIN /* * Given a parent table and partition value, return the name of the child partition it would go in. * If using epoch time partitioning, give the text representation of the timestamp NOT the epoch integer value (use to_timestamp() to convert epoch values). * Also returns just the suffix value and true if the child table exists or false if it does not */ SELECT partition_type , control , time_encoder , partition_interval , datetime_string , epoch INTO v_type , v_control , v_time_encoder , v_partition_interval , v_datetime_string , v_epoch FROM @extschema@.part_config WHERE parent_table = p_parent_table; IF v_type IS NULL THEN RAISE EXCEPTION 'Parent table given is not managed by pg_partman (%)', p_parent_table; END IF; SELECT n.nspname, c.relname INTO v_parent_schemaname, v_parent_tablename FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = split_part(p_parent_table, '.', 1)::name AND c.relname = split_part(p_parent_table, '.', 2)::name; IF v_parent_tablename IS NULL THEN RAISE EXCEPTION 'Parent table given does not exist (%)', p_parent_table; END IF; partition_schema := v_parent_schemaname; SELECT general_type INTO v_control_type FROM @extschema@.check_control_type(v_parent_schemaname, v_parent_tablename, v_control); IF (v_control_type IN ('time', 'text', 'uuid') OR (v_control_type = 'id' AND v_epoch <> 'none')) THEN v_given_timestamp := p_value::timestamptz; RAISE DEBUG 'show_partition_name: v_given_timestamp: %, v_child_start_time: %, v_child_end_time: % ', v_given_timestamp, v_child_start_time, v_child_end_time; FOR v_row IN SELECT partition_schemaname ||'.'|| partition_tablename AS child_table FROM @extschema@.show_partitions(p_parent_table, 'DESC') LOOP RAISE DEBUG 'show_partition_name: v_row.child_table: %', v_row.child_table; SELECT child_start_time INTO v_child_start_time FROM @extschema@.show_partition_info(v_row.child_table, v_partition_interval, p_parent_table); -- Don't use child_end_time from above function to avoid edge cases around user supplied timestamps v_child_end_time := v_child_start_time + v_partition_interval::interval; RAISE DEBUG 'show_partition_name: v_given_timestamp: %, v_child_start_time: %, v_child_end_time: % ', v_given_timestamp, v_child_start_time, v_child_end_time; IF v_given_timestamp >= v_child_end_time THEN -- given value is higher than any existing child table. handled below. v_child_larger := true; EXIT; END IF; IF v_given_timestamp >= v_child_start_time THEN -- found target child table v_child_smaller := false; suffix_timestamp := v_child_start_time; EXIT; END IF; -- Should only get here if no matching child table was found. handled below. v_child_smaller := true; END LOOP; IF v_child_start_time IS NULL OR v_child_end_time IS NULL THEN -- This should never happen since there should never be a partition set without children. -- Handling just in case so issues can be reported with context RAISE EXCEPTION 'Unexpected code path encountered in show_partition_name(). Please report this issue to author with relevant partition config info.'; END IF; IF v_child_larger THEN LOOP -- keep adding interval until found v_child_start_time := v_child_start_time + v_partition_interval::interval; v_child_end_time := v_child_end_time + v_partition_interval::interval; IF v_given_timestamp >= v_child_start_time AND v_given_timestamp < v_child_end_time THEN suffix_timestamp := v_child_start_time; EXIT; END IF; END LOOP; ELSIF v_child_smaller THEN LOOP -- keep subtracting interval until found v_child_start_time := v_child_start_time - v_partition_interval::interval; v_child_end_time := v_child_end_time - v_partition_interval::interval; IF v_given_timestamp >= v_child_start_time AND v_given_timestamp < v_child_end_time THEN suffix_timestamp := v_child_start_time; EXIT; END IF; END LOOP; END IF; partition_table := @extschema@.check_name_length(v_parent_tablename, to_char(suffix_timestamp, v_datetime_string), TRUE); ELSIF v_control_type = 'id' THEN suffix_id := (p_value::bigint - (p_value::bigint % v_partition_interval::bigint)); partition_table := @extschema@.check_name_length(v_parent_tablename, suffix_id::text, TRUE); ELSE RAISE EXCEPTION 'Unexpected code path encountered in show_partition_name(). No valid control type found. Please report this issue to author with relevant partition config info.'; END IF; SELECT tablename INTO v_child_exists FROM pg_catalog.pg_tables WHERE schemaname = partition_schema::name AND tablename = partition_table::name; IF v_child_exists IS NOT NULL THEN table_exists := true; ELSE table_exists := false; END IF; RETURN; END $$; CREATE OR REPLACE FUNCTION @extschema@.run_maintenance( p_parent_table text DEFAULT NULL -- If these defaults change reflect them in `run_maintenance_proc`! , p_analyze boolean DEFAULT false , p_jobmon boolean DEFAULT true ) RETURNS void LANGUAGE plpgsql AS $$ DECLARE ex_context text; ex_detail text; ex_hint text; ex_message text; v_adv_lock boolean; v_analyze boolean := FALSE; v_check_subpart int; v_child_timestamp timestamptz; v_control_type text; v_time_encoder text; v_time_decoder text; v_create_count int := 0; v_current_partition_id bigint; v_current_partition_timestamp timestamptz; v_default_tablename text; v_drop_count int := 0; v_exact_control_type text; v_is_default text; v_job_id bigint; v_jobmon_schema text; v_last_partition text; v_last_partition_created boolean; v_last_partition_id bigint; v_last_partition_timestamp timestamptz; v_max_id bigint; v_max_id_default bigint; v_max_time_default timestamptz; v_new_search_path text; v_next_partition_id bigint; v_next_partition_timestamp timestamptz; v_old_search_path text; v_parent_exists text; v_parent_oid oid; v_parent_schema text; v_parent_tablename text; v_partition_expression text; v_premade_count int; v_row record; v_row_max_id record; v_row_max_time record; v_sql text; v_step_id bigint; v_step_overflow_id bigint; v_sub_id_max bigint; v_sub_id_max_suffix bigint; v_sub_id_min bigint; v_sub_parent text; v_sub_timestamp_max timestamptz; v_sub_timestamp_max_suffix timestamptz; v_sub_timestamp_min timestamptz; v_tables_list_sql text; BEGIN /* * Function to manage pre-creation of the next partitions in a set. * Also manages dropping old partitions if the retention option is set. * If p_parent_table is passed, will only run run_maintenance() on that one table (no matter what the configuration table may have set for it) * Otherwise, will run on all tables in the config table with p_automatic_maintenance() set to true. * For large partition sets, running analyze can cause maintenance to take longer than expected so is not done by default. Can set p_analyze to true to force analyze. Be aware that constraint exclusion may not work properly until an analyze on the partition set is run. */ v_adv_lock := pg_try_advisory_xact_lock(hashtext('pg_partman run_maintenance')); IF v_adv_lock = 'false' THEN RAISE NOTICE 'Partman maintenance already running.'; RETURN; END IF; IF pg_is_in_recovery() THEN RAISE DEBUG 'pg_partmain maintenance called on replica. Doing nothing.'; RETURN; END IF; SELECT current_setting('search_path') INTO v_old_search_path; IF length(v_old_search_path) > 0 THEN v_new_search_path := '@extschema@,pg_temp,'||v_old_search_path; ELSE v_new_search_path := '@extschema@,pg_temp'; END IF; IF p_jobmon THEN SELECT nspname INTO v_jobmon_schema FROM pg_catalog.pg_namespace n, pg_catalog.pg_extension e WHERE e.extname = 'pg_jobmon'::name AND e.extnamespace = n.oid; IF v_jobmon_schema IS NOT NULL THEN v_new_search_path := format('%s,%s',v_jobmon_schema, v_new_search_path); END IF; END IF; EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_new_search_path, 'false'); IF v_jobmon_schema IS NOT NULL THEN v_job_id := add_job('PARTMAN RUN MAINTENANCE'); v_step_id := add_step(v_job_id, 'Running maintenance loop'); END IF; v_tables_list_sql := 'SELECT parent_table , partition_type , partition_interval , control , premake , undo_in_progress , sub_partition_set_full , epoch , infinite_time_partitions , retention , ignore_default_data , datetime_string , maintenance_order , date_trunc_interval , async_partitioning_in_progress FROM @extschema@.part_config WHERE undo_in_progress = false'; IF p_parent_table IS NULL THEN v_tables_list_sql := v_tables_list_sql || format(' AND automatic_maintenance = %L ', 'on'); ELSE v_tables_list_sql := v_tables_list_sql || format(' AND parent_table = %L ', p_parent_table); END IF; v_tables_list_sql := v_tables_list_sql || format(' ORDER BY maintenance_order ASC NULLS LAST, parent_table ASC NULLS LAST '); RAISE DEBUG 'run_maint: v_tables_list_sql: %', v_tables_list_sql; FOR v_row IN EXECUTE v_tables_list_sql LOOP CONTINUE WHEN v_row.undo_in_progress; IF v_row.async_partitioning_in_progress IS NOT NULL THEN RAISE WARNING 'Async partitioning in progress for partition set: %. Maintenance is being skipped for this partition set while this is in progress and will resume when it is complete during the next maintenance run. If this is not expected, please check the value of "async_partitioning_in_progress" in the "part_config" table and investigate for any incomplete asynchronous partitioning job attempts for this partition set.', v_row.parent_table; CONTINUE; END IF; -- When sub-partitioning, retention may drop tables that were already put into the query loop values. -- Check if they still exist in part_config before continuing v_parent_exists := NULL; SELECT parent_table, time_encoder, time_decoder INTO v_parent_exists, v_time_encoder, v_time_decoder FROM @extschema@.part_config WHERE parent_table = v_row.parent_table; IF v_parent_exists IS NULL THEN RAISE DEBUG 'run_maint: Parent table possibly removed from part_config by retenion'; END IF; CONTINUE WHEN v_parent_exists IS NULL; -- Check for old quarterly and ISO weekly partitioning from prior to version 5.x. Error out to avoid breaking these partition sets -- with new datetime_string formats IF v_row.datetime_string IN ('YYYY"q"Q', 'IYYY"w"IW') THEN RAISE EXCEPTION 'Quarterly and ISO weekly partitioning is no longer supported in pg_partman 5.0.0 and greater. Please see documentation for migrating away from these partitioning patterns. Partition set: %', v_row.parent_table; END IF; -- Check for consistent data in part_config_sub table. Was unable to get this working properly as either a constraint or trigger. -- Would either delay raising an error until the next write (which I cannot predict) or disallow future edits to update a sub-partition set's configuration. -- This way at least provides a consistent way to check that I know will run. If anyone can get a working constraint/trigger, please help! SELECT sub_parent INTO v_sub_parent FROM @extschema@.part_config_sub WHERE sub_parent = v_row.parent_table; IF v_sub_parent IS NOT NULL THEN SELECT count(*) INTO v_check_subpart FROM @extschema@.check_subpart_sameconfig(v_row.parent_table); IF v_check_subpart > 1 THEN RAISE EXCEPTION 'Inconsistent data in part_config_sub table. Sub-partition tables that are themselves sub-partitions cannot have differing configuration values among their siblings. Run this query: "SELECT * FROM @extschema@.check_subpart_sameconfig(''%'');" This should only return a single row or nothing. If multiple rows are returned, the results are differing configurations in the part_config_sub table for children of the given parent. Determine the child tables of the given parent and look up their entries based on the "part_config_sub.sub_parent" column. Update the differing values to be consistent for your desired values.', v_row.parent_table; END IF; END IF; SELECT n.nspname, c.relname, c.oid INTO v_parent_schema, v_parent_tablename, v_parent_oid FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE n.nspname = split_part(v_row.parent_table, '.', 1)::name AND c.relname = split_part(v_row.parent_table, '.', 2)::name; -- Always returns the default partition first if it exists SELECT partition_tablename INTO v_default_tablename FROM @extschema@.show_partitions(v_row.parent_table, p_include_default := true) LIMIT 1; SELECT pg_get_expr(relpartbound, v_parent_oid) INTO v_is_default FROM pg_catalog.pg_class c JOIN pg_catalog.pg_namespace n on c.relnamespace = n.oid WHERE n.nspname = v_parent_schema AND c.relname = v_default_tablename; IF v_is_default != 'DEFAULT' THEN -- Parent table will never have data, but allows code below to "just work" v_default_tablename := v_parent_tablename; END IF; SELECT general_type, exact_type INTO v_control_type, v_exact_control_type FROM @extschema@.check_control_type(v_parent_schema, v_parent_tablename, v_row.control); v_partition_expression := CASE WHEN v_row.epoch = 'seconds' THEN format('to_timestamp(%I)', v_row.control) WHEN v_row.epoch = 'milliseconds' THEN format('to_timestamp((%I/1000)::float)', v_row.control) WHEN v_row.epoch = 'microseconds' THEN format('to_timestamp((%I/1000000)::float)', v_row.control) WHEN v_row.epoch = 'nanoseconds' THEN format('to_timestamp((%I/1000000000)::float)', v_row.control) ELSE format('%I', v_row.control) END; RAISE DEBUG 'run_maint: v_partition_expression: %', v_partition_expression; SELECT partition_tablename INTO v_last_partition FROM @extschema@.show_partitions(v_row.parent_table, 'DESC') LIMIT 1; RAISE DEBUG 'run_maint: parent_table: %, v_last_partition: %', v_row.parent_table, v_last_partition; IF v_control_type = 'time' OR (v_control_type = 'id' AND v_row.epoch <> 'none') OR (v_control_type IN ('text', 'uuid')) THEN IF v_row.sub_partition_set_full THEN UPDATE @extschema@.part_config SET maintenance_last_run = clock_timestamp() WHERE parent_table = v_row.parent_table; CONTINUE; END IF; SELECT child_start_time INTO v_last_partition_timestamp FROM @extschema@.show_partition_info(v_parent_schema||'.'||v_last_partition, v_row.partition_interval, v_row.parent_table); -- Do not create child tables if they would be dropped by retention anyway. Edge case where maintenance was missed for -- an extended period of time IF v_row.retention IS NOT NULL THEN v_last_partition_timestamp := greatest(v_last_partition_timestamp, CURRENT_TIMESTAMP - v_row.retention::interval); -- Need to properly truncate the interval and account for custom date truncation SELECT base_timestamp INTO v_last_partition_timestamp FROM @extschema@.calculate_time_partition_info(v_row.partition_interval::interval, v_last_partition_timestamp, v_row.date_trunc_interval); END IF; -- Must be reset to null otherwise if the next partition set in the loop is empty, the previous partition set's value could be used v_current_partition_timestamp := NULL; -- Loop through child tables starting from highest to get a timestamp from the highest non-empty partition in the set -- Avoids doing a scan on entire partition set and/or getting any values accidentally in default. FOR v_row_max_time IN SELECT partition_schemaname, partition_tablename FROM @extschema@.show_partitions(v_row.parent_table, 'DESC', false) LOOP IF v_control_type = 'time' OR (v_control_type = 'id' AND v_row.epoch <> 'none') THEN EXECUTE format('SELECT %s::text FROM %I.%I LIMIT 1' , v_partition_expression , v_row_max_time.partition_schemaname , v_row_max_time.partition_tablename ) INTO v_child_timestamp; ELSIF v_control_type IN ('text', 'uuid') THEN EXECUTE format('SELECT %s(%s::text) FROM %I.%I LIMIT 1' , v_time_decoder , v_partition_expression , v_row_max_time.partition_schemaname , v_row_max_time.partition_tablename ) INTO v_child_timestamp; END IF; IF v_row.infinite_time_partitions AND v_child_timestamp < CURRENT_TIMESTAMP THEN -- No new data has been inserted relative to "now", but keep making child tables anyway v_current_partition_timestamp = CURRENT_TIMESTAMP; -- Nothing else to do in this case so just end early EXIT; END IF; IF v_child_timestamp IS NOT NULL THEN SELECT suffix_timestamp INTO v_current_partition_timestamp FROM @extschema@.show_partition_name(v_row.parent_table, v_child_timestamp::text); EXIT; END IF; END LOOP; IF v_row.infinite_time_partitions AND v_child_timestamp IS NULL THEN -- If partition set is completely empty, still keep making child tables anyway -- Has to be separate check outside above loop since "future" tables are likely going to be empty, hence ignored in that loop v_current_partition_timestamp = CURRENT_TIMESTAMP; END IF; -- If not ignoring the default table, check for max values there. If they are there and greater than all child values, use that instead -- Note the default is NOT to care about data in the default, so maintenance will fail if new child table boundaries overlap with -- data that exists in the default. This is intentional so user removes data from default to avoid larger problems. IF v_row.ignore_default_data THEN v_max_time_default := NULL; ELSE EXECUTE format('SELECT max(%s) FROM ONLY %I.%I', v_partition_expression, v_parent_schema, v_default_tablename) INTO v_max_time_default; END IF; RAISE DEBUG 'run_maint: v_current_partition_timestamp: %, v_max_time_default: %', v_current_partition_timestamp, v_max_time_default; IF v_current_partition_timestamp IS NULL AND v_max_time_default IS NULL THEN -- Partition set is completely empty and infinite time partitions not set -- Still need to run retention if needed. Note similar call below for non-empty sets. Keep in sync. IF v_row.retention IS NOT NULL THEN v_drop_count := v_drop_count + @extschema@.drop_partition_time(v_row.parent_table); END IF; -- Nothing else to do UPDATE @extschema@.part_config SET maintenance_last_run = clock_timestamp() WHERE parent_table = v_row.parent_table; CONTINUE; END IF; RAISE DEBUG 'run_maint: v_child_timestamp: %, v_current_partition_timestamp: %, v_max_time_default: %', v_child_timestamp, v_current_partition_timestamp, v_max_time_default; IF v_current_partition_timestamp IS NULL OR (v_max_time_default > v_current_partition_timestamp) THEN SELECT suffix_timestamp INTO v_current_partition_timestamp FROM @extschema@.show_partition_name(v_row.parent_table, v_max_time_default::text); END IF; -- If this is a subpartition, determine if the last child table has been made. If so, mark it as full so future maintenance runs can skip it SELECT sub_min::timestamptz, sub_max::timestamptz INTO v_sub_timestamp_min, v_sub_timestamp_max FROM @extschema@.check_subpartition_limits(v_row.parent_table, 'time'); IF v_sub_timestamp_max IS NOT NULL THEN SELECT suffix_timestamp INTO v_sub_timestamp_max_suffix FROM @extschema@.show_partition_name(v_row.parent_table, v_sub_timestamp_max::text); IF v_sub_timestamp_max_suffix = v_last_partition_timestamp THEN -- Final partition for this set is created. Set full and skip it UPDATE @extschema@.part_config SET sub_partition_set_full = true, maintenance_last_run = clock_timestamp() WHERE parent_table = v_row.parent_table; CONTINUE; END IF; END IF; -- Check and see how many premade partitions there are. v_premade_count = round(EXTRACT('epoch' FROM age(v_last_partition_timestamp, v_current_partition_timestamp)) / EXTRACT('epoch' FROM v_row.partition_interval::interval)); v_next_partition_timestamp := v_last_partition_timestamp; RAISE DEBUG 'run_maint before loop: last_partition_timestamp: %, current_partition_timestamp: %, v_premade_count: %, v_sub_timestamp_min: %, v_sub_timestamp_max: %' , v_last_partition_timestamp , v_current_partition_timestamp , v_premade_count , v_sub_timestamp_min , v_sub_timestamp_max; -- Loop premaking until config setting is met. Allows it to catch up if it fell behind or if premake changed WHILE (v_premade_count < v_row.premake) LOOP RAISE DEBUG 'run_maint: parent_table: %, v_premade_count: %, v_next_partition_timestamp: %', v_row.parent_table, v_premade_count, v_next_partition_timestamp; IF v_next_partition_timestamp < v_sub_timestamp_min OR v_next_partition_timestamp > v_sub_timestamp_max THEN -- With subpartitioning, no need to run if the timestamp is not in the parent table's range EXIT; END IF; BEGIN v_next_partition_timestamp := v_next_partition_timestamp + v_row.partition_interval::interval; EXCEPTION WHEN datetime_field_overflow THEN v_premade_count := v_row.premake; -- do this so it can exit the premake check loop and continue in the outer for loop IF v_jobmon_schema IS NOT NULL THEN v_step_overflow_id := add_step(v_job_id, 'Attempted partition time interval is outside PostgreSQL''s supported time range.'); PERFORM update_step(v_step_overflow_id, 'CRITICAL', format('Child partition creation skipped for parent table: %s', v_partition_time)); END IF; RAISE WARNING 'Attempted partition time interval is outside PostgreSQL''s supported time range. Child partition creation skipped for parent table %', v_row.parent_table; CONTINUE; END; v_last_partition_created := @extschema@.create_partition_time(v_row.parent_table , ARRAY[v_next_partition_timestamp]); IF v_last_partition_created THEN v_analyze := true; v_create_count := v_create_count + 1; END IF; v_premade_count = round(EXTRACT('epoch' FROM age(v_next_partition_timestamp, v_current_partition_timestamp)) / EXTRACT('epoch' FROM v_row.partition_interval::interval)); END LOOP; -- Run retention if needed. Note similar call above when partition set is empty. Keep in sync. IF v_row.retention IS NOT NULL THEN v_drop_count := v_drop_count + @extschema@.drop_partition_time(v_row.parent_table); END IF; ELSIF v_control_type = 'id' THEN IF v_row.sub_partition_set_full THEN UPDATE @extschema@.part_config SET maintenance_last_run = clock_timestamp() WHERE parent_table = v_row.parent_table; CONTINUE; END IF; -- Must be reset to null otherwise if the next partition set in the loop is empty, the previous partition set's value could be used v_current_partition_id := NULL; FOR v_row_max_id IN SELECT partition_schemaname, partition_tablename FROM @extschema@.show_partitions(v_row.parent_table, 'DESC', false) LOOP -- Loop through child tables starting from highest to get current max value in partition set -- Avoids doing a scan on entire partition set and/or getting any values accidentally in default. EXECUTE format('SELECT trunc(max(%I))::bigint FROM %I.%I' , v_row.control , v_row_max_id.partition_schemaname , v_row_max_id.partition_tablename) INTO v_max_id; IF v_max_id IS NOT NULL THEN SELECT suffix_id INTO v_current_partition_id FROM @extschema@.show_partition_name(v_row.parent_table, v_max_id::text); EXIT; END IF; END LOOP; -- If not ignoring the default table, check for max values there. If they are there and greater than all child values, use that instead -- Note the default is NOT to care about data in the default, so maintenance will fail if new child table boundaries overlap with -- data that exists in the default. This is intentional so user removes data from default to avoid larger problems. IF v_row.ignore_default_data THEN v_max_id_default := NULL; ELSE EXECUTE format('SELECT trunc(max(%I))::bigint FROM ONLY %I.%I', v_row.control, v_parent_schema, v_default_tablename) INTO v_max_id_default; END IF; RAISE DEBUG 'run_maint: v_max_id: %, v_current_partition_id: %, v_max_id_default: %', v_max_id, v_current_partition_id, v_max_id_default; IF v_current_partition_id IS NULL AND v_max_id_default IS NULL THEN -- Partition set is completely empty. -- Still need to run retention if needed. Note similar call below for non-empty sets. Keep in sync. IF v_row.retention IS NOT NULL THEN v_drop_count := v_drop_count + @extschema@.drop_partition_id(v_row.parent_table); END IF; -- Nothing else to do UPDATE @extschema@.part_config SET maintenance_last_run = clock_timestamp() WHERE parent_table = v_row.parent_table; CONTINUE; END IF; IF v_current_partition_id IS NULL OR (v_max_id_default > v_current_partition_id) THEN SELECT suffix_id INTO v_current_partition_id FROM @extschema@.show_partition_name(v_row.parent_table, v_max_id_default::text); END IF; SELECT child_start_id INTO v_last_partition_id FROM @extschema@.show_partition_info(v_parent_schema||'.'||v_last_partition, v_row.partition_interval, v_row.parent_table); -- Determine if this table is a child of a subpartition parent. If so, get limits to see if run_maintenance even needs to run for it. SELECT sub_min::bigint, sub_max::bigint INTO v_sub_id_min, v_sub_id_max FROM @extschema@.check_subpartition_limits(v_row.parent_table, 'id'); IF v_sub_id_max IS NOT NULL THEN SELECT suffix_id INTO v_sub_id_max_suffix FROM @extschema@.show_partition_name(v_row.parent_table, v_sub_id_max::text); IF v_sub_id_max_suffix = v_last_partition_id THEN -- Final partition for this set is created. Set full and skip it UPDATE @extschema@.part_config SET sub_partition_set_full = true, maintenance_last_run = clock_timestamp() WHERE parent_table = v_row.parent_table; CONTINUE; END IF; END IF; v_next_partition_id := v_last_partition_id; v_premade_count := ((v_last_partition_id - v_current_partition_id) / v_row.partition_interval::bigint); -- Loop premaking until config setting is met. Allows it to catch up if it fell behind or if premake changed. RAISE DEBUG 'run_maint: before child creation loop: parent_table: %, v_last_partition_id: %, v_premade_count: %, v_next_partition_id: %', v_row.parent_table, v_last_partition_id, v_premade_count, v_next_partition_id; WHILE (v_premade_count < v_row.premake) LOOP RAISE DEBUG 'run_maint: parent_table: %, v_premade_count: %, v_next_partition_id: %', v_row.parent_table, v_premade_count, v_next_partition_id; IF v_next_partition_id < v_sub_id_min OR v_next_partition_id > v_sub_id_max THEN -- With subpartitioning, no need to run if the id is not in the parent table's range EXIT; END IF; v_next_partition_id := v_next_partition_id + v_row.partition_interval::bigint; v_last_partition_created := @extschema@.create_partition_id(v_row.parent_table, ARRAY[v_next_partition_id]); IF v_last_partition_created THEN v_analyze := true; v_create_count := v_create_count + 1; END IF; v_premade_count := ((v_next_partition_id - v_current_partition_id) / v_row.partition_interval::bigint); END LOOP; -- Run retention if needed. Note similar call above when partition set is empty. Keep in sync. IF v_row.retention IS NOT NULL THEN v_drop_count := v_drop_count + @extschema@.drop_partition_id(v_row.parent_table); END IF; END IF; -- end main IF check for time or id IF v_analyze AND p_analyze THEN IF v_jobmon_schema IS NOT NULL THEN v_step_id := add_step(v_job_id, format('Analyzing partition set: %s', v_row.parent_table)); END IF; EXECUTE format('ANALYZE %I.%I',v_parent_schema, v_parent_tablename); IF v_jobmon_schema IS NOT NULL THEN PERFORM update_step(v_step_id, 'OK', 'Done'); END IF; END IF; UPDATE @extschema@.part_config SET maintenance_last_run = clock_timestamp() WHERE parent_table = v_row.parent_table; END LOOP; -- end of main loop through part_config IF v_jobmon_schema IS NOT NULL THEN v_step_id := add_step(v_job_id, format('Finished maintenance')); PERFORM update_step(v_step_id, 'OK', format('Partition maintenance finished. %s partitions made. %s partitions dropped.', v_create_count, v_drop_count)); IF v_step_overflow_id IS NOT NULL THEN PERFORM fail_job(v_job_id); ELSE PERFORM close_job(v_job_id); END IF; END IF; EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false'); EXCEPTION WHEN OTHERS THEN GET STACKED DIAGNOSTICS ex_message = MESSAGE_TEXT, ex_context = PG_EXCEPTION_CONTEXT, ex_detail = PG_EXCEPTION_DETAIL, ex_hint = PG_EXCEPTION_HINT; IF v_jobmon_schema IS NOT NULL THEN IF v_job_id IS NULL THEN EXECUTE format('SELECT %I.add_job(''PARTMAN RUN MAINTENANCE'')', v_jobmon_schema) INTO v_job_id; EXECUTE format('SELECT %I.add_step(%s, ''EXCEPTION before job logging started'')', v_jobmon_schema, v_job_id, p_parent_table) INTO v_step_id; ELSIF v_step_id IS NULL THEN EXECUTE format('SELECT %I.add_step(%s, ''EXCEPTION before first step logged'')', v_jobmon_schema, v_job_id) INTO v_step_id; END IF; EXECUTE format('SELECT %I.update_step(%s, ''CRITICAL'', %L)', v_jobmon_schema, v_step_id, 'ERROR: '||coalesce(SQLERRM,'unknown')); EXECUTE format('SELECT %I.fail_job(%s)', v_jobmon_schema, v_job_id); END IF; RAISE EXCEPTION '% CONTEXT: % DETAIL: % HINT: %', ex_message, ex_context, ex_detail, ex_hint; END $$; -- Restore dropped object privileges DO $$ DECLARE v_row record; BEGIN FOR v_row IN SELECT statement FROM partman_preserve_privs_temp LOOP IF v_row.statement IS NOT NULL THEN EXECUTE v_row.statement; END IF; END LOOP; END $$; DROP TABLE IF EXISTS partman_preserve_privs_temp;