000001 # 2011 October 28 000002 # 000003 # The author disclaims copyright to this source code. In place of 000004 # a legal notice, here is a blessing: 000005 # 000006 # May you do good and not evil. 000007 # May you find forgiveness for yourself and forgive others. 000008 # May you share freely, never taking more than you give. 000009 # 000010 #*********************************************************************** 000011 # 000012 000013 set testdir [file dirname $argv0] 000014 source $testdir/tester.tcl 000015 set testprefix e_changes 000016 000017 # Like [do_execsql_test], except it appends the value returned by 000018 # [db changes] to the result of executing the SQL script. 000019 # 000020 proc do_changes_test {tn sql res} { 000021 uplevel [list \ 000022 do_test $tn "concat \[execsql {$sql}\] \[db changes\]" $res 000023 ] 000024 } 000025 000026 000027 #-------------------------------------------------------------------------- 000028 # EVIDENCE-OF: R-15996-49369 This function returns the number of rows 000029 # modified, inserted or deleted by the most recently completed INSERT, 000030 # UPDATE or DELETE statement on the database connection specified by the 000031 # only parameter. 000032 # 000033 do_execsql_test 1.0 { 000034 CREATE TABLE t1(a, b); 000035 CREATE TABLE t2(x, y, PRIMARY KEY(x, y)) WITHOUT ROWID; 000036 CREATE INDEX i1 ON t1(a); 000037 CREATE INDEX i2 ON t2(y); 000038 } 000039 foreach {tn schema} { 000040 1 { 000041 CREATE TABLE t1(a, b); 000042 CREATE INDEX i1 ON t1(b); 000043 } 000044 2 { 000045 CREATE TABLE t1(a, b, PRIMARY KEY(a, b)) WITHOUT ROWID; 000046 CREATE INDEX i1 ON t1(b); 000047 } 000048 } { 000049 reset_db 000050 execsql $schema 000051 000052 # Insert 1 row. 000053 do_changes_test 1.$tn.1 { INSERT INTO t1 VALUES(0, 0) } 1 000054 000055 # Insert 10 rows. 000056 do_changes_test 1.$tn.2 { 000057 WITH rows(i, j) AS ( 000058 SELECT 1, 1 UNION ALL SELECT i+1, j+i FROM rows WHERE i<10 000059 ) 000060 INSERT INTO t1 SELECT * FROM rows 000061 } 10 000062 000063 # Modify 5 rows. 000064 do_changes_test 1.$tn.3 { 000065 UPDATE t1 SET b=b+1 WHERE a<5; 000066 } 5 000067 000068 # Delete 4 rows 000069 do_changes_test 1.$tn.4 { 000070 DELETE FROM t1 WHERE a>6 000071 } 4 000072 000073 # Check the "on the database connecton specified" part of hte 000074 # requirement - changes made by other connections do not show up in 000075 # the return value of sqlite3_changes(). 000076 do_test 1.$tn.5 { 000077 sqlite3 db2 test.db 000078 execsql { INSERT INTO t1 VALUES(-1, -1) } db2 000079 db2 changes 000080 } 1 000081 do_test 1.$tn.6 { 000082 db changes 000083 } 4 000084 db2 close 000085 000086 # Test that statements that modify no rows because they hit UNIQUE 000087 # constraints set the sqlite3_changes() value to 0. Regardless of 000088 # whether or not they are executed inside an explicit transaction. 000089 # 000090 # 1.$tn.8-9: outside of a transaction 000091 # 1.$tn.10-12: inside a transaction 000092 # 000093 do_changes_test 1.$tn.7 { 000094 CREATE UNIQUE INDEX i2 ON t1(a); 000095 } 4 000096 do_catchsql_test 1.$tn.8 { 000097 INSERT INTO t1 VALUES('a', 0), ('b', 0), ('c', 0), (0, 11); 000098 } {1 {UNIQUE constraint failed: t1.a}} 000099 do_test 1.$tn.9 { db changes } 0 000100 do_catchsql_test 1.$tn.10 { 000101 BEGIN; 000102 INSERT INTO t1 VALUES('a', 0), ('b', 0), ('c', 0), (0, 11); 000103 } {1 {UNIQUE constraint failed: t1.a}} 000104 do_test 1.$tn.11 { db changes } 0 000105 do_changes_test 1.$tn.12 COMMIT 0 000106 000107 } 000108 000109 000110 #-------------------------------------------------------------------------- 000111 # EVIDENCE-OF: R-44877-05564 Executing any other type of SQL statement 000112 # does not modify the value returned by this function. 000113 # 000114 reset_db 000115 do_changes_test 2.1 { CREATE TABLE t1(x) } 0 000116 do_changes_test 2.2 { 000117 WITH d(y) AS (SELECT 1 UNION ALL SELECT y+1 FROM d WHERE y<47) 000118 INSERT INTO t1 SELECT y FROM d; 000119 } 47 000120 000121 # The statement above set changes() to 47. Check that none of the following 000122 # modify this. 000123 do_changes_test 2.3 { SELECT count(x) FROM t1 } {47 47} 000124 do_changes_test 2.4 { DROP TABLE t1 } 47 000125 do_changes_test 2.5 { CREATE TABLE t1(x) } 47 000126 do_changes_test 2.6 { ALTER TABLE t1 ADD COLUMN b } 47 000127 000128 000129 #-------------------------------------------------------------------------- 000130 # EVIDENCE-OF: R-53938-27527 Only changes made directly by the INSERT, 000131 # UPDATE or DELETE statement are considered - auxiliary changes caused 000132 # by triggers, foreign key actions or REPLACE constraint resolution are 000133 # not counted. 000134 # 000135 # 3.1.*: triggers 000136 # 3.2.*: foreign key actions 000137 # 3.3.*: replace constraints 000138 # 000139 reset_db 000140 do_execsql_test 3.1.0 { 000141 CREATE TABLE log(x); 000142 CREATE TABLE p1(one PRIMARY KEY, two); 000143 000144 CREATE TRIGGER tr_ai AFTER INSERT ON p1 BEGIN 000145 INSERT INTO log VALUES('insert'); 000146 END; 000147 CREATE TRIGGER tr_bd BEFORE DELETE ON p1 BEGIN 000148 INSERT INTO log VALUES('delete'); 000149 END; 000150 CREATE TRIGGER tr_au AFTER UPDATE ON p1 BEGIN 000151 INSERT INTO log VALUES('update'); 000152 END; 000153 000154 } 000155 000156 do_changes_test 3.1.1 { 000157 INSERT INTO p1 VALUES('a', 'A'), ('b', 'B'), ('c', 'C'); 000158 } 3 000159 do_changes_test 3.1.2 { 000160 UPDATE p1 SET two = two||two; 000161 } 3 000162 do_changes_test 3.1.3 { 000163 DELETE FROM p1 WHERE one IN ('a', 'c'); 000164 } 2 000165 do_execsql_test 3.1.4 { 000166 -- None of the inserts on table log were counted. 000167 SELECT count(*) FROM log 000168 } 8 000169 000170 do_execsql_test 3.2.0 { 000171 DELETE FROM p1; 000172 INSERT INTO p1 VALUES('a', 'A'), ('b', 'B'), ('c', 'C'); 000173 000174 CREATE TABLE c1(a, b, FOREIGN KEY(a) REFERENCES p1 ON DELETE SET NULL); 000175 CREATE TABLE c2(a, b, FOREIGN KEY(a) REFERENCES p1 ON DELETE SET DEFAULT); 000176 CREATE TABLE c3(a, b, FOREIGN KEY(a) REFERENCES p1 ON DELETE CASCADE); 000177 INSERT INTO c1 VALUES('a', 'aaa'); 000178 INSERT INTO c2 VALUES('b', 'bbb'); 000179 INSERT INTO c3 VALUES('c', 'ccc'); 000180 000181 INSERT INTO p1 VALUES('d', 'D'), ('e', 'E'), ('f', 'F'); 000182 CREATE TABLE c4(a, b, FOREIGN KEY(a) REFERENCES p1 ON UPDATE SET NULL); 000183 CREATE TABLE c5(a, b, FOREIGN KEY(a) REFERENCES p1 ON UPDATE SET DEFAULT); 000184 CREATE TABLE c6(a, b, FOREIGN KEY(a) REFERENCES p1 ON UPDATE CASCADE); 000185 INSERT INTO c4 VALUES('d', 'aaa'); 000186 INSERT INTO c5 VALUES('e', 'bbb'); 000187 INSERT INTO c6 VALUES('f', 'ccc'); 000188 000189 PRAGMA foreign_keys = ON; 000190 } 000191 000192 do_changes_test 3.2.1 { DELETE FROM p1 WHERE one = 'a' } 1 000193 do_changes_test 3.2.2 { DELETE FROM p1 WHERE one = 'b' } 1 000194 do_changes_test 3.2.3 { DELETE FROM p1 WHERE one = 'c' } 1 000195 do_execsql_test 3.2.4 { 000196 SELECT * FROM c1; 000197 SELECT * FROM c2; 000198 SELECT * FROM c3; 000199 } {{} aaa {} bbb} 000200 000201 do_changes_test 3.2.5 { UPDATE p1 SET one = 'g' WHERE one = 'd' } 1 000202 do_changes_test 3.2.6 { UPDATE p1 SET one = 'h' WHERE one = 'e' } 1 000203 do_changes_test 3.2.7 { UPDATE p1 SET one = 'i' WHERE one = 'f' } 1 000204 do_execsql_test 3.2.8 { 000205 SELECT * FROM c4; 000206 SELECT * FROM c5; 000207 SELECT * FROM c6; 000208 } {{} aaa {} bbb i ccc} 000209 000210 do_execsql_test 3.3.0 { 000211 CREATE TABLE r1(a UNIQUE, b UNIQUE); 000212 INSERT INTO r1 VALUES('i', 'i'); 000213 INSERT INTO r1 VALUES('ii', 'ii'); 000214 INSERT INTO r1 VALUES('iii', 'iii'); 000215 INSERT INTO r1 VALUES('iv', 'iv'); 000216 INSERT INTO r1 VALUES('v', 'v'); 000217 INSERT INTO r1 VALUES('vi', 'vi'); 000218 INSERT INTO r1 VALUES('vii', 'vii'); 000219 } 000220 000221 do_changes_test 3.3.1 { INSERT OR REPLACE INTO r1 VALUES('i', 1) } 1 000222 do_changes_test 3.3.2 { INSERT OR REPLACE INTO r1 VALUES('iv', 'v') } 1 000223 do_changes_test 3.3.3 { UPDATE OR REPLACE r1 SET b='v' WHERE a='iii' } 1 000224 do_changes_test 3.3.4 { UPDATE OR REPLACE r1 SET b='vi',a='vii' WHERE a='ii' } 1 000225 do_execsql_test 3.3.5 { 000226 SELECT * FROM r1 ORDER BY a; 000227 } {i 1 iii v vii vi} 000228 000229 000230 #-------------------------------------------------------------------------- 000231 # EVIDENCE-OF: R-09813-48563 The value returned by sqlite3_changes() 000232 # immediately after an INSERT, UPDATE or DELETE statement run on a view 000233 # is always zero. 000234 # 000235 reset_db 000236 do_execsql_test 4.1 { 000237 CREATE TABLE log(log); 000238 CREATE TABLE t1(x, y); 000239 INSERT INTO t1 VALUES(1, 2); 000240 INSERT INTO t1 VALUES(3, 4); 000241 INSERT INTO t1 VALUES(5, 6); 000242 000243 CREATE VIEW v1 AS SELECT * FROM t1; 000244 CREATE TRIGGER v1_i INSTEAD OF INSERT ON v1 BEGIN 000245 INSERT INTO log VALUES('insert'); 000246 END; 000247 CREATE TRIGGER v1_u INSTEAD OF UPDATE ON v1 BEGIN 000248 INSERT INTO log VALUES('update'), ('update'); 000249 END; 000250 CREATE TRIGGER v1_d INSTEAD OF DELETE ON v1 BEGIN 000251 INSERT INTO log VALUES('delete'), ('delete'), ('delete'); 000252 END; 000253 } 000254 000255 do_changes_test 4.2.1 { INSERT INTO t1 SELECT * FROM t1 } 3 000256 do_changes_test 4.2.2 { INSERT INTO v1 VALUES(1, 2) } 0 000257 000258 do_changes_test 4.3.1 { INSERT INTO t1 SELECT * FROM t1 } 6 000259 do_changes_test 4.3.2 { UPDATE v1 SET y='xyz' WHERE x=1 } 0 000260 000261 do_changes_test 4.4.1 { INSERT INTO t1 SELECT * FROM t1 } 12 000262 do_changes_test 4.4.2 { DELETE FROM v1 WHERE x=5 } 0 000263 000264 000265 #-------------------------------------------------------------------------- 000266 # EVIDENCE-OF: R-32918-61474 Before entering a trigger program the value 000267 # returned by sqlite3_changes() function is saved. After the trigger 000268 # program has finished, the original value is restored. 000269 # 000270 reset_db 000271 db func my_changes my_changes 000272 set ::changes [list] 000273 proc my_changes {x} { 000274 set res [db changes] 000275 lappend ::changes $x $res 000276 return $res 000277 } 000278 000279 do_execsql_test 5.1.0 { 000280 CREATE TABLE t1(a INTEGER PRIMARY KEY, b); 000281 CREATE TABLE t2(x); 000282 INSERT INTO t1 VALUES(1, NULL); 000283 INSERT INTO t1 VALUES(2, NULL); 000284 INSERT INTO t1 VALUES(3, NULL); 000285 CREATE TRIGGER AFTER UPDATE ON t1 BEGIN 000286 INSERT INTO t2 VALUES('a'), ('b'), ('c'); 000287 SELECT my_changes('trigger'); 000288 END; 000289 } 000290 000291 do_execsql_test 5.1.1 { 000292 INSERT INTO t2 VALUES('a'), ('b'); 000293 UPDATE t1 SET b = my_changes('update'); 000294 SELECT * FROM t1; 000295 } {1 2 2 2 3 2} 000296 000297 # Value is being restored to "2" when the trigger program exits. 000298 do_test 5.1.2 { 000299 set ::changes 000300 } {update 2 trigger 3 update 2 trigger 3 update 2 trigger 3} 000301 000302 000303 reset_db 000304 do_execsql_test 5.2.0 { 000305 CREATE TABLE t1(a, b); 000306 CREATE TABLE log(x); 000307 INSERT INTO t1 VALUES(1, 0); 000308 INSERT INTO t1 VALUES(2, 0); 000309 INSERT INTO t1 VALUES(3, 0); 000310 CREATE TRIGGER t1_a_u AFTER UPDATE ON t1 BEGIN 000311 INSERT INTO log VALUES(old.b || ' -> ' || new.b || ' c = ' || changes() ); 000312 END; 000313 CREATE TABLE t2(a); 000314 INSERT INTO t2 VALUES(1), (2), (3); 000315 UPDATE t1 SET b = changes(); 000316 } 000317 do_execsql_test 5.2.1 { 000318 SELECT * FROM t1; 000319 } {1 3 2 3 3 3} 000320 do_execsql_test 5.2.2 { 000321 SELECT * FROM log; 000322 } {{0 -> 3 c = 3} {0 -> 3 c = 3} {0 -> 3 c = 3}} 000323 000324 000325 #-------------------------------------------------------------------------- 000326 # EVIDENCE-OF: R-17146-37073 Within a trigger program each INSERT, 000327 # UPDATE and DELETE statement sets the value returned by 000328 # sqlite3_changes() upon completion as normal. Of course, this value 000329 # will not include any changes performed by sub-triggers, as the 000330 # sqlite3_changes() value will be saved and restored after each 000331 # sub-trigger has run. 000332 reset_db 000333 do_execsql_test 6.0 { 000334 000335 CREATE TABLE t1(a, b); 000336 CREATE TABLE t2(a, b); 000337 CREATE TABLE t3(a, b); 000338 CREATE TABLE log(x); 000339 000340 CREATE TRIGGER t1_i BEFORE INSERT ON t1 BEGIN 000341 INSERT INTO t2 VALUES(new.a, new.b), (new.a, new.b); 000342 INSERT INTO log VALUES('t2->' || changes()); 000343 END; 000344 000345 CREATE TRIGGER t2_i AFTER INSERT ON t2 BEGIN 000346 INSERT INTO t3 VALUES(new.a, new.b), (new.a, new.b), (new.a, new.b); 000347 INSERT INTO log VALUES('t3->' || changes()); 000348 END; 000349 000350 CREATE TRIGGER t1_u AFTER UPDATE ON t1 BEGIN 000351 UPDATE t2 SET b=new.b WHERE a=old.a; 000352 INSERT INTO log VALUES('t2->' || changes()); 000353 END; 000354 000355 CREATE TRIGGER t2_u BEFORE UPDATE ON t2 BEGIN 000356 UPDATE t3 SET b=new.b WHERE a=old.a; 000357 INSERT INTO log VALUES('t3->' || changes()); 000358 END; 000359 000360 CREATE TRIGGER t1_d AFTER DELETE ON t1 BEGIN 000361 DELETE FROM t2 WHERE a=old.a AND b=old.b; 000362 INSERT INTO log VALUES('t2->' || changes()); 000363 END; 000364 000365 CREATE TRIGGER t2_d BEFORE DELETE ON t2 BEGIN 000366 DELETE FROM t3 WHERE a=old.a AND b=old.b; 000367 INSERT INTO log VALUES('t3->' || changes()); 000368 END; 000369 } 000370 000371 do_changes_test 6.1 { 000372 INSERT INTO t1 VALUES('+', 'o'); 000373 SELECT * FROM log; 000374 } {t3->3 t3->3 t2->2 1} 000375 000376 do_changes_test 6.2 { 000377 DELETE FROM log; 000378 UPDATE t1 SET b='*'; 000379 SELECT * FROM log; 000380 } {t3->6 t3->6 t2->2 1} 000381 000382 do_changes_test 6.3 { 000383 DELETE FROM log; 000384 DELETE FROM t1; 000385 SELECT * FROM log; 000386 } {t3->6 t3->0 t2->2 1} 000387 000388 000389 #-------------------------------------------------------------------------- 000390 # EVIDENCE-OF: R-43399-09409 This means that if the changes() SQL 000391 # function (or similar) is used by the first INSERT, UPDATE or DELETE 000392 # statement within a trigger, it returns the value as set when the 000393 # calling statement began executing. 000394 # 000395 # EVIDENCE-OF: R-53215-27584 If it is used by the second or subsequent 000396 # such statement within a trigger program, the value returned reflects 000397 # the number of rows modified by the previous INSERT, UPDATE or DELETE 000398 # statement within the same trigger. 000399 # 000400 reset_db 000401 do_execsql_test 7.1 { 000402 CREATE TABLE q1(t); 000403 CREATE TABLE q2(u, v); 000404 CREATE TABLE q3(w); 000405 000406 CREATE TRIGGER q2_insert BEFORE INSERT ON q2 BEGIN 000407 000408 /* changes() returns value from previous I/U/D in callers context */ 000409 INSERT INTO q1 VALUES('1:' || changes()); 000410 000411 /* changes() returns value of previous I/U/D in this context */ 000412 INSERT INTO q3 VALUES(changes()), (2), (3); 000413 INSERT INTO q1 VALUES('2:' || changes()); 000414 INSERT INTO q3 VALUES(changes() + 3), (changes()+4); 000415 SELECT 'this does not affect things!'; 000416 INSERT INTO q1 VALUES('3:' || changes()); 000417 UPDATE q3 SET w = w+10 WHERE w%2; 000418 INSERT INTO q1 VALUES('4:' || changes()); 000419 DELETE FROM q3; 000420 INSERT INTO q1 VALUES('5:' || changes()); 000421 END; 000422 } 000423 000424 do_execsql_test 7.2 { 000425 INSERT INTO q2 VALUES('x', 'y'); 000426 SELECT * FROM q1; 000427 } { 000428 1:0 2:3 3:2 4:3 5:5 000429 } 000430 000431 do_execsql_test 7.3 { 000432 DELETE FROM q1; 000433 INSERT INTO q2 VALUES('x', 'y'); 000434 SELECT * FROM q1; 000435 } { 000436 1:5 2:3 3:2 4:3 5:5 000437 } 000438 000439 000440 000441 finish_test