/* * Create a partition set that is a subpartition of an already existing partition set. * Given the parent table of any current partition set, it will turn all existing children into parent tables of their own partition sets * using the configuration options given as parameters to this function. * Uses another config table that allows for turning all future child partitions into a new parent automatically. * To avoid logical complications and contention issues, ALL subpartitions must be maintained using run_maintenance(). * This means the automatic, trigger based partition creation for serial partitioning will not work if it is a subpartition. */ CREATE FUNCTION create_sub_parent( p_top_parent text , p_control text , p_type text , p_interval text , p_constraint_cols text[] DEFAULT NULL , p_premake int DEFAULT 4 , p_start_partition text DEFAULT NULL , p_inherit_fk boolean DEFAULT true , p_epoch boolean DEFAULT false , p_upsert text DEFAULT '' , p_jobmon boolean DEFAULT true , p_debug boolean DEFAULT false) RETURNS boolean LANGUAGE plpgsql SECURITY DEFINER AS $$ DECLARE v_last_partition text; v_new_search_path text := '@extschema@,pg_temp'; v_old_search_path text; v_parent_interval text; v_parent_type text; v_row record; v_row_last_part record; v_run_maint boolean; v_sql text; v_success boolean := false; v_top_type text; BEGIN SELECT use_run_maintenance INTO v_run_maint FROM @extschema@.part_config WHERE parent_table = p_top_parent; IF v_run_maint IS NULL THEN RAISE EXCEPTION 'Cannot subpartition a table that is not managed by pg_partman already. Given top parent table not found in @extschema@.part_config: %', p_top_parent; ELSIF v_run_maint = false THEN RAISE EXCEPTION 'Any parent table that will be part of a sub-partitioned set (on any level) must have use_run_maintenance set to true in part_config table, even for serial partitioning. See documentation for more info.'; END IF; IF p_upsert <> '' AND @extschema@.check_version('9.5.0') = 'false' THEN RAISE EXCEPTION 'INSERT ... ON CONFLICT (UPSERT) feature is only supported in PostgreSQL 9.5 and later'; 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'); FOR v_row IN -- Loop through all current children to turn them into partitioned tables SELECT partition_schemaname||'.'||partition_tablename AS child_table FROM @extschema@.show_partitions(p_top_parent) LOOP SELECT partition_type, partition_interval INTO v_parent_type, v_parent_interval FROM @extschema@.part_config WHERE parent_table = v_row.child_table; IF v_parent_interval = p_interval THEN EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false'); RAISE EXCEPTION 'Sub-partition interval cannot be equal to parent interval'; END IF; IF (v_parent_type = 'time' OR v_parent_type = 'time-custom') AND (p_type = 'time' OR p_type = 'time-custom') THEN IF p_interval::interval > v_parent_interval::interval THEN EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false'); RAISE EXCEPTION 'Sub-partition interval cannot be greater than the given parent interval'; END IF; IF p_interval = 'weekly' AND v_parent_interval::interval > '1 week'::interval THEN EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false'); RAISE EXCEPTION 'Due to conflicting data boundaries between ISO weeks and any larger interval of time, pg_partman cannot support a sub-partition interval of weekly'; END IF; ELSIF v_parent_type = 'id' THEN IF p_interval::bigint > v_parent_interval::bigint THEN EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false'); RAISE EXCEPTION 'Sub-partition interval cannot be greater than the given parent interval'; END IF; END IF; -- Just call existing create_parent() function but add the given parameters to the part_config_sub table as well v_sql := format('SELECT @extschema@.create_parent( p_parent_table := %L , p_control := %L , p_type := %L , p_interval := %L , p_constraint_cols := %L , p_premake := %L , p_use_run_maintenance := %L , p_start_partition := %L , p_inherit_fk := %L , p_epoch := %L , p_upsert := %L , p_jobmon := %L , p_debug := %L )' , v_row.child_table , p_control , p_type , p_interval , p_constraint_cols , p_premake , true , p_start_partition , p_inherit_fk , p_epoch , p_upsert , p_jobmon , p_debug); EXECUTE v_sql; END LOOP; INSERT INTO @extschema@.part_config_sub ( sub_parent , sub_control , sub_partition_type , sub_partition_interval , sub_constraint_cols , sub_premake , sub_inherit_fk , sub_use_run_maintenance , sub_epoch , sub_upsert , sub_jobmon) VALUES ( p_top_parent , p_control , p_type , p_interval , p_constraint_cols , p_premake , p_inherit_fk , true , p_epoch , p_upsert , p_jobmon); v_success := true; EXECUTE format('SELECT set_config(%L, %L, %L)', 'search_path', v_old_search_path, 'false'); RETURN v_success; END $$;