├── _2gis_partition_magic_test.sql ├── README.md └── _2gis_partition_magic.sql /_2gis_partition_magic_test.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION test_table_before_insert_trigger() RETURNS trigger AS $$ 2 | BEGIN 3 | NEW.id = (NEW.project_id::bit(64) << 47 | NEW.id::bit(64))::bigint; 4 | RETURN NEW; 5 | END; 6 | $$ LANGUAGE plpgsql; 7 | 8 | CREATE OR REPLACE FUNCTION initTestPartitions() RETURNS VOID AS $$ 9 | BEGIN 10 | DROP SEQUENCE IF EXISTS "test_table_id_seq1" CASCADE; 11 | CREATE SEQUENCE "test_table_id_seq1" START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1; 12 | 13 | DROP TABLE IF EXISTS test_table CASCADE; 14 | CREATE TABLE test_table ( 15 | id BIGINT DEFAULT nextval('test_table_id_seq1'::regclass), 16 | project_id INT, 17 | value TEXT 18 | ); 19 | ALTER TABLE ONLY "test_table" ADD CONSTRAINT "pk_test_table" PRIMARY KEY ("id"); 20 | 21 | CREATE TRIGGER test_table_before_insert BEFORE INSERT ON test_table FOR EACH ROW EXECUTE PROCEDURE test_table_before_insert_trigger(); 22 | 23 | PERFORM _2gis_partition_magic('test_table', 'project_id'); 24 | END; $$ LANGUAGE 'plpgsql'; 25 | 26 | SELECT initTestPartitions(); 27 | 28 | INSERT INTO test_table(project_id, value) VALUES (1, 'Item 1') RETURNING *; 29 | INSERT INTO test_table(project_id, value) VALUES (2, 'Item 2') RETURNING *; 30 | INSERT INTO test_table(project_id, value) VALUES (3, 'Item 3') RETURNING *; 31 | INSERT INTO test_table(project_id, value) VALUES (4, 'Item 4') RETURNING *; 32 | INSERT INTO test_table(project_id, value) 33 | VALUES 34 | (1, 'Item 5'), 35 | (1, 'Item 6'), 36 | (2, 'Item 7'), 37 | (2, 'Item 8'), 38 | (3, 'Item 9'), 39 | (3, 'Item 10') 40 | RETURNING *; 41 | 42 | SELECT COUNT(*) FROM test_table; 43 | SELECT COUNT(*) FROM test_table_1; 44 | SELECT COUNT(*) FROM test_table_2; 45 | SELECT COUNT(*) FROM test_table_3; 46 | SELECT COUNT(*) FROM test_table_4; 47 | 48 | SELECT * FROM ONLY test_table; 49 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | Partition magic 2 | =============== 3 | 4 | Partition magic - скрипт-сниппет для Postgresql на plpgsql, позволяющий лёгко, быстро и просто создавать партицированные таблицы в вашем проекте, а также изменять, добавлять и удалять данные. 5 | 6 | Без единой правки кода вашего приложения - вы можете "разбить" данные на партиции. 7 | 8 | Как начать? 9 | =========== 10 | 11 | 1. Запустите данный скрипт в ваш Postgresql ```_2gis_partition_magic.sql``` - произойдёт установка 12 | 2. Создайте базовую таблицу, которую вы собираетесь разбить на партиции, например: 13 | ``` 14 | CREATE SEQUENCE "news_id_seq" START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1; 15 | 16 | CREATE TABLE news ( 17 | id BIGINT DEFAULT nextval('news_id_seq'::regclass), 18 | category_id INT, 19 | title TEXT, 20 | data TEXT 21 | ); 22 | ALTER TABLE ONLY "news" ADD CONSTRAINT "pk_news" PRIMARY KEY ("id"); 23 | ``` 24 | 3. Из примера выше - мы будем партицировать таблицу новостей (news) по полю category_id 25 | ``` 26 | _2gis_partition_magic('news', 'category_id'); 27 | ``` 28 | 4. .... 29 | 5. PROFIT - это действительно так просто 30 | 31 | Как пользоваться? 32 | ================= 33 | Пример можно посмотреть в файле ```_2gis_partition_magic_test.sql```, а также вот краткий экскурс: 34 | 35 | ``` 36 | INSERT INTO news(category_id, title) VALUES (1, 'Item 1') RETURNING *; 37 | INSERT INTO news(category_id, title) VALUES (2, 'Item 2') RETURNING *; 38 | INSERT INTO news(category_id, title) VALUES (3, 'Item 3') RETURNING *; 39 | INSERT INTO news(category_id, title) VALUES (4, 'Item 4') RETURNING *; 40 | INSERT INTO news(category_id, title) 41 | VALUES 42 | (1, 'Item 5'), 43 | (1, 'Item 6'), 44 | (2, 'Item 7'), 45 | (2, 'Item 8'), 46 | (3, 'Item 9'), 47 | (3, 'Item 10') 48 | RETURNING *; 49 | ``` 50 | 51 | Данные автоматически попадут в нужные партиции, а если партиция еще не существовала - она будет создана автоматически. Можно проверить: 52 | ``` 53 | SELECT COUNT(*) FROM news; 54 | SELECT COUNT(*) FROM news_1; 55 | SELECT COUNT(*) FROM news_2; 56 | SELECT COUNT(*) FROM news_3; 57 | SELECT COUNT(*) FROM news_4; 58 | ``` 59 | 60 | А также, в основной таблице ничего нет: 61 | ``` 62 | SELECT * FROM ONLY test_table; 63 | ``` 64 | 65 | *Домашнее задание*: попробуйте UPDATE и DELETE 66 | 67 | Что важно помнить? 68 | ================== 69 | Накатывайте изменения структуры только на основную таблице, после чего запускайте 70 | ``` 71 | _2gis_partition_magic('news', 'category_id'); 72 | ``` 73 | Таблицы будут обновлены автоматически. 74 | 75 | Что еще важно помнить? 76 | ================== 77 | 78 | Сам по себе partition magic не даёт ускорения при работе с таблицами. Вы можете не изменять ваш код, а работать также с основной таблицей, если вы пишите запросы такого вида: 79 | ``` 80 | SELECT * FROM news ...; 81 | UPDATE news ...; 82 | DELETE FROM news ...; 83 | ``` 84 | 85 | Будет происходить поиск по всем партициям, чтобы получить буст, выберите один из 2х вариантов: 86 | 1. Укажите ваш constraint (в примере выше - category_id) в WHERE-условии, например: 87 | ``` 88 | SELECT * FROM news WHERE category_id = 1; 89 | UPDATE news WHERE category_id = 1; 90 | DELETE FROM news WHERE category_id = 1; 91 | ``` 92 | или так: 93 | ``` 94 | SELECT * FROM news WHERE category_id = 1 OR category_id = 2; 95 | UPDATE news WHERE category_id = 1 OR category_id = 2; 96 | DELETE FROM news WHERE category_id = 1 OR category_id = 2; 97 | ``` 98 | или так: 99 | ``` 100 | SELECT * FROM news WHERE category_id IN (1, 2); 101 | UPDATE news WHERE category_id IN (1, 2); 102 | DELETE FROM news WHERE category_id IN (1, 2); 103 | ``` 104 | 2. Укажите партицию, с которой вы работаете: 105 | ``` 106 | SELECT * FROM news_1 ...; 107 | UPDATE news_2 ...; 108 | DELETE FROM news_3 ...; 109 | ``` 110 | -------------------------------------------------------------------------------- /_2gis_partition_magic.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION _2gis_partition_magic_before_insert_trigger() RETURNS trigger AS $$ 2 | DECLARE 3 | hasMeta boolean; 4 | meta RECORD; 5 | partition_id integer; 6 | itable text; 7 | partitionRes boolean; 8 | BEGIN 9 | hasMeta := false; 10 | FOR meta IN SELECT * FROM _2gis_partition_magic_meta m WHERE m.table_name = TG_TABLE_NAME 11 | LOOP 12 | hasMeta := true; 13 | END LOOP; 14 | 15 | IF hasMeta THEN 16 | EXECUTE format('SELECT ($1).%I', meta.action_field) USING NEW INTO partition_id; 17 | itable := meta.partition_table_prefix || partition_id::text; 18 | 19 | IF ( NOT EXISTS ( SELECT 1 FROM pg_tables t WHERE t.schemaname = meta.schema_name AND t.tablename = itable ) ) THEN 20 | partitionRes := _2gis_partition_magic(meta.parent_table_name, meta.action_field, partition_id, meta.schema_name, meta.partition_table_prefix, FALSE); 21 | END IF; 22 | 23 | EXECUTE 'INSERT INTO ' || itable || ' VALUES (($1).*) ' USING NEW; 24 | END IF; 25 | 26 | RETURN NEW; 27 | END; 28 | $$ LANGUAGE plpgsql; 29 | 30 | CREATE OR REPLACE FUNCTION _2gis_partition_magic_after_insert_trigger() RETURNS trigger AS $$ 31 | DECLARE 32 | hasMeta boolean; 33 | meta RECORD; 34 | itable text; 35 | BEGIN 36 | hasMeta := false; 37 | FOR meta IN SELECT * FROM _2gis_partition_magic_meta m WHERE m.table_name = TG_TABLE_NAME 38 | LOOP 39 | hasMeta := true; 40 | END LOOP; 41 | 42 | IF hasMeta THEN 43 | EXECUTE 'DELETE FROM ONLY ' || meta.parent_table_name || ' WHERE id = ' || NEW.id || ';'; 44 | END IF; 45 | 46 | RETURN NULL; 47 | END; 48 | $$ LANGUAGE plpgsql; 49 | 50 | CREATE OR REPLACE FUNCTION _2gis_partition_magic(parent_table text, action_field text, partition_idx integer = NULL, schema_name text = NULL, partition_table_prefix text = NULL, is_debug boolean = FALSE) RETURNS boolean AS $$ 51 | DECLARE 52 | itable varchar(255); 53 | logtable varchar(255); 54 | idx1_name varchar(255); 55 | idx2_name varchar(255); 56 | s1 varchar(255); 57 | s2 varchar(255); 58 | idx1_def text; 59 | idx2_def text; 60 | tbl RECORD; 61 | idx1 RECORD; 62 | idx2 RECORD; 63 | rule1 RECORD; 64 | rule2 RECORD; 65 | trig1 RECORD; 66 | trig2 RECORD; 67 | res boolean; 68 | BEGIN 69 | res := TRUE; 70 | 71 | IF(schema_name IS NULL) THEN 72 | schema_name := current_schema(); --'public' 73 | END IF; 74 | 75 | IF(partition_table_prefix IS NULL) THEN 76 | partition_table_prefix := parent_table || '_'; 77 | END IF; 78 | 79 | IF ( NOT EXISTS ( SELECT 1 FROM pg_tables t WHERE t.schemaname = schema_name AND t.tablename = '_2gis_partition_magic_meta' ) ) THEN 80 | IF(is_debug) THEN RAISE INFO '----- [Creating META table "%"] -----', '_2gis_partition_magic_meta'; END IF; 81 | EXECUTE 'CREATE TABLE _2gis_partition_magic_meta (id integer, table_name character varying(255), action_field character varying(255), partition_id integer, schema_name character varying(255), partition_table_prefix character varying(255), parent_table_name character varying(255), created_at TIMESTAMP DEFAULT NOW());'; 82 | EXECUTE 'CREATE INDEX table_name_idx ON _2gis_partition_magic_meta (table_name);'; 83 | EXECUTE 'CREATE INDEX partition_id_idx ON _2gis_partition_magic_meta (partition_id);'; 84 | EXECUTE 'CREATE INDEX parent_table_name_idx ON _2gis_partition_magic_meta (parent_table_name);'; 85 | END IF; 86 | 87 | IF ( NOT EXISTS ( SELECT 1 FROM _2gis_partition_magic_meta m WHERE m.table_name = parent_table ) ) THEN 88 | IF(is_debug) THEN RAISE INFO '----- [Creating META for table "%.%"] -----', schema_name, parent_table; END IF; 89 | EXECUTE 'INSERT INTO _2gis_partition_magic_meta (table_name, action_field, partition_id, schema_name, partition_table_prefix, parent_table_name) VALUES (''' || parent_table || ''', ''' || action_field || ''', NULL, ''' || schema_name || ''', ''' || partition_table_prefix || ''', ''' || parent_table || ''');'; 90 | END IF; 91 | 92 | IF ( NOT EXISTS ( SELECT g.tgfoid::regclass::text, pg_get_functiondef(p.oid) as procdef, prosrc, pg_get_triggerdef(g.oid) as tgdef, g.tgname 93 | FROM pg_trigger g 94 | LEFT JOIN pg_proc p ON p.oid = g.tgfoid 95 | WHERE g.tgrelid::regclass::text = parent_table AND g.tgname = '_2gis_partition_magic_before_insert_' || parent_table AND g.tgenabled != 'D' AND NOT g.tgisinternal ) ) 96 | THEN 97 | IF(is_debug) THEN RAISE INFO '----- [Creating before insert trigger on parent_table "%.%"] -----', schema_name, parent_table; END IF; 98 | EXECUTE 'CREATE TRIGGER _2gis_partition_magic_before_insert_' || parent_table || ' BEFORE INSERT ON ' || parent_table || ' FOR EACH ROW EXECUTE PROCEDURE _2gis_partition_magic_before_insert_trigger();'; 99 | IF(is_debug) THEN RAISE INFO '----- [Creating after insert trigger on parent_table "%.%"] -----', schema_name, parent_table; END IF; 100 | EXECUTE 'CREATE TRIGGER _2gis_partition_magic_after_insert_' || parent_table || ' AFTER INSERT ON ' || parent_table || ' FOR EACH ROW EXECUTE PROCEDURE _2gis_partition_magic_after_insert_trigger();'; 101 | END IF; 102 | 103 | IF(partition_idx IS NULL) THEN 104 | IF(is_debug) THEN RAISE INFO '----- [Detecting partitions...] -----'; END IF; 105 | FOR tbl IN SELECT t.tablename, substring(t.tablename from '\_(\d+)$')::integer AS part_index FROM pg_tables t WHERE t.schemaname = schema_name AND t.tablename ~* ('^' || partition_table_prefix || '\d+') ORDER BY part_index ASC 106 | LOOP 107 | partition_idx := replace(tbl.tablename, partition_table_prefix, '')::integer; 108 | IF(is_debug) THEN RAISE INFO '----- [Found partition #%, table: "%.%"] -----', partition_idx, schema_name, tbl.tablename; END IF; 109 | res := res AND _2gis_partition_magic(parent_table, action_field, partition_idx, schema_name, partition_table_prefix, is_debug); 110 | END LOOP; 111 | 112 | RETURN res; 113 | END IF; 114 | 115 | IF(partition_idx < 0) THEN 116 | partition_idx := NULL; 117 | itable := partition_table_prefix; 118 | ELSE 119 | itable := partition_table_prefix || partition_idx; 120 | END IF; 121 | 122 | IF(is_debug) THEN RAISE INFO '----- [Working with table "%.%"] -----', schema_name, itable; END IF; 123 | 124 | IF ( NOT EXISTS ( SELECT 1 FROM pg_tables t WHERE t.schemaname = schema_name AND t.tablename = itable ) ) THEN 125 | IF(is_debug) THEN RAISE INFO 'Creating partition "%.%" for table "%.%"...', schema_name, itable, schema_name, parent_table; END IF; 126 | EXECUTE 'CREATE TABLE ' || itable || ' (CONSTRAINT ' || itable || '_' || action_field || '_check CHECK (' || action_field || ' = ' || partition_idx || ')) INHERITS (' || parent_table ||');'; 127 | -- IF(is_debug) THEN RAISE INFO 'Creating rules on table...'; END IF; 128 | -- EXECUTE 'CREATE RULE ' || itable || '_insert AS ON INSERT TO ' || parent_table || ' WHERE NEW.' || action_field || ' = ' || partition_idx || ' DO INSTEAD INSERT INTO ' || itable || ' VALUES (NEW.*) RETURNING ' || itable || '.*;'; 129 | IF(is_debug) THEN RAISE INFO 'Creating meta info...'; END IF; 130 | EXECUTE 'INSERT INTO _2gis_partition_magic_meta (table_name, action_field, partition_id, schema_name, partition_table_prefix, parent_table_name) VALUES (''' || itable || ''', ''' || action_field || ''', ' || partition_idx || ', ''' || schema_name || ''', ''' || partition_table_prefix || ''', ''' || parent_table || ''');'; 131 | END IF; 132 | 133 | IF(is_debug) THEN RAISE INFO 'Checking indexes...'; END IF; 134 | FOR idx1 IN SELECT t.indexname, t.indexdef FROM pg_indexes t WHERE t.schemaname = schema_name AND t.tablename = parent_table 135 | LOOP 136 | idx1_name := idx1.indexname; 137 | idx2_name := regexp_replace(idx1_name, '^(' || parent_table || '_)', itable || '_'); 138 | IF (idx2_name = idx1_name) THEN 139 | idx2_name := regexp_replace(idx1_name, '(\w+_|)(' || parent_table || ')(_\w+|)', '\1' || itable || '\3'); 140 | END IF; 141 | 142 | SELECT t.indexname, t.indexdef INTO idx2 FROM pg_indexes t WHERE t.schemaname = schema_name AND t.tablename = itable AND t.indexname = idx2_name; 143 | 144 | idx1_def := idx1.indexdef; 145 | idx1_def := regexp_replace(idx1_def, 'CREATE (UNIQUE |)INDEX (' || idx1_name || ') ON (' || parent_table || ') ', 'CREATE \1INDEX ' || idx2_name || ' ON ' || itable || ' '); 146 | idx2_def := idx2.indexdef; 147 | 148 | IF (idx2.indexname IS NULL) THEN 149 | IF(is_debug) THEN RAISE INFO 'Creating index "%" ON "%.%"...', idx2_name, schema_name, itable; END IF; 150 | EXECUTE idx1_def; 151 | ELSE 152 | IF(idx1_def != idx2_def) THEN 153 | IF(is_debug) THEN RAISE INFO 'Dropping old index "%" ON "%.%"...', idx2_name, schema_name, itable; END IF; 154 | EXECUTE 'DROP INDEX ' || idx2_name || ';'; 155 | 156 | IF(is_debug) THEN RAISE INFO 'Creating new index "%" ON "%.%"...', idx2_name, schema_name, itable; END IF; 157 | EXECUTE idx1_def; 158 | END IF; 159 | END IF; 160 | END LOOP; 161 | 162 | IF(is_debug) THEN RAISE INFO 'Checking for removed indexes...'; END IF; 163 | FOR idx1 IN SELECT t.indexname, t.indexdef FROM pg_indexes t WHERE t.schemaname = schema_name AND t.tablename = itable 164 | LOOP 165 | idx1_name := idx1.indexname; 166 | idx2_name := regexp_replace(idx1_name, '^(' || itable || '_)', parent_table || '_'); 167 | IF (idx2_name = idx1_name) THEN 168 | idx2_name := regexp_replace(idx1_name, '(\w+_|)(' || itable || ')(_\w+|)', '\1' || parent_table || '\3'); 169 | END IF; 170 | 171 | SELECT t.indexname, t.indexdef INTO idx2 FROM pg_indexes t WHERE t.schemaname = schema_name AND t.tablename = parent_table AND t.indexname = idx2_name; 172 | IF (idx2.indexname IS NULL) THEN 173 | IF(is_debug) THEN RAISE INFO 'Dropping removed index "%" ON "%.%"...', idx1_name, schema_name, itable; END IF; 174 | EXECUTE 'DROP INDEX ' || idx1_name || ';'; 175 | END IF; 176 | END LOOP; 177 | 178 | IF(is_debug) THEN RAISE INFO 'Checking constraints...'; END IF; 179 | 180 | FOR idx1 IN SELECT conrelid::regclass AS tablename, conname as indexname, c.contype AS indextype, pg_get_constraintdef(c.oid) AS indexdef FROM pg_constraint c JOIN pg_namespace n ON n.oid = c.connamespace WHERE n.nspname = schema_name AND conrelid::regclass::text = parent_table AND c.contype != 'c' 181 | LOOP 182 | idx1_name := idx1.indexname; 183 | idx2_name := regexp_replace(idx1_name, '^(' || parent_table || '_)', itable || '_'); 184 | IF (idx2_name = idx1_name) THEN 185 | idx2_name := regexp_replace(idx1_name, '(\w+_|)(' || parent_table || ')(_\w+|)', '\1' || itable || '\3'); 186 | END IF; 187 | 188 | SELECT conrelid::regclass AS tablename, c.conname as indexname, c.contype AS indextype, pg_get_constraintdef(c.oid) AS indexdef INTO idx2 FROM pg_constraint c JOIN pg_namespace n ON n.oid = c.connamespace WHERE n.nspname = schema_name AND conrelid::regclass::text = itable AND c.conname = idx2_name; 189 | 190 | idx1_def := idx1.indexdef; 191 | idx2_def := idx2.indexdef; 192 | 193 | IF (idx2.indexname IS NULL) THEN 194 | IF(EXISTS(SELECT 1 FROM pg_indexes t WHERE t.schemaname = schema_name AND t.tablename = itable AND t.indexname = idx2_name)) THEN 195 | IF(is_debug) THEN RAISE INFO 'Dropping old index "%" ON "%.%", converting to constraint...', idx2_name, schema_name, itable; END IF; 196 | EXECUTE 'DROP INDEX ' || idx2_name || ';'; 197 | END IF; 198 | IF(is_debug) THEN RAISE INFO 'Creating constraint "%" ON "%.%"...', idx1_def, schema_name, itable; END IF; 199 | EXECUTE 'ALTER TABLE ONLY ' || itable || ' ADD CONSTRAINT ' || idx2_name || ' ' || idx1_def || ';'; 200 | ELSE 201 | IF(idx1_def != idx2_def) THEN 202 | IF(is_debug) THEN RAISE INFO 'Dropping old constraint "%" ON "%.%"...', idx2_name, schema_name, itable; END IF; 203 | EXECUTE 'ALTER TABLE ONLY ' || itable || ' DROP CONSTRAINT ' || idx2_name || ';'; 204 | 205 | IF(is_debug) THEN RAISE INFO 'Creating new constraint "%" ON "%.%"...', idx2_name, schema_name, itable; END IF; 206 | EXECUTE 'ALTER TABLE ONLY ' || itable || ' ADD CONSTRAINT ' || idx2_name || ' ' || idx1_def || ';'; 207 | END IF; 208 | END IF; 209 | END LOOP; 210 | 211 | IF(is_debug) THEN RAISE INFO 'Checking for removed constraints...'; END IF; 212 | FOR idx1 IN SELECT conrelid::regclass AS tablename, conname as indexname, c.contype AS indextype, pg_get_constraintdef(c.oid) AS indexdef FROM pg_constraint c JOIN pg_namespace n ON n.oid = c.connamespace WHERE n.nspname = schema_name AND conrelid::regclass::text = itable AND c.contype != 'c' 213 | LOOP 214 | idx1_name := idx1.indexname; 215 | idx2_name := regexp_replace(idx1_name, '^(' || itable || '_)', parent_table || '_'); 216 | IF (idx2_name = idx1_name) THEN 217 | idx2_name := regexp_replace(idx1_name, '(\w+_|)(' || itable || ')(_\w+|)', '\1' || parent_table || '\3'); 218 | END IF; 219 | 220 | SELECT conrelid::regclass AS tablename, c.conname as indexname, c.contype AS indextype, pg_get_constraintdef(c.oid) AS indexdef INTO idx2 FROM pg_constraint c JOIN pg_namespace n ON n.oid = c.connamespace WHERE n.nspname = schema_name AND conrelid::regclass::text = parent_table AND c.conname = idx2_name; 221 | 222 | IF (idx2.indexname IS NULL) THEN 223 | IF(is_debug) THEN RAISE INFO 'Dropping removed constraint "%" ON "%.%"...', idx1_name, schema_name, itable; END IF; 224 | EXECUTE 'ALTER TABLE ONLY ' || itable || ' DROP CONSTRAINT ' || idx1_name || ';'; 225 | END IF; 226 | END LOOP; 227 | 228 | IF(is_debug) THEN RAISE INFO 'Checking rules...'; END IF; 229 | FOR rule1 IN SELECT r.rulename, r.definition as ruledef FROM pg_rules r WHERE r.schemaname = schema_name AND r.tablename = parent_table 230 | LOOP 231 | idx1_name := rule1.rulename; 232 | idx2_name := regexp_replace(idx1_name, '^(' || parent_table || '_)', itable || '_'); 233 | IF (idx2_name = idx1_name) THEN 234 | idx2_name := regexp_replace(idx1_name, '(\w+_|)(' || parent_table || ')(_\w+|)', '\1' || itable || '\3'); 235 | END IF; 236 | 237 | IF (regexp_matches(idx1_name, '^' || parent_table || '\_' || '.*' || '\_insert$') IS NOT NULL) THEN 238 | CONTINUE; 239 | END IF; 240 | 241 | SELECT r.rulename, r.definition as ruledef INTO rule2 FROM pg_rules r WHERE r.schemaname = schema_name AND r.tablename = itable AND r.rulename = idx2_name; 242 | 243 | idx1_def := rule1.ruledef; 244 | idx1_def := regexp_replace(idx1_def, 'CREATE (OR REPLACE |)RULE (' || idx1_name || ') AS[\s]+ON (SELECT |INSERT |UPDATE |DELETE |TRUNCATE )TO (' || parent_table || ')[\s]+', 'CREATE \1RULE ' || idx2_name || ' AS ON \3 TO ' || itable || ' '); 245 | idx2_def := rule2.ruledef; 246 | 247 | IF (rule2.rulename IS NULL) THEN 248 | IF(is_debug) THEN RAISE INFO 'Creating new rule "%" ON "%.%"...', idx1_name, schema_name, itable; END IF; 249 | EXECUTE idx1_def; 250 | ELSE 251 | s1 := regexp_replace(idx1_def, '\s', '', 'g'); 252 | s2 := regexp_replace(idx2_def, '\s', '', 'g'); 253 | IF(s1 != s2) THEN 254 | IF(is_debug) THEN RAISE INFO 'Dropping old rule "%" ON "%.%"...', idx2_name, schema_name, itable; END IF; 255 | EXECUTE 'DROP RULE ' || idx2_name || ' ON ' || itable || ';'; 256 | 257 | IF(is_debug) THEN RAISE INFO 'Creating new rule "%" ON "%.%"...', idx2_name, schema_name, itable; END IF; 258 | EXECUTE idx1_def; 259 | END IF; 260 | END IF; 261 | END LOOP; 262 | 263 | IF(is_debug) THEN RAISE INFO 'Checking for removed rules...'; END IF; 264 | -- @TODO 265 | -- Delete removed rules 266 | 267 | IF(is_debug) THEN RAISE INFO 'Checking triggers...'; END IF; 268 | FOR trig1 IN SELECT g.tgfoid::regclass::text, pg_get_functiondef(p.oid) as procdef, prosrc, pg_get_triggerdef(g.oid) as tgdef, g.tgname 269 | FROM pg_trigger g 270 | LEFT JOIN pg_proc p ON p.oid = g.tgfoid 271 | WHERE g.tgrelid::regclass::text = parent_table AND g.tgenabled != 'D' AND NOT g.tgisinternal 272 | LOOP 273 | idx1_name := trig1.tgname; 274 | idx2_name := regexp_replace(idx1_name, '^(' || parent_table || '_)', itable || '_'); 275 | IF (idx2_name = idx1_name) THEN 276 | idx2_name := regexp_replace(idx1_name, '(\w+_|)(' || parent_table || ')(_\w+|)', '\1' || itable || '\3'); 277 | END IF; 278 | 279 | IF idx1_name = '_2gis_partition_magic_before_insert_' || parent_table THEN 280 | CONTINUE; 281 | END IF; 282 | 283 | IF idx1_name = '_2gis_partition_magic_after_insert_' || parent_table THEN 284 | CONTINUE; 285 | END IF; 286 | 287 | SELECT g.tgfoid::regclass::text as pc, pg_get_functiondef(p.oid) as procdef, prosrc, pg_get_triggerdef(g.oid) as tgdef, g.tgname 288 | INTO trig2 289 | FROM pg_trigger g 290 | LEFT JOIN pg_proc p ON p.oid = g.tgfoid 291 | WHERE g.tgrelid::regclass::text = itable AND g.tgenabled != 'D' AND g.tgname = idx2_name AND NOT g.tgisinternal; 292 | 293 | idx1_def := trig1.tgdef; 294 | idx1_def := regexp_replace(idx1_def, ' TRIGGER (' || idx1_name || ') (BEFORE |AFTER |INSTEAD OF )(INSERT |UPDATE |DELETE |TRUNCATE )ON (' || parent_table || ') ', ' TRIGGER ' || idx2_name || ' \2\3ON ' || itable || ' '); 295 | idx2_def := trig2.tgdef; 296 | 297 | IF (trig2.tgname IS NULL) THEN 298 | IF(is_debug) THEN RAISE INFO 'Creating trigger "%" ON "%.%"...', idx2_name, schema_name, itable; END IF; 299 | EXECUTE idx1_def; 300 | ELSE 301 | IF(idx1_def != idx2_def) THEN 302 | IF(is_debug) THEN RAISE INFO 'Removing old trigger "%" ON "%.%"...', idx2_name, schema_name, itable; END IF; 303 | EXECUTE 'DROP TRIGGER ' || idx2_name || ';'; 304 | IF(is_debug) THEN RAISE INFO 'Creating new trigger "%" ON "%.%"...', idx2_name, schema_name, itable; END IF; 305 | EXECUTE idx1_def; 306 | END IF; 307 | END IF; 308 | END LOOP; 309 | 310 | IF(is_debug) THEN RAISE INFO 'Checking for removed triggers...'; END IF; 311 | -- @TODO 312 | -- Delete removed triggers 313 | 314 | RETURN res; 315 | END; 316 | $$ LANGUAGE plpgsql; 317 | 318 | --------------------------------------------------------------------------------