|
| 1 | +/* |
| 2 | +-- =================== GET_TABLE_NAME =================== |
| 3 | +*/ |
| 4 | +CREATE FUNCTION @ [email protected]_table_name ( "relid" REGCLASS, "is_full" BOOLEAN = TRUE) |
| 5 | + RETURNS TEXT |
| 6 | +AS $$ |
| 7 | +BEGIN |
| 8 | + RETURN ( |
| 9 | + SELECT CASE WHEN "is_full" THEN format('%I.%I', n.nspname, c.relname) |
| 10 | + ELSE format('%I', c.relname) |
| 11 | + END |
| 12 | + FROM pg_class c JOIN pg_namespace n on c.relnamespace = n.oid |
| 13 | + WHERE c.oid = "relid"); |
| 14 | +END |
| 15 | +$$ |
| 16 | +LANGUAGE plpgsql |
| 17 | +RETURNS NULL ON NULL INPUT; |
| 18 | +/* |
| 19 | +=================== NAME =================== |
| 20 | +*/ |
| 21 | +DROP FUNCTION @ [email protected]_child_constraint_name ( "name" TEXT, "parent" TEXT, "child" TEXT); |
| 22 | + |
| 23 | +CREATE FUNCTION @ [email protected]_child_constraint_name ( "name" TEXT, "parent" REGCLASS, "child" REGCLASS) |
| 24 | + RETURNS TEXT |
| 25 | +AS $$ |
| 26 | +BEGIN |
| 27 | + RETURN regexp_replace( "name", '^' || @ [email protected]_table_name( "parent", FALSE), @ [email protected]_table_name( "child", FALSE)); |
| 28 | +END |
| 29 | +$$ |
| 30 | +LANGUAGE plpgsql |
| 31 | +IMMUTABLE |
| 32 | +RETURNS NULL ON NULL INPUT; |
| 33 | + |
| 34 | +DROP FUNCTION @ [email protected]_child_trigger_name ( "name" TEXT, "parent" TEXT, "child" TEXT); |
| 35 | + |
| 36 | +CREATE FUNCTION @ [email protected]_child_trigger_name ( "name" TEXT, "parent" REGCLASS, "child" REGCLASS) |
| 37 | + RETURNS TEXT |
| 38 | +AS $$ |
| 39 | +BEGIN |
| 40 | + RETURN "name"; |
| 41 | +END |
| 42 | +$$ |
| 43 | +LANGUAGE plpgsql |
| 44 | +IMMUTABLE |
| 45 | +RETURNS NULL ON NULL INPUT; |
| 46 | +/* |
| 47 | +=================== DEF =================== |
| 48 | +*/ |
| 49 | +DROP FUNCTION @ [email protected]_child_trigger_def ( "parentdef" TEXT, "parentname" TEXT, "parent" TEXT, "child" TEXT); |
| 50 | + |
| 51 | +CREATE FUNCTION @ [email protected]_child_trigger_def ( "parentdef" TEXT, "parentname" TEXT, "parent" REGCLASS, "child" REGCLASS) |
| 52 | + RETURNS TEXT |
| 53 | +AS $$ |
| 54 | +BEGIN |
| 55 | + RETURN regexp_replace ( |
| 56 | + replace ( "parentdef", @ [email protected]_table_name( "parent", TRUE), @ [email protected]_table_name( "child", TRUE)), |
| 57 | + '(CREATE (CONSTRAINT )?TRIGGER) ' || quote_ident ("parentname"), |
| 58 | + '\1 ' || quote_ident (@ [email protected]_child_trigger_name( "parentname", "parent", "child"))); |
| 59 | +END |
| 60 | +$$ |
| 61 | +LANGUAGE plpgsql |
| 62 | +IMMUTABLE |
| 63 | +RETURNS NULL ON NULL INPUT; |
| 64 | +/* |
| 65 | +=================== GET_INHERIT_TRIGGERS =================== |
| 66 | +*/ |
| 67 | +CREATE OR REPLACE FUNCTION @ [email protected]_inherit_triggers () |
| 68 | + RETURNS TABLE |
| 69 | +( |
| 70 | + "parentid" OID, |
| 71 | + "parentrelid" OID, |
| 72 | + "parentname" TEXT, |
| 73 | + "parentdef" TEXT, |
| 74 | + "childid" OID, |
| 75 | + "childrelid" OID, |
| 76 | + "childname" TEXT, |
| 77 | + "childdef" TEXT, |
| 78 | + "is_inherited" BOOL |
| 79 | +) |
| 80 | +AS $$ |
| 81 | +BEGIN |
| 82 | + RETURN QUERY |
| 83 | + WITH "triggers" AS ( |
| 84 | + SELECT "t"."oid", "t"."tgrelid", "t"."tgname", pg_get_triggerdef("t"."oid") AS "tgdef" |
| 85 | + FROM "pg_trigger" "t" |
| 86 | + WHERE "t"."tgisinternal" = FALSE) |
| 87 | + SELECT "pc"."oid" AS "parentid", |
| 88 | + "i"."inhparent" AS "parentrelid", |
| 89 | + "pc"."tgname"::TEXT AS "parentname", |
| 90 | + "pc"."tgdef" AS "parentdef", |
| 91 | + "cc"."oid" AS "childid", |
| 92 | + "i"."inhrelid" AS "childrelid", |
| 93 | + "cc"."tgname"::TEXT AS "childname", |
| 94 | + "cc"."tgdef" AS "childdef", |
| 95 | + "cc"."tgdef" IS NOT NULL AS "is_inherited" |
| 96 | + FROM "pg_inherits" "i" |
| 97 | + LEFT JOIN "triggers" "pc" ON "i"."inhparent" = "pc"."tgrelid" |
| 98 | + LEFT JOIN "triggers" "cc" ON "i"."inhrelid" = "cc"."tgrelid" |
| 99 | + AND @ [email protected]_child_trigger_def( "pc". "tgdef", "pc". "tgname":: TEXT, "i". "inhparent"::REGCLASS, "i". "inhrelid"::REGCLASS) = "cc". "tgdef" |
| 100 | + WHERE "pc"."oid" IS NOT NULL OR "cc"."oid" IS NOT NULL; |
| 101 | +END |
| 102 | +$$ |
| 103 | +LANGUAGE plpgsql |
| 104 | +STABLE |
| 105 | +RETURNS NULL ON NULL INPUT; |
| 106 | +/* |
| 107 | +=================== EVENT_TRIGGER_ADD_INHERIT_CONSTRAINTS =================== |
| 108 | +*/ |
| 109 | +CREATE OR REPLACE FUNCTION @ [email protected]_trigger_add_inherit_constraints () |
| 110 | + RETURNS EVENT_TRIGGER |
| 111 | +AS $$ |
| 112 | +DECLARE |
| 113 | + "command" RECORD; |
| 114 | + "parent" OID; |
| 115 | + "child" OID; |
| 116 | + "constraint" RECORD; |
| 117 | + "name" TEXT; |
| 118 | + "query" TEXT; |
| 119 | + "constraints" REFCURSOR; |
| 120 | +BEGIN |
| 121 | + FOR "command" IN |
| 122 | + SELECT * FROM pg_event_trigger_ddl_commands () |
| 123 | + LOOP |
| 124 | + IF "command".in_extension = TRUE THEN |
| 125 | + CONTINUE; |
| 126 | + END IF; |
| 127 | + |
| 128 | + IF "command".command_tag = 'CREATE TABLE' THEN |
| 129 | + "child" = "command".objid; |
| 130 | + OPEN "constraints" FOR |
| 131 | + SELECT * FROM @ [email protected]_inherit_constraints() "c" |
| 132 | + WHERE "c"."childrelid" = "child" AND "c"."is_inherited" = FALSE |
| 133 | + LIMIT 1; |
| 134 | + ELSEIF "command".command_tag = 'ALTER TABLE' THEN |
| 135 | + "parent" = "command".objid; |
| 136 | + "child" = "command".objid; |
| 137 | + OPEN "constraints" FOR |
| 138 | + SELECT * FROM @ [email protected]_inherit_constraints() "c" |
| 139 | + WHERE ("c"."parentrelid" = "parent" OR "c"."childrelid" = "child") |
| 140 | + AND "c"."is_inherited" = FALSE |
| 141 | + LIMIT 1; |
| 142 | + ELSE |
| 143 | + CONTINUE; |
| 144 | + END IF; |
| 145 | + |
| 146 | + LOOP |
| 147 | + FETCH NEXT FROM "constraints" INTO "constraint"; |
| 148 | + EXIT WHEN "constraint" IS NULL; |
| 149 | + |
| 150 | + "name" = @ [email protected]_child_constraint_name( "constraint". "parentname", "constraint". "parentrelid"::REGCLASS, "constraint". "childrelid"::REGCLASS); |
| 151 | + "query" = format('ALTER TABLE %1s ADD CONSTRAINT %2I %3s;', "constraint"."childrelid"::REGCLASS, "name", "constraint"."parentdef"); |
| 152 | + RAISE NOTICE USING MESSAGE = format('-- ADD CONSTRAINT %1I TO %2s TABLE FROM %3s TABLE', "name", "constraint"."childrelid"::REGCLASS, "constraint"."parentrelid"::REGCLASS); |
| 153 | + RAISE NOTICE USING MESSAGE = "query"; |
| 154 | + EXECUTE "query"; |
| 155 | + END LOOP; |
| 156 | + CLOSE "constraints"; |
| 157 | + END LOOP; |
| 158 | +END; |
| 159 | +$$ |
| 160 | +LANGUAGE plpgsql |
| 161 | +VOLATILE; |
| 162 | +/* |
| 163 | +=================== EVENT_TRIGGER_ADD_INHERIT_TRIGGERS =================== |
| 164 | +*/ |
| 165 | +CREATE OR REPLACE FUNCTION @ [email protected]_trigger_add_inherit_triggers () |
| 166 | + RETURNS EVENT_TRIGGER |
| 167 | +AS $$ |
| 168 | +DECLARE |
| 169 | + "command" RECORD; |
| 170 | + "triggerid" OID; |
| 171 | + "child" OID; |
| 172 | + "trigger" RECORD; |
| 173 | + "name" TEXT; |
| 174 | + "query" TEXT; |
| 175 | + "triggers" REFCURSOR; |
| 176 | +BEGIN |
| 177 | + FOR "command" IN |
| 178 | + SELECT * FROM pg_event_trigger_ddl_commands () |
| 179 | + LOOP |
| 180 | + IF "command".in_extension = TRUE THEN |
| 181 | + CONTINUE; |
| 182 | + END IF; |
| 183 | + |
| 184 | + IF "command".command_tag = 'CREATE TABLE' THEN |
| 185 | + "child" = "command".objid; |
| 186 | + OPEN "triggers" FOR |
| 187 | + SELECT * FROM @ [email protected]_inherit_triggers() "t" |
| 188 | + WHERE "t"."childrelid" = "child" AND "t"."is_inherited" = FALSE; |
| 189 | + ELSEIF "command".command_tag = 'ALTER TABLE' THEN |
| 190 | + "child" = "command".objid; |
| 191 | + OPEN "triggers" FOR |
| 192 | + SELECT * FROM @ [email protected]_inherit_triggers() "t" |
| 193 | + WHERE "t"."childrelid" = "child" AND "t"."is_inherited" = FALSE; |
| 194 | + ELSEIF "command".command_tag = 'CREATE TRIGGER' THEN |
| 195 | + "triggerid" = "command".objid; |
| 196 | + OPEN "triggers" FOR |
| 197 | + SELECT * FROM @ [email protected]_inherit_triggers() "t" |
| 198 | + WHERE "t"."parentid" = "triggerid" AND "t"."is_inherited" = FALSE; |
| 199 | + ELSE |
| 200 | + CONTINUE; |
| 201 | + END IF; |
| 202 | + |
| 203 | + LOOP |
| 204 | + FETCH NEXT FROM "triggers" INTO "trigger"; |
| 205 | + EXIT WHEN "trigger" IS NULL; |
| 206 | + |
| 207 | + "name" = @ [email protected]_child_trigger_name( "trigger". "parentname", "trigger". "parentrelid"::REGCLASS, "trigger". "childrelid"::REGCLASS); |
| 208 | + "query" = @ [email protected]_child_trigger_def( "trigger". "parentdef", "trigger". "parentname", "trigger". "parentrelid"::REGCLASS, "trigger". "childrelid"::REGCLASS); |
| 209 | + RAISE NOTICE USING MESSAGE = format('-- ADD TRIGGER %1I TO %2s TABLE FROM %3s TABLE', "name", "trigger"."childrelid"::REGCLASS, "trigger"."parentrelid"::REGCLASS); |
| 210 | + RAISE NOTICE USING MESSAGE = "query"; |
| 211 | + EXECUTE "query"; |
| 212 | + END LOOP; |
| 213 | + CLOSE "triggers"; |
| 214 | + END LOOP; |
| 215 | +END; |
| 216 | +$$ |
| 217 | +LANGUAGE plpgsql |
| 218 | +VOLATILE; |
| 219 | +/* |
| 220 | +=================== EVENT_TRIGGER_DROP_INHERIT_CONSTRAINTS =================== |
| 221 | +*/ |
| 222 | +CREATE OR REPLACE FUNCTION @ [email protected]_trigger_drop_inherit_constraints () |
| 223 | + RETURNS EVENT_TRIGGER |
| 224 | +AS $$ |
| 225 | +DECLARE |
| 226 | + "object" RECORD; |
| 227 | + "parent" OID; |
| 228 | + "child" OID; |
| 229 | + "name" TEXT; |
| 230 | + "query" TEXT; |
| 231 | + "schema" TEXT; |
| 232 | + "table" TEXT; |
| 233 | +BEGIN |
| 234 | + FOR "object" IN |
| 235 | + SELECT * FROM pg_event_trigger_dropped_objects() |
| 236 | + LOOP |
| 237 | + IF "object".object_type = 'table constraint' THEN |
| 238 | + "schema" = "object".address_names[1]; |
| 239 | + "table" = "object".address_names[2]; |
| 240 | + "parent" = format('%1I.%2I', "schema", "table")::REGCLASS::OID; |
| 241 | + "name" = "object".address_names[3]; |
| 242 | + FOR "child" IN |
| 243 | + SELECT inhrelid FROM pg_inherits WHERE inhparent = "parent" |
| 244 | + LOOP |
| 245 | + "name" = @ [email protected]_child_constraint_name( "name", "parent"::REGCLASS, "child"::REGCLASS); |
| 246 | + "query" = format('ALTER TABLE %1s DROP CONSTRAINT IF EXISTS %2I;', "child"::REGCLASS, "name"); |
| 247 | + RAISE NOTICE USING MESSAGE = format('-- DROP CONSTRAINT %1I FROM %2s TABLE BASED ON DEPENDENCY ON %3s TABLE', "name", "child"::REGCLASS, "parent"::REGCLASS); |
| 248 | + RAISE NOTICE USING MESSAGE = "query"; |
| 249 | + EXECUTE "query"; |
| 250 | + END LOOP; |
| 251 | + END IF; |
| 252 | + END LOOP; |
| 253 | +END; |
| 254 | +$$ |
| 255 | +LANGUAGE plpgsql |
| 256 | +VOLATILE; |
| 257 | +/* |
| 258 | +=================== EVENT_TRIGGER_DROP_INHERIT_TRIGGERS =================== |
| 259 | +*/ |
| 260 | +CREATE OR REPLACE FUNCTION @ [email protected]_trigger_drop_inherit_triggers () |
| 261 | + RETURNS EVENT_TRIGGER |
| 262 | +AS $$ |
| 263 | +DECLARE |
| 264 | + "object" RECORD; |
| 265 | + "parent" OID; |
| 266 | + "child" OID; |
| 267 | + "name" TEXT; |
| 268 | + "query" TEXT; |
| 269 | + "schema" TEXT; |
| 270 | + "table" TEXT; |
| 271 | +BEGIN |
| 272 | + FOR "object" IN |
| 273 | + SELECT * FROM pg_event_trigger_dropped_objects() |
| 274 | + LOOP |
| 275 | + IF "object".object_type = 'trigger' THEN |
| 276 | + "schema" = "object".address_names[1]; |
| 277 | + "table" = "object".address_names[2]; |
| 278 | + "parent" = format('%1I.%2I', "schema", "table")::REGCLASS::OID; |
| 279 | + "name" = "object".address_names[3]; |
| 280 | + FOR "child" IN |
| 281 | + SELECT inhrelid FROM pg_inherits WHERE inhparent = "parent" |
| 282 | + LOOP |
| 283 | + "name" = @ [email protected]_child_trigger_name( "name", "parent"::REGCLASS, "child"::REGCLASS); |
| 284 | + "query" = format('DROP TRIGGER IF EXISTS %1I ON %2s;', "name", "child"::REGCLASS); |
| 285 | + RAISE NOTICE USING MESSAGE = format('-- DROP TRIGGER %1I FROM %2s TABLE BASED ON DEPENDENCY ON %3s TABLE', "name", "child"::REGCLASS, "parent"::REGCLASS); |
| 286 | + RAISE NOTICE USING MESSAGE = "query"; |
| 287 | + EXECUTE "query"; |
| 288 | + END LOOP; |
| 289 | + END IF; |
| 290 | + END LOOP; |
| 291 | +END; |
| 292 | +$$ |
| 293 | +LANGUAGE plpgsql |
| 294 | +VOLATILE; |
0 commit comments