blob: adce114509bdb659ddd8ed0e94559a0430e25140 [file] [log] [blame]
danielk1977c3f9bad2002-05-15 08:30:12 +00001# The author disclaims copyright to this source code. In place of
2# a legal notice, here is a blessing:
3#
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.
7#
8#***********************************************************************
9#
10# Regression testing of FOR EACH ROW table triggers
11#
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.
15#
16# trig-1.1.*: ON UPDATE trigger execution model.
17# trig-1.2.*: DELETE trigger execution model.
18# trig-1.3.*: INSERT trigger execution model.
19#
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).
24#
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.
28#
29# trig-3.1: UPDATE OF triggers
30# trig-3.2: WHEN clause
31#
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.
35#
36# trig-4.1: Trivial cascading trigger
37# trig-4.2: Trivial recursive trigger handling
38#
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.
42#
43# 6. ON CONFLICT clause handling
44# trig-6.1[a-f]: INSERT statements
45# trig-6.2[a-f]: UPDATE statements
46#
47# 7. Triggers on views fire correctly.
48#
49
50set testdir [file dirname $argv0]
51source $testdir/tester.tcl
52
53# 1.
54set ii 0
55foreach tbl_defn [ list \
56 {CREATE TABLE tbl (a, b);} \
57 {CREATE TABLE tbl (a INTEGER PRIMARY KEY, b);} \
58 {CREATE TABLE tbl (a, b PRIMARY KEY);} \
59 {CREATE TABLE tbl (a, b); CREATE INDEX tbl_idx ON tbl(b);} ] {
60 incr ii
61 catchsql { DROP INDEX tbl_idx; }
62 catchsql {
63 DROP TABLE rlog;
64 DROP TABLE clog;
65 DROP TABLE tbl;
66 DROP TABLE other_tbl;
67 }
68
69 execsql $tbl_defn
70
71 execsql {
72 INSERT INTO tbl VALUES(1, 2);
73 INSERT INTO tbl VALUES(3, 4);
74
75 CREATE TABLE rlog (idx, old_a, old_b, db_sum_a, db_sum_b, new_a, new_b);
76 CREATE TABLE clog (idx, old_a, old_b, db_sum_a, db_sum_b, new_a, new_b);
77
78 CREATE TRIGGER before_update_row BEFORE UPDATE ON tbl FOR EACH ROW
79 BEGIN
80 INSERT INTO rlog VALUES ( (SELECT max(idx) + 1 FROM rlog),
81 old.a, old.b,
82 (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl),
83 new.a, new.b);
84 END;
85
86 CREATE TRIGGER after_update_row AFTER UPDATE ON tbl FOR EACH ROW
87 BEGIN
88 INSERT INTO rlog VALUES ( (SELECT max(idx) + 1 FROM rlog),
89 old.a, old.b,
90 (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl),
91 new.a, new.b);
92 END;
93
94 CREATE TRIGGER conditional_update_row AFTER UPDATE ON tbl FOR EACH ROW
95 WHEN old.a = 1
96 BEGIN
97 INSERT INTO clog VALUES ( (SELECT max(idx) + 1 FROM clog),
98 old.a, old.b,
99 (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl),
100 new.a, new.b);
101 END;
102 }
103
104 do_test trig-1.1.$ii {
105 execsql {
106 UPDATE tbl SET a = a * 10, b = b * 10;
107 SELECT * FROM rlog ORDER BY idx;
108 SELECT * FROM clog ORDER BY idx;
109 }
110 } [list 1 1 2 4 6 10 20 \
111 2 1 2 13 24 10 20 \
112 3 3 4 13 24 30 40 \
113 4 3 4 40 60 30 40 \
114 1 1 2 13 24 10 20 ]
115
116 execsql {
117 DELETE FROM rlog;
118 DELETE FROM tbl;
119 INSERT INTO tbl VALUES (100, 100);
120 INSERT INTO tbl VALUES (300, 200);
121 CREATE TRIGGER delete_before_row BEFORE DELETE ON tbl FOR EACH ROW
122 BEGIN
123 INSERT INTO rlog VALUES ( (SELECT max(idx) + 1 FROM rlog),
124 old.a, old.b,
125 (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl),
126 0, 0);
127 END;
128
129 CREATE TRIGGER delete_after_row AFTER DELETE ON tbl FOR EACH ROW
130 BEGIN
131 INSERT INTO rlog VALUES ( (SELECT max(idx) + 1 FROM rlog),
132 old.a, old.b,
133 (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl),
134 0, 0);
135 END;
136 }
137 do_test trig-1.2.$ii {
138 execsql {
139 DELETE FROM tbl;
140 SELECT * FROM rlog;
141 }
142 } [list 1 100 100 400 300 0 0 \
143 2 100 100 300 200 0 0 \
144 3 300 200 300 200 0 0 \
145 4 300 200 0 0 0 0 ]
146
147 execsql {
148 DELETE FROM rlog;
149 CREATE TRIGGER insert_before_row BEFORE INSERT ON tbl FOR EACH ROW
150 BEGIN
151 INSERT INTO rlog VALUES ( (SELECT max(idx) + 1 FROM rlog),
152 0, 0,
153 (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl),
154 new.a, new.b);
155 END;
156
157 CREATE TRIGGER insert_after_row AFTER INSERT ON tbl FOR EACH ROW
158 BEGIN
159 INSERT INTO rlog VALUES ( (SELECT max(idx) + 1 FROM rlog),
160 0, 0,
161 (SELECT sum(a) FROM tbl), (SELECT sum(b) FROM tbl),
162 new.a, new.b);
163 END;
164 }
165 do_test trig-1.3.$ii {
166 execsql {
167
168 CREATE TABLE other_tbl(a, b);
169 INSERT INTO other_tbl VALUES(1, 2);
170 INSERT INTO other_tbl VALUES(3, 4);
171 -- INSERT INTO tbl SELECT * FROM other_tbl;
172 INSERT INTO tbl VALUES(5, 6);
173 DROP TABLE other_tbl;
174
175 SELECT * FROM rlog;
176 }
177 } [list 1 0 0 0 0 5 6 \
178 2 0 0 5 6 5 6 ]
179}
180catchsql {
181 DROP TABLE rlog;
182 DROP TABLE clog;
183 DROP TABLE tbl;
184 DROP TABLE other_tbl;
185}
186
187# 2.
188set ii 0
189foreach tr_program [ list \
190 {UPDATE tbl SET b = old.b;} \
191 {INSERT INTO log VALUES(new.c, 2, 3);} \
192 {DELETE FROM log WHERE a = 1;} \
193 {INSERT INTO tbl VALUES(500, new.b * 10, 700);
194 UPDATE tbl SET c = old.c;
195 DELETE FROM log;} \
196 {INSERT INTO log select * from tbl;}
197 ] \
198{
199 foreach test_varset [ list \
200 {
201 set statement {UPDATE tbl SET c = 10 WHERE a = 1;}
202 set prep {INSERT INTO tbl VALUES(1, 2, 3);}
203 set newC 10
204 set newB 2
205 set newA 1
206 set oldA 1
207 set oldB 2
208 set oldC 3
209 } \
210 {
211 set statement {DELETE FROM tbl WHERE a = 1;}
212 set prep {INSERT INTO tbl VALUES(1, 2, 3);}
213 set oldA 1
214 set oldB 2
215 set oldC 3
216 } \
217 {
218 set statement {INSERT INTO tbl VALUES(1, 2, 3);}
219 set newA 1
220 set newB 2
221 set newC 3
222 }
223 ] \
224 {
225 set statement {}
226 set prep {}
227 set newA {''}
228 set newB {''}
229 set newC {''}
230 set oldA {''}
231 set oldB {''}
232 set oldC {''}
233
234 incr ii
235
236 eval $test_varset
237
238 set statement_type [string range $statement 0 5]
239 set tr_program_fixed $tr_program
240 if {$statement_type == "DELETE"} {
241 regsub -all new\.a $tr_program_fixed {''} tr_program_fixed
242 regsub -all new\.b $tr_program_fixed {''} tr_program_fixed
243 regsub -all new\.c $tr_program_fixed {''} tr_program_fixed
244 }
245 if {$statement_type == "INSERT"} {
246 regsub -all old\.a $tr_program_fixed {''} tr_program_fixed
247 regsub -all old\.b $tr_program_fixed {''} tr_program_fixed
248 regsub -all old\.c $tr_program_fixed {''} tr_program_fixed
249 }
250
251
252 set tr_program_cooked $tr_program
253 regsub -all new\.a $tr_program_cooked $newA tr_program_cooked
254 regsub -all new\.b $tr_program_cooked $newB tr_program_cooked
255 regsub -all new\.c $tr_program_cooked $newC tr_program_cooked
256 regsub -all old\.a $tr_program_cooked $oldA tr_program_cooked
257 regsub -all old\.b $tr_program_cooked $oldB tr_program_cooked
258 regsub -all old\.c $tr_program_cooked $oldC tr_program_cooked
259
260 catchsql {
261 DROP TABLE tbl;
262 DROP TABLE log;
263 }
264 execsql {
265 CREATE TABLE tbl(a PRIMARY KEY, b, c);
266 CREATE TABLE log(a, b, c);
267 }
268
269 set query {SELECT * FROM tbl; SELECT * FROM log;}
270 set prep "$prep; INSERT INTO log VALUES(1, 2, 3); INSERT INTO log VALUES(10, 20, 30);"
271
272# Check execution of BEFORE programs:
273
274 set before_data [ execsql "$prep $tr_program_cooked $statement $query" ]
275
276 execsql "DELETE FROM tbl; DELETE FROM log; $prep";
277 execsql "CREATE TRIGGER the_trigger BEFORE [string range $statement 0 6] ON tbl BEGIN $tr_program_fixed END;"
278
279 do_test trig-2-$ii-before "execsql {$statement $query}" $before_data
280
281 execsql "DROP TRIGGER the_trigger;"
282 execsql "DELETE FROM tbl; DELETE FROM log;"
283
284# Check execution of AFTER programs
285 set after_data [ execsql "$prep $statement $tr_program_cooked $query" ]
286
287 execsql "DELETE FROM tbl; DELETE FROM log; $prep";
288
289 execsql "CREATE TRIGGER the_trigger AFTER [string range $statement 0 6] ON tbl BEGIN $tr_program_fixed END;"
290
291 do_test trig-2-$ii-after "execsql {$statement $query}" $after_data
292 execsql "DROP TRIGGER the_trigger;"
293 }
294}
295catchsql {
296 DROP TABLE tbl;
297 DROP TABLE log;
298}
299
300# 3.
301
302# trig-3.1: UPDATE OF triggers
303execsql {
304 CREATE TABLE tbl (a, b, c, d);
305 CREATE TABLE log (a);
306 INSERT INTO log VALUES (0);
307 INSERT INTO tbl VALUES (0, 0, 0, 0);
308 INSERT INTO tbl VALUES (1, 0, 0, 0);
309 CREATE TRIGGER tbl_after_update_cd BEFORE UPDATE OF c, d ON tbl
310 BEGIN
311 UPDATE log SET a = a + 1;
312 END;
313}
314do_test trig-3.1 {
315 execsql {
316 UPDATE tbl SET b = 1, c = 10; -- 2
317 UPDATE tbl SET b = 10; -- 0
318 UPDATE tbl SET d = 4 WHERE a = 0; --1
319 UPDATE tbl SET a = 4, b = 10; --0
320 SELECT * FROM log;
321 }
322} {3}
323execsql {
324 DROP TABLE tbl;
325 DROP TABLE log;
326}
327
328# trig-3.2: WHEN clause
329set when_triggers [ list \
330 {t1 BEFORE INSERT ON tbl WHEN new.a > 20} \
331 {t2 BEFORE INSERT ON tbl WHEN (SELECT count(*) FROM tbl) = 0} ]
332
333execsql {
334 CREATE TABLE tbl (a, b, c, d);
335 CREATE TABLE log (a);
336 INSERT INTO log VALUES (0);
337}
338
339foreach trig $when_triggers {
340 execsql "CREATE TRIGGER $trig BEGIN UPDATE log set a = a + 1; END;"
341}
342
343do_test trig-3.2 {
344 execsql {
345
346 INSERT INTO tbl VALUES(0, 0, 0, 0); -- 1
347 SELECT * FROM log;
348 UPDATE log SET a = 0;
349
350 INSERT INTO tbl VALUES(0, 0, 0, 0); -- 0
351 SELECT * FROM log;
352 UPDATE log SET a = 0;
353
354 INSERT INTO tbl VALUES(200, 0, 0, 0); -- 1
355 SELECT * FROM log;
356 UPDATE log SET a = 0;
357 }
358} {1 0 1}
359execsql {
360 DROP TABLE tbl;
361 DROP TABLE log;
362}
363
364# Simple cascaded trigger
365execsql {
366 CREATE TABLE tblA(a, b);
367 CREATE TABLE tblB(a, b);
368 CREATE TABLE tblC(a, b);
369
370 CREATE TRIGGER tr1 BEFORE INSERT ON tblA BEGIN
371 INSERT INTO tblB values(new.a, new.b);
372 END;
373
374 CREATE TRIGGER tr2 BEFORE INSERT ON tblB BEGIN
375 INSERT INTO tblC values(new.a, new.b);
376 END;
377}
378do_test trig-4.1 {
379 execsql {
380 INSERT INTO tblA values(1, 2);
381 SELECT * FROM tblA;
382 SELECT * FROM tblB;
383 SELECT * FROM tblC;
384 }
385} {1 2 1 2 1 2}
386execsql {
387 DROP TABLE tblA;
388 DROP TABLE tblB;
389 DROP TABLE tblC;
390}
391
392# Simple recursive trigger
393execsql {
394 CREATE TABLE tbl(a, b, c);
395 CREATE TRIGGER tbl_trig BEFORE INSERT ON tbl
396 BEGIN
397 INSERT INTO tbl VALUES (new.a, new.b, new.c);
398 END;
399}
400do_test trig-4.2 {
401 execsql {
402 INSERT INTO tbl VALUES (1, 2, 3);
403 select * from tbl;
404 }
405} {1 2 3 1 2 3}
406execsql {
407 DROP TABLE tbl;
408}
409
410# 5.
411execsql {
412 CREATE TABLE tbl(a, b, c);
413 CREATE TRIGGER tbl_trig BEFORE INSERT ON tbl
414 BEGIN
415 INSERT INTO tbl VALUES (1, 2, 3);
416 INSERT INTO tbl VALUES (2, 2, 3);
417 UPDATE tbl set b = 10 WHERE a = 1;
418 DELETE FROM tbl WHERE a = 1;
419 DELETE FROM tbl;
420 END;
421}
422do_test trig-5 {
423 execsql {
424 INSERT INTO tbl VALUES(100, 200, 300);
425 }
426 db changes
427} {1}
428execsql {
429 DROP TABLE tbl;
430}
431
432
433# Handling of ON CONFLICT by INSERT statements inside triggers
434execsql {
435 CREATE TABLE tbl (a primary key, b, c);
436 CREATE TRIGGER ai_tbl AFTER INSERT ON tbl BEGIN
437 INSERT OR IGNORE INTO tbl values (new.a, 0, 0);
438 END;
439}
440do_test trig-6.1a {
441 execsql {
442 BEGIN;
443 INSERT INTO tbl values (1, 2, 3);
444 SELECT * from tbl;
445 }
446} {1 2 3}
447do_test trig-6.1b {
448 catchsql {
449 INSERT OR ABORT INTO tbl values (2, 2, 3);
450 }
451} {1 {constraint failed}}
452do_test trig-6.1c {
453 execsql {
454 SELECT * from tbl;
455 }
456} {1 2 3}
457do_test trig-6.1d {
458 catchsql {
459 INSERT OR FAIL INTO tbl values (2, 2, 3);
460 }
461} {1 {constraint failed}}
462do_test trig-6.1e {
463 execsql {
464 SELECT * from tbl;
465 }
466} {1 2 3 2 2 3}
467do_test trig-6.1f {
468 execsql {
469 INSERT OR REPLACE INTO tbl values (2, 2, 3);
470 SELECT * from tbl;
471 }
472} {1 2 3 2 0 0}
473do_test trig-6.1g {
474 catchsql {
475 INSERT OR ROLLBACK INTO tbl values (3, 2, 3);
476 }
477} {1 {constraint failed}}
478do_test trig-6.1h {
479 execsql {
480 SELECT * from tbl;
481 }
482} {}
483
484
485# Handling of ON CONFLICT by UPDATE statements inside triggers
486execsql {
487 INSERT INTO tbl values (4, 2, 3);
488 INSERT INTO tbl values (6, 3, 4);
489 CREATE TRIGGER au_tbl AFTER UPDATE ON tbl BEGIN
490 UPDATE OR IGNORE tbl SET a = new.a, c = 10;
491 END;
492}
493do_test trig-6.2a {
494 execsql {
495 BEGIN;
496 UPDATE tbl SET a = 1 WHERE a = 4;
497 SELECT * from tbl;
498 }
499} {1 2 10 6 3 4}
500do_test trig-6.2b {
501 catchsql {
502 UPDATE OR ABORT tbl SET a = 4 WHERE a = 1;
503 }
504} {1 {constraint failed}}
505do_test trig-6.2c {
506 execsql {
507 SELECT * from tbl;
508 }
509} {1 2 10 6 3 4}
510do_test trig-6.2d {
511 catchsql {
512 UPDATE OR FAIL tbl SET a = 4 WHERE a = 1;
513 }
514} {1 {constraint failed}}
515do_test trig-6.2e {
516 execsql {
517 SELECT * from tbl;
518 }
519} {4 2 10 6 3 4}
520do_test trig-6.2f {
521 execsql {
522 UPDATE OR REPLACE tbl SET a = 1 WHERE a = 4;
523 SELECT * from tbl;
524 }
525} {1 3 10}
526execsql {
527 INSERT INTO tbl VALUES (2, 3, 4);
528}
529do_test trig-6.2g {
530 catchsql {
531 UPDATE OR ROLLBACK tbl SET a = 4 WHERE a = 1;
532 }
533} {1 {constraint failed}}
534do_test trig-6.2h {
535 execsql {
536 SELECT * from tbl;
537 }
538} {4 2 3 6 3 4}
539execsql {
540 DROP TABLE tbl;
541}
542
543# 7. Triggers on views
drh1873cd52002-05-23 00:30:31 +0000544do_test trig-7.1 {
545 execsql {
danielk1977c3f9bad2002-05-15 08:30:12 +0000546 CREATE TABLE ab(a, b);
547 CREATE TABLE cd(c, d);
548 INSERT INTO ab VALUES (1, 2);
549 INSERT INTO ab VALUES (0, 0);
550 INSERT INTO cd VALUES (3, 4);
551
552 CREATE TABLE tlog(ii INTEGER PRIMARY KEY,
553 olda, oldb, oldc, oldd, newa, newb, newc, newd);
554
555 CREATE VIEW abcd AS SELECT a, b, c, d FROM ab, cd;
556
557 CREATE TRIGGER before_update BEFORE UPDATE ON abcd BEGIN
558 INSERT INTO tlog VALUES(NULL,
559 old.a, old.b, old.c, old.d, new.a, new.b, new.c, new.d);
560 END;
561 CREATE TRIGGER after_update AFTER UPDATE ON abcd BEGIN
562 INSERT INTO tlog VALUES(NULL,
563 old.a, old.b, old.c, old.d, new.a, new.b, new.c, new.d);
564 END;
565
566 CREATE TRIGGER before_delete BEFORE DELETE ON abcd BEGIN
567 INSERT INTO tlog VALUES(NULL,
568 old.a, old.b, old.c, old.d, 0, 0, 0, 0);
569 END;
570 CREATE TRIGGER after_delete AFTER DELETE ON abcd BEGIN
571 INSERT INTO tlog VALUES(NULL,
572 old.a, old.b, old.c, old.d, 0, 0, 0, 0);
573 END;
574
575 CREATE TRIGGER before_insert BEFORE INSERT ON abcd BEGIN
576 INSERT INTO tlog VALUES(NULL,
577 0, 0, 0, 0, new.a, new.b, new.c, new.d);
578 END;
579 CREATE TRIGGER after_insert AFTER INSERT ON abcd BEGIN
580 INSERT INTO tlog VALUES(NULL,
581 0, 0, 0, 0, new.a, new.b, new.c, new.d);
582 END;
drh1873cd52002-05-23 00:30:31 +0000583 }
584} {}
danielk1977c3f9bad2002-05-15 08:30:12 +0000585
drh1873cd52002-05-23 00:30:31 +0000586do_test trig-7.2 {
danielk1977c3f9bad2002-05-15 08:30:12 +0000587 execsql {
588 UPDATE abcd SET a = 100, b = 5*5 WHERE a = 1;
589 DELETE FROM abcd WHERE a = 1;
590 INSERT INTO abcd VALUES(10, 20, 30, 40);
591 SELECT * FROM tlog;
592 }
593} [ list 1 1 2 3 4 100 25 3 4 \
594 2 1 2 3 4 100 25 3 4 \
595 3 1 2 3 4 0 0 0 0 4 1 2 3 4 0 0 0 0 \
596 5 0 0 0 0 10 20 30 40 6 0 0 0 0 10 20 30 40 ]
597
598finish_test