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) RETURNS bigint LANGUAGE plpgsql AS $$ DECLARE 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_new_search_path text := '@extschema@,pg_temp'; v_old_search_path text; v_parent_tablename text; v_partition_interval bigint; v_partition_id bigint[]; v_partition_type text; 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 old data from the original parent */ SELECT partition_interval::bigint , partition_type , control , epoch INTO v_partition_interval , v_partition_type , 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 real parent tablename for use below 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; ELSIF v_partition_type = 'native' AND current_setting('server_version_num')::int >= 110000 THEN 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 in a native set. 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 PG11+, p_source_table is not set, and it exists -- Otherwise just return with a DEBUG that no data source exists v_sql := format('SELECT n.nspname::text, c.relname::text 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 = ''%I.%I''::regclass AND pg_get_expr(relpartbound, c.oid) = ''DEFAULT''' , v_source_schemaname , v_source_tablename); EXECUTE v_sql INTO v_default_schemaname, v_default_tablename; 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)', 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; SELECT current_setting('search_path') INTO v_old_search_path; EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_new_search_path, 'false'); IF p_batch_interval IS NULL OR p_batch_interval > v_partition_interval THEN p_batch_interval := v_partition_interval; END IF; 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 v_default_exists THEN -- Child tables cannot be created in native partitioning 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$I >= %4$s AND %3$I < %5$s RETURNING *) INSERT INTO partman_temp_data_storage SELECT * FROM partition_data' , v_source_schemaname , v_source_tablename , v_control , v_min_partition_id , v_max_partition_id); PERFORM @extschema@.create_partition_id(p_parent_table, v_partition_id, p_analyze); EXECUTE format('WITH partition_data AS ( DELETE FROM partman_temp_data_storage RETURNING *) INSERT INTO %I.%I SELECT * FROM partition_data' , v_source_schemaname , v_current_partition_name); ELSE PERFORM @extschema@.create_partition_id(p_parent_table, v_partition_id, p_analyze); 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 %1$I.%6$I SELECT * FROM partition_data' , v_source_schemaname , v_source_tablename , v_control , v_min_partition_id , v_max_partition_id , v_current_partition_name); 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; IF v_partition_type = 'partman' THEN PERFORM @extschema@.create_function_id(p_parent_table); END IF; EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false'); RETURN v_total_rows; END $$;