xref: /sqlite-3.40.0/test/lastinsert.test (revision ef5ecb41)
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# ----------------------------------------------------------------------------
65# 2.x - tests with after insert trigger
66
67# LIRID changed properly after an insert into table containing an after trigger
68do_test lastinsert-2.1 {
69    catchsql {
70        delete from t2;
71        create trigger r1 after insert on t1 for each row begin
72            insert into t2 values (NEW.k*2, last_insert_rowid(), NULL, NULL);
73            update t2 set k=k+10, val2=100+last_insert_rowid();
74            update t2 set val3=1000+last_insert_rowid();
75        end;
76        insert into t1 values (13);
77        select last_insert_rowid();
78    }
79} {0 13}
80
81# LIRID equals NEW.k upon entry into after insert trigger
82do_test lastinsert-2.2 {
83    catchsql {
84        select val1 from t2;
85    }
86} {0 13}
87
88# LIRID changed properly by insert within context of after insert trigger
89do_test lastinsert-2.3 {
90    catchsql {
91        select val2 from t2;
92    }
93} {0 126}
94
95# LIRID unchanged by update within context of after insert trigger
96do_test lastinsert-2.4 {
97    catchsql {
98        select val3 from t2;
99    }
100} {0 1026}
101
102# ----------------------------------------------------------------------------
103# 3.x - tests with after update trigger
104
105# LIRID not changed after an update onto a table containing an after trigger
106do_test lastinsert-3.1 {
107    catchsql {
108        delete from t2;
109        drop trigger r1;
110        create trigger r1 after update on t1 for each row begin
111            insert into t2 values (NEW.k*2, last_insert_rowid(), NULL, NULL);
112            update t2 set k=k+10, val2=100+last_insert_rowid();
113            update t2 set val3=1000+last_insert_rowid();
114        end;
115        update t1 set k=14 where k=3;
116        select last_insert_rowid();
117    }
118} {0 13}
119
120# LIRID unchanged upon entry into after update trigger
121do_test lastinsert-3.2 {
122    catchsql {
123        select val1 from t2;
124    }
125} {0 13}
126
127# LIRID changed properly by insert within context of after update trigger
128do_test lastinsert-3.3 {
129    catchsql {
130        select val2 from t2;
131    }
132} {0 128}
133
134# LIRID unchanged by update within context of after update trigger
135do_test lastinsert-3.4 {
136    catchsql {
137        select val3 from t2;
138    }
139} {0 1028}
140
141# ----------------------------------------------------------------------------
142# 4.x - tests with instead of insert trigger
143
144# LIRID not changed after an insert into view containing an instead of trigger
145do_test lastinsert-4.1 {
146    catchsql {
147        delete from t2;
148        drop trigger r1;
149        create trigger r1 instead of insert on v for each row begin
150            insert into t2 values (NEW.k*2, last_insert_rowid(), NULL, NULL);
151            update t2 set k=k+10, val2=100+last_insert_rowid();
152            update t2 set val3=1000+last_insert_rowid();
153        end;
154        insert into v values (15);
155        select last_insert_rowid();
156    }
157} {0 13}
158
159# LIRID unchanged upon entry into instead of trigger
160do_test lastinsert-4.2 {
161    catchsql {
162        select val1 from t2;
163    }
164} {0 13}
165
166# LIRID changed properly by insert within context of instead of trigger
167do_test lastinsert-4.3 {
168    catchsql {
169        select val2 from t2;
170    }
171} {0 130}
172
173# LIRID unchanged by update within context of instead of trigger
174do_test lastinsert-4.4 {
175    catchsql {
176        select val3 from t2;
177    }
178} {0 1030}
179
180# ----------------------------------------------------------------------------
181# 5.x - tests with before delete trigger
182
183# LIRID not changed after a delete on a table containing a before trigger
184do_test lastinsert-5.1 {
185    catchsql {
186        delete from t2;
187        drop trigger r1;
188        create trigger r1 before delete on t1 for each row begin
189            insert into t2 values (77, last_insert_rowid(), NULL, NULL);
190            update t2 set k=k+10, val2=100+last_insert_rowid();
191            update t2 set val3=1000+last_insert_rowid();
192        end;
193        delete from t1 where k=1;
194        select last_insert_rowid();
195    }
196} {0 13}
197
198# LIRID unchanged upon entry into delete trigger
199do_test lastinsert-5.2 {
200    catchsql {
201        select val1 from t2;
202    }
203} {0 13}
204
205# LIRID changed properly by insert within context of delete trigger
206do_test lastinsert-5.3 {
207    catchsql {
208        select val2 from t2;
209    }
210} {0 177}
211
212# LIRID unchanged by update within context of delete trigger
213do_test lastinsert-5.4 {
214    catchsql {
215        select val3 from t2;
216    }
217} {0 1077}
218
219# ----------------------------------------------------------------------------
220# 6.x - tests with instead of update trigger
221
222# LIRID not changed after an update on a view containing an instead of trigger
223do_test lastinsert-6.1 {
224    catchsql {
225        delete from t2;
226        drop trigger r1;
227        create trigger r1 instead of update on v for each row begin
228            insert into t2 values (NEW.k*2, last_insert_rowid(), NULL, NULL);
229            update t2 set k=k+10, val2=100+last_insert_rowid();
230            update t2 set val3=1000+last_insert_rowid();
231        end;
232        update v set k=16 where k=14;
233        select last_insert_rowid();
234    }
235} {0 13}
236
237# LIRID unchanged upon entry into instead of trigger
238do_test lastinsert-6.2 {
239    catchsql {
240        select val1 from t2;
241    }
242} {0 13}
243
244# LIRID changed properly by insert within context of instead of trigger
245do_test lastinsert-6.3 {
246    catchsql {
247        select val2 from t2;
248    }
249} {0 132}
250
251# LIRID unchanged by update within context of instead of trigger
252do_test lastinsert-6.4 {
253    catchsql {
254        select val3 from t2;
255    }
256} {0 1032}
257
258# ----------------------------------------------------------------------------
259# 7.x - complex tests with temporary tables and nested instead of triggers
260
261do_test lastinsert-7.1 {
262    catchsql {
263        drop table t1; drop table t2; drop trigger r1;
264        create temp table t1 (k integer primary key);
265        create temp table t2 (k integer primary key);
266        create temp view v1 as select * from t1;
267        create temp view v2 as select * from t2;
268        create temp table rid (k integer primary key, rin, rout);
269        insert into rid values (1, NULL, NULL);
270        insert into rid values (2, NULL, NULL);
271        create temp trigger r1 instead of insert on v1 for each row begin
272            update rid set rin=last_insert_rowid() where k=1;
273            insert into t1 values (100+NEW.k);
274            insert into v2 values (100+last_insert_rowid());
275            update rid set rout=last_insert_rowid() where k=1;
276        end;
277        create temp trigger r2 instead of insert on v2 for each row begin
278            update rid set rin=last_insert_rowid() where k=2;
279            insert into t2 values (1000+NEW.k);
280            update rid set rout=last_insert_rowid() where k=2;
281        end;
282        insert into t1 values (77);
283        select last_insert_rowid();
284    }
285} {0 77}
286
287do_test lastinsert-7.2 {
288    catchsql {
289        insert into v1 values (5);
290        select last_insert_rowid();
291    }
292} {0 77}
293
294do_test lastinsert-7.3 {
295    catchsql {
296        select rin from rid where k=1;
297    }
298} {0 77}
299
300do_test lastinsert-7.4 {
301    catchsql {
302        select rout from rid where k=1;
303    }
304} {0 105}
305
306do_test lastinsert-7.5 {
307    catchsql {
308        select rin from rid where k=2;
309    }
310} {0 105}
311
312do_test lastinsert-7.6 {
313    catchsql {
314        select rout from rid where k=2;
315    }
316} {0 1205}
317
318finish_test
319
320