1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211
|
CREATE FUNCTION @extschema@.inherit_template_properties(
p_parent_table text
, p_child_schema text
, p_child_tablename text
)
RETURNS boolean
LANGUAGE plpgsql
AS $$
DECLARE
v_child_relkind char;
v_child_schema text;
v_child_tablename text;
v_child_unlogged char;
v_dupe_found boolean := false;
v_index_list record;
v_parent_index_list record;
v_parent_oid oid;
v_parent_table text;
v_relopt record;
v_sql text;
v_template_oid oid;
v_template_schemaname text;
v_template_table text;
v_template_tablename name;
v_template_unlogged char;
BEGIN
/*
* Function to inherit the properties of the template table to newly created child tables.
* For PG14+, used to inherit non-partition-key unique indexes & primary keys, unlogged status, and relation options
*/
SELECT parent_table, template_table
INTO v_parent_table, v_template_table
FROM @extschema@.part_config
WHERE parent_table = p_parent_table;
IF v_parent_table IS NULL THEN
RAISE EXCEPTION 'Given parent table has no configuration in pg_partman: %', p_parent_table;
ELSIF v_template_table IS NULL THEN
RAISE EXCEPTION 'No template table set in configuration for given parent table: %', p_parent_table;
END IF;
SELECT c.oid INTO 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(p_parent_table, '.', 1)::name
AND c.relname = split_part(p_parent_table, '.', 2)::name;
IF v_parent_oid IS NULL THEN
RAISE EXCEPTION 'Unable to find given parent table in system catalogs: %', p_parent_table;
END IF;
SELECT n.nspname, c.relname, c.relkind INTO v_child_schema, v_child_tablename, v_child_relkind
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE n.nspname = p_child_schema::name
AND c.relname = p_child_tablename::name;
IF v_child_tablename IS NULL THEN
RAISE EXCEPTION 'Unable to find given child table in system catalogs: %.%', v_child_schema, v_child_tablename;
END IF;
IF v_child_relkind = 'p' THEN
-- Subpartitioned parent, do not apply properties
RAISE DEBUG 'inherit_template_properties: found given child is subpartition parent, so properties not inherited';
RETURN false;
END IF;
v_template_schemaname := split_part(v_template_table, '.', 1)::name;
v_template_tablename := split_part(v_template_table, '.', 2)::name;
SELECT c.oid INTO v_template_oid
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
LEFT OUTER JOIN pg_catalog.pg_tablespace ts ON c.reltablespace = ts.oid
WHERE n.nspname = v_template_schemaname
AND c.relname = v_template_tablename;
IF v_template_oid IS NULL THEN
RAISE EXCEPTION 'Unable to find configured template table in system catalogs: %', v_template_table;
END IF;
-- Index creation (Only for unique, non-partition key indexes)
FOR v_index_list IN
SELECT
array_to_string(regexp_matches(pg_get_indexdef(indexrelid), ' USING .*'),',') AS statement
, i.indisprimary
, i.indisunique
, ( SELECT array_agg( a.attname ORDER by x.r )
FROM pg_catalog.pg_attribute a
JOIN ( SELECT k, row_number() over () as r
FROM unnest(i.indkey) k ) as x
ON a.attnum = x.k AND a.attrelid = i.indrelid
) AS indkey_names
, c.relname AS index_name
, ts.spcname AS tablespace_name
FROM pg_catalog.pg_index i
JOIN pg_catalog.pg_class c ON i.indexrelid = c.oid
LEFT OUTER JOIN pg_catalog.pg_tablespace ts ON c.reltablespace = ts.oid
WHERE i.indrelid = v_template_oid
AND i.indisvalid
AND (i.indisprimary OR i.indisunique)
ORDER BY 1
LOOP
v_dupe_found := false;
FOR v_parent_index_list IN
SELECT
array_to_string(regexp_matches(pg_get_indexdef(indexrelid), ' USING .*'),',') AS statement
, i.indisprimary
, ( SELECT array_agg( a.attname ORDER by x.r )
FROM pg_catalog.pg_attribute a
JOIN ( SELECT k, row_number() over () as r
FROM unnest(i.indkey) k ) as x
ON a.attnum = x.k AND a.attrelid = i.indrelid
) AS indkey_names
FROM pg_catalog.pg_index i
WHERE i.indrelid = v_parent_oid
AND i.indisvalid
ORDER BY 1
LOOP
IF v_parent_index_list.indisprimary AND v_index_list.indisprimary THEN
IF v_parent_index_list.indkey_names = v_index_list.indkey_names THEN
RAISE DEBUG 'inherit_template_properties: Ignoring duplicate primary key on template table: % ', v_index_list.indkey_names;
v_dupe_found := true;
CONTINUE; -- only continue within this nested loop
END IF;
END IF;
IF v_parent_index_list.statement = v_index_list.statement THEN
RAISE DEBUG 'inherit_template_properties: Ignoring duplicate unique index on template table: %', v_index_list.statement;
v_dupe_found := true;
CONTINUE; -- only continue within this nested loop
END IF;
END LOOP; -- end parent index loop
IF v_dupe_found = true THEN
CONTINUE;
END IF;
IF v_index_list.indisprimary THEN
v_sql := format('ALTER TABLE %I.%I ADD PRIMARY KEY (%s)'
, v_child_schema
, v_child_tablename
, '"' || array_to_string(v_index_list.indkey_names, '","') || '"');
IF v_index_list.tablespace_name IS NOT NULL THEN
v_sql := v_sql || format(' USING INDEX TABLESPACE %I', v_index_list.tablespace_name);
END IF;
RAISE DEBUG 'inherit_template_properties: Create pk: %', v_sql;
EXECUTE v_sql;
ELSIF v_index_list.indisunique THEN
-- statement column should be just the portion of the index definition that defines what it actually is
v_sql := format('CREATE UNIQUE INDEX ON %I.%I %s', v_child_schema, v_child_tablename, v_index_list.statement);
IF v_index_list.tablespace_name IS NOT NULL THEN
IF (ARRAY_length(regexp_matches(v_sql, ' WHERE ', 'i'), 1) > 0) THEN
v_sql := regexp_replace(v_sql, ' WHERE ', format(' TABLESPACE %I WHERE ', v_index_list.tablespace_name), 'i');
ELSE
v_sql := v_sql || format(' TABLESPACE %I', v_index_list.tablespace_name);
END IF;
END IF;
RAISE DEBUG 'inherit_template_properties: Create index: %', v_sql;
EXECUTE v_sql;
ELSE
RAISE EXCEPTION 'inherit_template_properties: Unexpected code path in unique index creation. Please report the steps that lead to this error to extension maintainers.';
END IF;
END LOOP;
-- End index creation
-- UNLOGGED status. Currently waiting on final stance of how upstream will handle this property being changed for its children.
-- See release notes for v4.2.0
SELECT relpersistence INTO v_template_unlogged
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE n.nspname = v_template_schemaname
AND c.relname = v_template_tablename;
SELECT relpersistence INTO v_child_unlogged
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid
WHERE n.nspname = v_child_schema::name
AND c.relname = v_child_tablename::name;
IF v_template_unlogged = 'u' AND v_child_unlogged = 'p' THEN
v_sql := format ('ALTER TABLE %I.%I SET UNLOGGED', v_child_schema, v_child_tablename);
RAISE DEBUG 'inherit_template_properties: Alter UNLOGGED: %', v_sql;
EXECUTE v_sql;
ELSIF v_template_unlogged = 'p' AND v_child_unlogged = 'u' THEN
v_sql := format ('ALTER TABLE %I.%I SET LOGGED', v_child_schema, v_child_tablename);
RAISE DEBUG 'inherit_template_properties: Alter UNLOGGED: %', v_sql;
EXECUTE v_sql;
END IF;
-- Relation options are not either not being inherited or not supported (autovac tuning) on <= PG15
FOR v_relopt IN
SELECT unnest(reloptions) as value
FROM pg_catalog.pg_class
WHERE oid = v_template_oid
LOOP
v_sql := format('ALTER TABLE %I.%I SET (%s)'
, v_child_schema
, v_child_tablename
, v_relopt.value);
RAISE DEBUG 'inherit_template_properties: Set relopts: %', v_sql;
EXECUTE v_sql;
END LOOP;
RETURN true;
END
$$;
|