1# 2# The author disclaims copyright to this source code. In place of 3# a legal notice, here is a blessing: 4# 5# May you do good and not evil. 6# May you find forgiveness for yourself and forgive others. 7# May you share freely, never taking more than you give. 8# 9#*********************************************************************** 10# 11# This file tests creating and dropping triggers, and interaction thereof 12# with the database COMMIT/ROLLBACK logic. 13# 14# 1. CREATE and DROP TRIGGER tests 15# trig-1.1: Error if table does not exist 16# trig-1.2: Error if trigger already exists 17# trig-1.3: Created triggers are deleted if the transaction is rolled back 18# trig-1.4: DROP TRIGGER removes trigger 19# trig-1.5: Dropped triggers are restored if the transaction is rolled back 20# trig-1.6: Error if dropped trigger doesn't exist 21# trig-1.7: Dropping the table automatically drops all triggers 22# trig-1.8: A trigger created on a TEMP table is not inserted into sqlite_master 23# trig-1.9: Ensure that we cannot create a trigger on sqlite_master 24# trig-1.10: 25# trig-1.11: 26# trig-1.12: Ensure that INSTEAD OF triggers cannot be created on tables 27# trig-1.13: Ensure that AFTER triggers cannot be created on views 28# trig-1.14: Ensure that BEFORE triggers cannot be created on views 29# 30 31set testdir [file dirname $argv0] 32source $testdir/tester.tcl 33 34do_test trigger1-1.1.2 { 35 catchsql { 36 CREATE TRIGGER trig UPDATE ON no_such_table BEGIN 37 SELECT * from sqlite_master; 38 END; 39 } 40} {1 {no such table: no_such_table}} 41do_test trigger1-1.1.2 { 42 catchsql { 43 CREATE TEMP TRIGGER trig UPDATE ON no_such_table BEGIN 44 SELECT * from sqlite_master; 45 END; 46 } 47} {1 {no such table: no_such_table}} 48 49execsql { 50 CREATE TABLE t1(a); 51} 52execsql { 53 CREATE TRIGGER tr1 INSERT ON t1 BEGIN 54 INSERT INTO t1 values(1); 55 END; 56} 57do_test trigger1-1.2 { 58 catchsql { 59 CREATE TRIGGER tr1 DELETE ON t1 BEGIN 60 SELECT * FROM sqlite_master; 61 END 62 } 63} {1 {trigger tr1 already exists}} 64 65do_test trigger1-1.3 { 66 catchsql { 67 BEGIN; 68 CREATE TRIGGER tr2 INSERT ON t1 BEGIN 69 SELECT * from sqlite_master; END; 70 ROLLBACK; 71 CREATE TRIGGER tr2 INSERT ON t1 BEGIN 72 SELECT * from sqlite_master; END; 73 } 74} {0 {}} 75 76do_test trigger1-1.4 { 77 catchsql { 78 DROP TRIGGER tr1; 79 CREATE TRIGGER tr1 DELETE ON t1 BEGIN 80 SELECT * FROM sqlite_master; 81 END 82 } 83} {0 {}} 84 85do_test trigger1-1.5 { 86 execsql { 87 BEGIN; 88 DROP TRIGGER tr2; 89 ROLLBACK; 90 DROP TRIGGER tr2; 91 } 92} {} 93 94do_test trigger1-1.6 { 95 catchsql { 96 DROP TRIGGER biggles; 97 } 98} {1 {no such trigger: biggles}} 99 100do_test trigger1-1.7 { 101 catchsql { 102 DROP TABLE t1; 103 DROP TRIGGER tr1; 104 } 105} {1 {no such trigger: tr1}} 106 107execsql { 108 CREATE TEMP TABLE temp_table(a); 109} 110do_test trigger1-1.8 { 111 execsql { 112 CREATE TRIGGER temp_trig UPDATE ON temp_table BEGIN 113 SELECT * from sqlite_master; 114 END; 115 SELECT count(*) FROM sqlite_master WHERE name = 'temp_trig'; 116 } 117} {0} 118 119do_test trigger1-1.9 { 120 catchsql { 121 CREATE TRIGGER tr1 AFTER UPDATE ON sqlite_master BEGIN 122 SELECT * FROM sqlite_master; 123 END; 124 } 125} {1 {cannot create trigger on system table}} 126 127# Check to make sure that a DELETE statement within the body of 128# a trigger does not mess up the DELETE that caused the trigger to 129# run in the first place. 130# 131do_test trigger1-1.10 { 132 execsql { 133 create table t1(a,b); 134 insert into t1 values(1,'a'); 135 insert into t1 values(2,'b'); 136 insert into t1 values(3,'c'); 137 insert into t1 values(4,'d'); 138 create trigger r1 after delete on t1 for each row begin 139 delete from t1 WHERE a=old.a+2; 140 end; 141 delete from t1 where a in (1,3); 142 select * from t1; 143 drop table t1; 144 } 145} {2 b 4 d} 146do_test trigger1-1.11 { 147 execsql { 148 create table t1(a,b); 149 insert into t1 values(1,'a'); 150 insert into t1 values(2,'b'); 151 insert into t1 values(3,'c'); 152 insert into t1 values(4,'d'); 153 create trigger r1 after update on t1 for each row begin 154 delete from t1 WHERE a=old.a+2; 155 end; 156 update t1 set b='x-' || b where a in (1,3); 157 select * from t1; 158 drop table t1; 159 } 160} {1 x-a 2 b 4 d} 161 162# Ensure that we cannot create INSTEAD OF triggers on tables 163do_test trigger1-1.12 { 164 catchsql { 165 create table t1(a,b); 166 create trigger t1t instead of update on t1 for each row begin 167 delete from t1 WHERE a=old.a+2; 168 end; 169 } 170} {1 {cannot create INSTEAD OF trigger on table: t1}} 171# Ensure that we cannot create BEFORE triggers on views 172do_test trigger1-1.13 { 173 catchsql { 174 create view v1 as select * from t1; 175 create trigger v1t before update on v1 for each row begin 176 delete from t1 WHERE a=old.a+2; 177 end; 178 } 179} {1 {cannot create BEFORE trigger on view: v1}} 180# Ensure that we cannot create AFTER triggers on views 181do_test trigger1-1.14 { 182 catchsql { 183 drop view v1; 184 create view v1 as select * from t1; 185 create trigger v1t AFTER update on v1 for each row begin 186 delete from t1 WHERE a=old.a+2; 187 end; 188 } 189} {1 {cannot create AFTER trigger on view: v1}} 190 191# Check for memory leaks in the trigger parser 192# 193do_test trigger1-2.1 { 194 catchsql { 195 CREATE TRIGGER r1 AFTER INSERT ON t1 BEGIN 196 SELECT * FROM; -- Syntax error 197 END; 198 } 199} {1 {near ";": syntax error}} 200do_test trigger1-2.2 { 201 catchsql { 202 CREATE TRIGGER r1 AFTER INSERT ON t1 BEGIN 203 SELECT * FROM t1; 204 SELECT * FROM; -- Syntax error 205 END; 206 } 207} {1 {near ";": syntax error}} 208 209# Create a trigger that refers to a table that might not exist. 210# 211do_test trigger1-3.1 { 212 execsql { 213 CREATE TEMP TABLE t2(x,y); 214 } 215 catchsql { 216 CREATE TRIGGER r1 AFTER INSERT ON t1 BEGIN 217 INSERT INTO t2 VALUES(NEW.a,NEW.b); 218 END; 219 } 220} {0 {}} 221do_test trigger-3.2 { 222 catchsql { 223 INSERT INTO t1 VALUES(1,2); 224 SELECT * FROM t2; 225 } 226} {1 {no such table: main.t2}} 227do_test trigger-3.3 { 228 db close 229 set rc [catch {sqlite db test.db} err] 230 if {$rc} {lappend rc $err} 231 set rc 232} {0} 233do_test trigger-3.4 { 234 catchsql { 235 INSERT INTO t1 VALUES(1,2); 236 SELECT * FROM t2; 237 } 238} {1 {no such table: main.t2}} 239do_test trigger-3.5 { 240 catchsql { 241 CREATE TEMP TABLE t2(x,y); 242 INSERT INTO t1 VALUES(1,2); 243 SELECT * FROM t2; 244 } 245} {1 {no such table: main.t2}} 246do_test trigger-3.6 { 247 catchsql { 248 DROP TRIGGER r1; 249 CREATE TEMP TRIGGER r1 AFTER INSERT ON t1 BEGIN 250 INSERT INTO t2 VALUES(NEW.a,NEW.b); 251 END; 252 INSERT INTO t1 VALUES(1,2); 253 SELECT * FROM t2; 254 } 255} {0 {1 2}} 256do_test trigger-3.7 { 257 execsql { 258 DROP TABLE t2; 259 CREATE TABLE t2(x,y); 260 SELECT * FROM t2; 261 } 262} {} 263do_test trigger-3.8 { 264 execsql { 265 INSERT INTO t1 VALUES(3,4); 266 SELECT * FROM t1 UNION ALL SELECT * FROM t2; 267 } 268} {1 2 3 4 3 4} 269do_test trigger-3.9 { 270 db close 271 sqlite db test.db 272 execsql { 273 INSERT INTO t1 VALUES(5,6); 274 SELECT * FROM t1 UNION ALL SELECT * FROM t2; 275 } 276} {1 2 3 4 5 6 3 4} 277 278do_test trigger-4.1 { 279 execsql { 280 CREATE TEMP TRIGGER r1 BEFORE INSERT ON t1 BEGIN 281 INSERT INTO t2 VALUES(NEW.a,NEW.b); 282 END; 283 INSERT INTO t1 VALUES(7,8); 284 SELECT * FROM t2; 285 } 286} {3 4 7 8} 287do_test trigger-4.2 { 288 sqlite db2 test.db 289 execsql { 290 INSERT INTO t1 VALUES(9,10); 291 } db2; 292 db2 close 293 execsql { 294 SELECT * FROM t2; 295 } 296} {3 4 7 8} 297do_test trigger-4.3 { 298 execsql { 299 DROP TABLE t1; 300 SELECT * FROM t2; 301 }; 302} {3 4 7 8} 303do_test trigger-4.4 { 304 db close 305 sqlite db test.db 306 execsql { 307 SELECT * FROM t2; 308 }; 309} {3 4 7 8} 310 311integrity_check trigger-5.1 312 313# Create a trigger with the same name as a table. Make sure the 314# trigger works. Then drop the trigger. Make sure the table is 315# still there. 316# 317do_test trigger-6.1 { 318 execsql {SELECT type, name FROM sqlite_master} 319} {view v1 table t2} 320do_test trigger-6.2 { 321 execsql { 322 CREATE TRIGGER t2 BEFORE DELETE ON t2 BEGIN 323 SELECT RAISE(ABORT,'deletes are not allows'); 324 END; 325 SELECT type, name FROM sqlite_master; 326 } 327} {view v1 table t2 trigger t2} 328do_test trigger-6.3 { 329 catchsql {DELETE FROM t2} 330} {1 {deletes are not allows}} 331do_test trigger-6.4 { 332 execsql {SELECT * FROM t2} 333} {3 4 7 8} 334do_test trigger-6.5 { 335 db close 336 sqlite db test.db 337 execsql {SELECT type, name FROM sqlite_master} 338} {view v1 table t2 trigger t2} 339do_test trigger-6.6 { 340 execsql { 341 DROP TRIGGER t2; 342 SELECT type, name FROM sqlite_master; 343 } 344} {view v1 table t2} 345do_test trigger-6.7 { 346 execsql {SELECT * FROM t2} 347} {3 4 7 8} 348do_test trigger-6.8 { 349 db close 350 sqlite db test.db 351 execsql {SELECT * FROM t2} 352} {3 4 7 8} 353 354integrity_check trigger-7.1 355 356# Check to make sure the name of a trigger can be quoted so that keywords 357# can be used as trigger names. Ticket #468 358# 359do_test trigger-8.1 { 360 execsql { 361 CREATE TRIGGER 'trigger' AFTER INSERT ON t2 BEGIN SELECT 1; END; 362 SELECT name FROM sqlite_master WHERE type='trigger'; 363 } 364} {trigger} 365do_test trigger-8.2 { 366 execsql { 367 DROP TRIGGER 'trigger'; 368 SELECT name FROM sqlite_master WHERE type='trigger'; 369 } 370} {} 371do_test trigger-8.3 { 372 execsql { 373 CREATE TRIGGER "trigger" AFTER INSERT ON t2 BEGIN SELECT 1; END; 374 SELECT name FROM sqlite_master WHERE type='trigger'; 375 } 376} {trigger} 377do_test trigger-8.4 { 378 execsql { 379 DROP TRIGGER "trigger"; 380 SELECT name FROM sqlite_master WHERE type='trigger'; 381 } 382} {} 383do_test trigger-8.5 { 384 execsql { 385 CREATE TRIGGER [trigger] AFTER INSERT ON t2 BEGIN SELECT 1; END; 386 SELECT name FROM sqlite_master WHERE type='trigger'; 387 } 388} {trigger} 389do_test trigger-8.6 { 390 execsql { 391 DROP TRIGGER [trigger]; 392 SELECT name FROM sqlite_master WHERE type='trigger'; 393 } 394} {} 395 396# Make sure REPLACE works inside of triggers. 397# 398do_test trigger-9.1 { 399 execsql { 400 CREATE TABLE t3(a,b); 401 CREATE TABLE t4(x UNIQUE, b); 402 CREATE TRIGGER r34 AFTER INSERT ON t3 BEGIN 403 REPLACE INTO t4 VALUES(new.a,new.b); 404 END; 405 INSERT INTO t3 VALUES(1,2); 406 SELECT * FROM t3 UNION ALL SELECT 99, 99 UNION ALL SELECT * FROM t4; 407 } 408} {1 2 99 99 1 2} 409do_test trigger-9.2 { 410 execsql { 411 INSERT INTO t3 VALUES(1,3); 412 SELECT * FROM t3 UNION ALL SELECT 99, 99 UNION ALL SELECT * FROM t4; 413 } 414} {1 2 1 3 99 99 1 3} 415 416execsql { 417 DROP TABLE t2; 418 DROP TABLE t3; 419 DROP TABLE t4; 420} 421 422# Ticket #764. At one stage TEMP triggers would fail to re-install when the 423# schema was reloaded. The following tests ensure that TEMP triggers are 424# correctly re-installed. 425# 426# Also verify that references within trigger programs are resolved at 427# statement compile time, not trigger installation time. This means, for 428# example, that you can drop and re-create tables referenced by triggers. 429do_test trigger-10.0 { 430 file delete -force test2.db 431 file delete -force test2.db-journal 432 sqlite db2 test2.db 433 execsql {CREATE TABLE t3(a, b, c);} db2 434 db2 close 435 execsql { 436 ATTACH 'test2.db' AS aux; 437 } 438} {} 439do_test trigger-10.1 { 440 execsql { 441 CREATE TABLE t1(a, b, c); 442 CREATE temp TABLE t2(a, b, c); 443 CREATE TABLE insert_log(db, a, b, c); 444 } 445} {} 446do_test trigger-10.2 { 447 execsql { 448 CREATE TEMP TRIGGER trig1 AFTER INSERT ON t1 BEGIN 449 INSERT INTO insert_log VALUES('main', new.a, new.b, new.c); 450 END; 451 CREATE TEMP TRIGGER trig2 AFTER INSERT ON t2 BEGIN 452 INSERT INTO insert_log VALUES('temp', new.a, new.b, new.c); 453 END; 454 CREATE TEMP TRIGGER trig3 AFTER INSERT ON t3 BEGIN 455 INSERT INTO insert_log VALUES('aux', new.a, new.b, new.c); 456 END; 457 } 458} {} 459do_test trigger-10.3 { 460 execsql { 461 INSERT INTO t1 VALUES(1, 2, 3); 462 INSERT INTO t2 VALUES(4, 5, 6); 463 INSERT INTO t3 VALUES(7, 8, 9); 464 } 465} {} 466do_test trigger-10.4 { 467 execsql { 468 SELECT * FROM insert_log; 469 } 470} {main 1 2 3 temp 4 5 6 aux 7 8 9} 471do_test trigger-10.5 { 472 execsql { 473 BEGIN; 474 INSERT INTO t1 VALUES(1, 2, 3); 475 INSERT INTO t2 VALUES(4, 5, 6); 476 INSERT INTO t3 VALUES(7, 8, 9); 477 ROLLBACK; 478 } 479} {} 480do_test trigger-10.6 { 481 execsql { 482 SELECT * FROM insert_log; 483 } 484} {main 1 2 3 temp 4 5 6 aux 7 8 9} 485do_test trigger-10.7 { 486 execsql { 487 DELETE FROM insert_log; 488 INSERT INTO t1 VALUES(11, 12, 13); 489 INSERT INTO t2 VALUES(14, 15, 16); 490 INSERT INTO t3 VALUES(17, 18, 19); 491 } 492} {} 493do_test trigger-10.8 { 494 execsql { 495 SELECT * FROM insert_log; 496 } 497} {main 11 12 13 temp 14 15 16 aux 17 18 19} 498do_test trigger-10.8 { 499# Drop and re-create the insert_log table in a different database. Note 500# that we can change the column names because the trigger programs don't 501# use them explicitly. 502 execsql { 503 DROP TABLE insert_log; 504 CREATE temp TABLE insert_log(db, d, e, f); 505 } 506} {} 507do_test trigger-10.10 { 508 execsql { 509 INSERT INTO t1 VALUES(21, 22, 23); 510 INSERT INTO t2 VALUES(24, 25, 26); 511 INSERT INTO t3 VALUES(27, 28, 29); 512 } 513} {} 514do_test trigger-10.11 { 515 execsql { 516 SELECT * FROM insert_log; 517 } 518} {main 21 22 23 temp 24 25 26 aux 27 28 29} 519 520finish_test 521