1--
2-- TRIGGERS
3--
4
5create table pkeys (pkey1 int4 not null, pkey2 text not null);
6create table fkeys (fkey1 int4, fkey2 text, fkey3 int);
7create table fkeys2 (fkey21 int4, fkey22 text, pkey23 int not null);
8
9create index fkeys_i on fkeys (fkey1, fkey2);
10create index fkeys2_i on fkeys2 (fkey21, fkey22);
11create index fkeys2p_i on fkeys2 (pkey23);
12
13insert into pkeys values (10, '1');
14insert into pkeys values (20, '2');
15insert into pkeys values (30, '3');
16insert into pkeys values (40, '4');
17insert into pkeys values (50, '5');
18insert into pkeys values (60, '6');
19create unique index pkeys_i on pkeys (pkey1, pkey2);
20
21--
22-- For fkeys:
23-- 	(fkey1, fkey2)	--> pkeys (pkey1, pkey2)
24-- 	(fkey3)		--> fkeys2 (pkey23)
25--
26create trigger check_fkeys_pkey_exist
27	before insert or update on fkeys
28	for each row
29	execute function
30	check_primary_key ('fkey1', 'fkey2', 'pkeys', 'pkey1', 'pkey2');
31
32create trigger check_fkeys_pkey2_exist
33	before insert or update on fkeys
34	for each row
35	execute function check_primary_key ('fkey3', 'fkeys2', 'pkey23');
36
37--
38-- For fkeys2:
39-- 	(fkey21, fkey22)	--> pkeys (pkey1, pkey2)
40--
41create trigger check_fkeys2_pkey_exist
42	before insert or update on fkeys2
43	for each row
44	execute procedure
45	check_primary_key ('fkey21', 'fkey22', 'pkeys', 'pkey1', 'pkey2');
46
47-- Test comments
48COMMENT ON TRIGGER check_fkeys2_pkey_bad ON fkeys2 IS 'wrong';
49COMMENT ON TRIGGER check_fkeys2_pkey_exist ON fkeys2 IS 'right';
50COMMENT ON TRIGGER check_fkeys2_pkey_exist ON fkeys2 IS NULL;
51
52--
53-- For pkeys:
54-- 	ON DELETE/UPDATE (pkey1, pkey2) CASCADE:
55-- 		fkeys (fkey1, fkey2) and fkeys2 (fkey21, fkey22)
56--
57create trigger check_pkeys_fkey_cascade
58	before delete or update on pkeys
59	for each row
60	execute procedure
61	check_foreign_key (2, 'cascade', 'pkey1', 'pkey2',
62	'fkeys', 'fkey1', 'fkey2', 'fkeys2', 'fkey21', 'fkey22');
63
64--
65-- For fkeys2:
66-- 	ON DELETE/UPDATE (pkey23) RESTRICT:
67-- 		fkeys (fkey3)
68--
69create trigger check_fkeys2_fkey_restrict
70	before delete or update on fkeys2
71	for each row
72	execute procedure check_foreign_key (1, 'restrict', 'pkey23', 'fkeys', 'fkey3');
73
74insert into fkeys2 values (10, '1', 1);
75insert into fkeys2 values (30, '3', 2);
76insert into fkeys2 values (40, '4', 5);
77insert into fkeys2 values (50, '5', 3);
78-- no key in pkeys
79insert into fkeys2 values (70, '5', 3);
80
81insert into fkeys values (10, '1', 2);
82insert into fkeys values (30, '3', 3);
83insert into fkeys values (40, '4', 2);
84insert into fkeys values (50, '5', 2);
85-- no key in pkeys
86insert into fkeys values (70, '5', 1);
87-- no key in fkeys2
88insert into fkeys values (60, '6', 4);
89
90delete from pkeys where pkey1 = 30 and pkey2 = '3';
91delete from pkeys where pkey1 = 40 and pkey2 = '4';
92update pkeys set pkey1 = 7, pkey2 = '70' where pkey1 = 50 and pkey2 = '5';
93update pkeys set pkey1 = 7, pkey2 = '70' where pkey1 = 10 and pkey2 = '1';
94
95SELECT trigger_name, event_manipulation, event_object_schema, event_object_table,
96       action_order, action_condition, action_orientation, action_timing,
97       action_reference_old_table, action_reference_new_table
98  FROM information_schema.triggers
99  WHERE event_object_table in ('pkeys', 'fkeys', 'fkeys2')
100  ORDER BY trigger_name COLLATE "C", 2;
101
102DROP TABLE pkeys;
103DROP TABLE fkeys;
104DROP TABLE fkeys2;
105
106-- Check behavior when trigger returns unmodified trigtuple
107create table trigtest (f1 int, f2 text);
108
109create trigger trigger_return_old
110	before insert or delete or update on trigtest
111	for each row execute procedure trigger_return_old();
112
113insert into trigtest values(1, 'foo');
114select * from trigtest;
115update trigtest set f2 = f2 || 'bar';
116select * from trigtest;
117delete from trigtest;
118select * from trigtest;
119
120-- Also check what happens when such a trigger runs before or after others
121create function f1_times_10() returns trigger as
122$$ begin new.f1 := new.f1 * 10; return new; end $$ language plpgsql;
123
124create trigger trigger_alpha
125	before insert or update on trigtest
126	for each row execute procedure f1_times_10();
127
128insert into trigtest values(1, 'foo');
129select * from trigtest;
130update trigtest set f2 = f2 || 'bar';
131select * from trigtest;
132delete from trigtest;
133select * from trigtest;
134
135create trigger trigger_zed
136	before insert or update on trigtest
137	for each row execute procedure f1_times_10();
138
139insert into trigtest values(1, 'foo');
140select * from trigtest;
141update trigtest set f2 = f2 || 'bar';
142select * from trigtest;
143delete from trigtest;
144select * from trigtest;
145
146drop trigger trigger_alpha on trigtest;
147
148insert into trigtest values(1, 'foo');
149select * from trigtest;
150update trigtest set f2 = f2 || 'bar';
151select * from trigtest;
152delete from trigtest;
153select * from trigtest;
154
155drop table trigtest;
156
157create sequence ttdummy_seq increment 10 start 0 minvalue 0;
158
159create table tttest (
160	price_id	int4,
161	price_val	int4,
162	price_on	int4,
163	price_off	int4 default 999999
164);
165
166create trigger ttdummy
167	before delete or update on tttest
168	for each row
169	execute procedure
170	ttdummy (price_on, price_off);
171
172create trigger ttserial
173	before insert or update on tttest
174	for each row
175	execute procedure
176	autoinc (price_on, ttdummy_seq);
177
178insert into tttest values (1, 1, null);
179insert into tttest values (2, 2, null);
180insert into tttest values (3, 3, 0);
181
182select * from tttest;
183delete from tttest where price_id = 2;
184select * from tttest;
185-- what do we see ?
186
187-- get current prices
188select * from tttest where price_off = 999999;
189
190-- change price for price_id == 3
191update tttest set price_val = 30 where price_id = 3;
192select * from tttest;
193
194-- now we want to change pric_id in ALL tuples
195-- this gets us not what we need
196update tttest set price_id = 5 where price_id = 3;
197select * from tttest;
198
199-- restore data as before last update:
200select set_ttdummy(0);
201delete from tttest where price_id = 5;
202update tttest set price_off = 999999 where price_val = 30;
203select * from tttest;
204
205-- and try change price_id now!
206update tttest set price_id = 5 where price_id = 3;
207select * from tttest;
208-- isn't it what we need ?
209
210select set_ttdummy(1);
211
212-- we want to correct some "date"
213update tttest set price_on = -1 where price_id = 1;
214-- but this doesn't work
215
216-- try in this way
217select set_ttdummy(0);
218update tttest set price_on = -1 where price_id = 1;
219select * from tttest;
220-- isn't it what we need ?
221
222-- get price for price_id == 5 as it was @ "date" 35
223select * from tttest where price_on <= 35 and price_off > 35 and price_id = 5;
224
225drop table tttest;
226drop sequence ttdummy_seq;
227
228--
229-- tests for per-statement triggers
230--
231
232CREATE TABLE log_table (tstamp timestamp default timeofday()::timestamp);
233
234CREATE TABLE main_table (a int unique, b int);
235
236COPY main_table (a,b) FROM stdin;
2375	10
23820	20
23930	10
24050	35
24180	15
242\.
243
244CREATE FUNCTION trigger_func() RETURNS trigger LANGUAGE plpgsql AS '
245BEGIN
246	RAISE NOTICE ''trigger_func(%) called: action = %, when = %, level = %'', TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
247	RETURN NULL;
248END;';
249
250CREATE TRIGGER before_ins_stmt_trig BEFORE INSERT ON main_table
251FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func('before_ins_stmt');
252
253CREATE TRIGGER after_ins_stmt_trig AFTER INSERT ON main_table
254FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func('after_ins_stmt');
255
256--
257-- if neither 'FOR EACH ROW' nor 'FOR EACH STATEMENT' was specified,
258-- CREATE TRIGGER should default to 'FOR EACH STATEMENT'
259--
260CREATE TRIGGER after_upd_stmt_trig AFTER UPDATE ON main_table
261EXECUTE PROCEDURE trigger_func('after_upd_stmt');
262
263-- Both insert and update statement level triggers (before and after) should
264-- fire.  Doesn't fire UPDATE before trigger, but only because one isn't
265-- defined.
266INSERT INTO main_table (a, b) VALUES (5, 10) ON CONFLICT (a)
267  DO UPDATE SET b = EXCLUDED.b;
268
269CREATE TRIGGER after_upd_row_trig AFTER UPDATE ON main_table
270FOR EACH ROW EXECUTE PROCEDURE trigger_func('after_upd_row');
271
272INSERT INTO main_table DEFAULT VALUES;
273
274UPDATE main_table SET a = a + 1 WHERE b < 30;
275-- UPDATE that effects zero rows should still call per-statement trigger
276UPDATE main_table SET a = a + 2 WHERE b > 100;
277
278-- constraint now unneeded
279ALTER TABLE main_table DROP CONSTRAINT main_table_a_key;
280
281-- COPY should fire per-row and per-statement INSERT triggers
282COPY main_table (a, b) FROM stdin;
28330	40
28450	60
285\.
286
287SELECT * FROM main_table ORDER BY a, b;
288
289--
290-- test triggers with WHEN clause
291--
292
293CREATE TRIGGER modified_a BEFORE UPDATE OF a ON main_table
294FOR EACH ROW WHEN (OLD.a <> NEW.a) EXECUTE PROCEDURE trigger_func('modified_a');
295CREATE TRIGGER modified_any BEFORE UPDATE OF a ON main_table
296FOR EACH ROW WHEN (OLD.* IS DISTINCT FROM NEW.*) EXECUTE PROCEDURE trigger_func('modified_any');
297CREATE TRIGGER insert_a AFTER INSERT ON main_table
298FOR EACH ROW WHEN (NEW.a = 123) EXECUTE PROCEDURE trigger_func('insert_a');
299CREATE TRIGGER delete_a AFTER DELETE ON main_table
300FOR EACH ROW WHEN (OLD.a = 123) EXECUTE PROCEDURE trigger_func('delete_a');
301CREATE TRIGGER insert_when BEFORE INSERT ON main_table
302FOR EACH STATEMENT WHEN (true) EXECUTE PROCEDURE trigger_func('insert_when');
303CREATE TRIGGER delete_when AFTER DELETE ON main_table
304FOR EACH STATEMENT WHEN (true) EXECUTE PROCEDURE trigger_func('delete_when');
305SELECT trigger_name, event_manipulation, event_object_schema, event_object_table,
306       action_order, action_condition, action_orientation, action_timing,
307       action_reference_old_table, action_reference_new_table
308  FROM information_schema.triggers
309  WHERE event_object_table IN ('main_table')
310  ORDER BY trigger_name COLLATE "C", 2;
311INSERT INTO main_table (a) VALUES (123), (456);
312COPY main_table FROM stdin;
313123	999
314456	999
315\.
316DELETE FROM main_table WHERE a IN (123, 456);
317UPDATE main_table SET a = 50, b = 60;
318SELECT * FROM main_table ORDER BY a, b;
319SELECT pg_get_triggerdef(oid, true) FROM pg_trigger WHERE tgrelid = 'main_table'::regclass AND tgname = 'modified_a';
320SELECT pg_get_triggerdef(oid, false) FROM pg_trigger WHERE tgrelid = 'main_table'::regclass AND tgname = 'modified_a';
321SELECT pg_get_triggerdef(oid, true) FROM pg_trigger WHERE tgrelid = 'main_table'::regclass AND tgname = 'modified_any';
322DROP TRIGGER modified_a ON main_table;
323DROP TRIGGER modified_any ON main_table;
324DROP TRIGGER insert_a ON main_table;
325DROP TRIGGER delete_a ON main_table;
326DROP TRIGGER insert_when ON main_table;
327DROP TRIGGER delete_when ON main_table;
328
329-- Test column-level triggers
330DROP TRIGGER after_upd_row_trig ON main_table;
331
332CREATE TRIGGER before_upd_a_row_trig BEFORE UPDATE OF a ON main_table
333FOR EACH ROW EXECUTE PROCEDURE trigger_func('before_upd_a_row');
334CREATE TRIGGER after_upd_b_row_trig AFTER UPDATE OF b ON main_table
335FOR EACH ROW EXECUTE PROCEDURE trigger_func('after_upd_b_row');
336CREATE TRIGGER after_upd_a_b_row_trig AFTER UPDATE OF a, b ON main_table
337FOR EACH ROW EXECUTE PROCEDURE trigger_func('after_upd_a_b_row');
338
339CREATE TRIGGER before_upd_a_stmt_trig BEFORE UPDATE OF a ON main_table
340FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func('before_upd_a_stmt');
341CREATE TRIGGER after_upd_b_stmt_trig AFTER UPDATE OF b ON main_table
342FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func('after_upd_b_stmt');
343
344SELECT pg_get_triggerdef(oid) FROM pg_trigger WHERE tgrelid = 'main_table'::regclass AND tgname = 'after_upd_a_b_row_trig';
345
346UPDATE main_table SET a = 50;
347UPDATE main_table SET b = 10;
348
349--
350-- Test case for bug with BEFORE trigger followed by AFTER trigger with WHEN
351--
352
353CREATE TABLE some_t (some_col boolean NOT NULL);
354CREATE FUNCTION dummy_update_func() RETURNS trigger AS $$
355BEGIN
356  RAISE NOTICE 'dummy_update_func(%) called: action = %, old = %, new = %',
357    TG_ARGV[0], TG_OP, OLD, NEW;
358  RETURN NEW;
359END;
360$$ LANGUAGE plpgsql;
361CREATE TRIGGER some_trig_before BEFORE UPDATE ON some_t FOR EACH ROW
362  EXECUTE PROCEDURE dummy_update_func('before');
363CREATE TRIGGER some_trig_aftera AFTER UPDATE ON some_t FOR EACH ROW
364  WHEN (NOT OLD.some_col AND NEW.some_col)
365  EXECUTE PROCEDURE dummy_update_func('aftera');
366CREATE TRIGGER some_trig_afterb AFTER UPDATE ON some_t FOR EACH ROW
367  WHEN (NOT NEW.some_col)
368  EXECUTE PROCEDURE dummy_update_func('afterb');
369INSERT INTO some_t VALUES (TRUE);
370UPDATE some_t SET some_col = TRUE;
371UPDATE some_t SET some_col = FALSE;
372UPDATE some_t SET some_col = TRUE;
373DROP TABLE some_t;
374
375-- bogus cases
376CREATE TRIGGER error_upd_and_col BEFORE UPDATE OR UPDATE OF a ON main_table
377FOR EACH ROW EXECUTE PROCEDURE trigger_func('error_upd_and_col');
378CREATE TRIGGER error_upd_a_a BEFORE UPDATE OF a, a ON main_table
379FOR EACH ROW EXECUTE PROCEDURE trigger_func('error_upd_a_a');
380CREATE TRIGGER error_ins_a BEFORE INSERT OF a ON main_table
381FOR EACH ROW EXECUTE PROCEDURE trigger_func('error_ins_a');
382CREATE TRIGGER error_ins_when BEFORE INSERT OR UPDATE ON main_table
383FOR EACH ROW WHEN (OLD.a <> NEW.a)
384EXECUTE PROCEDURE trigger_func('error_ins_old');
385CREATE TRIGGER error_del_when BEFORE DELETE OR UPDATE ON main_table
386FOR EACH ROW WHEN (OLD.a <> NEW.a)
387EXECUTE PROCEDURE trigger_func('error_del_new');
388CREATE TRIGGER error_del_when BEFORE INSERT OR UPDATE ON main_table
389FOR EACH ROW WHEN (NEW.tableoid <> 0)
390EXECUTE PROCEDURE trigger_func('error_when_sys_column');
391CREATE TRIGGER error_stmt_when BEFORE UPDATE OF a ON main_table
392FOR EACH STATEMENT WHEN (OLD.* IS DISTINCT FROM NEW.*)
393EXECUTE PROCEDURE trigger_func('error_stmt_when');
394
395-- check dependency restrictions
396ALTER TABLE main_table DROP COLUMN b;
397-- this should succeed, but we'll roll it back to keep the triggers around
398begin;
399DROP TRIGGER after_upd_a_b_row_trig ON main_table;
400DROP TRIGGER after_upd_b_row_trig ON main_table;
401DROP TRIGGER after_upd_b_stmt_trig ON main_table;
402ALTER TABLE main_table DROP COLUMN b;
403rollback;
404
405-- Test enable/disable triggers
406
407create table trigtest (i serial primary key);
408-- test that disabling RI triggers works
409create table trigtest2 (i int references trigtest(i) on delete cascade);
410
411create function trigtest() returns trigger as $$
412begin
413	raise notice '% % % %', TG_RELNAME, TG_OP, TG_WHEN, TG_LEVEL;
414	return new;
415end;$$ language plpgsql;
416
417create trigger trigtest_b_row_tg before insert or update or delete on trigtest
418for each row execute procedure trigtest();
419create trigger trigtest_a_row_tg after insert or update or delete on trigtest
420for each row execute procedure trigtest();
421create trigger trigtest_b_stmt_tg before insert or update or delete on trigtest
422for each statement execute procedure trigtest();
423create trigger trigtest_a_stmt_tg after insert or update or delete on trigtest
424for each statement execute procedure trigtest();
425
426insert into trigtest default values;
427alter table trigtest disable trigger trigtest_b_row_tg;
428insert into trigtest default values;
429alter table trigtest disable trigger user;
430insert into trigtest default values;
431alter table trigtest enable trigger trigtest_a_stmt_tg;
432insert into trigtest default values;
433set session_replication_role = replica;
434insert into trigtest default values;  -- does not trigger
435alter table trigtest enable always trigger trigtest_a_stmt_tg;
436insert into trigtest default values;  -- now it does
437reset session_replication_role;
438insert into trigtest2 values(1);
439insert into trigtest2 values(2);
440delete from trigtest where i=2;
441select * from trigtest2;
442alter table trigtest disable trigger all;
443delete from trigtest where i=1;
444select * from trigtest2;
445-- ensure we still insert, even when all triggers are disabled
446insert into trigtest default values;
447select *  from trigtest;
448drop table trigtest2;
449drop table trigtest;
450
451
452-- dump trigger data
453CREATE TABLE trigger_test (
454        i int,
455        v varchar
456);
457
458CREATE OR REPLACE FUNCTION trigger_data()  RETURNS trigger
459LANGUAGE plpgsql AS $$
460
461declare
462
463	argstr text;
464	relid text;
465
466begin
467
468	relid := TG_relid::regclass;
469
470	-- plpgsql can't discover its trigger data in a hash like perl and python
471	-- can, or by a sort of reflection like tcl can,
472	-- so we have to hard code the names.
473	raise NOTICE 'TG_NAME: %', TG_name;
474	raise NOTICE 'TG_WHEN: %', TG_when;
475	raise NOTICE 'TG_LEVEL: %', TG_level;
476	raise NOTICE 'TG_OP: %', TG_op;
477	raise NOTICE 'TG_RELID::regclass: %', relid;
478	raise NOTICE 'TG_RELNAME: %', TG_relname;
479	raise NOTICE 'TG_TABLE_NAME: %', TG_table_name;
480	raise NOTICE 'TG_TABLE_SCHEMA: %', TG_table_schema;
481	raise NOTICE 'TG_NARGS: %', TG_nargs;
482
483	argstr := '[';
484	for i in 0 .. TG_nargs - 1 loop
485		if i > 0 then
486			argstr := argstr || ', ';
487		end if;
488		argstr := argstr || TG_argv[i];
489	end loop;
490	argstr := argstr || ']';
491	raise NOTICE 'TG_ARGV: %', argstr;
492
493	if TG_OP != 'INSERT' then
494		raise NOTICE 'OLD: %', OLD;
495	end if;
496
497	if TG_OP != 'DELETE' then
498		raise NOTICE 'NEW: %', NEW;
499	end if;
500
501	if TG_OP = 'DELETE' then
502		return OLD;
503	else
504		return NEW;
505	end if;
506
507end;
508$$;
509
510CREATE TRIGGER show_trigger_data_trig
511BEFORE INSERT OR UPDATE OR DELETE ON trigger_test
512FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
513
514insert into trigger_test values(1,'insert');
515update trigger_test set v = 'update' where i = 1;
516delete from trigger_test;
517
518DROP TRIGGER show_trigger_data_trig on trigger_test;
519
520DROP FUNCTION trigger_data();
521
522DROP TABLE trigger_test;
523
524--
525-- Test use of row comparisons on OLD/NEW
526--
527
528CREATE TABLE trigger_test (f1 int, f2 text, f3 text);
529
530-- this is the obvious (and wrong...) way to compare rows
531CREATE FUNCTION mytrigger() RETURNS trigger LANGUAGE plpgsql as $$
532begin
533	if row(old.*) = row(new.*) then
534		raise notice 'row % not changed', new.f1;
535	else
536		raise notice 'row % changed', new.f1;
537	end if;
538	return new;
539end$$;
540
541CREATE TRIGGER t
542BEFORE UPDATE ON trigger_test
543FOR EACH ROW EXECUTE PROCEDURE mytrigger();
544
545INSERT INTO trigger_test VALUES(1, 'foo', 'bar');
546INSERT INTO trigger_test VALUES(2, 'baz', 'quux');
547
548UPDATE trigger_test SET f3 = 'bar';
549UPDATE trigger_test SET f3 = NULL;
550-- this demonstrates that the above isn't really working as desired:
551UPDATE trigger_test SET f3 = NULL;
552
553-- the right way when considering nulls is
554CREATE OR REPLACE FUNCTION mytrigger() RETURNS trigger LANGUAGE plpgsql as $$
555begin
556	if row(old.*) is distinct from row(new.*) then
557		raise notice 'row % changed', new.f1;
558	else
559		raise notice 'row % not changed', new.f1;
560	end if;
561	return new;
562end$$;
563
564UPDATE trigger_test SET f3 = 'bar';
565UPDATE trigger_test SET f3 = NULL;
566UPDATE trigger_test SET f3 = NULL;
567
568DROP TABLE trigger_test;
569
570DROP FUNCTION mytrigger();
571
572-- Test snapshot management in serializable transactions involving triggers
573-- per bug report in 6bc73d4c0910042358k3d1adff3qa36f8df75198ecea@mail.gmail.com
574CREATE FUNCTION serializable_update_trig() RETURNS trigger LANGUAGE plpgsql AS
575$$
576declare
577	rec record;
578begin
579	new.description = 'updated in trigger';
580	return new;
581end;
582$$;
583
584CREATE TABLE serializable_update_tab (
585	id int,
586	filler  text,
587	description text
588);
589
590CREATE TRIGGER serializable_update_trig BEFORE UPDATE ON serializable_update_tab
591	FOR EACH ROW EXECUTE PROCEDURE serializable_update_trig();
592
593INSERT INTO serializable_update_tab SELECT a, repeat('xyzxz', 100), 'new'
594	FROM generate_series(1, 50) a;
595
596BEGIN;
597SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;
598UPDATE serializable_update_tab SET description = 'no no', id = 1 WHERE id = 1;
599COMMIT;
600SELECT description FROM serializable_update_tab WHERE id = 1;
601DROP TABLE serializable_update_tab;
602
603-- minimal update trigger
604
605CREATE TABLE min_updates_test (
606	f1	text,
607	f2 int,
608	f3 int);
609
610CREATE TABLE min_updates_test_oids (
611	f1	text,
612	f2 int,
613	f3 int) WITH OIDS;
614
615INSERT INTO min_updates_test VALUES ('a',1,2),('b','2',null);
616
617INSERT INTO min_updates_test_oids VALUES ('a',1,2),('b','2',null);
618
619CREATE TRIGGER z_min_update
620BEFORE UPDATE ON min_updates_test
621FOR EACH ROW EXECUTE PROCEDURE suppress_redundant_updates_trigger();
622
623CREATE TRIGGER z_min_update
624BEFORE UPDATE ON min_updates_test_oids
625FOR EACH ROW EXECUTE PROCEDURE suppress_redundant_updates_trigger();
626
627\set QUIET false
628
629UPDATE min_updates_test SET f1 = f1;
630
631UPDATE min_updates_test SET f2 = f2 + 1;
632
633UPDATE min_updates_test SET f3 = 2 WHERE f3 is null;
634
635UPDATE min_updates_test_oids SET f1 = f1;
636
637UPDATE min_updates_test_oids SET f2 = f2 + 1;
638
639UPDATE min_updates_test_oids SET f3 = 2 WHERE f3 is null;
640
641\set QUIET true
642
643SELECT * FROM min_updates_test;
644
645SELECT * FROM min_updates_test_oids;
646
647DROP TABLE min_updates_test;
648
649DROP TABLE min_updates_test_oids;
650
651--
652-- Test triggers on views
653--
654
655CREATE VIEW main_view AS SELECT a, b FROM main_table;
656
657-- VIEW trigger function
658CREATE OR REPLACE FUNCTION view_trigger() RETURNS trigger
659LANGUAGE plpgsql AS $$
660declare
661    argstr text := '';
662begin
663    for i in 0 .. TG_nargs - 1 loop
664        if i > 0 then
665            argstr := argstr || ', ';
666        end if;
667        argstr := argstr || TG_argv[i];
668    end loop;
669
670    raise notice '% % % % (%)', TG_RELNAME, TG_WHEN, TG_OP, TG_LEVEL, argstr;
671
672    if TG_LEVEL = 'ROW' then
673        if TG_OP = 'INSERT' then
674            raise NOTICE 'NEW: %', NEW;
675            INSERT INTO main_table VALUES (NEW.a, NEW.b);
676            RETURN NEW;
677        end if;
678
679        if TG_OP = 'UPDATE' then
680            raise NOTICE 'OLD: %, NEW: %', OLD, NEW;
681            UPDATE main_table SET a = NEW.a, b = NEW.b WHERE a = OLD.a AND b = OLD.b;
682            if NOT FOUND then RETURN NULL; end if;
683            RETURN NEW;
684        end if;
685
686        if TG_OP = 'DELETE' then
687            raise NOTICE 'OLD: %', OLD;
688            DELETE FROM main_table WHERE a = OLD.a AND b = OLD.b;
689            if NOT FOUND then RETURN NULL; end if;
690            RETURN OLD;
691        end if;
692    end if;
693
694    RETURN NULL;
695end;
696$$;
697
698-- Before row triggers aren't allowed on views
699CREATE TRIGGER invalid_trig BEFORE INSERT ON main_view
700FOR EACH ROW EXECUTE PROCEDURE trigger_func('before_ins_row');
701
702CREATE TRIGGER invalid_trig BEFORE UPDATE ON main_view
703FOR EACH ROW EXECUTE PROCEDURE trigger_func('before_upd_row');
704
705CREATE TRIGGER invalid_trig BEFORE DELETE ON main_view
706FOR EACH ROW EXECUTE PROCEDURE trigger_func('before_del_row');
707
708-- After row triggers aren't allowed on views
709CREATE TRIGGER invalid_trig AFTER INSERT ON main_view
710FOR EACH ROW EXECUTE PROCEDURE trigger_func('before_ins_row');
711
712CREATE TRIGGER invalid_trig AFTER UPDATE ON main_view
713FOR EACH ROW EXECUTE PROCEDURE trigger_func('before_upd_row');
714
715CREATE TRIGGER invalid_trig AFTER DELETE ON main_view
716FOR EACH ROW EXECUTE PROCEDURE trigger_func('before_del_row');
717
718-- Truncate triggers aren't allowed on views
719CREATE TRIGGER invalid_trig BEFORE TRUNCATE ON main_view
720EXECUTE PROCEDURE trigger_func('before_tru_row');
721
722CREATE TRIGGER invalid_trig AFTER TRUNCATE ON main_view
723EXECUTE PROCEDURE trigger_func('before_tru_row');
724
725-- INSTEAD OF triggers aren't allowed on tables
726CREATE TRIGGER invalid_trig INSTEAD OF INSERT ON main_table
727FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_ins');
728
729CREATE TRIGGER invalid_trig INSTEAD OF UPDATE ON main_table
730FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_upd');
731
732CREATE TRIGGER invalid_trig INSTEAD OF DELETE ON main_table
733FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_del');
734
735-- Don't support WHEN clauses with INSTEAD OF triggers
736CREATE TRIGGER invalid_trig INSTEAD OF UPDATE ON main_view
737FOR EACH ROW WHEN (OLD.a <> NEW.a) EXECUTE PROCEDURE view_trigger('instead_of_upd');
738
739-- Don't support column-level INSTEAD OF triggers
740CREATE TRIGGER invalid_trig INSTEAD OF UPDATE OF a ON main_view
741FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_upd');
742
743-- Don't support statement-level INSTEAD OF triggers
744CREATE TRIGGER invalid_trig INSTEAD OF UPDATE ON main_view
745EXECUTE PROCEDURE view_trigger('instead_of_upd');
746
747-- Valid INSTEAD OF triggers
748CREATE TRIGGER instead_of_insert_trig INSTEAD OF INSERT ON main_view
749FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_ins');
750
751CREATE TRIGGER instead_of_update_trig INSTEAD OF UPDATE ON main_view
752FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_upd');
753
754CREATE TRIGGER instead_of_delete_trig INSTEAD OF DELETE ON main_view
755FOR EACH ROW EXECUTE PROCEDURE view_trigger('instead_of_del');
756
757-- Valid BEFORE statement VIEW triggers
758CREATE TRIGGER before_ins_stmt_trig BEFORE INSERT ON main_view
759FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('before_view_ins_stmt');
760
761CREATE TRIGGER before_upd_stmt_trig BEFORE UPDATE ON main_view
762FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('before_view_upd_stmt');
763
764CREATE TRIGGER before_del_stmt_trig BEFORE DELETE ON main_view
765FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('before_view_del_stmt');
766
767-- Valid AFTER statement VIEW triggers
768CREATE TRIGGER after_ins_stmt_trig AFTER INSERT ON main_view
769FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('after_view_ins_stmt');
770
771CREATE TRIGGER after_upd_stmt_trig AFTER UPDATE ON main_view
772FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('after_view_upd_stmt');
773
774CREATE TRIGGER after_del_stmt_trig AFTER DELETE ON main_view
775FOR EACH STATEMENT EXECUTE PROCEDURE view_trigger('after_view_del_stmt');
776
777\set QUIET false
778
779-- Insert into view using trigger
780INSERT INTO main_view VALUES (20, 30);
781INSERT INTO main_view VALUES (21, 31) RETURNING a, b;
782
783-- Table trigger will prevent updates
784UPDATE main_view SET b = 31 WHERE a = 20;
785UPDATE main_view SET b = 32 WHERE a = 21 AND b = 31 RETURNING a, b;
786
787-- Remove table trigger to allow updates
788DROP TRIGGER before_upd_a_row_trig ON main_table;
789UPDATE main_view SET b = 31 WHERE a = 20;
790UPDATE main_view SET b = 32 WHERE a = 21 AND b = 31 RETURNING a, b;
791
792-- Before and after stmt triggers should fire even when no rows are affected
793UPDATE main_view SET b = 0 WHERE false;
794
795-- Delete from view using trigger
796DELETE FROM main_view WHERE a IN (20,21);
797DELETE FROM main_view WHERE a = 31 RETURNING a, b;
798
799\set QUIET true
800
801-- Describe view should list triggers
802\d main_view
803
804-- Test dropping view triggers
805DROP TRIGGER instead_of_insert_trig ON main_view;
806DROP TRIGGER instead_of_delete_trig ON main_view;
807\d+ main_view
808DROP VIEW main_view;
809
810--
811-- Test triggers on a join view
812--
813CREATE TABLE country_table (
814    country_id        serial primary key,
815    country_name    text unique not null,
816    continent        text not null
817);
818
819INSERT INTO country_table (country_name, continent)
820    VALUES ('Japan', 'Asia'),
821           ('UK', 'Europe'),
822           ('USA', 'North America')
823    RETURNING *;
824
825CREATE TABLE city_table (
826    city_id        serial primary key,
827    city_name    text not null,
828    population    bigint,
829    country_id    int references country_table
830);
831
832CREATE VIEW city_view AS
833    SELECT city_id, city_name, population, country_name, continent
834    FROM city_table ci
835    LEFT JOIN country_table co ON co.country_id = ci.country_id;
836
837CREATE FUNCTION city_insert() RETURNS trigger LANGUAGE plpgsql AS $$
838declare
839    ctry_id int;
840begin
841    if NEW.country_name IS NOT NULL then
842        SELECT country_id, continent INTO ctry_id, NEW.continent
843            FROM country_table WHERE country_name = NEW.country_name;
844        if NOT FOUND then
845            raise exception 'No such country: "%"', NEW.country_name;
846        end if;
847    else
848        NEW.continent := NULL;
849    end if;
850
851    if NEW.city_id IS NOT NULL then
852        INSERT INTO city_table
853            VALUES(NEW.city_id, NEW.city_name, NEW.population, ctry_id);
854    else
855        INSERT INTO city_table(city_name, population, country_id)
856            VALUES(NEW.city_name, NEW.population, ctry_id)
857            RETURNING city_id INTO NEW.city_id;
858    end if;
859
860    RETURN NEW;
861end;
862$$;
863
864CREATE TRIGGER city_insert_trig INSTEAD OF INSERT ON city_view
865FOR EACH ROW EXECUTE PROCEDURE city_insert();
866
867CREATE FUNCTION city_delete() RETURNS trigger LANGUAGE plpgsql AS $$
868begin
869    DELETE FROM city_table WHERE city_id = OLD.city_id;
870    if NOT FOUND then RETURN NULL; end if;
871    RETURN OLD;
872end;
873$$;
874
875CREATE TRIGGER city_delete_trig INSTEAD OF DELETE ON city_view
876FOR EACH ROW EXECUTE PROCEDURE city_delete();
877
878CREATE FUNCTION city_update() RETURNS trigger LANGUAGE plpgsql AS $$
879declare
880    ctry_id int;
881begin
882    if NEW.country_name IS DISTINCT FROM OLD.country_name then
883        SELECT country_id, continent INTO ctry_id, NEW.continent
884            FROM country_table WHERE country_name = NEW.country_name;
885        if NOT FOUND then
886            raise exception 'No such country: "%"', NEW.country_name;
887        end if;
888
889        UPDATE city_table SET city_name = NEW.city_name,
890                              population = NEW.population,
891                              country_id = ctry_id
892            WHERE city_id = OLD.city_id;
893    else
894        UPDATE city_table SET city_name = NEW.city_name,
895                              population = NEW.population
896            WHERE city_id = OLD.city_id;
897        NEW.continent := OLD.continent;
898    end if;
899
900    if NOT FOUND then RETURN NULL; end if;
901    RETURN NEW;
902end;
903$$;
904
905CREATE TRIGGER city_update_trig INSTEAD OF UPDATE ON city_view
906FOR EACH ROW EXECUTE PROCEDURE city_update();
907
908\set QUIET false
909
910-- INSERT .. RETURNING
911INSERT INTO city_view(city_name) VALUES('Tokyo') RETURNING *;
912INSERT INTO city_view(city_name, population) VALUES('London', 7556900) RETURNING *;
913INSERT INTO city_view(city_name, country_name) VALUES('Washington DC', 'USA') RETURNING *;
914INSERT INTO city_view(city_id, city_name) VALUES(123456, 'New York') RETURNING *;
915INSERT INTO city_view VALUES(234567, 'Birmingham', 1016800, 'UK', 'EU') RETURNING *;
916
917-- UPDATE .. RETURNING
918UPDATE city_view SET country_name = 'Japon' WHERE city_name = 'Tokyo'; -- error
919UPDATE city_view SET country_name = 'Japan' WHERE city_name = 'Takyo'; -- no match
920UPDATE city_view SET country_name = 'Japan' WHERE city_name = 'Tokyo' RETURNING *; -- OK
921
922UPDATE city_view SET population = 13010279 WHERE city_name = 'Tokyo' RETURNING *;
923UPDATE city_view SET country_name = 'UK' WHERE city_name = 'New York' RETURNING *;
924UPDATE city_view SET country_name = 'USA', population = 8391881 WHERE city_name = 'New York' RETURNING *;
925UPDATE city_view SET continent = 'EU' WHERE continent = 'Europe' RETURNING *;
926UPDATE city_view v1 SET country_name = v2.country_name FROM city_view v2
927    WHERE v2.city_name = 'Birmingham' AND v1.city_name = 'London' RETURNING *;
928
929-- DELETE .. RETURNING
930DELETE FROM city_view WHERE city_name = 'Birmingham' RETURNING *;
931
932\set QUIET true
933
934-- read-only view with WHERE clause
935CREATE VIEW european_city_view AS
936    SELECT * FROM city_view WHERE continent = 'Europe';
937SELECT count(*) FROM european_city_view;
938
939CREATE FUNCTION no_op_trig_fn() RETURNS trigger LANGUAGE plpgsql
940AS 'begin RETURN NULL; end';
941
942CREATE TRIGGER no_op_trig INSTEAD OF INSERT OR UPDATE OR DELETE
943ON european_city_view FOR EACH ROW EXECUTE PROCEDURE no_op_trig_fn();
944
945\set QUIET false
946
947INSERT INTO european_city_view VALUES (0, 'x', 10000, 'y', 'z');
948UPDATE european_city_view SET population = 10000;
949DELETE FROM european_city_view;
950
951\set QUIET true
952
953-- rules bypassing no-op triggers
954CREATE RULE european_city_insert_rule AS ON INSERT TO european_city_view
955DO INSTEAD INSERT INTO city_view
956VALUES (NEW.city_id, NEW.city_name, NEW.population, NEW.country_name, NEW.continent)
957RETURNING *;
958
959CREATE RULE european_city_update_rule AS ON UPDATE TO european_city_view
960DO INSTEAD UPDATE city_view SET
961    city_name = NEW.city_name,
962    population = NEW.population,
963    country_name = NEW.country_name
964WHERE city_id = OLD.city_id
965RETURNING NEW.*;
966
967CREATE RULE european_city_delete_rule AS ON DELETE TO european_city_view
968DO INSTEAD DELETE FROM city_view WHERE city_id = OLD.city_id RETURNING *;
969
970\set QUIET false
971
972-- INSERT not limited by view's WHERE clause, but UPDATE AND DELETE are
973INSERT INTO european_city_view(city_name, country_name)
974    VALUES ('Cambridge', 'USA') RETURNING *;
975UPDATE european_city_view SET country_name = 'UK'
976    WHERE city_name = 'Cambridge';
977DELETE FROM european_city_view WHERE city_name = 'Cambridge';
978
979-- UPDATE and DELETE via rule and trigger
980UPDATE city_view SET country_name = 'UK'
981    WHERE city_name = 'Cambridge' RETURNING *;
982UPDATE european_city_view SET population = 122800
983    WHERE city_name = 'Cambridge' RETURNING *;
984DELETE FROM european_city_view WHERE city_name = 'Cambridge' RETURNING *;
985
986-- join UPDATE test
987UPDATE city_view v SET population = 599657
988    FROM city_table ci, country_table co
989    WHERE ci.city_name = 'Washington DC' and co.country_name = 'USA'
990    AND v.city_id = ci.city_id AND v.country_name = co.country_name
991    RETURNING co.country_id, v.country_name,
992              v.city_id, v.city_name, v.population;
993
994\set QUIET true
995
996SELECT * FROM city_view;
997
998DROP TABLE city_table CASCADE;
999DROP TABLE country_table;
1000
1001
1002-- Test pg_trigger_depth()
1003
1004create table depth_a (id int not null primary key);
1005create table depth_b (id int not null primary key);
1006create table depth_c (id int not null primary key);
1007
1008create function depth_a_tf() returns trigger
1009  language plpgsql as $$
1010begin
1011  raise notice '%: depth = %', tg_name, pg_trigger_depth();
1012  insert into depth_b values (new.id);
1013  raise notice '%: depth = %', tg_name, pg_trigger_depth();
1014  return new;
1015end;
1016$$;
1017create trigger depth_a_tr before insert on depth_a
1018  for each row execute procedure depth_a_tf();
1019
1020create function depth_b_tf() returns trigger
1021  language plpgsql as $$
1022begin
1023  raise notice '%: depth = %', tg_name, pg_trigger_depth();
1024  begin
1025    execute 'insert into depth_c values (' || new.id::text || ')';
1026  exception
1027    when sqlstate 'U9999' then
1028      raise notice 'SQLSTATE = U9999: depth = %', pg_trigger_depth();
1029  end;
1030  raise notice '%: depth = %', tg_name, pg_trigger_depth();
1031  if new.id = 1 then
1032    execute 'insert into depth_c values (' || new.id::text || ')';
1033  end if;
1034  return new;
1035end;
1036$$;
1037create trigger depth_b_tr before insert on depth_b
1038  for each row execute procedure depth_b_tf();
1039
1040create function depth_c_tf() returns trigger
1041  language plpgsql as $$
1042begin
1043  raise notice '%: depth = %', tg_name, pg_trigger_depth();
1044  if new.id = 1 then
1045    raise exception sqlstate 'U9999';
1046  end if;
1047  raise notice '%: depth = %', tg_name, pg_trigger_depth();
1048  return new;
1049end;
1050$$;
1051create trigger depth_c_tr before insert on depth_c
1052  for each row execute procedure depth_c_tf();
1053
1054select pg_trigger_depth();
1055insert into depth_a values (1);
1056select pg_trigger_depth();
1057insert into depth_a values (2);
1058select pg_trigger_depth();
1059
1060drop table depth_a, depth_b, depth_c;
1061drop function depth_a_tf();
1062drop function depth_b_tf();
1063drop function depth_c_tf();
1064
1065--
1066-- Test updates to rows during firing of BEFORE ROW triggers.
1067-- As of 9.2, such cases should be rejected (see bug #6123).
1068--
1069
1070create temp table parent (
1071    aid int not null primary key,
1072    val1 text,
1073    val2 text,
1074    val3 text,
1075    val4 text,
1076    bcnt int not null default 0);
1077create temp table child (
1078    bid int not null primary key,
1079    aid int not null,
1080    val1 text);
1081
1082create function parent_upd_func()
1083  returns trigger language plpgsql as
1084$$
1085begin
1086  if old.val1 <> new.val1 then
1087    new.val2 = new.val1;
1088    delete from child where child.aid = new.aid and child.val1 = new.val1;
1089  end if;
1090  return new;
1091end;
1092$$;
1093create trigger parent_upd_trig before update on parent
1094  for each row execute procedure parent_upd_func();
1095
1096create function parent_del_func()
1097  returns trigger language plpgsql as
1098$$
1099begin
1100  delete from child where aid = old.aid;
1101  return old;
1102end;
1103$$;
1104create trigger parent_del_trig before delete on parent
1105  for each row execute procedure parent_del_func();
1106
1107create function child_ins_func()
1108  returns trigger language plpgsql as
1109$$
1110begin
1111  update parent set bcnt = bcnt + 1 where aid = new.aid;
1112  return new;
1113end;
1114$$;
1115create trigger child_ins_trig after insert on child
1116  for each row execute procedure child_ins_func();
1117
1118create function child_del_func()
1119  returns trigger language plpgsql as
1120$$
1121begin
1122  update parent set bcnt = bcnt - 1 where aid = old.aid;
1123  return old;
1124end;
1125$$;
1126create trigger child_del_trig after delete on child
1127  for each row execute procedure child_del_func();
1128
1129insert into parent values (1, 'a', 'a', 'a', 'a', 0);
1130insert into child values (10, 1, 'b');
1131select * from parent; select * from child;
1132
1133update parent set val1 = 'b' where aid = 1; -- should fail
1134select * from parent; select * from child;
1135
1136delete from parent where aid = 1; -- should fail
1137select * from parent; select * from child;
1138
1139-- replace the trigger function with one that restarts the deletion after
1140-- having modified a child
1141create or replace function parent_del_func()
1142  returns trigger language plpgsql as
1143$$
1144begin
1145  delete from child where aid = old.aid;
1146  if found then
1147    delete from parent where aid = old.aid;
1148    return null; -- cancel outer deletion
1149  end if;
1150  return old;
1151end;
1152$$;
1153
1154delete from parent where aid = 1;
1155select * from parent; select * from child;
1156
1157drop table parent, child;
1158
1159drop function parent_upd_func();
1160drop function parent_del_func();
1161drop function child_ins_func();
1162drop function child_del_func();
1163
1164-- similar case, but with a self-referencing FK so that parent and child
1165-- rows can be affected by a single operation
1166
1167create temp table self_ref_trigger (
1168    id int primary key,
1169    parent int references self_ref_trigger,
1170    data text,
1171    nchildren int not null default 0
1172);
1173
1174create function self_ref_trigger_ins_func()
1175  returns trigger language plpgsql as
1176$$
1177begin
1178  if new.parent is not null then
1179    update self_ref_trigger set nchildren = nchildren + 1
1180      where id = new.parent;
1181  end if;
1182  return new;
1183end;
1184$$;
1185create trigger self_ref_trigger_ins_trig before insert on self_ref_trigger
1186  for each row execute procedure self_ref_trigger_ins_func();
1187
1188create function self_ref_trigger_del_func()
1189  returns trigger language plpgsql as
1190$$
1191begin
1192  if old.parent is not null then
1193    update self_ref_trigger set nchildren = nchildren - 1
1194      where id = old.parent;
1195  end if;
1196  return old;
1197end;
1198$$;
1199create trigger self_ref_trigger_del_trig before delete on self_ref_trigger
1200  for each row execute procedure self_ref_trigger_del_func();
1201
1202insert into self_ref_trigger values (1, null, 'root');
1203insert into self_ref_trigger values (2, 1, 'root child A');
1204insert into self_ref_trigger values (3, 1, 'root child B');
1205insert into self_ref_trigger values (4, 2, 'grandchild 1');
1206insert into self_ref_trigger values (5, 3, 'grandchild 2');
1207
1208update self_ref_trigger set data = 'root!' where id = 1;
1209
1210select * from self_ref_trigger;
1211
1212delete from self_ref_trigger;
1213
1214select * from self_ref_trigger;
1215
1216drop table self_ref_trigger;
1217drop function self_ref_trigger_ins_func();
1218drop function self_ref_trigger_del_func();
1219
1220--
1221-- Check that statement triggers work correctly even with all children excluded
1222--
1223
1224create table stmt_trig_on_empty_upd (a int);
1225create table stmt_trig_on_empty_upd1 () inherits (stmt_trig_on_empty_upd);
1226create function update_stmt_notice() returns trigger as $$
1227begin
1228	raise notice 'updating %', TG_TABLE_NAME;
1229	return null;
1230end;
1231$$ language plpgsql;
1232create trigger before_stmt_trigger
1233	before update on stmt_trig_on_empty_upd
1234	execute procedure update_stmt_notice();
1235create trigger before_stmt_trigger
1236	before update on stmt_trig_on_empty_upd1
1237	execute procedure update_stmt_notice();
1238
1239-- inherited no-op update
1240update stmt_trig_on_empty_upd set a = a where false returning a+1 as aa;
1241-- simple no-op update
1242update stmt_trig_on_empty_upd1 set a = a where false returning a+1 as aa;
1243
1244drop table stmt_trig_on_empty_upd cascade;
1245drop function update_stmt_notice();
1246
1247--
1248-- Check that index creation (or DDL in general) is prohibited in a trigger
1249--
1250
1251create table trigger_ddl_table (
1252   col1 integer,
1253   col2 integer
1254);
1255
1256create function trigger_ddl_func() returns trigger as $$
1257begin
1258  alter table trigger_ddl_table add primary key (col1);
1259  return new;
1260end$$ language plpgsql;
1261
1262create trigger trigger_ddl_func before insert on trigger_ddl_table for each row
1263  execute procedure trigger_ddl_func();
1264
1265insert into trigger_ddl_table values (1, 42);  -- fail
1266
1267create or replace function trigger_ddl_func() returns trigger as $$
1268begin
1269  create index on trigger_ddl_table (col2);
1270  return new;
1271end$$ language plpgsql;
1272
1273insert into trigger_ddl_table values (1, 42);  -- fail
1274
1275drop table trigger_ddl_table;
1276drop function trigger_ddl_func();
1277
1278--
1279-- Verify behavior of before and after triggers with INSERT...ON CONFLICT
1280-- DO UPDATE
1281--
1282create table upsert (key int4 primary key, color text);
1283
1284create function upsert_before_func()
1285  returns trigger language plpgsql as
1286$$
1287begin
1288  if (TG_OP = 'UPDATE') then
1289    raise warning 'before update (old): %', old.*::text;
1290    raise warning 'before update (new): %', new.*::text;
1291  elsif (TG_OP = 'INSERT') then
1292    raise warning 'before insert (new): %', new.*::text;
1293    if new.key % 2 = 0 then
1294      new.key := new.key + 1;
1295      new.color := new.color || ' trig modified';
1296      raise warning 'before insert (new, modified): %', new.*::text;
1297    end if;
1298  end if;
1299  return new;
1300end;
1301$$;
1302create trigger upsert_before_trig before insert or update on upsert
1303  for each row execute procedure upsert_before_func();
1304
1305create function upsert_after_func()
1306  returns trigger language plpgsql as
1307$$
1308begin
1309  if (TG_OP = 'UPDATE') then
1310    raise warning 'after update (old): %', old.*::text;
1311    raise warning 'after update (new): %', new.*::text;
1312  elsif (TG_OP = 'INSERT') then
1313    raise warning 'after insert (new): %', new.*::text;
1314  end if;
1315  return null;
1316end;
1317$$;
1318create trigger upsert_after_trig after insert or update on upsert
1319  for each row execute procedure upsert_after_func();
1320
1321insert into upsert values(1, 'black') on conflict (key) do update set color = 'updated ' || upsert.color;
1322insert into upsert values(2, 'red') on conflict (key) do update set color = 'updated ' || upsert.color;
1323insert into upsert values(3, 'orange') on conflict (key) do update set color = 'updated ' || upsert.color;
1324insert into upsert values(4, 'green') on conflict (key) do update set color = 'updated ' || upsert.color;
1325insert into upsert values(5, 'purple') on conflict (key) do update set color = 'updated ' || upsert.color;
1326insert into upsert values(6, 'white') on conflict (key) do update set color = 'updated ' || upsert.color;
1327insert into upsert values(7, 'pink') on conflict (key) do update set color = 'updated ' || upsert.color;
1328insert into upsert values(8, 'yellow') on conflict (key) do update set color = 'updated ' || upsert.color;
1329
1330select * from upsert;
1331
1332drop table upsert;
1333drop function upsert_before_func();
1334drop function upsert_after_func();
1335
1336--
1337-- Verify that triggers with transition tables are not allowed on
1338-- views
1339--
1340
1341create table my_table (i int);
1342create view my_view as select * from my_table;
1343create function my_trigger_function() returns trigger as $$ begin end; $$ language plpgsql;
1344create trigger my_trigger after update on my_view referencing old table as old_table
1345   for each statement execute procedure my_trigger_function();
1346drop function my_trigger_function();
1347drop view my_view;
1348drop table my_table;
1349
1350--
1351-- Verify cases that are unsupported with partitioned tables
1352--
1353create table parted_trig (a int) partition by list (a);
1354create function trigger_nothing() returns trigger
1355  language plpgsql as $$ begin end; $$;
1356create trigger failed before insert or update or delete on parted_trig
1357  for each row execute procedure trigger_nothing();
1358create trigger failed instead of update on parted_trig
1359  for each row execute procedure trigger_nothing();
1360create trigger failed after update on parted_trig
1361  referencing old table as old_table
1362  for each row execute procedure trigger_nothing();
1363drop table parted_trig;
1364
1365--
1366-- Verify trigger creation for partitioned tables, and drop behavior
1367--
1368create table trigpart (a int, b int) partition by range (a);
1369create table trigpart1 partition of trigpart for values from (0) to (1000);
1370create trigger trg1 after insert on trigpart for each row execute procedure trigger_nothing();
1371create table trigpart2 partition of trigpart for values from (1000) to (2000);
1372create table trigpart3 (like trigpart);
1373alter table trigpart attach partition trigpart3 for values from (2000) to (3000);
1374create table trigpart4 partition of trigpart for values from (3000) to (4000) partition by range (a);
1375create table trigpart41 partition of trigpart4 for values from (3000) to (3500);
1376create table trigpart42 (like trigpart);
1377alter table trigpart4 attach partition trigpart42 for values from (3500) to (4000);
1378select tgrelid::regclass, tgname, tgfoid::regproc from pg_trigger
1379  where tgrelid::regclass::text like 'trigpart%' order by tgrelid::regclass::text;
1380drop trigger trg1 on trigpart1;	-- fail
1381drop trigger trg1 on trigpart2;	-- fail
1382drop trigger trg1 on trigpart3;	-- fail
1383drop table trigpart2;			-- ok, trigger should be gone in that partition
1384select tgrelid::regclass, tgname, tgfoid::regproc from pg_trigger
1385  where tgrelid::regclass::text like 'trigpart%' order by tgrelid::regclass::text;
1386drop trigger trg1 on trigpart;		-- ok, all gone
1387select tgrelid::regclass, tgname, tgfoid::regproc from pg_trigger
1388  where tgrelid::regclass::text like 'trigpart%' order by tgrelid::regclass::text;
1389
1390-- check detach behavior
1391create trigger trg1 after insert on trigpart for each row execute procedure trigger_nothing();
1392\d trigpart3
1393alter table trigpart detach partition trigpart3;
1394drop trigger trg1 on trigpart3; -- fail due to "does not exist"
1395alter table trigpart detach partition trigpart4;
1396drop trigger trg1 on trigpart41; -- fail due to "does not exist"
1397drop table trigpart4;
1398alter table trigpart attach partition trigpart3 for values from (2000) to (3000);
1399alter table trigpart detach partition trigpart3;
1400alter table trigpart attach partition trigpart3 for values from (2000) to (3000);
1401drop table trigpart3;
1402
1403select tgrelid::regclass::text, tgname, tgfoid::regproc, tgenabled, tgisinternal from pg_trigger
1404  where tgname ~ '^trg1' order by 1;
1405create table trigpart3 (like trigpart);
1406create trigger trg1 after insert on trigpart3 for each row execute procedure trigger_nothing();
1407\d trigpart3
1408alter table trigpart attach partition trigpart3 FOR VALUES FROM (2000) to (3000); -- fail
1409drop table trigpart3;
1410
1411drop table trigpart;
1412drop function trigger_nothing();
1413
1414--
1415-- Verify that triggers are fired for partitioned tables
1416--
1417create table parted_stmt_trig (a int) partition by list (a);
1418create table parted_stmt_trig1 partition of parted_stmt_trig for values in (1);
1419create table parted_stmt_trig2 partition of parted_stmt_trig for values in (2);
1420
1421create table parted2_stmt_trig (a int) partition by list (a);
1422create table parted2_stmt_trig1 partition of parted2_stmt_trig for values in (1);
1423create table parted2_stmt_trig2 partition of parted2_stmt_trig for values in (2);
1424
1425create or replace function trigger_notice() returns trigger as $$
1426  begin
1427    raise notice 'trigger % on % % % for %', TG_NAME, TG_TABLE_NAME, TG_WHEN, TG_OP, TG_LEVEL;
1428    if TG_LEVEL = 'ROW' then
1429       return NEW;
1430    end if;
1431    return null;
1432  end;
1433  $$ language plpgsql;
1434
1435-- insert/update/delete statement-level triggers on the parent
1436create trigger trig_ins_before before insert on parted_stmt_trig
1437  for each statement execute procedure trigger_notice();
1438create trigger trig_ins_after after insert on parted_stmt_trig
1439  for each statement execute procedure trigger_notice();
1440create trigger trig_upd_before before update on parted_stmt_trig
1441  for each statement execute procedure trigger_notice();
1442create trigger trig_upd_after after update on parted_stmt_trig
1443  for each statement execute procedure trigger_notice();
1444create trigger trig_del_before before delete on parted_stmt_trig
1445  for each statement execute procedure trigger_notice();
1446create trigger trig_del_after after delete on parted_stmt_trig
1447  for each statement execute procedure trigger_notice();
1448
1449-- insert/update/delete row-level triggers on the parent
1450create trigger trig_ins_after_parent after insert on parted_stmt_trig
1451  for each row execute procedure trigger_notice();
1452create trigger trig_upd_after_parent after update on parted_stmt_trig
1453  for each row execute procedure trigger_notice();
1454create trigger trig_del_after_parent after delete on parted_stmt_trig
1455  for each row execute procedure trigger_notice();
1456
1457-- insert/update/delete row-level triggers on the first partition
1458create trigger trig_ins_before_child before insert on parted_stmt_trig1
1459  for each row execute procedure trigger_notice();
1460create trigger trig_ins_after_child after insert on parted_stmt_trig1
1461  for each row execute procedure trigger_notice();
1462create trigger trig_upd_before_child before update on parted_stmt_trig1
1463  for each row execute procedure trigger_notice();
1464create trigger trig_upd_after_child after update on parted_stmt_trig1
1465  for each row execute procedure trigger_notice();
1466create trigger trig_del_before_child before delete on parted_stmt_trig1
1467  for each row execute procedure trigger_notice();
1468create trigger trig_del_after_child after delete on parted_stmt_trig1
1469  for each row execute procedure trigger_notice();
1470
1471-- insert/update/delete statement-level triggers on the parent
1472create trigger trig_ins_before_3 before insert on parted2_stmt_trig
1473  for each statement execute procedure trigger_notice();
1474create trigger trig_ins_after_3 after insert on parted2_stmt_trig
1475  for each statement execute procedure trigger_notice();
1476create trigger trig_upd_before_3 before update on parted2_stmt_trig
1477  for each statement execute procedure trigger_notice();
1478create trigger trig_upd_after_3 after update on parted2_stmt_trig
1479  for each statement execute procedure trigger_notice();
1480create trigger trig_del_before_3 before delete on parted2_stmt_trig
1481  for each statement execute procedure trigger_notice();
1482create trigger trig_del_after_3 after delete on parted2_stmt_trig
1483  for each statement execute procedure trigger_notice();
1484
1485with ins (a) as (
1486  insert into parted2_stmt_trig values (1), (2) returning a
1487) insert into parted_stmt_trig select a from ins returning tableoid::regclass, a;
1488
1489with upd as (
1490  update parted2_stmt_trig set a = a
1491) update parted_stmt_trig  set a = a;
1492
1493delete from parted_stmt_trig;
1494
1495-- insert via copy on the parent
1496copy parted_stmt_trig(a) from stdin;
14971
14982
1499\.
1500
1501-- insert via copy on the first partition
1502copy parted_stmt_trig1(a) from stdin;
15031
1504\.
1505
1506-- Disabling a trigger in the parent table should disable children triggers too
1507alter table parted_stmt_trig disable trigger trig_ins_after_parent;
1508insert into parted_stmt_trig values (1);
1509alter table parted_stmt_trig enable trigger trig_ins_after_parent;
1510insert into parted_stmt_trig values (1);
1511
1512drop table parted_stmt_trig, parted2_stmt_trig;
1513
1514-- Verify that triggers fire in alphabetical order
1515create table parted_trig (a int) partition by range (a);
1516create table parted_trig_1 partition of parted_trig for values from (0) to (1000)
1517   partition by range (a);
1518create table parted_trig_1_1 partition of parted_trig_1 for values from (0) to (100);
1519create table parted_trig_2 partition of parted_trig for values from (1000) to (2000);
1520create trigger zzz after insert on parted_trig for each row execute procedure trigger_notice();
1521create trigger mmm after insert on parted_trig_1_1 for each row execute procedure trigger_notice();
1522create trigger aaa after insert on parted_trig_1 for each row execute procedure trigger_notice();
1523create trigger bbb after insert on parted_trig for each row execute procedure trigger_notice();
1524create trigger qqq after insert on parted_trig_1_1 for each row execute procedure trigger_notice();
1525insert into parted_trig values (50), (1500);
1526drop table parted_trig;
1527
1528-- Verify propagation of trigger arguments to partitions
1529create table parted_trig (a int) partition by list (a);
1530create table parted_trig1 partition of parted_trig for values in (1);
1531create or replace function trigger_notice() returns trigger as $$
1532  declare
1533    arg1 text = TG_ARGV[0];
1534    arg2 integer = TG_ARGV[1];
1535  begin
1536    raise notice 'trigger % on % % % for % args % %',
1537		TG_NAME, TG_TABLE_NAME, TG_WHEN, TG_OP, TG_LEVEL, arg1, arg2;
1538    return null;
1539  end;
1540  $$ language plpgsql;
1541create trigger aaa after insert on parted_trig
1542   for each row execute procedure trigger_notice('quirky', 1);
1543
1544-- Verify propagation of trigger arguments to partitions attached after creating trigger
1545create table parted_trig2 partition of parted_trig for values in (2);
1546create table parted_trig3 (like parted_trig);
1547alter table parted_trig attach partition parted_trig3 for values in (3);
1548insert into parted_trig values (1), (2), (3);
1549drop table parted_trig;
1550
1551-- test irregular partitions (i.e., different column definitions),
1552-- including that the WHEN clause works
1553create function bark(text) returns bool language plpgsql immutable
1554  as $$ begin raise notice '% <- woof!', $1; return true; end; $$;
1555create or replace function trigger_notice_ab() returns trigger as $$
1556  begin
1557    raise notice 'trigger % on % % % for %: (a,b)=(%,%)',
1558		TG_NAME, TG_TABLE_NAME, TG_WHEN, TG_OP, TG_LEVEL,
1559		NEW.a, NEW.b;
1560    if TG_LEVEL = 'ROW' then
1561       return NEW;
1562    end if;
1563    return null;
1564  end;
1565  $$ language plpgsql;
1566create table parted_irreg_ancestor (fd text, b text, fd2 int, fd3 int, a int)
1567  partition by range (b);
1568alter table parted_irreg_ancestor drop column fd,
1569  drop column fd2, drop column fd3;
1570create table parted_irreg (fd int, a int, fd2 int, b text)
1571  partition by range (b);
1572alter table parted_irreg drop column fd, drop column fd2;
1573alter table parted_irreg_ancestor attach partition parted_irreg
1574  for values from ('aaaa') to ('zzzz');
1575create table parted1_irreg (b text, fd int, a int);
1576alter table parted1_irreg drop column fd;
1577alter table parted_irreg attach partition parted1_irreg
1578  for values from ('aaaa') to ('bbbb');
1579create trigger parted_trig after insert on parted_irreg
1580  for each row execute procedure trigger_notice_ab();
1581create trigger parted_trig_odd after insert on parted_irreg for each row
1582  when (bark(new.b) AND new.a % 2 = 1) execute procedure trigger_notice_ab();
1583-- we should hear barking for every insert, but parted_trig_odd only emits
1584-- noise for odd values of a. parted_trig does it for all inserts.
1585insert into parted_irreg values (1, 'aardvark'), (2, 'aanimals');
1586insert into parted1_irreg values ('aardwolf', 2);
1587insert into parted_irreg_ancestor values ('aasvogel', 3);
1588drop table parted_irreg_ancestor;
1589
1590--
1591-- Constraint triggers and partitioned tables
1592create table parted_constr_ancestor (a int, b text)
1593  partition by range (b);
1594create table parted_constr (a int, b text)
1595  partition by range (b);
1596alter table parted_constr_ancestor attach partition parted_constr
1597  for values from ('aaaa') to ('zzzz');
1598create table parted1_constr (a int, b text);
1599alter table parted_constr attach partition parted1_constr
1600  for values from ('aaaa') to ('bbbb');
1601create constraint trigger parted_trig after insert on parted_constr_ancestor
1602  deferrable
1603  for each row execute procedure trigger_notice_ab();
1604create constraint trigger parted_trig_two after insert on parted_constr
1605  deferrable initially deferred
1606  for each row when (bark(new.b) AND new.a % 2 = 1)
1607  execute procedure trigger_notice_ab();
1608
1609-- The immediate constraint is fired immediately; the WHEN clause of the
1610-- deferred constraint is also called immediately.  The deferred constraint
1611-- is fired at commit time.
1612begin;
1613insert into parted_constr values (1, 'aardvark');
1614insert into parted1_constr values (2, 'aardwolf');
1615insert into parted_constr_ancestor values (3, 'aasvogel');
1616commit;
1617
1618-- The WHEN clause is immediate, and both constraint triggers are fired at
1619-- commit time.
1620begin;
1621set constraints parted_trig deferred;
1622insert into parted_constr values (1, 'aardvark');
1623insert into parted1_constr values (2, 'aardwolf'), (3, 'aasvogel');
1624commit;
1625drop table parted_constr_ancestor;
1626drop function bark(text);
1627
1628-- Test that the WHEN clause is set properly to partitions
1629create table parted_trigger (a int, b text) partition by range (a);
1630create table parted_trigger_1 partition of parted_trigger for values from (0) to (1000);
1631create table parted_trigger_2 (drp int, a int, b text);
1632alter table parted_trigger_2 drop column drp;
1633alter table parted_trigger attach partition parted_trigger_2 for values from (1000) to (2000);
1634create trigger parted_trigger after update on parted_trigger
1635  for each row when (new.a % 2 = 1 and length(old.b) >= 2) execute procedure trigger_notice_ab();
1636create table parted_trigger_3 (b text, a int) partition by range (length(b));
1637create table parted_trigger_3_1 partition of parted_trigger_3 for values from (1) to (3);
1638create table parted_trigger_3_2 partition of parted_trigger_3 for values from (3) to (5);
1639alter table parted_trigger attach partition parted_trigger_3 for values from (2000) to (3000);
1640insert into parted_trigger values
1641    (0, 'a'), (1, 'bbb'), (2, 'bcd'), (3, 'c'),
1642	(1000, 'c'), (1001, 'ddd'), (1002, 'efg'), (1003, 'f'),
1643	(2000, 'e'), (2001, 'fff'), (2002, 'ghi'), (2003, 'h');
1644update parted_trigger set a = a + 2; -- notice for odd 'a' values, long 'b' values
1645drop table parted_trigger;
1646
1647-- try a constraint trigger, also
1648create table parted_referenced (a int);
1649create table unparted_trigger (a int, b text);	-- for comparison purposes
1650create table parted_trigger (a int, b text) partition by range (a);
1651create table parted_trigger_1 partition of parted_trigger for values from (0) to (1000);
1652create table parted_trigger_2 (drp int, a int, b text);
1653alter table parted_trigger_2 drop column drp;
1654alter table parted_trigger attach partition parted_trigger_2 for values from (1000) to (2000);
1655create constraint trigger parted_trigger after update on parted_trigger
1656  from parted_referenced
1657  for each row execute procedure trigger_notice_ab();
1658create constraint trigger parted_trigger after update on unparted_trigger
1659  from parted_referenced
1660  for each row execute procedure trigger_notice_ab();
1661create table parted_trigger_3 (b text, a int) partition by range (length(b));
1662create table parted_trigger_3_1 partition of parted_trigger_3 for values from (1) to (3);
1663create table parted_trigger_3_2 partition of parted_trigger_3 for values from (3) to (5);
1664alter table parted_trigger attach partition parted_trigger_3 for values from (2000) to (3000);
1665select tgname, conname, t.tgrelid::regclass, t.tgconstrrelid::regclass,
1666  c.conrelid::regclass, c.confrelid::regclass
1667  from pg_trigger t join pg_constraint c on (t.tgconstraint = c.oid)
1668  where tgname = 'parted_trigger'
1669  order by t.tgrelid::regclass::text;
1670drop table parted_referenced, parted_trigger, unparted_trigger;
1671
1672-- verify that the "AFTER UPDATE OF columns" event is propagated correctly
1673create table parted_trigger (a int, b text) partition by range (a);
1674create table parted_trigger_1 partition of parted_trigger for values from (0) to (1000);
1675create table parted_trigger_2 (drp int, a int, b text);
1676alter table parted_trigger_2 drop column drp;
1677alter table parted_trigger attach partition parted_trigger_2 for values from (1000) to (2000);
1678create trigger parted_trigger after update of b on parted_trigger
1679  for each row execute procedure trigger_notice_ab();
1680create table parted_trigger_3 (b text, a int) partition by range (length(b));
1681create table parted_trigger_3_1 partition of parted_trigger_3 for values from (1) to (4);
1682create table parted_trigger_3_2 partition of parted_trigger_3 for values from (4) to (8);
1683alter table parted_trigger attach partition parted_trigger_3 for values from (2000) to (3000);
1684insert into parted_trigger values (0, 'a'), (1000, 'c'), (2000, 'e'), (2001, 'eeee');
1685update parted_trigger set a = a + 2;	-- no notices here
1686update parted_trigger set b = b || 'b';	-- all triggers should fire
1687drop table parted_trigger;
1688
1689drop function trigger_notice_ab();
1690
1691-- Make sure we don't end up with unnecessary copies of triggers, when
1692-- cloning them.
1693create table trg_clone (a int) partition by range (a);
1694create table trg_clone1 partition of trg_clone for values from (0) to (1000);
1695alter table trg_clone add constraint uniq unique (a) deferrable;
1696create table trg_clone2 partition of trg_clone for values from (1000) to (2000);
1697create table trg_clone3 partition of trg_clone for values from (2000) to (3000)
1698  partition by range (a);
1699create table trg_clone_3_3 partition of trg_clone3 for values from (2000) to (2100);
1700select tgrelid::regclass, count(*) from pg_trigger
1701  where tgrelid::regclass in ('trg_clone', 'trg_clone1', 'trg_clone2',
1702	'trg_clone3', 'trg_clone_3_3')
1703  group by tgrelid::regclass order by tgrelid::regclass;
1704drop table trg_clone;
1705
1706-- Test the interaction between ALTER TABLE .. DISABLE TRIGGER and
1707-- both kinds of inheritance.  Historically, legacy inheritance has
1708-- not recursed to children, so that behavior is preserved.
1709create table parent (a int);
1710create table child1 () inherits (parent);
1711create function trig_nothing() returns trigger language plpgsql
1712  as $$ begin return null; end $$;
1713create trigger tg after insert on parent
1714  for each row execute function trig_nothing();
1715create trigger tg after insert on child1
1716  for each row execute function trig_nothing();
1717alter table parent disable trigger tg;
1718select tgrelid::regclass, tgname, tgenabled from pg_trigger
1719  where tgrelid in ('parent'::regclass, 'child1'::regclass)
1720  order by tgrelid::regclass::text;
1721alter table only parent enable always trigger tg;
1722select tgrelid::regclass, tgname, tgenabled from pg_trigger
1723  where tgrelid in ('parent'::regclass, 'child1'::regclass)
1724  order by tgrelid::regclass::text;
1725drop table parent, child1;
1726
1727create table parent (a int) partition by list (a);
1728create table child1 partition of parent for values in (1);
1729create trigger tg after insert on parent
1730  for each row execute procedure trig_nothing();
1731select tgrelid::regclass, tgname, tgenabled from pg_trigger
1732  where tgrelid in ('parent'::regclass, 'child1'::regclass)
1733  order by tgrelid::regclass::text;
1734alter table only parent enable always trigger tg;
1735select tgrelid::regclass, tgname, tgenabled from pg_trigger
1736  where tgrelid in ('parent'::regclass, 'child1'::regclass)
1737  order by tgrelid::regclass::text;
1738drop table parent, child1;
1739
1740-- Verify that firing state propagates correctly
1741CREATE TABLE trgfire (i int) PARTITION BY RANGE (i);
1742CREATE TABLE trgfire1 PARTITION OF trgfire FOR VALUES FROM (1) TO (10);
1743CREATE OR REPLACE FUNCTION tgf() RETURNS trigger LANGUAGE plpgsql
1744  AS $$ begin raise exception 'except'; end $$;
1745CREATE TRIGGER tg AFTER INSERT ON trgfire FOR EACH ROW EXECUTE FUNCTION tgf();
1746INSERT INTO trgfire VALUES (1);
1747ALTER TABLE trgfire DISABLE TRIGGER tg;
1748INSERT INTO trgfire VALUES (1);
1749CREATE TABLE trgfire2 PARTITION OF trgfire FOR VALUES FROM (10) TO (20);
1750INSERT INTO trgfire VALUES (11);
1751CREATE TABLE trgfire3 (LIKE trgfire);
1752ALTER TABLE trgfire ATTACH PARTITION trgfire3 FOR VALUES FROM (20) TO (30);
1753INSERT INTO trgfire VALUES (21);
1754CREATE TABLE trgfire4 PARTITION OF trgfire FOR VALUES FROM (30) TO (40) PARTITION BY LIST (i);
1755CREATE TABLE trgfire4_30 PARTITION OF trgfire4 FOR VALUES IN (30);
1756INSERT INTO trgfire VALUES (30);
1757CREATE TABLE trgfire5 (LIKE trgfire) PARTITION BY LIST (i);
1758CREATE TABLE trgfire5_40 PARTITION OF trgfire5 FOR VALUES IN (40);
1759ALTER TABLE trgfire ATTACH PARTITION trgfire5 FOR VALUES FROM (40) TO (50);
1760INSERT INTO trgfire VALUES (40);
1761SELECT tgrelid::regclass, tgenabled FROM pg_trigger
1762  WHERE tgrelid::regclass IN (SELECT oid from pg_class where relname LIKE 'trgfire%')
1763  ORDER BY tgrelid::regclass::text;
1764ALTER TABLE trgfire ENABLE TRIGGER tg;
1765INSERT INTO trgfire VALUES (1);
1766INSERT INTO trgfire VALUES (11);
1767INSERT INTO trgfire VALUES (21);
1768INSERT INTO trgfire VALUES (30);
1769INSERT INTO trgfire VALUES (40);
1770DROP TABLE trgfire;
1771DROP FUNCTION tgf();
1772
1773--
1774-- Test the interaction between transition tables and both kinds of
1775-- inheritance.  We'll dump the contents of the transition tables in a
1776-- format that shows the attribute order, so that we can distinguish
1777-- tuple formats (though not dropped attributes).
1778--
1779
1780create or replace function dump_insert() returns trigger language plpgsql as
1781$$
1782  begin
1783    raise notice 'trigger = %, new table = %',
1784                 TG_NAME,
1785                 (select string_agg(new_table::text, ', ' order by a) from new_table);
1786    return null;
1787  end;
1788$$;
1789
1790create or replace function dump_update() returns trigger language plpgsql as
1791$$
1792  begin
1793    raise notice 'trigger = %, old table = %, new table = %',
1794                 TG_NAME,
1795                 (select string_agg(old_table::text, ', ' order by a) from old_table),
1796                 (select string_agg(new_table::text, ', ' order by a) from new_table);
1797    return null;
1798  end;
1799$$;
1800
1801create or replace function dump_delete() returns trigger language plpgsql as
1802$$
1803  begin
1804    raise notice 'trigger = %, old table = %',
1805                 TG_NAME,
1806                 (select string_agg(old_table::text, ', ' order by a) from old_table);
1807    return null;
1808  end;
1809$$;
1810
1811--
1812-- Verify behavior of statement triggers on partition hierarchy with
1813-- transition tables.  Tuples should appear to each trigger in the
1814-- format of the relation the trigger is attached to.
1815--
1816
1817-- set up a partition hierarchy with some different TupleDescriptors
1818create table parent (a text, b int) partition by list (a);
1819
1820-- a child matching parent
1821create table child1 partition of parent for values in ('AAA');
1822
1823-- a child with a dropped column
1824create table child2 (x int, a text, b int);
1825alter table child2 drop column x;
1826alter table parent attach partition child2 for values in ('BBB');
1827
1828-- a child with a different column order
1829create table child3 (b int, a text);
1830alter table parent attach partition child3 for values in ('CCC');
1831
1832create trigger parent_insert_trig
1833  after insert on parent referencing new table as new_table
1834  for each statement execute procedure dump_insert();
1835create trigger parent_update_trig
1836  after update on parent referencing old table as old_table new table as new_table
1837  for each statement execute procedure dump_update();
1838create trigger parent_delete_trig
1839  after delete on parent referencing old table as old_table
1840  for each statement execute procedure dump_delete();
1841
1842create trigger child1_insert_trig
1843  after insert on child1 referencing new table as new_table
1844  for each statement execute procedure dump_insert();
1845create trigger child1_update_trig
1846  after update on child1 referencing old table as old_table new table as new_table
1847  for each statement execute procedure dump_update();
1848create trigger child1_delete_trig
1849  after delete on child1 referencing old table as old_table
1850  for each statement execute procedure dump_delete();
1851
1852create trigger child2_insert_trig
1853  after insert on child2 referencing new table as new_table
1854  for each statement execute procedure dump_insert();
1855create trigger child2_update_trig
1856  after update on child2 referencing old table as old_table new table as new_table
1857  for each statement execute procedure dump_update();
1858create trigger child2_delete_trig
1859  after delete on child2 referencing old table as old_table
1860  for each statement execute procedure dump_delete();
1861
1862create trigger child3_insert_trig
1863  after insert on child3 referencing new table as new_table
1864  for each statement execute procedure dump_insert();
1865create trigger child3_update_trig
1866  after update on child3 referencing old table as old_table new table as new_table
1867  for each statement execute procedure dump_update();
1868create trigger child3_delete_trig
1869  after delete on child3 referencing old table as old_table
1870  for each statement execute procedure dump_delete();
1871
1872SELECT trigger_name, event_manipulation, event_object_schema, event_object_table,
1873       action_order, action_condition, action_orientation, action_timing,
1874       action_reference_old_table, action_reference_new_table
1875  FROM information_schema.triggers
1876  WHERE event_object_table IN ('parent', 'child1', 'child2', 'child3')
1877  ORDER BY trigger_name COLLATE "C", 2;
1878
1879-- insert directly into children sees respective child-format tuples
1880insert into child1 values ('AAA', 42);
1881insert into child2 values ('BBB', 42);
1882insert into child3 values (42, 'CCC');
1883
1884-- update via parent sees parent-format tuples
1885update parent set b = b + 1;
1886
1887-- delete via parent sees parent-format tuples
1888delete from parent;
1889
1890-- insert into parent sees parent-format tuples
1891insert into parent values ('AAA', 42);
1892insert into parent values ('BBB', 42);
1893insert into parent values ('CCC', 42);
1894
1895-- delete from children sees respective child-format tuples
1896delete from child1;
1897delete from child2;
1898delete from child3;
1899
1900-- copy into parent sees parent-format tuples
1901copy parent (a, b) from stdin;
1902AAA	42
1903BBB	42
1904CCC	42
1905\.
1906
1907-- DML affecting parent sees tuples collected from children even if
1908-- there is no transition table trigger on the children
1909drop trigger child1_insert_trig on child1;
1910drop trigger child1_update_trig on child1;
1911drop trigger child1_delete_trig on child1;
1912drop trigger child2_insert_trig on child2;
1913drop trigger child2_update_trig on child2;
1914drop trigger child2_delete_trig on child2;
1915drop trigger child3_insert_trig on child3;
1916drop trigger child3_update_trig on child3;
1917drop trigger child3_delete_trig on child3;
1918delete from parent;
1919
1920-- copy into parent sees tuples collected from children even if there
1921-- is no transition-table trigger on the children
1922copy parent (a, b) from stdin;
1923AAA	42
1924BBB	42
1925CCC	42
1926\.
1927
1928-- insert into parent with a before trigger on a child tuple before
1929-- insertion, and we capture the newly modified row in parent format
1930create or replace function intercept_insert() returns trigger language plpgsql as
1931$$
1932  begin
1933    new.b = new.b + 1000;
1934    return new;
1935  end;
1936$$;
1937
1938create trigger intercept_insert_child3
1939  before insert on child3
1940  for each row execute procedure intercept_insert();
1941
1942
1943-- insert, parent trigger sees post-modification parent-format tuple
1944insert into parent values ('AAA', 42), ('BBB', 42), ('CCC', 66);
1945
1946-- copy, parent trigger sees post-modification parent-format tuple
1947copy parent (a, b) from stdin;
1948AAA	42
1949BBB	42
1950CCC	234
1951\.
1952
1953drop table child1, child2, child3, parent;
1954drop function intercept_insert();
1955
1956--
1957-- Verify prohibition of row triggers with transition triggers on
1958-- partitions
1959--
1960create table parent (a text, b int) partition by list (a);
1961create table child partition of parent for values in ('AAA');
1962
1963-- adding row trigger with transition table fails
1964create trigger child_row_trig
1965  after insert on child referencing new table as new_table
1966  for each row execute procedure dump_insert();
1967
1968-- detaching it first works
1969alter table parent detach partition child;
1970
1971create trigger child_row_trig
1972  after insert on child referencing new table as new_table
1973  for each row execute procedure dump_insert();
1974
1975-- but now we're not allowed to reattach it
1976alter table parent attach partition child for values in ('AAA');
1977
1978-- drop the trigger, and now we're allowed to attach it again
1979drop trigger child_row_trig on child;
1980alter table parent attach partition child for values in ('AAA');
1981
1982drop table child, parent;
1983
1984--
1985-- Verify behavior of statement triggers on (non-partition)
1986-- inheritance hierarchy with transition tables; similar to the
1987-- partition case, except there is no rerouting on insertion and child
1988-- tables can have extra columns
1989--
1990
1991-- set up inheritance hierarchy with different TupleDescriptors
1992create table parent (a text, b int);
1993
1994-- a child matching parent
1995create table child1 () inherits (parent);
1996
1997-- a child with a different column order
1998create table child2 (b int, a text);
1999alter table child2 inherit parent;
2000
2001-- a child with an extra column
2002create table child3 (c text) inherits (parent);
2003
2004create trigger parent_insert_trig
2005  after insert on parent referencing new table as new_table
2006  for each statement execute procedure dump_insert();
2007create trigger parent_update_trig
2008  after update on parent referencing old table as old_table new table as new_table
2009  for each statement execute procedure dump_update();
2010create trigger parent_delete_trig
2011  after delete on parent referencing old table as old_table
2012  for each statement execute procedure dump_delete();
2013
2014create trigger child1_insert_trig
2015  after insert on child1 referencing new table as new_table
2016  for each statement execute procedure dump_insert();
2017create trigger child1_update_trig
2018  after update on child1 referencing old table as old_table new table as new_table
2019  for each statement execute procedure dump_update();
2020create trigger child1_delete_trig
2021  after delete on child1 referencing old table as old_table
2022  for each statement execute procedure dump_delete();
2023
2024create trigger child2_insert_trig
2025  after insert on child2 referencing new table as new_table
2026  for each statement execute procedure dump_insert();
2027create trigger child2_update_trig
2028  after update on child2 referencing old table as old_table new table as new_table
2029  for each statement execute procedure dump_update();
2030create trigger child2_delete_trig
2031  after delete on child2 referencing old table as old_table
2032  for each statement execute procedure dump_delete();
2033
2034create trigger child3_insert_trig
2035  after insert on child3 referencing new table as new_table
2036  for each statement execute procedure dump_insert();
2037create trigger child3_update_trig
2038  after update on child3 referencing old table as old_table new table as new_table
2039  for each statement execute procedure dump_update();
2040create trigger child3_delete_trig
2041  after delete on child3 referencing old table as old_table
2042  for each statement execute procedure dump_delete();
2043
2044-- insert directly into children sees respective child-format tuples
2045insert into child1 values ('AAA', 42);
2046insert into child2 values (42, 'BBB');
2047insert into child3 values ('CCC', 42, 'foo');
2048
2049-- update via parent sees parent-format tuples
2050update parent set b = b + 1;
2051
2052-- delete via parent sees parent-format tuples
2053delete from parent;
2054
2055-- reinsert values into children for next test...
2056insert into child1 values ('AAA', 42);
2057insert into child2 values (42, 'BBB');
2058insert into child3 values ('CCC', 42, 'foo');
2059
2060-- delete from children sees respective child-format tuples
2061delete from child1;
2062delete from child2;
2063delete from child3;
2064
2065-- copy into parent sees parent-format tuples (no rerouting, so these
2066-- are really inserted into the parent)
2067copy parent (a, b) from stdin;
2068AAA	42
2069BBB	42
2070CCC	42
2071\.
2072
2073-- same behavior for copy if there is an index (interesting because rows are
2074-- captured by a different code path in copy.c if there are indexes)
2075create index on parent(b);
2076copy parent (a, b) from stdin;
2077DDD	42
2078\.
2079
2080-- DML affecting parent sees tuples collected from children even if
2081-- there is no transition table trigger on the children
2082drop trigger child1_insert_trig on child1;
2083drop trigger child1_update_trig on child1;
2084drop trigger child1_delete_trig on child1;
2085drop trigger child2_insert_trig on child2;
2086drop trigger child2_update_trig on child2;
2087drop trigger child2_delete_trig on child2;
2088drop trigger child3_insert_trig on child3;
2089drop trigger child3_update_trig on child3;
2090drop trigger child3_delete_trig on child3;
2091delete from parent;
2092
2093drop table child1, child2, child3, parent;
2094
2095--
2096-- Verify prohibition of row triggers with transition triggers on
2097-- inheritance children
2098--
2099create table parent (a text, b int);
2100create table child () inherits (parent);
2101
2102-- adding row trigger with transition table fails
2103create trigger child_row_trig
2104  after insert on child referencing new table as new_table
2105  for each row execute procedure dump_insert();
2106
2107-- disinheriting it first works
2108alter table child no inherit parent;
2109
2110create trigger child_row_trig
2111  after insert on child referencing new table as new_table
2112  for each row execute procedure dump_insert();
2113
2114-- but now we're not allowed to make it inherit anymore
2115alter table child inherit parent;
2116
2117-- drop the trigger, and now we're allowed to make it inherit again
2118drop trigger child_row_trig on child;
2119alter table child inherit parent;
2120
2121drop table child, parent;
2122
2123--
2124-- Verify behavior of queries with wCTEs, where multiple transition
2125-- tuplestores can be active at the same time because there are
2126-- multiple DML statements that might fire triggers with transition
2127-- tables
2128--
2129create table table1 (a int);
2130create table table2 (a text);
2131create trigger table1_trig
2132  after insert on table1 referencing new table as new_table
2133  for each statement execute procedure dump_insert();
2134create trigger table2_trig
2135  after insert on table2 referencing new table as new_table
2136  for each statement execute procedure dump_insert();
2137
2138with wcte as (insert into table1 values (42))
2139  insert into table2 values ('hello world');
2140
2141with wcte as (insert into table1 values (43))
2142  insert into table1 values (44);
2143
2144select * from table1;
2145select * from table2;
2146
2147drop table table1;
2148drop table table2;
2149
2150--
2151-- Verify behavior of INSERT ... ON CONFLICT DO UPDATE ... with
2152-- transition tables.
2153--
2154
2155create table my_table (a int primary key, b text);
2156create trigger my_table_insert_trig
2157  after insert on my_table referencing new table as new_table
2158  for each statement execute procedure dump_insert();
2159create trigger my_table_update_trig
2160  after update on my_table referencing old table as old_table new table as new_table
2161  for each statement execute procedure dump_update();
2162
2163-- inserts only
2164insert into my_table values (1, 'AAA'), (2, 'BBB')
2165  on conflict (a) do
2166  update set b = my_table.b || ':' || excluded.b;
2167
2168-- mixture of inserts and updates
2169insert into my_table values (1, 'AAA'), (2, 'BBB'), (3, 'CCC'), (4, 'DDD')
2170  on conflict (a) do
2171  update set b = my_table.b || ':' || excluded.b;
2172
2173-- updates only
2174insert into my_table values (3, 'CCC'), (4, 'DDD')
2175  on conflict (a) do
2176  update set b = my_table.b || ':' || excluded.b;
2177
2178--
2179-- now using a partitioned table
2180--
2181
2182create table iocdu_tt_parted (a int primary key, b text) partition by list (a);
2183create table iocdu_tt_parted1 partition of iocdu_tt_parted for values in (1);
2184create table iocdu_tt_parted2 partition of iocdu_tt_parted for values in (2);
2185create table iocdu_tt_parted3 partition of iocdu_tt_parted for values in (3);
2186create table iocdu_tt_parted4 partition of iocdu_tt_parted for values in (4);
2187create trigger iocdu_tt_parted_insert_trig
2188  after insert on iocdu_tt_parted referencing new table as new_table
2189  for each statement execute procedure dump_insert();
2190create trigger iocdu_tt_parted_update_trig
2191  after update on iocdu_tt_parted referencing old table as old_table new table as new_table
2192  for each statement execute procedure dump_update();
2193
2194-- inserts only
2195insert into iocdu_tt_parted values (1, 'AAA'), (2, 'BBB')
2196  on conflict (a) do
2197  update set b = iocdu_tt_parted.b || ':' || excluded.b;
2198
2199-- mixture of inserts and updates
2200insert into iocdu_tt_parted values (1, 'AAA'), (2, 'BBB'), (3, 'CCC'), (4, 'DDD')
2201  on conflict (a) do
2202  update set b = iocdu_tt_parted.b || ':' || excluded.b;
2203
2204-- updates only
2205insert into iocdu_tt_parted values (3, 'CCC'), (4, 'DDD')
2206  on conflict (a) do
2207  update set b = iocdu_tt_parted.b || ':' || excluded.b;
2208
2209drop table iocdu_tt_parted;
2210
2211--
2212-- Verify that you can't create a trigger with transition tables for
2213-- more than one event.
2214--
2215
2216create trigger my_table_multievent_trig
2217  after insert or update on my_table referencing new table as new_table
2218  for each statement execute procedure dump_insert();
2219
2220--
2221-- Verify that you can't create a trigger with transition tables with
2222-- a column list.
2223--
2224
2225create trigger my_table_col_update_trig
2226  after update of b on my_table referencing new table as new_table
2227  for each statement execute procedure dump_insert();
2228
2229drop table my_table;
2230
2231--
2232-- Test firing of triggers with transition tables by foreign key cascades
2233--
2234
2235create table refd_table (a int primary key, b text);
2236create table trig_table (a int, b text,
2237  foreign key (a) references refd_table on update cascade on delete cascade
2238);
2239
2240create trigger trig_table_before_trig
2241  before insert or update or delete on trig_table
2242  for each statement execute procedure trigger_func('trig_table');
2243create trigger trig_table_insert_trig
2244  after insert on trig_table referencing new table as new_table
2245  for each statement execute procedure dump_insert();
2246create trigger trig_table_update_trig
2247  after update on trig_table referencing old table as old_table new table as new_table
2248  for each statement execute procedure dump_update();
2249create trigger trig_table_delete_trig
2250  after delete on trig_table referencing old table as old_table
2251  for each statement execute procedure dump_delete();
2252
2253insert into refd_table values
2254  (1, 'one'),
2255  (2, 'two'),
2256  (3, 'three');
2257insert into trig_table values
2258  (1, 'one a'),
2259  (1, 'one b'),
2260  (2, 'two a'),
2261  (2, 'two b'),
2262  (3, 'three a'),
2263  (3, 'three b');
2264
2265update refd_table set a = 11 where b = 'one';
2266
2267select * from trig_table;
2268
2269delete from refd_table where length(b) = 3;
2270
2271select * from trig_table;
2272
2273drop table refd_table, trig_table;
2274
2275--
2276-- self-referential FKs are even more fun
2277--
2278
2279create table self_ref (a int primary key,
2280                       b int references self_ref(a) on delete cascade);
2281
2282create trigger self_ref_before_trig
2283  before delete on self_ref
2284  for each statement execute procedure trigger_func('self_ref');
2285create trigger self_ref_r_trig
2286  after delete on self_ref referencing old table as old_table
2287  for each row execute procedure dump_delete();
2288create trigger self_ref_s_trig
2289  after delete on self_ref referencing old table as old_table
2290  for each statement execute procedure dump_delete();
2291
2292insert into self_ref values (1, null), (2, 1), (3, 2);
2293
2294delete from self_ref where a = 1;
2295
2296-- without AR trigger, cascaded deletes all end up in one transition table
2297drop trigger self_ref_r_trig on self_ref;
2298
2299insert into self_ref values (1, null), (2, 1), (3, 2), (4, 3);
2300
2301delete from self_ref where a = 1;
2302
2303drop table self_ref;
2304
2305-- cleanup
2306drop function dump_insert();
2307drop function dump_update();
2308drop function dump_delete();
2309
2310-- Leave around some objects for other tests
2311create table trigger_parted (a int primary key) partition by list (a);
2312create function trigger_parted_trigfunc() returns trigger language plpgsql as
2313  $$ begin end; $$;
2314create trigger aft_row after insert or update on trigger_parted
2315  for each row execute function trigger_parted_trigfunc();
2316create table trigger_parted_p1 partition of trigger_parted for values in (1)
2317  partition by list (a);
2318create table trigger_parted_p1_1 partition of trigger_parted_p1 for values in (1);
2319create table trigger_parted_p2 partition of trigger_parted for values in (2)
2320  partition by list (a);
2321create table trigger_parted_p2_2 partition of trigger_parted_p2 for values in (2);
2322alter table only trigger_parted_p2 disable trigger aft_row;
2323alter table trigger_parted_p2_2 enable always trigger aft_row;
2324
2325-- verify transition table conversion slot's lifetime
2326-- https://postgr.es/m/39a71864-b120-5a5c-8cc5-c632b6f16761@amazon.com
2327create table convslot_test_parent (col1 text primary key);
2328create table convslot_test_child (col1 text primary key,
2329	foreign key (col1) references convslot_test_parent(col1) on delete cascade on update cascade
2330);
2331
2332alter table convslot_test_child add column col2 text not null default 'tutu';
2333insert into convslot_test_parent(col1) values ('1');
2334insert into convslot_test_child(col1) values ('1');
2335insert into convslot_test_parent(col1) values ('3');
2336insert into convslot_test_child(col1) values ('3');
2337
2338create or replace function trigger_function1()
2339returns trigger
2340language plpgsql
2341AS $$
2342begin
2343raise notice 'trigger = %, old_table = %',
2344          TG_NAME,
2345          (select string_agg(old_table::text, ', ' order by col1) from old_table);
2346return null;
2347end; $$;
2348
2349create or replace function trigger_function2()
2350returns trigger
2351language plpgsql
2352AS $$
2353begin
2354raise notice 'trigger = %, new table = %',
2355          TG_NAME,
2356          (select string_agg(new_table::text, ', ' order by col1) from new_table);
2357return null;
2358end; $$;
2359
2360create trigger but_trigger after update on convslot_test_child
2361referencing new table as new_table
2362for each statement execute function trigger_function2();
2363
2364update convslot_test_parent set col1 = col1 || '1';
2365
2366create or replace function trigger_function3()
2367returns trigger
2368language plpgsql
2369AS $$
2370begin
2371raise notice 'trigger = %, old_table = %, new table = %',
2372          TG_NAME,
2373          (select string_agg(old_table::text, ', ' order by col1) from old_table),
2374          (select string_agg(new_table::text, ', ' order by col1) from new_table);
2375return null;
2376end; $$;
2377
2378create trigger but_trigger2 after update on convslot_test_child
2379referencing old table as old_table new table as new_table
2380for each statement execute function trigger_function3();
2381update convslot_test_parent set col1 = col1 || '1';
2382
2383create trigger bdt_trigger after delete on convslot_test_child
2384referencing old table as old_table
2385for each statement execute function trigger_function1();
2386delete from convslot_test_parent;
2387
2388drop table convslot_test_child, convslot_test_parent;
2389