xref: /sqlite-3.40.0/test/lastinsert.test (revision 798da52c)
1# The author disclaims copyright to this source code.  In place of
2# a legal notice, here is a blessing:
3#
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.
7#
8#***********************************************************************
9#
10# Tests to make sure that value returned by last_insert_rowid() (LIRID)
11# is updated properly, especially inside triggers
12#
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)
20#
21
22set testdir [file dirname $argv0]
23source $testdir/tester.tcl
24
25# ----------------------------------------------------------------------------
26# 1.x - basic tests (no triggers)
27
28# LIRID changed properly after an insert into a table
29do_test lastinsert-1.1 {
30    catchsql {
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();
36    }
37} {0 3}
38
39# LIRID unchanged after an update on a table
40do_test lastinsert-1.2 {
41    catchsql {
42        update t1 set k=4 where k=2;
43        select last_insert_rowid();
44    }
45} {0 3}
46
47# LIRID unchanged after a delete from a table
48do_test lastinsert-1.3 {
49    catchsql {
50        delete from t1 where k=4;
51        select last_insert_rowid();
52    }
53} {0 3}
54
55# LIRID unchanged after create table/view statements
56do_test lastinsert-1.4 {
57    catchsql {
58        create table t2 (k integer primary key, val1, val2, val3);
59        create view v as select * from t1;
60        select last_insert_rowid();
61    }
62} {0 3}
63
64# All remaining tests involve triggers.  Skip them if triggers are not
65# supported in this build.
66#
67ifcapable {!trigger} {
68  finish_test
69  return
70}
71
72# ----------------------------------------------------------------------------
73# 2.x - tests with after insert trigger
74
75# LIRID changed properly after an insert into table containing an after trigger
76do_test lastinsert-2.1 {
77    catchsql {
78        delete from t2;
79        create trigger r1 after insert on t1 for each row begin
80            insert into t2 values (NEW.k*2, last_insert_rowid(), NULL, NULL);
81            update t2 set k=k+10, val2=100+last_insert_rowid();
82            update t2 set val3=1000+last_insert_rowid();
83        end;
84        insert into t1 values (13);
85        select last_insert_rowid();
86    }
87} {0 13}
88
89# LIRID equals NEW.k upon entry into after insert trigger
90do_test lastinsert-2.2 {
91    catchsql {
92        select val1 from t2;
93    }
94} {0 13}
95
96# LIRID changed properly by insert within context of after insert trigger
97do_test lastinsert-2.3 {
98    catchsql {
99        select val2 from t2;
100    }
101} {0 126}
102
103# LIRID unchanged by update within context of after insert trigger
104do_test lastinsert-2.4 {
105    catchsql {
106        select val3 from t2;
107    }
108} {0 1026}
109
110# ----------------------------------------------------------------------------
111# 3.x - tests with after update trigger
112
113# LIRID not changed after an update onto a table containing an after trigger
114do_test lastinsert-3.1 {
115    catchsql {
116        delete from t2;
117        drop trigger r1;
118        create trigger r1 after update on t1 for each row begin
119            insert into t2 values (NEW.k*2, last_insert_rowid(), NULL, NULL);
120            update t2 set k=k+10, val2=100+last_insert_rowid();
121            update t2 set val3=1000+last_insert_rowid();
122        end;
123        update t1 set k=14 where k=3;
124        select last_insert_rowid();
125    }
126} {0 13}
127
128# LIRID unchanged upon entry into after update trigger
129do_test lastinsert-3.2 {
130    catchsql {
131        select val1 from t2;
132    }
133} {0 13}
134
135# LIRID changed properly by insert within context of after update trigger
136do_test lastinsert-3.3 {
137    catchsql {
138        select val2 from t2;
139    }
140} {0 128}
141
142# LIRID unchanged by update within context of after update trigger
143do_test lastinsert-3.4 {
144    catchsql {
145        select val3 from t2;
146    }
147} {0 1028}
148
149# ----------------------------------------------------------------------------
150# 4.x - tests with instead of insert trigger
151
152# LIRID not changed after an insert into view containing an instead of trigger
153do_test lastinsert-4.1 {
154    catchsql {
155        delete from t2;
156        drop trigger r1;
157        create trigger r1 instead of insert on v for each row begin
158            insert into t2 values (NEW.k*2, last_insert_rowid(), NULL, NULL);
159            update t2 set k=k+10, val2=100+last_insert_rowid();
160            update t2 set val3=1000+last_insert_rowid();
161        end;
162        insert into v values (15);
163        select last_insert_rowid();
164    }
165} {0 13}
166
167# LIRID unchanged upon entry into instead of trigger
168do_test lastinsert-4.2 {
169    catchsql {
170        select val1 from t2;
171    }
172} {0 13}
173
174# LIRID changed properly by insert within context of instead of trigger
175do_test lastinsert-4.3 {
176    catchsql {
177        select val2 from t2;
178    }
179} {0 130}
180
181# LIRID unchanged by update within context of instead of trigger
182do_test lastinsert-4.4 {
183    catchsql {
184        select val3 from t2;
185    }
186} {0 1030}
187
188# ----------------------------------------------------------------------------
189# 5.x - tests with before delete trigger
190
191# LIRID not changed after a delete on a table containing a before trigger
192do_test lastinsert-5.1 {
193    catchsql {
194        delete from t2;
195        drop trigger r1;
196        create trigger r1 before delete on t1 for each row begin
197            insert into t2 values (77, last_insert_rowid(), NULL, NULL);
198            update t2 set k=k+10, val2=100+last_insert_rowid();
199            update t2 set val3=1000+last_insert_rowid();
200        end;
201        delete from t1 where k=1;
202        select last_insert_rowid();
203    }
204} {0 13}
205
206# LIRID unchanged upon entry into delete trigger
207do_test lastinsert-5.2 {
208    catchsql {
209        select val1 from t2;
210    }
211} {0 13}
212
213# LIRID changed properly by insert within context of delete trigger
214do_test lastinsert-5.3 {
215    catchsql {
216        select val2 from t2;
217    }
218} {0 177}
219
220# LIRID unchanged by update within context of delete trigger
221do_test lastinsert-5.4 {
222    catchsql {
223        select val3 from t2;
224    }
225} {0 1077}
226
227# ----------------------------------------------------------------------------
228# 6.x - tests with instead of update trigger
229
230# LIRID not changed after an update on a view containing an instead of trigger
231do_test lastinsert-6.1 {
232    catchsql {
233        delete from t2;
234        drop trigger r1;
235        create trigger r1 instead of update on v for each row begin
236            insert into t2 values (NEW.k*2, last_insert_rowid(), NULL, NULL);
237            update t2 set k=k+10, val2=100+last_insert_rowid();
238            update t2 set val3=1000+last_insert_rowid();
239        end;
240        update v set k=16 where k=14;
241        select last_insert_rowid();
242    }
243} {0 13}
244
245# LIRID unchanged upon entry into instead of trigger
246do_test lastinsert-6.2 {
247    catchsql {
248        select val1 from t2;
249    }
250} {0 13}
251
252# LIRID changed properly by insert within context of instead of trigger
253do_test lastinsert-6.3 {
254    catchsql {
255        select val2 from t2;
256    }
257} {0 132}
258
259# LIRID unchanged by update within context of instead of trigger
260do_test lastinsert-6.4 {
261    catchsql {
262        select val3 from t2;
263    }
264} {0 1032}
265
266# ----------------------------------------------------------------------------
267# 7.x - complex tests with temporary tables and nested instead of triggers
268
269do_test lastinsert-7.1 {
270    catchsql {
271        drop table t1; drop table t2; drop trigger r1;
272        create temp table t1 (k integer primary key);
273        create temp table t2 (k integer primary key);
274        create temp view v1 as select * from t1;
275        create temp view v2 as select * from t2;
276        create temp table rid (k integer primary key, rin, rout);
277        insert into rid values (1, NULL, NULL);
278        insert into rid values (2, NULL, NULL);
279        create temp trigger r1 instead of insert on v1 for each row begin
280            update rid set rin=last_insert_rowid() where k=1;
281            insert into t1 values (100+NEW.k);
282            insert into v2 values (100+last_insert_rowid());
283            update rid set rout=last_insert_rowid() where k=1;
284        end;
285        create temp trigger r2 instead of insert on v2 for each row begin
286            update rid set rin=last_insert_rowid() where k=2;
287            insert into t2 values (1000+NEW.k);
288            update rid set rout=last_insert_rowid() where k=2;
289        end;
290        insert into t1 values (77);
291        select last_insert_rowid();
292    }
293} {0 77}
294
295do_test lastinsert-7.2 {
296    catchsql {
297        insert into v1 values (5);
298        select last_insert_rowid();
299    }
300} {0 77}
301
302do_test lastinsert-7.3 {
303    catchsql {
304        select rin from rid where k=1;
305    }
306} {0 77}
307
308do_test lastinsert-7.4 {
309    catchsql {
310        select rout from rid where k=1;
311    }
312} {0 105}
313
314do_test lastinsert-7.5 {
315    catchsql {
316        select rin from rid where k=2;
317    }
318} {0 105}
319
320do_test lastinsert-7.6 {
321    catchsql {
322        select rout from rid where k=2;
323    }
324} {0 1205}
325
326finish_test
327