125e978dfSdrh# 2009 December 29 225e978dfSdrh# 325e978dfSdrh# The author disclaims copyright to this source code. In place of 425e978dfSdrh# a legal notice', here is a blessing: 525e978dfSdrh# 625e978dfSdrh# May you do good and not evil. 725e978dfSdrh# May you find forgiveness for yourself and forgive others. 825e978dfSdrh# May you share freely, never taking more than you give. 925e978dfSdrh# 1025e978dfSdrh#*********************************************************************** 1125e978dfSdrh# 1225e978dfSdrh# Verify that when columns named "rowid", "oid", and "_rowid_" appear 1325e978dfSdrh# in a table as ordinary columns (not as the INTEGER PRIMARY KEY) then 1425e978dfSdrh# the use of these columns in triggers will refer to the column and not 1525e978dfSdrh# to the actual ROWID. Ticket [34d2ae1c6d08b5271ba5e5592936d4a1d913ffe3] 1625e978dfSdrh# 17f475e5aeSdrh# Also, verify that triggers created like this: 18f475e5aeSdrh# 19f475e5aeSdrh# CREATE TRIGGER attached.trig AFTER INSERT ON attached.tab ... 20f475e5aeSdrh# 21f475e5aeSdrh# can be reparsed as a main database. Ticket [d6ddba6706353915ceedc56b4e3] 22f475e5aeSdrh# 2325e978dfSdrh 2425e978dfSdrhset testdir [file dirname $argv0] 2525e978dfSdrhsource $testdir/tester.tcl 2625e978dfSdrhifcapable {!trigger} { 2725e978dfSdrh finish_test 2825e978dfSdrh return 2925e978dfSdrh} 3025e978dfSdrh 3125e978dfSdrh# Triggers on tables where the table has ordinary columns named 3225e978dfSdrh# rowid, oid, and _rowid_. 3325e978dfSdrh# 3425e978dfSdrhdo_test triggerD-1.1 { 3525e978dfSdrh db eval { 3625e978dfSdrh CREATE TABLE t1(rowid, oid, _rowid_, x); 3725e978dfSdrh CREATE TABLE log(a,b,c,d,e); 3825e978dfSdrh CREATE TRIGGER r1 BEFORE INSERT ON t1 BEGIN 3925e978dfSdrh INSERT INTO log VALUES('r1', new.rowid, new.oid, new._rowid_, new.x); 4025e978dfSdrh END; 4125e978dfSdrh CREATE TRIGGER r2 AFTER INSERT ON t1 BEGIN 4225e978dfSdrh INSERT INTO log VALUES('r2', new.rowid, new.oid, new._rowid_, new.x); 4325e978dfSdrh END; 4425e978dfSdrh CREATE TRIGGER r3 BEFORE UPDATE ON t1 BEGIN 4525e978dfSdrh INSERT INTO log VALUES('r3.old', old.rowid, old.oid, old._rowid_, old.x); 4625e978dfSdrh INSERT INTO log VALUES('r3.new', new.rowid, new.oid, new._rowid_, new.x); 4725e978dfSdrh END; 4825e978dfSdrh CREATE TRIGGER r4 AFTER UPDATE ON t1 BEGIN 4925e978dfSdrh INSERT INTO log VALUES('r4.old', old.rowid, old.oid, old._rowid_, old.x); 5025e978dfSdrh INSERT INTO log VALUES('r4.new', new.rowid, new.oid, new._rowid_, new.x); 5125e978dfSdrh END; 5225e978dfSdrh CREATE TRIGGER r5 BEFORE DELETE ON t1 BEGIN 5325e978dfSdrh INSERT INTO log VALUES('r5', old.rowid, old.oid, old._rowid_, old.x); 5425e978dfSdrh END; 5525e978dfSdrh CREATE TRIGGER r6 AFTER DELETE ON t1 BEGIN 5625e978dfSdrh INSERT INTO log VALUES('r6', old.rowid, old.oid, old._rowid_, old.x); 5725e978dfSdrh END; 5825e978dfSdrh } 5925e978dfSdrh} {} 6025e978dfSdrhdo_test triggerD-1.2 { 6125e978dfSdrh db eval { 6225e978dfSdrh INSERT INTO t1 VALUES(100,200,300,400); 6325e978dfSdrh SELECT * FROM log 6425e978dfSdrh } 6525e978dfSdrh} {r1 100 200 300 400 r2 100 200 300 400} 6625e978dfSdrhdo_test triggerD-1.3 { 6725e978dfSdrh db eval { 6825e978dfSdrh DELETE FROM log; 6925e978dfSdrh UPDATE t1 SET rowid=rowid+1; 7025e978dfSdrh SELECT * FROM log 7125e978dfSdrh } 7225e978dfSdrh} {r3.old 100 200 300 400 r3.new 101 200 300 400 r4.old 100 200 300 400 r4.new 101 200 300 400} 7325e978dfSdrhdo_test triggerD-1.4 { 7425e978dfSdrh db eval { 7525e978dfSdrh DELETE FROM log; 7625e978dfSdrh DELETE FROM t1; 7725e978dfSdrh SELECT * FROM log 7825e978dfSdrh } 7925e978dfSdrh} {r5 101 200 300 400 r6 101 200 300 400} 8025e978dfSdrh 8125e978dfSdrh# Triggers on tables where the table does not have ordinary columns named 8225e978dfSdrh# rowid, oid, and _rowid_. 8325e978dfSdrh# 8425e978dfSdrhdo_test triggerD-2.1 { 8525e978dfSdrh db eval { 8625e978dfSdrh DROP TABLE t1; 8725e978dfSdrh CREATE TABLE t1(w,x,y,z); 8825e978dfSdrh CREATE TRIGGER r1 BEFORE INSERT ON t1 BEGIN 8925e978dfSdrh INSERT INTO log VALUES('r1', new.rowid, new.oid, new._rowid_, new.x); 9025e978dfSdrh END; 9125e978dfSdrh CREATE TRIGGER r2 AFTER INSERT ON t1 BEGIN 9225e978dfSdrh INSERT INTO log VALUES('r2', new.rowid, new.oid, new._rowid_, new.x); 9325e978dfSdrh END; 9425e978dfSdrh CREATE TRIGGER r3 BEFORE UPDATE ON t1 BEGIN 9525e978dfSdrh INSERT INTO log VALUES('r3.old', old.rowid, old.oid, old._rowid_, old.x); 9625e978dfSdrh INSERT INTO log VALUES('r3.new', new.rowid, new.oid, new._rowid_, new.x); 9725e978dfSdrh END; 9825e978dfSdrh CREATE TRIGGER r4 AFTER UPDATE ON t1 BEGIN 9925e978dfSdrh INSERT INTO log VALUES('r4.old', old.rowid, old.oid, old._rowid_, old.x); 10025e978dfSdrh INSERT INTO log VALUES('r4.new', new.rowid, new.oid, new._rowid_, new.x); 10125e978dfSdrh END; 10225e978dfSdrh CREATE TRIGGER r5 BEFORE DELETE ON t1 BEGIN 10325e978dfSdrh INSERT INTO log VALUES('r5', old.rowid, old.oid, old._rowid_, old.x); 10425e978dfSdrh END; 10525e978dfSdrh CREATE TRIGGER r6 AFTER DELETE ON t1 BEGIN 10625e978dfSdrh INSERT INTO log VALUES('r6', old.rowid, old.oid, old._rowid_, old.x); 10725e978dfSdrh END; 10825e978dfSdrh } 10925e978dfSdrh} {} 11025e978dfSdrhdo_test triggerD-2.2 { 11125e978dfSdrh db eval { 11225e978dfSdrh DELETE FROM log; 11325e978dfSdrh INSERT INTO t1 VALUES(100,200,300,400); 11425e978dfSdrh SELECT * FROM log; 11525e978dfSdrh } 11625e978dfSdrh} {r1 -1 -1 -1 200 r2 1 1 1 200} 11725e978dfSdrhdo_test triggerD-2.3 { 11825e978dfSdrh db eval { 11925e978dfSdrh DELETE FROM log; 12025e978dfSdrh UPDATE t1 SET x=x+1; 12125e978dfSdrh SELECT * FROM log 12225e978dfSdrh } 12325e978dfSdrh} {r3.old 1 1 1 200 r3.new 1 1 1 201 r4.old 1 1 1 200 r4.new 1 1 1 201} 12425e978dfSdrhdo_test triggerD-2.4 { 12525e978dfSdrh db eval { 12625e978dfSdrh DELETE FROM log; 12725e978dfSdrh DELETE FROM t1; 12825e978dfSdrh SELECT * FROM log 12925e978dfSdrh } 13025e978dfSdrh} {r5 1 1 1 201 r6 1 1 1 201} 13125e978dfSdrh 132622d2887Sdrh 133622d2887Sdrh########################################################################### 134622d2887Sdrh# 135622d2887Sdrh# Ticket [985771e1161200ae5eac3162686ea6711c035d08]: 136622d2887Sdrh# 137622d2887Sdrh# When both a main database table and a TEMP table have the same name, 138622d2887Sdrh# and a main database trigge is created on the main table, the trigger 139622d2887Sdrh# is incorrectly bound to the TEMP table. For example: 140622d2887Sdrh# 141622d2887Sdrh# CREATE TABLE t1(x); 142622d2887Sdrh# CREATE TEMP TABLE t1(x); 143622d2887Sdrh# CREATE TABLE t2(z); 144622d2887Sdrh# CREATE TRIGGER main.r1 AFTER INSERT ON t1 BEGIN 145622d2887Sdrh# INSERT INTO t2 VALUES(10000 + new.x); 146622d2887Sdrh# END; 147622d2887Sdrh# INSERT INTO main.t1 VALUES(3); 148622d2887Sdrh# INSERT INTO temp.t1 VALUES(4); 149622d2887Sdrh# SELECT * FROM t2; 150622d2887Sdrh# 151622d2887Sdrh# The r1 trigger fires when the value 4 is inserted into the temp.t1 152622d2887Sdrh# table, rather than when value 3 is inserted into main.t1. 153622d2887Sdrh# 154622d2887Sdrhdo_test triggerD-3.1 { 155622d2887Sdrh db eval { 156622d2887Sdrh CREATE TABLE t300(x); 157622d2887Sdrh CREATE TEMP TABLE t300(x); 158622d2887Sdrh CREATE TABLE t301(y); 159622d2887Sdrh CREATE TRIGGER main.r300 AFTER INSERT ON t300 BEGIN 160622d2887Sdrh INSERT INTO t301 VALUES(10000 + new.x); 161622d2887Sdrh END; 162622d2887Sdrh INSERT INTO main.t300 VALUES(3); 163622d2887Sdrh INSERT INTO temp.t300 VALUES(4); 164622d2887Sdrh SELECT * FROM t301; 165622d2887Sdrh } 166622d2887Sdrh} {10003} 167622d2887Sdrhdo_test triggerD-3.2 { 168622d2887Sdrh db eval { 169622d2887Sdrh DELETE FROM t301; 170622d2887Sdrh CREATE TRIGGER temp.r301 AFTER INSERT ON t300 BEGIN 171622d2887Sdrh INSERT INTO t301 VALUES(20000 + new.x); 172622d2887Sdrh END; 173622d2887Sdrh INSERT INTO main.t300 VALUES(3); 174622d2887Sdrh INSERT INTO temp.t300 VALUES(4); 175622d2887Sdrh SELECT * FROM t301; 176622d2887Sdrh } 177622d2887Sdrh} {10003 20004} 178622d2887Sdrh 179622d2887Sdrh 180f475e5aeSdrh############################################################################# 181f475e5aeSdrh# 182f475e5aeSdrh# Ticket [d6ddba6706353915ceedc56b4e3e72ecb4d77ba4] 183f475e5aeSdrh# 184f475e5aeSdrh# The following syntax really should not be allowed: 185f475e5aeSdrh# 186f475e5aeSdrh# CREATE TRIGGER xyz.trig BEFORE UPDATE ON xyz.tab BEGIN ... 187f475e5aeSdrh# 188f475e5aeSdrh# But a long-standing bug does allow it. And the "xyz.tab" slips into 189f475e5aeSdrh# the sqlite_master table. We cannot fix the bug simply by disallowing 190f475e5aeSdrh# "xyz.tab" since that could break legacy applications. We have to 191f475e5aeSdrh# fix the system so that the "xyz." on "xyz.tab" is ignored. 192f475e5aeSdrh# Verify that this is the case. 193f475e5aeSdrh# 194f475e5aeSdrhdo_test triggerD-4.1 { 195f475e5aeSdrh db close 196*fda06befSmistachkin forcedelete test.db test2.db 197f475e5aeSdrh sqlite3 db test.db 198f475e5aeSdrh db eval { 199f475e5aeSdrh CREATE TABLE t1(x); 200f475e5aeSdrh ATTACH 'test2.db' AS db2; 201f475e5aeSdrh CREATE TABLE db2.t2(y); 202f475e5aeSdrh CREATE TABLE db2.log(z); 203f475e5aeSdrh CREATE TRIGGER db2.trig AFTER INSERT ON db2.t2 BEGIN 204f475e5aeSdrh INSERT INTO log(z) VALUES(new.y); 205f475e5aeSdrh END; 206f475e5aeSdrh INSERT INTO t2 VALUES(123); 207f475e5aeSdrh SELECT * FROM log; 208f475e5aeSdrh } 209f475e5aeSdrh} {123} 210f475e5aeSdrhdo_test triggerD-4.2 { 211f475e5aeSdrh sqlite3 db2 test2.db 212f475e5aeSdrh db2 eval { 213f475e5aeSdrh INSERT INTO t2 VALUES(234); 214f475e5aeSdrh SELECT * FROM log; 215f475e5aeSdrh } 216f475e5aeSdrh} {123 234} 217f475e5aeSdrhdb2 close 218f475e5aeSdrh 21925e978dfSdrhfinish_test 220