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 # Tests to make sure that value returned by last_insert_rowid() (LIRID)
11 # is updated properly, especially inside triggers
13 # Note 1: insert into table is now the only statement which changes LIRID
14 # Note 2: upon entry into before or instead of triggers,
15 # LIRID is unchanged (rather than -1)
16 # Note 3: LIRID is changed within the context of a trigger,
17 # but is restored once the trigger exits
18 # Note 4: LIRID is not changed by an insert into a view (since everything
19 # is done within instead of trigger context)
22 set testdir [file dirname $argv0]
23 source $testdir/tester.tcl
25 # ----------------------------------------------------------------------------
26 # 1.x - basic tests (no triggers)
28 # LIRID changed properly after an insert into a table
29 do_test lastinsert-1.1 {
31 create table t1 (k integer primary key);
32 insert into t1 values (1);
33 insert into t1 values (NULL);
34 insert into t1 values (NULL);
35 select last_insert_rowid();
39 # EVIDENCE-OF: R-47220-63683 The sqlite3_last_insert_rowid() function
40 # does not work for WITHOUT ROWID tables.
42 do_test lastinsert-1.1w {
44 create table t1w (k integer primary key) WITHOUT ROWID;
45 insert into t1w values (123456);
46 select last_insert_rowid(); -- returns 3 from above.
50 # LIRID unchanged after an update on a table
51 do_test lastinsert-1.2 {
53 update t1 set k=4 where k=2;
54 select last_insert_rowid();
58 # LIRID unchanged after a delete from a table
59 do_test lastinsert-1.3 {
61 delete from t1 where k=4;
62 select last_insert_rowid();
66 # LIRID unchanged after create table/view statements
67 do_test lastinsert-1.4.1 {
69 create table t2 (k integer primary key, val1, val2, val3);
70 select last_insert_rowid();
74 do_test lastinsert-1.4.2 {
76 create view v as select * from t1;
77 select last_insert_rowid();
82 # All remaining tests involve triggers. Skip them if triggers are not
83 # supported in this build.
85 ifcapable {!trigger} {
90 # ----------------------------------------------------------------------------
91 # 2.x - tests with after insert trigger
93 # LIRID changed properly after an insert into table containing an after trigger
94 do_test lastinsert-2.1 {
97 create trigger r1 after insert on t1 for each row begin
98 insert into t2 values (NEW.k*2, last_insert_rowid(), NULL, NULL);
99 update t2 set k=k+10, val2=100+last_insert_rowid();
100 update t2 set val3=1000+last_insert_rowid();
102 insert into t1 values (13);
103 select last_insert_rowid();
107 # LIRID equals NEW.k upon entry into after insert trigger
108 do_test lastinsert-2.2 {
114 # LIRID changed properly by insert within context of after insert trigger
115 do_test lastinsert-2.3 {
121 # LIRID unchanged by update within context of after insert trigger
122 do_test lastinsert-2.4 {
128 # ----------------------------------------------------------------------------
129 # 3.x - tests with after update trigger
131 # LIRID not changed after an update onto a table containing an after trigger
132 do_test lastinsert-3.1 {
136 create trigger r1 after update on t1 for each row begin
137 insert into t2 values (NEW.k*2, last_insert_rowid(), NULL, NULL);
138 update t2 set k=k+10, val2=100+last_insert_rowid();
139 update t2 set val3=1000+last_insert_rowid();
141 update t1 set k=14 where k=3;
142 select last_insert_rowid();
146 # LIRID unchanged upon entry into after update trigger
147 do_test lastinsert-3.2 {
153 # LIRID changed properly by insert within context of after update trigger
154 do_test lastinsert-3.3 {
160 # LIRID unchanged by update within context of after update trigger
161 do_test lastinsert-3.4 {
167 # ----------------------------------------------------------------------------
168 # 4.x - tests with instead of insert trigger
169 # These may not be run if either views or triggers were disabled at
172 ifcapable {view && trigger} {
173 # LIRID not changed after an insert into view containing an instead of trigger
174 do_test lastinsert-4.1 {
178 create trigger r1 instead of insert on v for each row begin
179 insert into t2 values (NEW.k*2, last_insert_rowid(), NULL, NULL);
180 update t2 set k=k+10, val2=100+last_insert_rowid();
181 update t2 set val3=1000+last_insert_rowid();
183 insert into v values (15);
184 select last_insert_rowid();
188 # LIRID unchanged upon entry into instead of trigger
189 do_test lastinsert-4.2 {
195 # LIRID changed properly by insert within context of instead of trigger
196 do_test lastinsert-4.3 {
202 # LIRID unchanged by update within context of instead of trigger
203 do_test lastinsert-4.4 {
208 } ;# ifcapable (view && trigger)
210 # ----------------------------------------------------------------------------
211 # 5.x - tests with before delete trigger
213 # LIRID not changed after a delete on a table containing a before trigger
214 do_test lastinsert-5.1 {
216 drop trigger r1; -- This was not created if views are disabled.
220 create trigger r1 before delete on t1 for each row begin
221 insert into t2 values (77, last_insert_rowid(), NULL, NULL);
222 update t2 set k=k+10, val2=100+last_insert_rowid();
223 update t2 set val3=1000+last_insert_rowid();
225 delete from t1 where k=1;
226 select last_insert_rowid();
230 # LIRID unchanged upon entry into delete trigger
231 do_test lastinsert-5.2 {
237 # LIRID changed properly by insert within context of delete trigger
238 do_test lastinsert-5.3 {
244 # LIRID unchanged by update within context of delete trigger
245 do_test lastinsert-5.4 {
251 # ----------------------------------------------------------------------------
252 # 6.x - tests with instead of update trigger
253 # These tests may not run if either views or triggers are disabled.
255 ifcapable {view && trigger} {
256 # LIRID not changed after an update on a view containing an instead of trigger
257 do_test lastinsert-6.1 {
261 create trigger r1 instead of update on v for each row begin
262 insert into t2 values (NEW.k*2, last_insert_rowid(), NULL, NULL);
263 update t2 set k=k+10, val2=100+last_insert_rowid();
264 update t2 set val3=1000+last_insert_rowid();
266 update v set k=16 where k=14;
267 select last_insert_rowid();
271 # LIRID unchanged upon entry into instead of trigger
272 do_test lastinsert-6.2 {
278 # LIRID changed properly by insert within context of instead of trigger
279 do_test lastinsert-6.3 {
285 # LIRID unchanged by update within context of instead of trigger
286 do_test lastinsert-6.4 {
291 } ;# ifcapable (view && trigger)
293 # ----------------------------------------------------------------------------
294 # 7.x - complex tests with temporary tables and nested instead of triggers
295 # These do not run if views or triggers are disabled.
297 ifcapable {trigger && view && tempdb} {
298 do_test lastinsert-7.1 {
300 drop table t1; drop table t2; drop trigger r1;
301 create temp table t1 (k integer primary key);
302 create temp table t2 (k integer primary key);
303 create temp view v1 as select * from t1;
304 create temp view v2 as select * from t2;
305 create temp table rid (k integer primary key, rin, rout);
306 insert into rid values (1, NULL, NULL);
307 insert into rid values (2, NULL, NULL);
308 create temp trigger r1 instead of insert on v1 for each row begin
309 update rid set rin=last_insert_rowid() where k=1;
310 insert into t1 values (100+NEW.k);
311 insert into v2 values (100+last_insert_rowid());
312 update rid set rout=last_insert_rowid() where k=1;
314 create temp trigger r2 instead of insert on v2 for each row begin
315 update rid set rin=last_insert_rowid() where k=2;
316 insert into t2 values (1000+NEW.k);
317 update rid set rout=last_insert_rowid() where k=2;
319 insert into t1 values (77);
320 select last_insert_rowid();
324 do_test lastinsert-7.2 {
326 insert into v1 values (5);
327 select last_insert_rowid();
331 do_test lastinsert-7.3 {
333 select rin from rid where k=1;
337 do_test lastinsert-7.4 {
339 select rout from rid where k=1;
343 do_test lastinsert-7.5 {
345 select rin from rid where k=2;
349 do_test lastinsert-7.6 {
351 select rout from rid where k=2;
355 do_test lastinsert-8.1 {
359 CREATE TABLE t2(x INTEGER PRIMARY KEY, y);
360 CREATE TABLE t3(a, b);
361 CREATE TRIGGER after_t2 AFTER INSERT ON t2 BEGIN
362 INSERT INTO t3 VALUES(new.x, new.y);
364 INSERT INTO t2 VALUES(5000000000, 1);
365 SELECT last_insert_rowid();
369 do_test lastinsert-9.1 {
370 db eval {INSERT INTO t2 VALUES(123456789012345,0)}
375 } ;# ifcapable (view && trigger)