|
| 1 | +/* |
| 2 | +This function generates a set of statements to create concurrent indexes on all partitions of a partitioned tables and a |
| 3 | +create index statement for the parent table. In case the table is partitioned on a column which is not part of the |
| 4 | +primary key, also a create index statement for the <table>_template is returned as wel. It does not execute these |
| 5 | +statements. |
| 6 | +
|
| 7 | +The function tries to find a unique index name in the form of <table_name>_<columns>[1-9]_idx. If no unique name |
| 8 | +can be found, the name with a nine in it will we returned. Executing this statement will fail with a duplicate index error. |
| 9 | +
|
| 10 | +When a unique index has to be created, we only add this index on the parent table when the partition column is included |
| 11 | +in the index. Otherwise we would get an error. |
| 12 | +
|
| 13 | + PARAMETER TYPE DESCRIPTION |
| 14 | + v_schema TEXT schema location for the table |
| 15 | + v_tablename TEXT the parent table name |
| 16 | + v_columns TEXT[] the columns to create the index on including the names the operator class parameters such as desc, nulls first, nulls distinct |
| 17 | + v_method TEXT the name of the index method, default btree. Possible other values: hash, gist, spgist, gin, brin |
| 18 | + v_is_unique BOOLEAN default false. Indicate the index has to be unique |
| 19 | +
|
| 20 | +Example: |
| 21 | + SELECT dba.partition_add_concurrent_index_on_partitioned_table('public','test_partition', ARRAY['column_1', 'column_2']); |
| 22 | + SELECT dba.partition_add_concurrent_index_on_partitioned_table('public','test_partition', ARRAY['lower(column_1)', 'column_2 desc nulls first'], 'gin'); |
| 23 | + SELECT dba.partition_add_concurrent_index_on_partitioned_table('public','test_partition', ARRAY['lower(column_1)', 'column_2 desc nulls first'], 'gin', true); |
| 24 | +
|
| 25 | +Returns: |
| 26 | + A table containing the following statements in order |
| 27 | + - A create index concurrently statement for every child table |
| 28 | + - A create index statement for the parent table |
| 29 | + - A create index statement for the parent_template table when this table exists |
| 30 | +*/ |
| 31 | + |
| 32 | +CREATE OR REPLACE FUNCTION dba.partition_add_concurrent_index_on_partitioned_table(v_schema TEXT, v_table TEXT, v_columns TEXT[], v_method TEXT default 'btree', v_is_unique boolean DEFAULT FALSE) |
| 33 | +RETURNS table(stmt text) LANGUAGE plpgsql AS $func$ |
| 34 | + |
| 35 | +DECLARE |
| 36 | + v_indexname TEXT; |
| 37 | + v_row RECORD; |
| 38 | + v_row_count INT; |
| 39 | + v_column_names TEXT[]; |
| 40 | + v_total_indexes INT; |
| 41 | + v_column_name TEXT; |
| 42 | + |
| 43 | +BEGIN |
| 44 | + v_schema:=LOWER(v_schema); |
| 45 | + v_table:=LOWER(v_table); |
| 46 | + |
| 47 | + -- When creating a unique index we need to know the partition column |
| 48 | + IF (v_is_unique) THEN |
| 49 | + EXECUTE format($sel$ |
| 50 | + SELECT |
| 51 | + LOWER(col.column_name) |
| 52 | + FROM |
| 53 | + (SELECT |
| 54 | + partrelid, |
| 55 | + unnest(partattrs) column_index |
| 56 | + FROM |
| 57 | + pg_partitioned_table) pt |
| 58 | + JOIN pg_class c on c.oid = pt.partrelid |
| 59 | + JOIN information_schema.columns col ON |
| 60 | + col.table_schema = c.relnamespace::regnamespace::text |
| 61 | + AND col.table_name = c.relname |
| 62 | + AND ordinal_position = pt.column_index |
| 63 | + WHERE |
| 64 | + c.relname = '%I' |
| 65 | + and relnamespace::regnamespace::text='%I' |
| 66 | + $sel$, v_table, v_schema) |
| 67 | + INTO v_column_name; |
| 68 | + END IF; |
| 69 | + |
| 70 | + -- separate the column names from the rest of the arguments like functions and operators like 'desc', 'nulls first', etc |
| 71 | + SELECT ARRAY (SELECT regexp_replace(split_part(UNNEST(v_columns), ' ', 1), '.*\((.*)\)', '\1')) |
| 72 | + INTO v_column_names; |
| 73 | + |
| 74 | + IF (SELECT LOWER(v_method) NOT IN ('btree', 'hash', 'gist', 'spgist', 'gin', 'brin') ) THEN |
| 75 | + RAISE EXCEPTION 'Index method % is not supported', v_method; |
| 76 | + END IF; |
| 77 | + |
| 78 | + -- Create a temporary table to store the results. |
| 79 | + CREATE TEMP TABLE IF NOT EXISTS temp_partition_concurrent_indexes (order_number int, table_name text, index_name text) |
| 80 | + ON COMMIT DELETE ROWS; |
| 81 | + |
| 82 | + -- List all the child partitions |
| 83 | + EXECUTE FORMAT ($sql$ |
| 84 | + INSERT INTO temp_partition_concurrent_indexes ( |
| 85 | + SELECT |
| 86 | + 1 AS order_number, |
| 87 | + child.relname as table_name, |
| 88 | + substring(LOWER(child.relname) || '_%I' , 1, 59) || '_idx' AS index_name |
| 89 | + FROM pg_inherits |
| 90 | + JOIN pg_class parent ON pg_inherits.inhparent = parent.oid |
| 91 | + JOIN pg_class child ON pg_inherits.inhrelid = child.oid |
| 92 | + JOIN pg_namespace nmsp_child ON nmsp_child.oid = child.relnamespace |
| 93 | + WHERE |
| 94 | + LOWER(parent.relnamespace::regnamespace::text) = LOWER('%I') |
| 95 | + AND LOWER(parent.relname)=LOWER('%I')) |
| 96 | + $sql$, |
| 97 | + LOWER(array_to_string(v_column_names, '_')), v_schema, v_table); |
| 98 | + |
| 99 | + -- Add the parent table if a non-unique index OR it is a unique index, but the index contains the partition column |
| 100 | + IF ( ( NOT v_is_unique) OR ( v_is_unique AND v_column_name=ANY(lower(v_columns::text)::text[]) ) )THEN |
| 101 | + EXECUTE FORMAT ($sql$ |
| 102 | + INSERT INTO temp_partition_concurrent_indexes values (2, '%I', substring(LOWER('%I') || '_%I', 1, 59) || '_idx') |
| 103 | + $sql$, v_table, v_table, LOWER(array_to_string(v_column_names, '_'))); |
| 104 | + END IF; |
| 105 | + |
| 106 | + -- Check if _template table exists |
| 107 | + perform 1 |
| 108 | + FROM pg_class c |
| 109 | + WHERE LOWER(c.relname) = LOWER(v_table || '_template') AND LOWER(c.relnamespace::regnamespace::text) = LOWER(v_schema); |
| 110 | + |
| 111 | + IF FOUND THEN |
| 112 | + EXECUTE FORMAT ($sql$ |
| 113 | + INSERT INTO temp_partition_concurrent_indexes values (3, '%I_template', substring(LOWER('%I_template') || '_%I', 1, 59) || '_idx') |
| 114 | + $sql$, v_table, v_table, LOWER(array_to_string(v_column_names, '_'))); |
| 115 | + END IF; |
| 116 | + |
| 117 | + FOR v_row IN SELECT * FROM temp_partition_concurrent_indexes LOOP |
| 118 | + EXECUTE FORMAT ($sql$ |
| 119 | + SELECT '1' FROM pg_class c, pg_namespace n WHERE c.relnamespace = n.oid |
| 120 | + AND relname = '%I' AND nspname = '%I' AND lower(relkind) = 'i' |
| 121 | + $sql$, v_row.index_name, v_schema) ; |
| 122 | + |
| 123 | + GET DIAGNOSTICS v_row_count = ROW_COUNT; |
| 124 | + |
| 125 | + IF v_row_count = 0 THEN |
| 126 | + -- Index name is unique. We are done. |
| 127 | + continue; |
| 128 | + ELSE |
| 129 | + -- An index with this name already exists. Remove the suffix and add a number at the end. |
| 130 | + -- After number 9 we give up and executing the create index statement will fail. |
| 131 | + FOR counter in 1..9 LOOP |
| 132 | + IF LENGTH(v_row.index_name) = 64 THEN |
| 133 | + -- We should not cross the 64 characters when adding a number. Remove the suffix and one character. |
| 134 | + v_indexname := left(v_row.index_name , -5) || counter || '_idx'; |
| 135 | + ELSE |
| 136 | + v_indexname := left(v_row.index_name , -4) || counter || '_idx'; |
| 137 | + END IF; |
| 138 | + |
| 139 | + RAISE DEBUG 'Testing index name % for uniqueness', v_indexname; |
| 140 | + |
| 141 | + EXECUTE FORMAT ($sql$ |
| 142 | + SELECT '1' FROM pg_class c, pg_namespace n WHERE c.relnamespace = n.oid |
| 143 | + AND relname = '%I' AND nspname = '%I' AND lower(relkind) = 'i' |
| 144 | + $sql$, v_indexname, v_schema) ; |
| 145 | + |
| 146 | + GET DIAGNOSTICS v_row_count = ROW_COUNT; |
| 147 | + |
| 148 | + IF v_row_count = 0 THEN |
| 149 | + -- We have found a unique index name. Update the temp table with this name. |
| 150 | + EXECUTE FORMAT($sql$ UPDATE temp_partition_concurrent_indexes SET index_name = '%I' WHERE table_name = '%I' |
| 151 | + $sql$, v_indexname, v_row.table_name); |
| 152 | + |
| 153 | + exit; |
| 154 | + END IF; |
| 155 | + END LOOP; |
| 156 | + END IF; |
| 157 | + END LOOP; |
| 158 | + |
| 159 | + SELECT COUNT(*) FROM temp_partition_concurrent_indexes |
| 160 | + INTO v_total_indexes; |
| 161 | + |
| 162 | + RETURN QUERY |
| 163 | + EXECUTE format($sql$ |
| 164 | + SELECT '/* Creating index ' || row_number() over (order by order_number, index_name) || ' of %s */ create ' || |
| 165 | + CASE WHEN '%I'::boolean THEN 'unique ' ELSE '' END || |
| 166 | + 'index ' || |
| 167 | + CASE WHEN order_number = 1 THEN 'concurrently ' ELSE '' END || |
| 168 | + index_name || ' on %I.' || |
| 169 | + table_name || ' using %I (%s);' |
| 170 | + FROM temp_partition_concurrent_indexes |
| 171 | + ORDER BY order_number, index_name |
| 172 | + $sql$, v_total_indexes, v_is_unique, v_schema, v_method, LOWER(array_to_string(v_columns, ', '))); |
| 173 | +END |
| 174 | +$func$; |
0 commit comments