xref: /sqlite-3.40.0/test/lastinsert.test (revision ef1bd970)
1a503d731Srdc# The author disclaims copyright to this source code.  In place of
2a503d731Srdc# a legal notice, here is a blessing:
3a503d731Srdc#
4a503d731Srdc#    May you do good and not evil.
5a503d731Srdc#    May you find forgiveness for yourself and forgive others.
6a503d731Srdc#    May you share freely, never taking more than you give.
7a503d731Srdc#
8a503d731Srdc#***********************************************************************
9a503d731Srdc#
10a503d731Srdc# Tests to make sure that value returned by last_insert_rowid() (LIRID)
11a503d731Srdc# is updated properly, especially inside triggers
12a503d731Srdc#
13a503d731Srdc# Note 1: insert into table is now the only statement which changes LIRID
14a503d731Srdc# Note 2: upon entry into before or instead of triggers,
15a503d731Srdc#           LIRID is unchanged (rather than -1)
16a503d731Srdc# Note 3: LIRID is changed within the context of a trigger,
17a503d731Srdc#           but is restored once the trigger exits
18a503d731Srdc# Note 4: LIRID is not changed by an insert into a view (since everything
19a503d731Srdc#           is done within instead of trigger context)
20a503d731Srdc#
21a503d731Srdc
22a503d731Srdcset testdir [file dirname $argv0]
23a503d731Srdcsource $testdir/tester.tcl
24a503d731Srdc
25a503d731Srdc# ----------------------------------------------------------------------------
26a503d731Srdc# 1.x - basic tests (no triggers)
27a503d731Srdc
28a503d731Srdc# LIRID changed properly after an insert into a table
29a503d731Srdcdo_test lastinsert-1.1 {
30a503d731Srdc    catchsql {
31a503d731Srdc        create table t1 (k integer primary key);
32a503d731Srdc        insert into t1 values (1);
33a503d731Srdc        insert into t1 values (NULL);
34a503d731Srdc        insert into t1 values (NULL);
35a503d731Srdc        select last_insert_rowid();
36a503d731Srdc    }
37a503d731Srdc} {0 3}
38a503d731Srdc
39*ef1bd970Sdrh# EVIDENCE-OF: R-47220-63683 The sqlite3_last_insert_rowid() function
40*ef1bd970Sdrh# does not work for WITHOUT ROWID tables.
41*ef1bd970Sdrh#
42*ef1bd970Sdrhdo_test lastinsert-1.1w {
43*ef1bd970Sdrh    catchsql {
44*ef1bd970Sdrh        create table t1w (k integer primary key) WITHOUT ROWID;
45*ef1bd970Sdrh        insert into t1w values (123456);
46*ef1bd970Sdrh        select last_insert_rowid(); -- returns 3 from above.
47*ef1bd970Sdrh    }
48*ef1bd970Sdrh} {0 3}
49*ef1bd970Sdrh
50a503d731Srdc# LIRID unchanged after an update on a table
51a503d731Srdcdo_test lastinsert-1.2 {
52a503d731Srdc    catchsql {
53a503d731Srdc        update t1 set k=4 where k=2;
54a503d731Srdc        select last_insert_rowid();
55a503d731Srdc    }
56a503d731Srdc} {0 3}
57a503d731Srdc
58a503d731Srdc# LIRID unchanged after a delete from a table
59a503d731Srdcdo_test lastinsert-1.3 {
60a503d731Srdc    catchsql {
61a503d731Srdc        delete from t1 where k=4;
62a503d731Srdc        select last_insert_rowid();
63a503d731Srdc    }
64a503d731Srdc} {0 3}
65a503d731Srdc
66a503d731Srdc# LIRID unchanged after create table/view statements
670fa8ddbdSdanielk1977do_test lastinsert-1.4.1 {
68a503d731Srdc    catchsql {
69a503d731Srdc        create table t2 (k integer primary key, val1, val2, val3);
700fa8ddbdSdanielk1977        select last_insert_rowid();
710fa8ddbdSdanielk1977    }
720fa8ddbdSdanielk1977} {0 3}
730fa8ddbdSdanielk1977ifcapable view {
740fa8ddbdSdanielk1977do_test lastinsert-1.4.2 {
750fa8ddbdSdanielk1977    catchsql {
76a503d731Srdc        create view v as select * from t1;
77a503d731Srdc        select last_insert_rowid();
78a503d731Srdc    }
79a503d731Srdc} {0 3}
800fa8ddbdSdanielk1977} ;# ifcapable view
81a503d731Srdc
82798da52cSdrh# All remaining tests involve triggers.  Skip them if triggers are not
83798da52cSdrh# supported in this build.
84798da52cSdrh#
85798da52cSdrhifcapable {!trigger} {
86798da52cSdrh  finish_test
87798da52cSdrh  return
88798da52cSdrh}
89798da52cSdrh
90a503d731Srdc# ----------------------------------------------------------------------------
91a503d731Srdc# 2.x - tests with after insert trigger
92a503d731Srdc
93a503d731Srdc# LIRID changed properly after an insert into table containing an after trigger
94a503d731Srdcdo_test lastinsert-2.1 {
95a503d731Srdc    catchsql {
96a503d731Srdc        delete from t2;
97a503d731Srdc        create trigger r1 after insert on t1 for each row begin
98a503d731Srdc            insert into t2 values (NEW.k*2, last_insert_rowid(), NULL, NULL);
99a503d731Srdc            update t2 set k=k+10, val2=100+last_insert_rowid();
100a503d731Srdc            update t2 set val3=1000+last_insert_rowid();
101a503d731Srdc        end;
102a503d731Srdc        insert into t1 values (13);
103a503d731Srdc        select last_insert_rowid();
104a503d731Srdc    }
105a503d731Srdc} {0 13}
106a503d731Srdc
107a503d731Srdc# LIRID equals NEW.k upon entry into after insert trigger
108a503d731Srdcdo_test lastinsert-2.2 {
109a503d731Srdc    catchsql {
110a503d731Srdc        select val1 from t2;
111a503d731Srdc    }
112a503d731Srdc} {0 13}
113a503d731Srdc
114a503d731Srdc# LIRID changed properly by insert within context of after insert trigger
115a503d731Srdcdo_test lastinsert-2.3 {
116a503d731Srdc    catchsql {
117a503d731Srdc        select val2 from t2;
118a503d731Srdc    }
119a503d731Srdc} {0 126}
120a503d731Srdc
121a503d731Srdc# LIRID unchanged by update within context of after insert trigger
122a503d731Srdcdo_test lastinsert-2.4 {
123a503d731Srdc    catchsql {
124a503d731Srdc        select val3 from t2;
125a503d731Srdc    }
126a503d731Srdc} {0 1026}
127a503d731Srdc
128a503d731Srdc# ----------------------------------------------------------------------------
129a503d731Srdc# 3.x - tests with after update trigger
130a503d731Srdc
131a503d731Srdc# LIRID not changed after an update onto a table containing an after trigger
132a503d731Srdcdo_test lastinsert-3.1 {
133a503d731Srdc    catchsql {
134a503d731Srdc        delete from t2;
135a503d731Srdc        drop trigger r1;
136a503d731Srdc        create trigger r1 after update on t1 for each row begin
137a503d731Srdc            insert into t2 values (NEW.k*2, last_insert_rowid(), NULL, NULL);
138a503d731Srdc            update t2 set k=k+10, val2=100+last_insert_rowid();
139a503d731Srdc            update t2 set val3=1000+last_insert_rowid();
140a503d731Srdc        end;
141a503d731Srdc        update t1 set k=14 where k=3;
142a503d731Srdc        select last_insert_rowid();
143a503d731Srdc    }
144a503d731Srdc} {0 13}
145a503d731Srdc
146a503d731Srdc# LIRID unchanged upon entry into after update trigger
147a503d731Srdcdo_test lastinsert-3.2 {
148a503d731Srdc    catchsql {
149a503d731Srdc        select val1 from t2;
150a503d731Srdc    }
151a503d731Srdc} {0 13}
152a503d731Srdc
153a503d731Srdc# LIRID changed properly by insert within context of after update trigger
154a503d731Srdcdo_test lastinsert-3.3 {
155a503d731Srdc    catchsql {
156a503d731Srdc        select val2 from t2;
157a503d731Srdc    }
158a503d731Srdc} {0 128}
159a503d731Srdc
160a503d731Srdc# LIRID unchanged by update within context of after update trigger
161a503d731Srdcdo_test lastinsert-3.4 {
162a503d731Srdc    catchsql {
163a503d731Srdc        select val3 from t2;
164a503d731Srdc    }
165a503d731Srdc} {0 1028}
166a503d731Srdc
167a503d731Srdc# ----------------------------------------------------------------------------
168a503d731Srdc# 4.x - tests with instead of insert trigger
1690fa8ddbdSdanielk1977# These may not be run if either views or triggers were disabled at
1700fa8ddbdSdanielk1977# compile-time
171a503d731Srdc
1720fa8ddbdSdanielk1977ifcapable {view && trigger} {
173a503d731Srdc# LIRID not changed after an insert into view containing an instead of trigger
174a503d731Srdcdo_test lastinsert-4.1 {
175a503d731Srdc    catchsql {
176a503d731Srdc        delete from t2;
177a503d731Srdc        drop trigger r1;
178a503d731Srdc        create trigger r1 instead of insert on v for each row begin
179a503d731Srdc            insert into t2 values (NEW.k*2, last_insert_rowid(), NULL, NULL);
180a503d731Srdc            update t2 set k=k+10, val2=100+last_insert_rowid();
181a503d731Srdc            update t2 set val3=1000+last_insert_rowid();
182a503d731Srdc        end;
183a503d731Srdc        insert into v values (15);
184a503d731Srdc        select last_insert_rowid();
185a503d731Srdc    }
186a503d731Srdc} {0 13}
187a503d731Srdc
188a503d731Srdc# LIRID unchanged upon entry into instead of trigger
189a503d731Srdcdo_test lastinsert-4.2 {
190a503d731Srdc    catchsql {
191a503d731Srdc        select val1 from t2;
192a503d731Srdc    }
193a503d731Srdc} {0 13}
194a503d731Srdc
195a503d731Srdc# LIRID changed properly by insert within context of instead of trigger
196a503d731Srdcdo_test lastinsert-4.3 {
197a503d731Srdc    catchsql {
198a503d731Srdc        select val2 from t2;
199a503d731Srdc    }
200a503d731Srdc} {0 130}
201a503d731Srdc
202a503d731Srdc# LIRID unchanged by update within context of instead of trigger
203a503d731Srdcdo_test lastinsert-4.4 {
204a503d731Srdc    catchsql {
205a503d731Srdc        select val3 from t2;
206a503d731Srdc    }
207a503d731Srdc} {0 1030}
2080fa8ddbdSdanielk1977} ;# ifcapable (view && trigger)
209a503d731Srdc
210a503d731Srdc# ----------------------------------------------------------------------------
211a503d731Srdc# 5.x - tests with before delete trigger
212a503d731Srdc
213a503d731Srdc# LIRID not changed after a delete on a table containing a before trigger
214a503d731Srdcdo_test lastinsert-5.1 {
215a503d731Srdc    catchsql {
2160fa8ddbdSdanielk1977      drop trigger r1;  -- This was not created if views are disabled.
2170fa8ddbdSdanielk1977    }
2180fa8ddbdSdanielk1977    catchsql {
219a503d731Srdc        delete from t2;
220a503d731Srdc        create trigger r1 before delete on t1 for each row begin
221a503d731Srdc            insert into t2 values (77, last_insert_rowid(), NULL, NULL);
222a503d731Srdc            update t2 set k=k+10, val2=100+last_insert_rowid();
223a503d731Srdc            update t2 set val3=1000+last_insert_rowid();
224a503d731Srdc        end;
225a503d731Srdc        delete from t1 where k=1;
226a503d731Srdc        select last_insert_rowid();
227a503d731Srdc    }
228a503d731Srdc} {0 13}
229a503d731Srdc
230a503d731Srdc# LIRID unchanged upon entry into delete trigger
231a503d731Srdcdo_test lastinsert-5.2 {
232a503d731Srdc    catchsql {
233a503d731Srdc        select val1 from t2;
234a503d731Srdc    }
235a503d731Srdc} {0 13}
236a503d731Srdc
237a503d731Srdc# LIRID changed properly by insert within context of delete trigger
238a503d731Srdcdo_test lastinsert-5.3 {
239a503d731Srdc    catchsql {
240a503d731Srdc        select val2 from t2;
241a503d731Srdc    }
242a503d731Srdc} {0 177}
243a503d731Srdc
244a503d731Srdc# LIRID unchanged by update within context of delete trigger
245a503d731Srdcdo_test lastinsert-5.4 {
246a503d731Srdc    catchsql {
247a503d731Srdc        select val3 from t2;
248a503d731Srdc    }
249a503d731Srdc} {0 1077}
250a503d731Srdc
251a503d731Srdc# ----------------------------------------------------------------------------
252a503d731Srdc# 6.x - tests with instead of update trigger
2530fa8ddbdSdanielk1977# These tests may not run if either views or triggers are disabled.
254a503d731Srdc
2550fa8ddbdSdanielk1977ifcapable {view && trigger} {
256a503d731Srdc# LIRID not changed after an update on a view containing an instead of trigger
257a503d731Srdcdo_test lastinsert-6.1 {
258a503d731Srdc    catchsql {
259a503d731Srdc        delete from t2;
260a503d731Srdc        drop trigger r1;
261a503d731Srdc        create trigger r1 instead of update on v for each row begin
262a503d731Srdc            insert into t2 values (NEW.k*2, last_insert_rowid(), NULL, NULL);
263a503d731Srdc            update t2 set k=k+10, val2=100+last_insert_rowid();
264a503d731Srdc            update t2 set val3=1000+last_insert_rowid();
265a503d731Srdc        end;
266a503d731Srdc        update v set k=16 where k=14;
267a503d731Srdc        select last_insert_rowid();
268a503d731Srdc    }
269a503d731Srdc} {0 13}
270a503d731Srdc
271a503d731Srdc# LIRID unchanged upon entry into instead of trigger
272a503d731Srdcdo_test lastinsert-6.2 {
273a503d731Srdc    catchsql {
274a503d731Srdc        select val1 from t2;
275a503d731Srdc    }
276a503d731Srdc} {0 13}
277a503d731Srdc
278a503d731Srdc# LIRID changed properly by insert within context of instead of trigger
279a503d731Srdcdo_test lastinsert-6.3 {
280a503d731Srdc    catchsql {
281a503d731Srdc        select val2 from t2;
282a503d731Srdc    }
283a503d731Srdc} {0 132}
284a503d731Srdc
285a503d731Srdc# LIRID unchanged by update within context of instead of trigger
286a503d731Srdcdo_test lastinsert-6.4 {
287a503d731Srdc    catchsql {
288a503d731Srdc        select val3 from t2;
289a503d731Srdc    }
290a503d731Srdc} {0 1032}
2910fa8ddbdSdanielk1977} ;# ifcapable (view && trigger)
292a503d731Srdc
293a503d731Srdc# ----------------------------------------------------------------------------
294a503d731Srdc# 7.x - complex tests with temporary tables and nested instead of triggers
2950fa8ddbdSdanielk1977# These do not run if views or triggers are disabled.
296a503d731Srdc
29753c0f748Sdanielk1977ifcapable {trigger && view && tempdb} {
298a503d731Srdcdo_test lastinsert-7.1 {
299a503d731Srdc    catchsql {
300a503d731Srdc        drop table t1; drop table t2; drop trigger r1;
301a503d731Srdc        create temp table t1 (k integer primary key);
302a503d731Srdc        create temp table t2 (k integer primary key);
303a503d731Srdc        create temp view v1 as select * from t1;
304a503d731Srdc        create temp view v2 as select * from t2;
305a503d731Srdc        create temp table rid (k integer primary key, rin, rout);
306a503d731Srdc        insert into rid values (1, NULL, NULL);
307a503d731Srdc        insert into rid values (2, NULL, NULL);
308a503d731Srdc        create temp trigger r1 instead of insert on v1 for each row begin
309a503d731Srdc            update rid set rin=last_insert_rowid() where k=1;
310a503d731Srdc            insert into t1 values (100+NEW.k);
311a503d731Srdc            insert into v2 values (100+last_insert_rowid());
312a503d731Srdc            update rid set rout=last_insert_rowid() where k=1;
313a503d731Srdc        end;
314a503d731Srdc        create temp trigger r2 instead of insert on v2 for each row begin
315a503d731Srdc            update rid set rin=last_insert_rowid() where k=2;
316a503d731Srdc            insert into t2 values (1000+NEW.k);
317a503d731Srdc            update rid set rout=last_insert_rowid() where k=2;
318a503d731Srdc        end;
319a503d731Srdc        insert into t1 values (77);
320a503d731Srdc        select last_insert_rowid();
321a503d731Srdc    }
322a503d731Srdc} {0 77}
323a503d731Srdc
324a503d731Srdcdo_test lastinsert-7.2 {
325a503d731Srdc    catchsql {
326a503d731Srdc        insert into v1 values (5);
327a503d731Srdc        select last_insert_rowid();
328a503d731Srdc    }
329a503d731Srdc} {0 77}
330a503d731Srdc
331a503d731Srdcdo_test lastinsert-7.3 {
332a503d731Srdc    catchsql {
333a503d731Srdc        select rin from rid where k=1;
334a503d731Srdc    }
335a503d731Srdc} {0 77}
336a503d731Srdc
337a503d731Srdcdo_test lastinsert-7.4 {
338a503d731Srdc    catchsql {
339a503d731Srdc        select rout from rid where k=1;
340a503d731Srdc    }
341a503d731Srdc} {0 105}
342a503d731Srdc
343a503d731Srdcdo_test lastinsert-7.5 {
344a503d731Srdc    catchsql {
345a503d731Srdc        select rin from rid where k=2;
346a503d731Srdc    }
347a503d731Srdc} {0 105}
348a503d731Srdc
349a503d731Srdcdo_test lastinsert-7.6 {
350a503d731Srdc    catchsql {
351a503d731Srdc        select rout from rid where k=2;
352a503d731Srdc    }
353a503d731Srdc} {0 1205}
354a503d731Srdc
35594c1f6f7Sdrhdo_test lastinsert-8.1 {
35694c1f6f7Sdrh  db close
35794c1f6f7Sdrh  sqlite3 db test.db
35894c1f6f7Sdrh  execsql {
35994c1f6f7Sdrh    CREATE TABLE t2(x INTEGER PRIMARY KEY, y);
36094c1f6f7Sdrh    CREATE TABLE t3(a, b);
36194c1f6f7Sdrh    CREATE TRIGGER after_t2 AFTER INSERT ON t2 BEGIN
36294c1f6f7Sdrh      INSERT INTO t3 VALUES(new.x, new.y);
36394c1f6f7Sdrh    END;
36494c1f6f7Sdrh    INSERT INTO t2 VALUES(5000000000, 1);
36594c1f6f7Sdrh    SELECT last_insert_rowid();
36694c1f6f7Sdrh  }
36794c1f6f7Sdrh} 5000000000
36894c1f6f7Sdrh
369f7e678d6Sdrhdo_test lastinsert-9.1 {
370f7e678d6Sdrh  db eval {INSERT INTO t2 VALUES(123456789012345,0)}
371f7e678d6Sdrh  db last_insert_rowid
372f7e678d6Sdrh} {123456789012345}
373f7e678d6Sdrh
37494c1f6f7Sdrh
3750fa8ddbdSdanielk1977} ;# ifcapable (view && trigger)
3760fa8ddbdSdanielk1977
377a503d731Srdcfinish_test
378