1 # The author disclaims copyright to this source code. In place of
2 # a legal notice, here is a blessing:
4 # May you do good and not evil.
5 # May you find forgiveness for yourself and forgive others.
6 # May you share freely, never taking more than you give.
8 #***********************************************************************
10 # Regression testing of FOR EACH ROW table triggers
12 # 1. Trigger execution order tests.
13 # These tests ensure that BEFORE and AFTER triggers are fired at the correct
14 # times relative to each other and the triggering statement.
16 # trigger2-1.1.*: ON UPDATE trigger execution model.
17 # trigger2-1.2.*: DELETE trigger execution model.
18 # trigger2-1.3.*: INSERT trigger execution model.
20 # 2. Trigger program execution tests.
21 # These tests ensure that trigger programs execute correctly (ie. that a
22 # trigger program can correctly execute INSERT, UPDATE, DELETE * SELECT
23 # statements, and combinations thereof).
25 # 3. Selective trigger execution
26 # This tests that conditional triggers (ie. UPDATE OF triggers and triggers
27 # with WHEN clauses) are fired only fired when they are supposed to be.
29 # trigger2-3.1: UPDATE OF triggers
30 # trigger2-3.2: WHEN clause
32 # 4. Cascaded trigger execution
33 # Tests that trigger-programs may cause other triggers to fire. Also that a
34 # trigger-program is never executed recursively.
36 # trigger2-4.1: Trivial cascading trigger
37 # trigger2-4.2: Trivial recursive trigger handling
39 # 5. Count changes behaviour.
40 # Verify that rows altered by triggers are not included in the return value
41 # of the "count changes" interface.
43 # 6. ON CONFLICT clause handling
44 # trigger2-6.1[a-f]: INSERT statements
45 # trigger2-6.2[a-f]: UPDATE statements
47 # 7. & 8. Triggers on views fire correctly.
50 set testdir [file dirname $argv0]
51 source $testdir/tester.tcl
52 ifcapable {!trigger} {
57 # The tests in this file were written before SQLite supported recursive
58 # trigger invocation, and some tests depend on that to pass. So disable
59 # recursive triggers for this file.
60 catchsql { pragma recursive_triggers = off }
65 set tbl_definitions [list \
66 {CREATE TABLE tbl (a, b);} \
67 {CREATE TABLE tbl (a INTEGER PRIMARY KEY, b);} \
68 {CREATE TABLE tbl (a, b PRIMARY KEY);} \
69 {CREATE TABLE tbl (a, b); CREATE INDEX tbl_idx ON tbl(b);} \
72 lappend tbl_definitions \
73 {CREATE TEMP TABLE tbl (a, b); CREATE INDEX tbl_idx ON tbl(b);}
74 lappend tbl_definitions {CREATE TEMP TABLE tbl (a, b);}
75 lappend tbl_definitions \
76 {CREATE TEMPORARY TABLE tbl (a INTEGER PRIMARY KEY, b);}
78 foreach tbl_defn $tbl_definitions {
80 catchsql { DROP INDEX tbl_idx; }
91 INSERT INTO tbl VALUES(1, 2);
92 INSERT INTO tbl VALUES(3, 4);
94 CREATE TABLE rlog (idx, old_a, old_b, db_sum_a, db_sum_b, new_a, new_b);
95 CREATE TABLE clog (idx, old_a, old_b, db_sum_a, db_sum_b, new_a, new_b);
97 CREATE TRIGGER before_update_row BEFORE UPDATE ON tbl FOR EACH ROW
99 INSERT INTO rlog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM rlog),
101 (SELECT coalesce(sum(a),0) FROM tbl),
102 (SELECT coalesce(sum(b),0) FROM tbl),
106 CREATE TRIGGER after_update_row AFTER UPDATE ON tbl FOR EACH ROW
108 INSERT INTO rlog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM rlog),
110 (SELECT coalesce(sum(a),0) FROM tbl),
111 (SELECT coalesce(sum(b),0) FROM tbl),
115 CREATE TRIGGER conditional_update_row AFTER UPDATE ON tbl FOR EACH ROW
118 INSERT INTO clog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM clog),
120 (SELECT coalesce(sum(a),0) FROM tbl),
121 (SELECT coalesce(sum(b),0) FROM tbl),
126 do_test trigger2-1.$ii.1 {
129 UPDATE tbl SET a = a * 10, b = b * 10;
130 SELECT * FROM rlog ORDER BY idx;
131 SELECT * FROM clog ORDER BY idx;
133 lappend r [expr {int($v)}]
136 } [list 1 1 2 4 6 10 20 \
145 INSERT INTO tbl VALUES (100, 100);
146 INSERT INTO tbl VALUES (300, 200);
147 CREATE TRIGGER delete_before_row BEFORE DELETE ON tbl FOR EACH ROW
149 INSERT INTO rlog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM rlog),
151 (SELECT coalesce(sum(a),0) FROM tbl),
152 (SELECT coalesce(sum(b),0) FROM tbl),
156 CREATE TRIGGER delete_after_row AFTER DELETE ON tbl FOR EACH ROW
158 INSERT INTO rlog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM rlog),
160 (SELECT coalesce(sum(a),0) FROM tbl),
161 (SELECT coalesce(sum(b),0) FROM tbl),
165 do_test trigger2-1.$ii.2 {
171 lappend r [expr {int($v)}]
174 } [list 1 100 100 400 300 0 0 \
175 2 100 100 300 200 0 0 \
176 3 300 200 300 200 0 0 \
181 CREATE TRIGGER insert_before_row BEFORE INSERT ON tbl FOR EACH ROW
183 INSERT INTO rlog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM rlog),
185 (SELECT coalesce(sum(a),0) FROM tbl),
186 (SELECT coalesce(sum(b),0) FROM tbl),
190 CREATE TRIGGER insert_after_row AFTER INSERT ON tbl FOR EACH ROW
192 INSERT INTO rlog VALUES ( (SELECT coalesce(max(idx),0) + 1 FROM rlog),
194 (SELECT coalesce(sum(a),0) FROM tbl),
195 (SELECT coalesce(sum(b),0) FROM tbl),
199 do_test trigger2-1.$ii.3 {
202 CREATE TABLE other_tbl(a, b);
203 INSERT INTO other_tbl VALUES(1, 2);
204 INSERT INTO other_tbl VALUES(3, 4);
205 -- INSERT INTO tbl SELECT * FROM other_tbl;
206 INSERT INTO tbl VALUES(5, 6);
207 DROP TABLE other_tbl;
211 } [list 1 0 0 0 0 5 6 \
214 integrity_check trigger2-1.$ii.4
220 DROP TABLE other_tbl;
227 {UPDATE tbl SET b = old.b;}
228 {INSERT INTO log VALUES(new.c, 2, 3);}
229 {DELETE FROM log WHERE a = 1;}
230 {INSERT INTO tbl VALUES(500, new.b * 10, 700);
231 UPDATE tbl SET c = old.c;
233 {INSERT INTO log select * from tbl;}
235 foreach test_varset [ list \
237 set statement {UPDATE tbl SET c = 10 WHERE a = 1;}
238 set prep {INSERT INTO tbl VALUES(1, 2, 3);}
247 set statement {DELETE FROM tbl WHERE a = 1;}
248 set prep {INSERT INTO tbl VALUES(1, 2, 3);}
254 set statement {INSERT INTO tbl VALUES(1, 2, 3);}
274 set statement_type [string range $statement 0 5]
275 set tr_program_fixed $tr_program
276 if {$statement_type == "DELETE"} {
277 regsub -all new\.a $tr_program_fixed {''} tr_program_fixed
278 regsub -all new\.b $tr_program_fixed {''} tr_program_fixed
279 regsub -all new\.c $tr_program_fixed {''} tr_program_fixed
281 if {$statement_type == "INSERT"} {
282 regsub -all old\.a $tr_program_fixed {''} tr_program_fixed
283 regsub -all old\.b $tr_program_fixed {''} tr_program_fixed
284 regsub -all old\.c $tr_program_fixed {''} tr_program_fixed
288 set tr_program_cooked $tr_program
289 regsub -all new\.a $tr_program_cooked $newA tr_program_cooked
290 regsub -all new\.b $tr_program_cooked $newB tr_program_cooked
291 regsub -all new\.c $tr_program_cooked $newC tr_program_cooked
292 regsub -all old\.a $tr_program_cooked $oldA tr_program_cooked
293 regsub -all old\.b $tr_program_cooked $oldB tr_program_cooked
294 regsub -all old\.c $tr_program_cooked $oldC tr_program_cooked
302 CREATE TABLE tbl(a PRIMARY KEY, b, c);
303 CREATE TABLE log(a, b, c);
306 set query {SELECT * FROM tbl; SELECT * FROM log;}
307 set prep "$prep; INSERT INTO log VALUES(1, 2, 3);\
308 INSERT INTO log VALUES(10, 20, 30);"
310 # Check execution of BEFORE programs:
312 set before_data [ execsql "$prep $tr_program_cooked $statement $query" ]
314 execsql "DELETE FROM tbl; DELETE FROM log; $prep";
315 execsql "CREATE TRIGGER the_trigger BEFORE [string range $statement 0 6]\
316 ON tbl BEGIN $tr_program_fixed END;"
318 do_test trigger2-2.$ii-before "execsql {$statement $query}" $before_data
320 execsql "DROP TRIGGER the_trigger;"
321 execsql "DELETE FROM tbl; DELETE FROM log;"
323 # Check execution of AFTER programs
324 set after_data [ execsql "$prep $statement $tr_program_cooked $query" ]
326 execsql "DELETE FROM tbl; DELETE FROM log; $prep";
327 execsql "CREATE TRIGGER the_trigger AFTER [string range $statement 0 6]\
328 ON tbl BEGIN $tr_program_fixed END;"
330 do_test trigger2-2.$ii-after "execsql {$statement $query}" $after_data
331 execsql "DROP TRIGGER the_trigger;"
333 integrity_check trigger2-2.$ii-integrity
343 # trigger2-3.1: UPDATE OF triggers
345 CREATE TABLE tbl (a, b, c, d);
346 CREATE TABLE log (a);
347 INSERT INTO log VALUES (0);
348 INSERT INTO tbl VALUES (0, 0, 0, 0);
349 INSERT INTO tbl VALUES (1, 0, 0, 0);
350 CREATE TRIGGER tbl_after_update_cd BEFORE UPDATE OF c, d ON tbl
352 UPDATE log SET a = a + 1;
355 do_test trigger2-3.1 {
357 UPDATE tbl SET b = 1, c = 10; -- 2
358 UPDATE tbl SET b = 10; -- 0
359 UPDATE tbl SET d = 4 WHERE a = 0; --1
360 UPDATE tbl SET a = 4, b = 10; --0
369 # trigger2-3.2: WHEN clause
370 set when_triggers [list {t1 BEFORE INSERT ON tbl WHEN new.a > 20}]
372 lappend when_triggers \
373 {t2 BEFORE INSERT ON tbl WHEN (SELECT count(*) FROM tbl) = 0}
377 CREATE TABLE tbl (a, b, c, d);
378 CREATE TABLE log (a);
379 INSERT INTO log VALUES (0);
382 foreach trig $when_triggers {
383 execsql "CREATE TRIGGER $trig BEGIN UPDATE log set a = a + 1; END;"
391 do_test trigger2-3.2 {
394 INSERT INTO tbl VALUES(0, 0, 0, 0); -- 1 (ifcapable subquery)
396 UPDATE log SET a = 0;
398 INSERT INTO tbl VALUES(0, 0, 0, 0); -- 0
400 UPDATE log SET a = 0;
402 INSERT INTO tbl VALUES(200, 0, 0, 0); -- 1
404 UPDATE log SET a = 0;
411 integrity_check trigger2-3.3
413 # Simple cascaded trigger
415 CREATE TABLE tblA(a, b);
416 CREATE TABLE tblB(a, b);
417 CREATE TABLE tblC(a, b);
419 CREATE TRIGGER tr1 BEFORE INSERT ON tblA BEGIN
420 INSERT INTO tblB values(new.a, new.b);
423 CREATE TRIGGER tr2 BEFORE INSERT ON tblB BEGIN
424 INSERT INTO tblC values(new.a, new.b);
427 do_test trigger2-4.1 {
429 INSERT INTO tblA values(1, 2);
441 # Simple recursive trigger
443 CREATE TABLE tbl(a, b, c);
444 CREATE TRIGGER tbl_trig BEFORE INSERT ON tbl
446 INSERT INTO tbl VALUES (new.a, new.b, new.c);
449 do_test trigger2-4.2 {
451 INSERT INTO tbl VALUES (1, 2, 3);
461 CREATE TABLE tbl(a, b, c);
462 CREATE TRIGGER tbl_trig BEFORE INSERT ON tbl
464 INSERT INTO tbl VALUES (1, 2, 3);
465 INSERT INTO tbl VALUES (2, 2, 3);
466 UPDATE tbl set b = 10 WHERE a = 1;
467 DELETE FROM tbl WHERE a = 1;
473 INSERT INTO tbl VALUES(100, 200, 300);
482 # Handling of ON CONFLICT by INSERT statements inside triggers
484 CREATE TABLE tbl (a primary key, b, c);
485 CREATE TRIGGER ai_tbl AFTER INSERT ON tbl BEGIN
486 INSERT OR IGNORE INTO tbl values (new.a, 0, 0);
489 do_test trigger2-6.1a {
492 INSERT INTO tbl values (1, 2, 3);
496 do_test trigger2-6.1b {
498 INSERT OR ABORT INTO tbl values (2, 2, 3);
500 } {1 {UNIQUE constraint failed: tbl.a}}
501 do_test trigger2-6.1c {
506 do_test trigger2-6.1d {
508 INSERT OR FAIL INTO tbl values (2, 2, 3);
510 } {1 {UNIQUE constraint failed: tbl.a}}
511 do_test trigger2-6.1e {
516 do_test trigger2-6.1f {
518 INSERT OR REPLACE INTO tbl values (2, 2, 3);
522 do_test trigger2-6.1g {
524 INSERT OR ROLLBACK INTO tbl values (3, 2, 3);
526 } {1 {UNIQUE constraint failed: tbl.a}}
527 do_test trigger2-6.1h {
532 execsql {DELETE FROM tbl}
535 # Handling of ON CONFLICT by UPDATE statements inside triggers
537 INSERT INTO tbl values (4, 2, 3);
538 INSERT INTO tbl values (6, 3, 4);
539 CREATE TRIGGER au_tbl AFTER UPDATE ON tbl BEGIN
540 UPDATE OR IGNORE tbl SET a = new.a, c = 10;
543 do_test trigger2-6.2a {
546 UPDATE tbl SET a = 1 WHERE a = 4;
550 do_test trigger2-6.2b {
552 UPDATE OR ABORT tbl SET a = 4 WHERE a = 1;
554 } {1 {UNIQUE constraint failed: tbl.a}}
555 do_test trigger2-6.2c {
560 do_test trigger2-6.2d {
562 UPDATE OR FAIL tbl SET a = 4 WHERE a = 1;
564 } {1 {UNIQUE constraint failed: tbl.a}}
565 do_test trigger2-6.2e {
570 do_test trigger2-6.2f.1 {
572 UPDATE OR REPLACE tbl SET a = 1 WHERE a = 4;
576 do_test trigger2-6.2f.2 {
578 INSERT INTO tbl VALUES (2, 3, 4);
582 do_test trigger2-6.2g {
584 UPDATE OR ROLLBACK tbl SET a = 4 WHERE a = 1;
586 } {1 {UNIQUE constraint failed: tbl.a}}
587 do_test trigger2-6.2h {
595 } ; # ifcapable conflict
597 # 7. Triggers on views
600 do_test trigger2-7.1 {
602 CREATE TABLE ab(a, b);
603 CREATE TABLE cd(c, d);
604 INSERT INTO ab VALUES (1, 2);
605 INSERT INTO ab VALUES (0, 0);
606 INSERT INTO cd VALUES (3, 4);
608 CREATE TABLE tlog(ii INTEGER PRIMARY KEY,
609 olda, oldb, oldc, oldd, newa, newb, newc, newd);
611 CREATE VIEW abcd AS SELECT a, b, c, d FROM ab, cd;
613 CREATE TRIGGER before_update INSTEAD OF UPDATE ON abcd BEGIN
614 INSERT INTO tlog VALUES(NULL,
615 old.a, old.b, old.c, old.d, new.a, new.b, new.c, new.d);
617 CREATE TRIGGER after_update INSTEAD OF UPDATE ON abcd BEGIN
618 INSERT INTO tlog VALUES(NULL,
619 old.a, old.b, old.c, old.d, new.a, new.b, new.c, new.d);
622 CREATE TRIGGER before_delete INSTEAD OF DELETE ON abcd BEGIN
623 INSERT INTO tlog VALUES(NULL,
624 old.a, old.b, old.c, old.d, 0, 0, 0, 0);
626 CREATE TRIGGER after_delete INSTEAD OF DELETE ON abcd BEGIN
627 INSERT INTO tlog VALUES(NULL,
628 old.a, old.b, old.c, old.d, 0, 0, 0, 0);
631 CREATE TRIGGER before_insert INSTEAD OF INSERT ON abcd BEGIN
632 INSERT INTO tlog VALUES(NULL,
633 0, 0, 0, 0, new.a, new.b, new.c, new.d);
635 CREATE TRIGGER after_insert INSTEAD OF INSERT ON abcd BEGIN
636 INSERT INTO tlog VALUES(NULL,
637 0, 0, 0, 0, new.a, new.b, new.c, new.d);
642 do_test trigger2-7.2 {
644 UPDATE abcd SET a = 100, b = 5*5 WHERE a = 1;
645 DELETE FROM abcd WHERE a = 1;
646 INSERT INTO abcd VALUES(10, 20, 30, 40);
649 } [ list 1 1 2 3 4 100 25 3 4 \
650 2 1 2 3 4 100 25 3 4 \
653 5 0 0 0 0 10 20 30 40 \
654 6 0 0 0 0 10 20 30 40 ]
656 do_test trigger2-7.3 {
659 INSERT INTO abcd VALUES(10, 20, 30, 40);
660 UPDATE abcd SET a = 100, b = 5*5 WHERE a = 1;
661 DELETE FROM abcd WHERE a = 1;
665 1 0 0 0 0 10 20 30 40 \
666 2 0 0 0 0 10 20 30 40 \
667 3 1 2 3 4 100 25 3 4 \
668 4 1 2 3 4 100 25 3 4 \
672 do_test trigger2-7.4 {
675 DELETE FROM abcd WHERE a = 1;
676 INSERT INTO abcd VALUES(10, 20, 30, 40);
677 UPDATE abcd SET a = 100, b = 5*5 WHERE a = 1;
683 3 0 0 0 0 10 20 30 40 \
684 4 0 0 0 0 10 20 30 40 \
685 5 1 2 3 4 100 25 3 4 \
686 6 1 2 3 4 100 25 3 4 \
689 do_test trigger2-8.1 {
691 CREATE TABLE t1(a,b,c);
692 INSERT INTO t1 VALUES(1,2,3);
694 SELECT a+b AS x, b+c AS y, a+c AS z FROM t1;
698 do_test trigger2-8.2 {
700 CREATE TABLE v1log(a,b,c,d,e,f);
701 CREATE TRIGGER r1 INSTEAD OF DELETE ON v1 BEGIN
702 INSERT INTO v1log VALUES(OLD.x,NULL,OLD.y,NULL,OLD.z,NULL);
704 DELETE FROM v1 WHERE x=1;
708 do_test trigger2-8.3 {
710 DELETE FROM v1 WHERE x=3;
714 do_test trigger2-8.4 {
716 INSERT INTO t1 VALUES(4,5,6);
718 DELETE FROM v1 WHERE y=11;
722 do_test trigger2-8.5 {
724 CREATE TRIGGER r2 INSTEAD OF INSERT ON v1 BEGIN
725 INSERT INTO v1log VALUES(NULL,NEW.x,NULL,NEW.y,NULL,NEW.z);
728 INSERT INTO v1 VALUES(1,2,3);
732 do_test trigger2-8.6 {
734 CREATE TRIGGER r3 INSTEAD OF UPDATE ON v1 BEGIN
735 INSERT INTO v1log VALUES(OLD.x,NEW.x,OLD.y,NEW.y,OLD.z,NEW.z);
738 UPDATE v1 SET x=x+100, y=y+200, z=z+300;
741 } {3 103 5 205 4 304 9 109 11 211 10 310}
743 # At one point the following was causing a segfault.
744 do_test trigger2-9.1 {
746 CREATE TABLE t3(a TEXT, b TEXT);
747 CREATE VIEW v3 AS SELECT t3.a FROM t3;
748 CREATE TRIGGER trig1 INSTEAD OF DELETE ON v3 BEGIN
751 DELETE FROM v3 WHERE a = 1;
757 integrity_check trigger2-9.9