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 ) RETURNS bigint LANGUAGE plpgsql AS $$ DECLARE v_analyze boolean := FALSE; v_column_list 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_parent_schema 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_total_rows bigint := 0; BEGIN /* * Populate the child table(s) of a time-based partition set with old data from the original parent */ SELECT partition_interval::interval , control , datetime_string , epoch INTO v_partition_interval , v_control , 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; 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_schema := 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 <> 'id' THEN RAISE EXCEPTION 'Cannot run on partition set without time based control column or epoch flag set with an id column. Found control: %, epoch: %', v_control_type, v_epoch; END IF; END IF; -- 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 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 INDEXES) ON COMMIT DROP', 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 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 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[])); FOR i IN 1..p_batch_count LOOP 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; 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_source_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 %s FROM ONLY %I.%I WHERE %s >= %L AND %4$s < %6$L FOR UPDATE NOWAIT' , v_column_list , 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 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 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 partman_temp_data_storage (%6$s) SELECT %6$s FROM partition_data' , v_source_schemaname , v_source_tablename , v_partition_expression , v_min_partition_timestamp , v_max_partition_timestamp , v_column_list); -- 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 partman_temp_data_storage RETURNING *) INSERT INTO %I.%I (%3$s) SELECT %3$s FROM partition_data' , v_parent_schema , v_current_partition_name , v_column_list); ELSE -- 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 ONLY %I.%I WHERE %s >= %L AND %3$s < %5$L RETURNING *) INSERT INTO %6$I.%7$I (%8$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_schema , v_current_partition_name , v_column_list); 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_schema, v_parent_tablename; EXECUTE format('ANALYZE %I.%I', v_parent_schema, v_parent_tablename); RAISE DEBUG 'partiton_data_time: End analyze of %.%', v_parent_schema, v_parent_tablename; END IF; RETURN v_total_rows; END $$;