blob: 75b16daa102c87cf2f6bd4242640ab28d12ff599 [file] [log] [blame]
drhf3388142004-11-13 03:48:06 +00001# 2004 November 12
2#
3# The author disclaims copyright to this source code. In place of
4# a legal notice, here is a blessing:
5#
6# May you do good and not evil.
7# May you find forgiveness for yourself and forgive others.
8# May you share freely, never taking more than you give.
9#
10#*************************************************************************
11# This file implements regression tests for SQLite library. The
12# focus of this script is testing the AUTOINCREMENT features.
13#
drh0b9f50d2009-06-23 20:28:53 +000014# $Id: autoinc.test,v 1.14 2009/06/23 20:28:54 drh Exp $
drhf3388142004-11-13 03:48:06 +000015#
16
17set testdir [file dirname $argv0]
18source $testdir/tester.tcl
19
20# If the library is not compiled with autoincrement support then
21# skip all tests in this file.
22#
23ifcapable {!autoinc} {
24 finish_test
25 return
26}
27
dan867e6de2018-05-29 16:37:12 +000028if {[permutation]=="inmemory_journal"} {
29 finish_test
30 return
31}
32
dan165921a2009-08-28 18:53:45 +000033sqlite3_db_config_lookaside db 0 0 0
34
drhf3388142004-11-13 03:48:06 +000035# The database is initially empty.
36#
37do_test autoinc-1.1 {
38 execsql {
39 SELECT name FROM sqlite_master WHERE type='table';
40 }
41} {}
42
43# Add a table with the AUTOINCREMENT feature. Verify that the
44# SQLITE_SEQUENCE table gets created.
45#
46do_test autoinc-1.2 {
47 execsql {
48 CREATE TABLE t1(x INTEGER PRIMARY KEY AUTOINCREMENT, y);
49 SELECT name FROM sqlite_master WHERE type='table';
50 }
51} {t1 sqlite_sequence}
52
53# The SQLITE_SEQUENCE table is initially empty
54#
55do_test autoinc-1.3 {
56 execsql {
57 SELECT * FROM sqlite_sequence;
58 }
59} {}
drhc456e572008-08-11 18:44:58 +000060do_test autoinc-1.3.1 {
61 catchsql {
62 CREATE INDEX seqidx ON sqlite_sequence(name)
63 }
64} {1 {table sqlite_sequence may not be indexed}}
drhf3388142004-11-13 03:48:06 +000065
66# Close and reopen the database. Verify that everything is still there.
67#
68do_test autoinc-1.4 {
69 db close
70 sqlite3 db test.db
71 execsql {
72 SELECT * FROM sqlite_sequence;
73 }
74} {}
75
76# We are not allowed to drop the sqlite_sequence table.
77#
78do_test autoinc-1.5 {
79 catchsql {DROP TABLE sqlite_sequence}
80} {1 {table sqlite_sequence may not be dropped}}
81do_test autoinc-1.6 {
82 execsql {SELECT name FROM sqlite_master WHERE type='table'}
83} {t1 sqlite_sequence}
84
85# Insert an entries into the t1 table and make sure the largest key
86# is always recorded in the sqlite_sequence table.
87#
88do_test autoinc-2.1 {
89 execsql {
90 SELECT * FROM sqlite_sequence
91 }
92} {}
93do_test autoinc-2.2 {
94 execsql {
95 INSERT INTO t1 VALUES(12,34);
96 SELECT * FROM sqlite_sequence;
97 }
98} {t1 12}
99do_test autoinc-2.3 {
100 execsql {
101 INSERT INTO t1 VALUES(1,23);
102 SELECT * FROM sqlite_sequence;
103 }
104} {t1 12}
105do_test autoinc-2.4 {
106 execsql {
107 INSERT INTO t1 VALUES(123,456);
108 SELECT * FROM sqlite_sequence;
109 }
110} {t1 123}
111do_test autoinc-2.5 {
112 execsql {
113 INSERT INTO t1 VALUES(NULL,567);
114 SELECT * FROM sqlite_sequence;
115 }
116} {t1 124}
117do_test autoinc-2.6 {
118 execsql {
119 DELETE FROM t1 WHERE y=567;
120 SELECT * FROM sqlite_sequence;
121 }
122} {t1 124}
123do_test autoinc-2.7 {
124 execsql {
125 INSERT INTO t1 VALUES(NULL,567);
126 SELECT * FROM sqlite_sequence;
127 }
128} {t1 125}
129do_test autoinc-2.8 {
130 execsql {
131 DELETE FROM t1;
132 SELECT * FROM sqlite_sequence;
133 }
134} {t1 125}
135do_test autoinc-2.9 {
136 execsql {
137 INSERT INTO t1 VALUES(12,34);
138 SELECT * FROM sqlite_sequence;
139 }
140} {t1 125}
141do_test autoinc-2.10 {
142 execsql {
143 INSERT INTO t1 VALUES(125,456);
144 SELECT * FROM sqlite_sequence;
145 }
146} {t1 125}
147do_test autoinc-2.11 {
148 execsql {
149 INSERT INTO t1 VALUES(-1234567,-1);
150 SELECT * FROM sqlite_sequence;
151 }
152} {t1 125}
153do_test autoinc-2.12 {
154 execsql {
155 INSERT INTO t1 VALUES(234,5678);
156 SELECT * FROM sqlite_sequence;
157 }
158} {t1 234}
159do_test autoinc-2.13 {
160 execsql {
161 DELETE FROM t1;
162 INSERT INTO t1 VALUES(NULL,1);
163 SELECT * FROM sqlite_sequence;
164 }
165} {t1 235}
166do_test autoinc-2.14 {
167 execsql {
168 SELECT * FROM t1;
169 }
170} {235 1}
171
172# Manually change the autoincrement values in sqlite_sequence.
173#
174do_test autoinc-2.20 {
175 execsql {
176 UPDATE sqlite_sequence SET seq=1234 WHERE name='t1';
177 INSERT INTO t1 VALUES(NULL,2);
178 SELECT * FROM t1;
179 }
180} {235 1 1235 2}
181do_test autoinc-2.21 {
182 execsql {
183 SELECT * FROM sqlite_sequence;
184 }
185} {t1 1235}
186do_test autoinc-2.22 {
187 execsql {
188 UPDATE sqlite_sequence SET seq=NULL WHERE name='t1';
189 INSERT INTO t1 VALUES(NULL,3);
190 SELECT * FROM t1;
191 }
192} {235 1 1235 2 1236 3}
193do_test autoinc-2.23 {
194 execsql {
195 SELECT * FROM sqlite_sequence;
196 }
197} {t1 1236}
198do_test autoinc-2.24 {
199 execsql {
200 UPDATE sqlite_sequence SET seq='a-string' WHERE name='t1';
201 INSERT INTO t1 VALUES(NULL,4);
202 SELECT * FROM t1;
203 }
204} {235 1 1235 2 1236 3 1237 4}
205do_test autoinc-2.25 {
206 execsql {
207 SELECT * FROM sqlite_sequence;
208 }
209} {t1 1237}
210do_test autoinc-2.26 {
211 execsql {
212 DELETE FROM sqlite_sequence WHERE name='t1';
213 INSERT INTO t1 VALUES(NULL,5);
214 SELECT * FROM t1;
215 }
216} {235 1 1235 2 1236 3 1237 4 1238 5}
217do_test autoinc-2.27 {
218 execsql {
219 SELECT * FROM sqlite_sequence;
220 }
221} {t1 1238}
222do_test autoinc-2.28 {
223 execsql {
drhde1a8b82013-11-26 15:45:02 +0000224 UPDATE sqlite_sequence SET seq='-12345678901234567890'
drhf3388142004-11-13 03:48:06 +0000225 WHERE name='t1';
226 INSERT INTO t1 VALUES(NULL,6);
227 SELECT * FROM t1;
228 }
229} {235 1 1235 2 1236 3 1237 4 1238 5 1239 6}
230do_test autoinc-2.29 {
231 execsql {
232 SELECT * FROM sqlite_sequence;
233 }
234} {t1 1239}
235
236# Test multi-row inserts
237#
238do_test autoinc-2.50 {
239 execsql {
240 DELETE FROM t1 WHERE y>=3;
241 INSERT INTO t1 SELECT NULL, y+2 FROM t1;
242 SELECT * FROM t1;
243 }
244} {235 1 1235 2 1240 3 1241 4}
245do_test autoinc-2.51 {
246 execsql {
247 SELECT * FROM sqlite_sequence
248 }
249} {t1 1241}
danielk197753c0f742005-03-29 03:10:59 +0000250
251ifcapable tempdb {
252 do_test autoinc-2.52 {
253 execsql {
254 CREATE TEMP TABLE t2 AS SELECT y FROM t1;
danielk1977287fb612008-01-04 19:10:28 +0000255 }
256 execsql {
danielk197753c0f742005-03-29 03:10:59 +0000257 INSERT INTO t1 SELECT NULL, y+4 FROM t2;
258 SELECT * FROM t1;
259 }
260 } {235 1 1235 2 1240 3 1241 4 1242 5 1243 6 1244 7 1245 8}
261 do_test autoinc-2.53 {
262 execsql {
263 SELECT * FROM sqlite_sequence
264 }
265 } {t1 1245}
266 do_test autoinc-2.54 {
267 execsql {
268 DELETE FROM t1;
269 INSERT INTO t1 SELECT NULL, y FROM t2;
270 SELECT * FROM t1;
271 }
272 } {1246 1 1247 2 1248 3 1249 4}
273 do_test autoinc-2.55 {
274 execsql {
275 SELECT * FROM sqlite_sequence
276 }
277 } {t1 1249}
278}
drhf3388142004-11-13 03:48:06 +0000279
280# Create multiple AUTOINCREMENT tables. Make sure all sequences are
281# tracked separately and do not interfere with one another.
282#
283do_test autoinc-2.70 {
danielk197753c0f742005-03-29 03:10:59 +0000284 catchsql {
drhf3388142004-11-13 03:48:06 +0000285 DROP TABLE t2;
danielk197753c0f742005-03-29 03:10:59 +0000286 }
287 execsql {
drhf3388142004-11-13 03:48:06 +0000288 CREATE TABLE t2(d, e INTEGER PRIMARY KEY AUTOINCREMENT, f);
289 INSERT INTO t2(d) VALUES(1);
290 SELECT * FROM sqlite_sequence;
291 }
danielk197753c0f742005-03-29 03:10:59 +0000292} [ifcapable tempdb {list t1 1249 t2 1} else {list t1 1241 t2 1}]
drhf3388142004-11-13 03:48:06 +0000293do_test autoinc-2.71 {
294 execsql {
295 INSERT INTO t2(d) VALUES(2);
296 SELECT * FROM sqlite_sequence;
297 }
danielk197753c0f742005-03-29 03:10:59 +0000298} [ifcapable tempdb {list t1 1249 t2 2} else {list t1 1241 t2 2}]
drhf3388142004-11-13 03:48:06 +0000299do_test autoinc-2.72 {
300 execsql {
301 INSERT INTO t1(x) VALUES(10000);
302 SELECT * FROM sqlite_sequence;
303 }
304} {t1 10000 t2 2}
305do_test autoinc-2.73 {
306 execsql {
307 CREATE TABLE t3(g INTEGER PRIMARY KEY AUTOINCREMENT, h);
308 INSERT INTO t3(h) VALUES(1);
309 SELECT * FROM sqlite_sequence;
310 }
311} {t1 10000 t2 2 t3 1}
312do_test autoinc-2.74 {
313 execsql {
314 INSERT INTO t2(d,e) VALUES(3,100);
315 SELECT * FROM sqlite_sequence;
316 }
317} {t1 10000 t2 100 t3 1}
318
319
320# When a table with an AUTOINCREMENT is deleted, the corresponding entry
321# in the SQLITE_SEQUENCE table should also be deleted. But the SQLITE_SEQUENCE
322# table itself should remain behind.
323#
324do_test autoinc-3.1 {
325 execsql {SELECT name FROM sqlite_sequence}
326} {t1 t2 t3}
327do_test autoinc-3.2 {
328 execsql {
329 DROP TABLE t1;
330 SELECT name FROM sqlite_sequence;
331 }
332} {t2 t3}
333do_test autoinc-3.3 {
334 execsql {
335 DROP TABLE t3;
336 SELECT name FROM sqlite_sequence;
337 }
338} {t2}
339do_test autoinc-3.4 {
340 execsql {
341 DROP TABLE t2;
342 SELECT name FROM sqlite_sequence;
343 }
344} {}
345
346# AUTOINCREMENT on TEMP tables.
347#
danielk197753c0f742005-03-29 03:10:59 +0000348ifcapable tempdb {
349 do_test autoinc-4.1 {
350 execsql {
351 SELECT 1, name FROM sqlite_master WHERE type='table';
drhe0a04a32016-12-16 01:00:21 +0000352 SELECT 2, name FROM temp.sqlite_master WHERE type='table';
danielk197753c0f742005-03-29 03:10:59 +0000353 }
354 } {1 sqlite_sequence}
355 do_test autoinc-4.2 {
356 execsql {
357 CREATE TABLE t1(x INTEGER PRIMARY KEY AUTOINCREMENT, y);
358 CREATE TEMP TABLE t3(a INTEGER PRIMARY KEY AUTOINCREMENT, b);
359 SELECT 1, name FROM sqlite_master WHERE type='table';
360 SELECT 2, name FROM sqlite_temp_master WHERE type='table';
361 }
362 } {1 sqlite_sequence 1 t1 2 t3 2 sqlite_sequence}
363 do_test autoinc-4.3 {
364 execsql {
365 SELECT 1, * FROM main.sqlite_sequence;
366 SELECT 2, * FROM temp.sqlite_sequence;
367 }
368 } {}
369 do_test autoinc-4.4 {
370 execsql {
371 INSERT INTO t1 VALUES(10,1);
372 INSERT INTO t3 VALUES(20,2);
373 INSERT INTO t1 VALUES(NULL,3);
374 INSERT INTO t3 VALUES(NULL,4);
375 }
376 } {}
377
378 ifcapable compound {
379 do_test autoinc-4.4.1 {
380 execsql {
381 SELECT * FROM t1 UNION ALL SELECT * FROM t3;
382 }
383 } {10 1 11 3 20 2 21 4}
384 } ;# ifcapable compound
385
386 do_test autoinc-4.5 {
387 execsql {
388 SELECT 1, * FROM main.sqlite_sequence;
389 SELECT 2, * FROM temp.sqlite_sequence;
390 }
391 } {1 t1 11 2 t3 21}
392 do_test autoinc-4.6 {
393 execsql {
394 INSERT INTO t1 SELECT * FROM t3;
395 SELECT 1, * FROM main.sqlite_sequence;
396 SELECT 2, * FROM temp.sqlite_sequence;
397 }
398 } {1 t1 21 2 t3 21}
399 do_test autoinc-4.7 {
400 execsql {
401 INSERT INTO t3 SELECT x+100, y FROM t1;
402 SELECT 1, * FROM main.sqlite_sequence;
403 SELECT 2, * FROM temp.sqlite_sequence;
404 }
405 } {1 t1 21 2 t3 121}
406 do_test autoinc-4.8 {
407 execsql {
408 DROP TABLE t3;
409 SELECT 1, * FROM main.sqlite_sequence;
410 SELECT 2, * FROM temp.sqlite_sequence;
411 }
412 } {1 t1 21}
413 do_test autoinc-4.9 {
414 execsql {
415 CREATE TEMP TABLE t2(p INTEGER PRIMARY KEY AUTOINCREMENT, q);
416 INSERT INTO t2 SELECT * FROM t1;
417 DROP TABLE t1;
418 SELECT 1, * FROM main.sqlite_sequence;
419 SELECT 2, * FROM temp.sqlite_sequence;
420 }
421 } {2 t2 21}
422 do_test autoinc-4.10 {
423 execsql {
424 DROP TABLE t2;
425 SELECT 1, * FROM main.sqlite_sequence;
426 SELECT 2, * FROM temp.sqlite_sequence;
427 }
428 } {}
429}
drhf3388142004-11-13 03:48:06 +0000430
431# Make sure AUTOINCREMENT works on ATTACH-ed tables.
432#
danielk19775a8f9372007-10-09 08:29:32 +0000433ifcapable tempdb&&attach {
danielk197753c0f742005-03-29 03:10:59 +0000434 do_test autoinc-5.1 {
mistachkinfda06be2011-08-02 00:57:34 +0000435 forcedelete test2.db
436 forcedelete test2.db-journal
danielk197753c0f742005-03-29 03:10:59 +0000437 sqlite3 db2 test2.db
438 execsql {
439 CREATE TABLE t4(m INTEGER PRIMARY KEY AUTOINCREMENT, n);
440 CREATE TABLE t5(o, p INTEGER PRIMARY KEY AUTOINCREMENT);
441 } db2;
442 execsql {
443 ATTACH 'test2.db' as aux;
444 SELECT 1, * FROM main.sqlite_sequence;
445 SELECT 2, * FROM temp.sqlite_sequence;
446 SELECT 3, * FROM aux.sqlite_sequence;
447 }
448 } {}
449 do_test autoinc-5.2 {
450 execsql {
451 INSERT INTO t4 VALUES(NULL,1);
452 SELECT 1, * FROM main.sqlite_sequence;
453 SELECT 2, * FROM temp.sqlite_sequence;
454 SELECT 3, * FROM aux.sqlite_sequence;
455 }
456 } {3 t4 1}
457 do_test autoinc-5.3 {
458 execsql {
459 INSERT INTO t5 VALUES(100,200);
460 SELECT * FROM sqlite_sequence
461 } db2
462 } {t4 1 t5 200}
463 do_test autoinc-5.4 {
464 execsql {
465 SELECT 1, * FROM main.sqlite_sequence;
466 SELECT 2, * FROM temp.sqlite_sequence;
467 SELECT 3, * FROM aux.sqlite_sequence;
468 }
469 } {3 t4 1 3 t5 200}
470}
drhf3388142004-11-13 03:48:06 +0000471
472# Requirement REQ00310: Make sure an insert fails if the sequence is
473# already at its maximum value.
474#
drh75f86a42005-02-17 00:03:06 +0000475ifcapable {rowid32} {
476 do_test autoinc-6.1 {
477 execsql {
478 CREATE TABLE t6(v INTEGER PRIMARY KEY AUTOINCREMENT, w);
479 INSERT INTO t6 VALUES(2147483647,1);
480 SELECT seq FROM main.sqlite_sequence WHERE name='t6';
481 }
482 } 2147483647
483}
484ifcapable {!rowid32} {
485 do_test autoinc-6.1 {
486 execsql {
487 CREATE TABLE t6(v INTEGER PRIMARY KEY AUTOINCREMENT, w);
488 INSERT INTO t6 VALUES(9223372036854775807,1);
489 SELECT seq FROM main.sqlite_sequence WHERE name='t6';
490 }
491 } 9223372036854775807
492}
drhf3388142004-11-13 03:48:06 +0000493do_test autoinc-6.2 {
494 catchsql {
495 INSERT INTO t6 VALUES(NULL,1);
496 }
drh2db0bbc2005-08-11 02:10:18 +0000497} {1 {database or disk is full}}
drhf3388142004-11-13 03:48:06 +0000498
499# Allow the AUTOINCREMENT keyword inside the parentheses
500# on a separate PRIMARY KEY designation.
501#
502do_test autoinc-7.1 {
503 execsql {
504 CREATE TABLE t7(x INTEGER, y REAL, PRIMARY KEY(x AUTOINCREMENT));
505 INSERT INTO t7(y) VALUES(123);
506 INSERT INTO t7(y) VALUES(234);
507 DELETE FROM t7;
508 INSERT INTO t7(y) VALUES(345);
509 SELECT * FROM t7;
510 }
drh8a512562005-11-14 22:29:05 +0000511} {3 345.0}
drhf3388142004-11-13 03:48:06 +0000512
danielk1977576ec6b2005-01-21 11:55:25 +0000513# Test that if the AUTOINCREMENT is applied to a non integer primary key
514# the error message is sensible.
515do_test autoinc-7.2 {
516 catchsql {
517 CREATE TABLE t8(x TEXT PRIMARY KEY AUTOINCREMENT);
518 }
519} {1 {AUTOINCREMENT is only allowed on an INTEGER PRIMARY KEY}}
520
drh78776ec2005-06-14 02:12:46 +0000521
522# Ticket #1283. Make sure that preparing but never running a statement
523# that creates the sqlite_sequence table does not mess up the database.
524#
525do_test autoinc-8.1 {
526 catch {db2 close}
527 catch {db close}
mistachkinfda06be2011-08-02 00:57:34 +0000528 forcedelete test.db
drhdddca282006-01-03 00:33:50 +0000529 sqlite3 db test.db
530 set DB [sqlite3_connection_pointer db]
drh78776ec2005-06-14 02:12:46 +0000531 set STMT [sqlite3_prepare $DB {
532 CREATE TABLE t1(
533 x INTEGER PRIMARY KEY AUTOINCREMENT
534 )
535 } -1 TAIL]
536 sqlite3_finalize $STMT
537 set STMT [sqlite3_prepare $DB {
538 CREATE TABLE t1(
539 x INTEGER PRIMARY KEY AUTOINCREMENT
540 )
541 } -1 TAIL]
542 sqlite3_step $STMT
543 sqlite3_finalize $STMT
544 execsql {
545 INSERT INTO t1 VALUES(NULL);
546 SELECT * FROM t1;
547 }
548} {1}
549
drhc9ded4c2008-05-29 03:20:59 +0000550# Ticket #3148
551# Make sure the sqlite_sequence table is not damaged when doing
552# an empty insert - an INSERT INTO ... SELECT ... where the SELECT
553# clause returns an empty set.
554#
555do_test autoinc-9.1 {
556 db eval {
557 CREATE TABLE t2(x INTEGER PRIMARY KEY AUTOINCREMENT, y);
558 INSERT INTO t2 VALUES(NULL, 1);
559 CREATE TABLE t3(a INTEGER PRIMARY KEY AUTOINCREMENT, b);
560 INSERT INTO t3 SELECT * FROM t2 WHERE y>1;
561
562 SELECT * FROM sqlite_sequence WHERE name='t3';
563 }
564} {t3 0}
565
dan75cbd982009-09-21 16:06:03 +0000566ifcapable trigger {
567 catchsql { pragma recursive_triggers = off }
568
569 # Ticket #3928. Make sure that triggers to not make extra slots in
570 # the SQLITE_SEQUENCE table.
571 #
572 do_test autoinc-3928.1 {
573 db eval {
574 CREATE TABLE t3928(a INTEGER PRIMARY KEY AUTOINCREMENT, b);
575 CREATE TRIGGER t3928r1 BEFORE INSERT ON t3928 BEGIN
576 INSERT INTO t3928(b) VALUES('before1');
577 INSERT INTO t3928(b) VALUES('before2');
578 END;
579 CREATE TRIGGER t3928r2 AFTER INSERT ON t3928 BEGIN
580 INSERT INTO t3928(b) VALUES('after1');
581 INSERT INTO t3928(b) VALUES('after2');
582 END;
583 INSERT INTO t3928(b) VALUES('test');
584 SELECT * FROM t3928 ORDER BY a;
585 }
586 } {1 before1 2 after1 3 after2 4 before2 5 after1 6 after2 7 test 8 before1 9 before2 10 after1 11 before1 12 before2 13 after2}
587 do_test autoinc-3928.2 {
588 db eval {
589 SELECT * FROM sqlite_sequence WHERE name='t3928'
590 }
591 } {t3928 13}
dan76d462e2009-08-30 11:42:51 +0000592
dan75cbd982009-09-21 16:06:03 +0000593 do_test autoinc-3928.3 {
594 db eval {
595 DROP TRIGGER t3928r1;
596 DROP TRIGGER t3928r2;
597 CREATE TRIGGER t3928r3 BEFORE UPDATE ON t3928
598 WHEN typeof(new.b)=='integer' BEGIN
599 INSERT INTO t3928(b) VALUES('before-int-' || new.b);
600 END;
601 CREATE TRIGGER t3928r4 AFTER UPDATE ON t3928
602 WHEN typeof(new.b)=='integer' BEGIN
603 INSERT INTO t3928(b) VALUES('after-int-' || new.b);
604 END;
605 DELETE FROM t3928 WHERE a!=1;
606 UPDATE t3928 SET b=456 WHERE a=1;
607 SELECT * FROM t3928 ORDER BY a;
608 }
609 } {1 456 14 before-int-456 15 after-int-456}
610 do_test autoinc-3928.4 {
611 db eval {
612 SELECT * FROM sqlite_sequence WHERE name='t3928'
613 }
614 } {t3928 15}
615
616 do_test autoinc-3928.5 {
617 db eval {
618 CREATE TABLE t3928b(x);
619 INSERT INTO t3928b VALUES(100);
620 INSERT INTO t3928b VALUES(200);
621 INSERT INTO t3928b VALUES(300);
622 DELETE FROM t3928;
623 CREATE TABLE t3928c(y INTEGER PRIMARY KEY AUTOINCREMENT, z);
624 CREATE TRIGGER t3928br1 BEFORE DELETE ON t3928b BEGIN
625 INSERT INTO t3928(b) VALUES('before-del-'||old.x);
626 INSERT INTO t3928c(z) VALUES('before-del-'||old.x);
627 END;
628 CREATE TRIGGER t3928br2 AFTER DELETE ON t3928b BEGIN
629 INSERT INTO t3928(b) VALUES('after-del-'||old.x);
630 INSERT INTO t3928c(z) VALUES('after-del-'||old.x);
631 END;
632 DELETE FROM t3928b;
633 SELECT * FROM t3928 ORDER BY a;
634 }
635 } {16 before-del-100 17 after-del-100 18 before-del-200 19 after-del-200 20 before-del-300 21 after-del-300}
636 do_test autoinc-3928.6 {
637 db eval {
638 SELECT * FROM t3928c ORDER BY y;
639 }
640 } {1 before-del-100 2 after-del-100 3 before-del-200 4 after-del-200 5 before-del-300 6 after-del-300}
641 do_test autoinc-3928.7 {
642 db eval {
643 SELECT * FROM sqlite_sequence WHERE name LIKE 't3928%' ORDER BY name;
644 }
645 } {t3928 21 t3928c 6}
646
647 # Ticket [a696379c1f0886615541a48b35bd8181a80e88f8]
648 do_test autoinc-a69637.1 {
649 db eval {
650 CREATE TABLE ta69637_1(x INTEGER PRIMARY KEY AUTOINCREMENT, y);
651 CREATE TABLE ta69637_2(z);
652 CREATE TRIGGER ra69637_1 AFTER INSERT ON ta69637_2 BEGIN
653 INSERT INTO ta69637_1(y) VALUES(new.z+1);
654 END;
655 INSERT INTO ta69637_2 VALUES(123);
656 SELECT * FROM ta69637_1;
657 }
658 } {1 124}
659 do_test autoinc-a69637.2 {
660 db eval {
661 CREATE VIEW va69637_2 AS SELECT * FROM ta69637_2;
662 CREATE TRIGGER ra69637_2 INSTEAD OF INSERT ON va69637_2 BEGIN
663 INSERT INTO ta69637_1(y) VALUES(new.z+10000);
664 END;
665 INSERT INTO va69637_2 VALUES(123);
666 SELECT * FROM ta69637_1;
667 }
668 } {1 124 2 10123}
669}
drh3492dd72009-09-14 23:47:24 +0000670
drh1dd518c2016-10-03 02:59:33 +0000671# 2016-10-03 ticket https://www.sqlite.org/src/tktview/7b3328086a5c1
672# Make sure autoincrement plays nicely with the xfer optimization
673#
674do_execsql_test autoinc-10.1 {
675 DELETE FROM sqlite_sequence;
676 CREATE TABLE t10a(a INTEGER PRIMARY KEY AUTOINCREMENT, b UNIQUE);
677 INSERT INTO t10a VALUES(888,9999);
678 CREATE TABLE t10b(x INTEGER PRIMARY KEY AUTOINCREMENT, y UNIQUE);
679 INSERT INTO t10b SELECT * FROM t10a;
680 SELECT * FROM sqlite_sequence;
681} {t10a 888 t10b 888}
682
drhf3d7bbb2018-04-21 03:06:29 +0000683# 2018-04-21 autoincrement does not cause problems for upsert
684#
685do_execsql_test autoinc-11.1 {
686 CREATE TABLE t11(a INTEGER PRIMARY KEY AUTOINCREMENT,b UNIQUE);
687 INSERT INTO t11(a,b) VALUES(2,3),(5,6),(4,3),(1,2)
688 ON CONFLICT(b) DO UPDATE SET a=a+1000;
689 SELECT seq FROM sqlite_sequence WHERE name='t11';
690} {5}
drh3492dd72009-09-14 23:47:24 +0000691
drh186ebd42018-05-23 16:50:21 +0000692# 2018-05-23 ticket d8dc2b3a58cd5dc2918a1d4acbba4676a23ada4c
693# Does not crash if the sqlite_sequence table schema is missing
694# or corrupt.
695#
696do_test autoinc-12.1 {
697 db close
698 forcedelete test.db
699 sqlite3 db test.db
700 db eval {
701 CREATE TABLE fake_sequence(name TEXT PRIMARY KEY,seq) WITHOUT ROWID;
702 PRAGMA writable_schema=on;
703 UPDATE sqlite_master SET
704 sql=replace(sql,'fake_','sqlite_'),
705 name='sqlite_sequence',
706 tbl_name='sqlite_sequence'
707 WHERE name='fake_sequence';
708 }
709 db close
710 sqlite3 db test.db
711 set res [catch {db eval {
712 CREATE TABLE t1(a INTEGER PRIMARY KEY AUTOINCREMENT, b TEXT);
713 INSERT INTO t1(b) VALUES('one');
714 }} msg]
715 lappend res $msg
716} {1 {database disk image is malformed}}
717do_test autoinc-12.2 {
718 db close
719 forcedelete test.db
720 sqlite3 db test.db
721 db eval {
722 CREATE TABLE t1(a INTEGER PRIMARY KEY AUTOINCREMENT, b TEXT);
723 INSERT INTO t1(b) VALUES('one');
724 PRAGMA writable_schema=on;
725 UPDATE sqlite_master SET
726 sql=replace(sql,'sqlite_','x_'),
727 name='x_sequence',
728 tbl_name='x_sequence'
729 WHERE name='sqlite_sequence';
730 }
731 db close
732 sqlite3 db test.db
733 set res [catch {db eval {
734 INSERT INTO t1(b) VALUES('two');
735 }} msg]
736 lappend res $msg
737} {1 {database disk image is malformed}}
dand3e17ff2018-05-29 14:06:55 +0000738ifcapable vtab {
739 set err "database disk image is malformed"
740} else {
741 set err {malformed database schema (sqlite_sequence) - near "VIRTUAL": syntax error}
742}
drh186ebd42018-05-23 16:50:21 +0000743do_test autoinc-12.3 {
744 db close
745 forcedelete test.db
746 sqlite3 db test.db
747 db eval {
748 CREATE TABLE t1(a INTEGER PRIMARY KEY AUTOINCREMENT, b TEXT);
749 INSERT INTO t1(b) VALUES('one');
750 PRAGMA writable_schema=on;
751 UPDATE sqlite_master SET
752 sql='CREATE VIRTUAL TABLE sqlite_sequence USING sqlite_dbpage'
753 WHERE name='sqlite_sequence';
754 }
755 db close
756 sqlite3 db test.db
757 set res [catch {db eval {
758 INSERT INTO t1(b) VALUES('two');
759 }} msg]
760 lappend res $msg
dand3e17ff2018-05-29 14:06:55 +0000761} [list 1 $err]
drh186ebd42018-05-23 16:50:21 +0000762do_test autoinc-12.4 {
763 db close
764 forcedelete test.db
765 sqlite3 db test.db
766 db eval {
767 CREATE TABLE t1(a INTEGER PRIMARY KEY AUTOINCREMENT, b TEXT);
768 INSERT INTO t1(b) VALUES('one');
769 CREATE TABLE fake(name TEXT PRIMARY KEY,seq) WITHOUT ROWID;
770 }
771 set root1 [db one {SELECT rootpage FROM sqlite_master
772 WHERE name='sqlite_sequence'}]
773 set root2 [db one {SELECT rootpage FROM sqlite_master
774 WHERE name='fake'}]
775 db eval {
776 PRAGMA writable_schema=on;
777 UPDATE sqlite_master SET rootpage=$root2
778 WHERE name='sqlite_sequence';
779 UPDATE sqlite_master SET rootpage=$root1
780 WHERE name='fake';
781 }
782 db close
783 sqlite3 db test.db
784 set res [catch {db eval {
785 INSERT INTO t1(b) VALUES('two');
786 }} msg]
787 lappend res $msg
788} {1 {database disk image is malformed}}
789breakpoint
790do_test autoinc-12.5 {
791 db close
792 forcedelete test.db
793 sqlite3 db test.db
794 db eval {
795 CREATE TABLE t1(a INTEGER PRIMARY KEY AUTOINCREMENT, b TEXT);
796 INSERT INTO t1(b) VALUES('one');
797 PRAGMA writable_schema=on;
798 UPDATE sqlite_master SET
799 sql='CREATE TABLE sqlite_sequence(x)'
800 WHERE name='sqlite_sequence';
801 }
802 db close
803 sqlite3 db test.db
804 set res [catch {db eval {
805 INSERT INTO t1(b) VALUES('two');
806 }} msg]
807 lappend res $msg
808} {1 {database disk image is malformed}}
809do_test autoinc-12.6 {
810 db close
811 forcedelete test.db
812 sqlite3 db test.db
813 db eval {
814 CREATE TABLE t1(a INTEGER PRIMARY KEY AUTOINCREMENT, b TEXT);
815 INSERT INTO t1(b) VALUES('one');
816 PRAGMA writable_schema=on;
817 UPDATE sqlite_master SET
818 sql='CREATE TABLE sqlite_sequence(x,y INTEGER PRIMARY KEY)'
819 WHERE name='sqlite_sequence';
820 }
821 db close
822 sqlite3 db test.db
823 set res [catch {db eval {
824 INSERT INTO t1(b) VALUES('two'),('three'),('four');
825 INSERT INTO t1(b) VALUES('five');
826 PRAGMA integrity_check;
827 }} msg]
828 lappend res $msg
829} {0 ok}
830do_test autoinc-12.7 {
831 db close
832 forcedelete test.db
833 sqlite3 db test.db
834 db eval {
835 CREATE TABLE t1(a INTEGER PRIMARY KEY AUTOINCREMENT, b TEXT);
836 INSERT INTO t1(b) VALUES('one');
837 PRAGMA writable_schema=on;
838 UPDATE sqlite_master SET
839 sql='CREATE TABLE sqlite_sequence(y INTEGER PRIMARY KEY,x)'
840 WHERE name='sqlite_sequence';
841 }
842 db close
843 sqlite3 db test.db
844 set res [catch {db eval {
845 INSERT INTO t1(b) VALUES('two'),('three'),('four');
846 INSERT INTO t1(b) VALUES('five');
847 PRAGMA integrity_check;
848 }} msg]
849 lappend res $msg
850} {0 ok}
851
drhf3388142004-11-13 03:48:06 +0000852finish_test