1# 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# 14# $Id: autoinc.test,v 1.11 2008/01/04 19:10:29 danielk1977 Exp $ 15# 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 28# The database is initially empty. 29# 30do_test autoinc-1.1 { 31 execsql { 32 SELECT name FROM sqlite_master WHERE type='table'; 33 } 34} {} 35 36# Add a table with the AUTOINCREMENT feature. Verify that the 37# SQLITE_SEQUENCE table gets created. 38# 39do_test autoinc-1.2 { 40 execsql { 41 CREATE TABLE t1(x INTEGER PRIMARY KEY AUTOINCREMENT, y); 42 SELECT name FROM sqlite_master WHERE type='table'; 43 } 44} {t1 sqlite_sequence} 45 46# The SQLITE_SEQUENCE table is initially empty 47# 48do_test autoinc-1.3 { 49 execsql { 50 SELECT * FROM sqlite_sequence; 51 } 52} {} 53 54# Close and reopen the database. Verify that everything is still there. 55# 56do_test autoinc-1.4 { 57 db close 58 sqlite3 db test.db 59 execsql { 60 SELECT * FROM sqlite_sequence; 61 } 62} {} 63 64# We are not allowed to drop the sqlite_sequence table. 65# 66do_test autoinc-1.5 { 67 catchsql {DROP TABLE sqlite_sequence} 68} {1 {table sqlite_sequence may not be dropped}} 69do_test autoinc-1.6 { 70 execsql {SELECT name FROM sqlite_master WHERE type='table'} 71} {t1 sqlite_sequence} 72 73# Insert an entries into the t1 table and make sure the largest key 74# is always recorded in the sqlite_sequence table. 75# 76do_test autoinc-2.1 { 77 execsql { 78 SELECT * FROM sqlite_sequence 79 } 80} {} 81do_test autoinc-2.2 { 82 execsql { 83 INSERT INTO t1 VALUES(12,34); 84 SELECT * FROM sqlite_sequence; 85 } 86} {t1 12} 87do_test autoinc-2.3 { 88 execsql { 89 INSERT INTO t1 VALUES(1,23); 90 SELECT * FROM sqlite_sequence; 91 } 92} {t1 12} 93do_test autoinc-2.4 { 94 execsql { 95 INSERT INTO t1 VALUES(123,456); 96 SELECT * FROM sqlite_sequence; 97 } 98} {t1 123} 99do_test autoinc-2.5 { 100 execsql { 101 INSERT INTO t1 VALUES(NULL,567); 102 SELECT * FROM sqlite_sequence; 103 } 104} {t1 124} 105do_test autoinc-2.6 { 106 execsql { 107 DELETE FROM t1 WHERE y=567; 108 SELECT * FROM sqlite_sequence; 109 } 110} {t1 124} 111do_test autoinc-2.7 { 112 execsql { 113 INSERT INTO t1 VALUES(NULL,567); 114 SELECT * FROM sqlite_sequence; 115 } 116} {t1 125} 117do_test autoinc-2.8 { 118 execsql { 119 DELETE FROM t1; 120 SELECT * FROM sqlite_sequence; 121 } 122} {t1 125} 123do_test autoinc-2.9 { 124 execsql { 125 INSERT INTO t1 VALUES(12,34); 126 SELECT * FROM sqlite_sequence; 127 } 128} {t1 125} 129do_test autoinc-2.10 { 130 execsql { 131 INSERT INTO t1 VALUES(125,456); 132 SELECT * FROM sqlite_sequence; 133 } 134} {t1 125} 135do_test autoinc-2.11 { 136 execsql { 137 INSERT INTO t1 VALUES(-1234567,-1); 138 SELECT * FROM sqlite_sequence; 139 } 140} {t1 125} 141do_test autoinc-2.12 { 142 execsql { 143 INSERT INTO t1 VALUES(234,5678); 144 SELECT * FROM sqlite_sequence; 145 } 146} {t1 234} 147do_test autoinc-2.13 { 148 execsql { 149 DELETE FROM t1; 150 INSERT INTO t1 VALUES(NULL,1); 151 SELECT * FROM sqlite_sequence; 152 } 153} {t1 235} 154do_test autoinc-2.14 { 155 execsql { 156 SELECT * FROM t1; 157 } 158} {235 1} 159 160# Manually change the autoincrement values in sqlite_sequence. 161# 162do_test autoinc-2.20 { 163 execsql { 164 UPDATE sqlite_sequence SET seq=1234 WHERE name='t1'; 165 INSERT INTO t1 VALUES(NULL,2); 166 SELECT * FROM t1; 167 } 168} {235 1 1235 2} 169do_test autoinc-2.21 { 170 execsql { 171 SELECT * FROM sqlite_sequence; 172 } 173} {t1 1235} 174do_test autoinc-2.22 { 175 execsql { 176 UPDATE sqlite_sequence SET seq=NULL WHERE name='t1'; 177 INSERT INTO t1 VALUES(NULL,3); 178 SELECT * FROM t1; 179 } 180} {235 1 1235 2 1236 3} 181do_test autoinc-2.23 { 182 execsql { 183 SELECT * FROM sqlite_sequence; 184 } 185} {t1 1236} 186do_test autoinc-2.24 { 187 execsql { 188 UPDATE sqlite_sequence SET seq='a-string' WHERE name='t1'; 189 INSERT INTO t1 VALUES(NULL,4); 190 SELECT * FROM t1; 191 } 192} {235 1 1235 2 1236 3 1237 4} 193do_test autoinc-2.25 { 194 execsql { 195 SELECT * FROM sqlite_sequence; 196 } 197} {t1 1237} 198do_test autoinc-2.26 { 199 execsql { 200 DELETE FROM sqlite_sequence WHERE name='t1'; 201 INSERT INTO t1 VALUES(NULL,5); 202 SELECT * FROM t1; 203 } 204} {235 1 1235 2 1236 3 1237 4 1238 5} 205do_test autoinc-2.27 { 206 execsql { 207 SELECT * FROM sqlite_sequence; 208 } 209} {t1 1238} 210do_test autoinc-2.28 { 211 execsql { 212 UPDATE sqlite_sequence SET seq='12345678901234567890' 213 WHERE name='t1'; 214 INSERT INTO t1 VALUES(NULL,6); 215 SELECT * FROM t1; 216 } 217} {235 1 1235 2 1236 3 1237 4 1238 5 1239 6} 218do_test autoinc-2.29 { 219 execsql { 220 SELECT * FROM sqlite_sequence; 221 } 222} {t1 1239} 223 224# Test multi-row inserts 225# 226do_test autoinc-2.50 { 227 execsql { 228 DELETE FROM t1 WHERE y>=3; 229 INSERT INTO t1 SELECT NULL, y+2 FROM t1; 230 SELECT * FROM t1; 231 } 232} {235 1 1235 2 1240 3 1241 4} 233do_test autoinc-2.51 { 234 execsql { 235 SELECT * FROM sqlite_sequence 236 } 237} {t1 1241} 238 239ifcapable tempdb { 240 do_test autoinc-2.52 { 241 execsql { 242 CREATE TEMP TABLE t2 AS SELECT y FROM t1; 243 } 244 execsql { 245 INSERT INTO t1 SELECT NULL, y+4 FROM t2; 246 SELECT * FROM t1; 247 } 248 } {235 1 1235 2 1240 3 1241 4 1242 5 1243 6 1244 7 1245 8} 249 do_test autoinc-2.53 { 250 execsql { 251 SELECT * FROM sqlite_sequence 252 } 253 } {t1 1245} 254 do_test autoinc-2.54 { 255 execsql { 256 DELETE FROM t1; 257 INSERT INTO t1 SELECT NULL, y FROM t2; 258 SELECT * FROM t1; 259 } 260 } {1246 1 1247 2 1248 3 1249 4} 261 do_test autoinc-2.55 { 262 execsql { 263 SELECT * FROM sqlite_sequence 264 } 265 } {t1 1249} 266} 267 268# Create multiple AUTOINCREMENT tables. Make sure all sequences are 269# tracked separately and do not interfere with one another. 270# 271do_test autoinc-2.70 { 272 catchsql { 273 DROP TABLE t2; 274 } 275 execsql { 276 CREATE TABLE t2(d, e INTEGER PRIMARY KEY AUTOINCREMENT, f); 277 INSERT INTO t2(d) VALUES(1); 278 SELECT * FROM sqlite_sequence; 279 } 280} [ifcapable tempdb {list t1 1249 t2 1} else {list t1 1241 t2 1}] 281do_test autoinc-2.71 { 282 execsql { 283 INSERT INTO t2(d) VALUES(2); 284 SELECT * FROM sqlite_sequence; 285 } 286} [ifcapable tempdb {list t1 1249 t2 2} else {list t1 1241 t2 2}] 287do_test autoinc-2.72 { 288 execsql { 289 INSERT INTO t1(x) VALUES(10000); 290 SELECT * FROM sqlite_sequence; 291 } 292} {t1 10000 t2 2} 293do_test autoinc-2.73 { 294 execsql { 295 CREATE TABLE t3(g INTEGER PRIMARY KEY AUTOINCREMENT, h); 296 INSERT INTO t3(h) VALUES(1); 297 SELECT * FROM sqlite_sequence; 298 } 299} {t1 10000 t2 2 t3 1} 300do_test autoinc-2.74 { 301 execsql { 302 INSERT INTO t2(d,e) VALUES(3,100); 303 SELECT * FROM sqlite_sequence; 304 } 305} {t1 10000 t2 100 t3 1} 306 307 308# When a table with an AUTOINCREMENT is deleted, the corresponding entry 309# in the SQLITE_SEQUENCE table should also be deleted. But the SQLITE_SEQUENCE 310# table itself should remain behind. 311# 312do_test autoinc-3.1 { 313 execsql {SELECT name FROM sqlite_sequence} 314} {t1 t2 t3} 315do_test autoinc-3.2 { 316 execsql { 317 DROP TABLE t1; 318 SELECT name FROM sqlite_sequence; 319 } 320} {t2 t3} 321do_test autoinc-3.3 { 322 execsql { 323 DROP TABLE t3; 324 SELECT name FROM sqlite_sequence; 325 } 326} {t2} 327do_test autoinc-3.4 { 328 execsql { 329 DROP TABLE t2; 330 SELECT name FROM sqlite_sequence; 331 } 332} {} 333 334# AUTOINCREMENT on TEMP tables. 335# 336ifcapable tempdb { 337 do_test autoinc-4.1 { 338 execsql { 339 SELECT 1, name FROM sqlite_master WHERE type='table'; 340 SELECT 2, name FROM sqlite_temp_master WHERE type='table'; 341 } 342 } {1 sqlite_sequence} 343 do_test autoinc-4.2 { 344 execsql { 345 CREATE TABLE t1(x INTEGER PRIMARY KEY AUTOINCREMENT, y); 346 CREATE TEMP TABLE t3(a INTEGER PRIMARY KEY AUTOINCREMENT, b); 347 SELECT 1, name FROM sqlite_master WHERE type='table'; 348 SELECT 2, name FROM sqlite_temp_master WHERE type='table'; 349 } 350 } {1 sqlite_sequence 1 t1 2 t3 2 sqlite_sequence} 351 do_test autoinc-4.3 { 352 execsql { 353 SELECT 1, * FROM main.sqlite_sequence; 354 SELECT 2, * FROM temp.sqlite_sequence; 355 } 356 } {} 357 do_test autoinc-4.4 { 358 execsql { 359 INSERT INTO t1 VALUES(10,1); 360 INSERT INTO t3 VALUES(20,2); 361 INSERT INTO t1 VALUES(NULL,3); 362 INSERT INTO t3 VALUES(NULL,4); 363 } 364 } {} 365 366 ifcapable compound { 367 do_test autoinc-4.4.1 { 368 execsql { 369 SELECT * FROM t1 UNION ALL SELECT * FROM t3; 370 } 371 } {10 1 11 3 20 2 21 4} 372 } ;# ifcapable compound 373 374 do_test autoinc-4.5 { 375 execsql { 376 SELECT 1, * FROM main.sqlite_sequence; 377 SELECT 2, * FROM temp.sqlite_sequence; 378 } 379 } {1 t1 11 2 t3 21} 380 do_test autoinc-4.6 { 381 execsql { 382 INSERT INTO t1 SELECT * FROM t3; 383 SELECT 1, * FROM main.sqlite_sequence; 384 SELECT 2, * FROM temp.sqlite_sequence; 385 } 386 } {1 t1 21 2 t3 21} 387 do_test autoinc-4.7 { 388 execsql { 389 INSERT INTO t3 SELECT x+100, y FROM t1; 390 SELECT 1, * FROM main.sqlite_sequence; 391 SELECT 2, * FROM temp.sqlite_sequence; 392 } 393 } {1 t1 21 2 t3 121} 394 do_test autoinc-4.8 { 395 execsql { 396 DROP TABLE t3; 397 SELECT 1, * FROM main.sqlite_sequence; 398 SELECT 2, * FROM temp.sqlite_sequence; 399 } 400 } {1 t1 21} 401 do_test autoinc-4.9 { 402 execsql { 403 CREATE TEMP TABLE t2(p INTEGER PRIMARY KEY AUTOINCREMENT, q); 404 INSERT INTO t2 SELECT * FROM t1; 405 DROP TABLE t1; 406 SELECT 1, * FROM main.sqlite_sequence; 407 SELECT 2, * FROM temp.sqlite_sequence; 408 } 409 } {2 t2 21} 410 do_test autoinc-4.10 { 411 execsql { 412 DROP TABLE t2; 413 SELECT 1, * FROM main.sqlite_sequence; 414 SELECT 2, * FROM temp.sqlite_sequence; 415 } 416 } {} 417} 418 419# Make sure AUTOINCREMENT works on ATTACH-ed tables. 420# 421ifcapable tempdb&&attach { 422 do_test autoinc-5.1 { 423 file delete -force test2.db 424 file delete -force test2.db-journal 425 sqlite3 db2 test2.db 426 execsql { 427 CREATE TABLE t4(m INTEGER PRIMARY KEY AUTOINCREMENT, n); 428 CREATE TABLE t5(o, p INTEGER PRIMARY KEY AUTOINCREMENT); 429 } db2; 430 execsql { 431 ATTACH 'test2.db' as aux; 432 SELECT 1, * FROM main.sqlite_sequence; 433 SELECT 2, * FROM temp.sqlite_sequence; 434 SELECT 3, * FROM aux.sqlite_sequence; 435 } 436 } {} 437 do_test autoinc-5.2 { 438 execsql { 439 INSERT INTO t4 VALUES(NULL,1); 440 SELECT 1, * FROM main.sqlite_sequence; 441 SELECT 2, * FROM temp.sqlite_sequence; 442 SELECT 3, * FROM aux.sqlite_sequence; 443 } 444 } {3 t4 1} 445 do_test autoinc-5.3 { 446 execsql { 447 INSERT INTO t5 VALUES(100,200); 448 SELECT * FROM sqlite_sequence 449 } db2 450 } {t4 1 t5 200} 451 do_test autoinc-5.4 { 452 execsql { 453 SELECT 1, * FROM main.sqlite_sequence; 454 SELECT 2, * FROM temp.sqlite_sequence; 455 SELECT 3, * FROM aux.sqlite_sequence; 456 } 457 } {3 t4 1 3 t5 200} 458} 459 460# Requirement REQ00310: Make sure an insert fails if the sequence is 461# already at its maximum value. 462# 463ifcapable {rowid32} { 464 do_test autoinc-6.1 { 465 execsql { 466 CREATE TABLE t6(v INTEGER PRIMARY KEY AUTOINCREMENT, w); 467 INSERT INTO t6 VALUES(2147483647,1); 468 SELECT seq FROM main.sqlite_sequence WHERE name='t6'; 469 } 470 } 2147483647 471} 472ifcapable {!rowid32} { 473 do_test autoinc-6.1 { 474 execsql { 475 CREATE TABLE t6(v INTEGER PRIMARY KEY AUTOINCREMENT, w); 476 INSERT INTO t6 VALUES(9223372036854775807,1); 477 SELECT seq FROM main.sqlite_sequence WHERE name='t6'; 478 } 479 } 9223372036854775807 480} 481do_test autoinc-6.2 { 482 catchsql { 483 INSERT INTO t6 VALUES(NULL,1); 484 } 485} {1 {database or disk is full}} 486 487# Allow the AUTOINCREMENT keyword inside the parentheses 488# on a separate PRIMARY KEY designation. 489# 490do_test autoinc-7.1 { 491 execsql { 492 CREATE TABLE t7(x INTEGER, y REAL, PRIMARY KEY(x AUTOINCREMENT)); 493 INSERT INTO t7(y) VALUES(123); 494 INSERT INTO t7(y) VALUES(234); 495 DELETE FROM t7; 496 INSERT INTO t7(y) VALUES(345); 497 SELECT * FROM t7; 498 } 499} {3 345.0} 500 501# Test that if the AUTOINCREMENT is applied to a non integer primary key 502# the error message is sensible. 503do_test autoinc-7.2 { 504 catchsql { 505 CREATE TABLE t8(x TEXT PRIMARY KEY AUTOINCREMENT); 506 } 507} {1 {AUTOINCREMENT is only allowed on an INTEGER PRIMARY KEY}} 508 509 510# Ticket #1283. Make sure that preparing but never running a statement 511# that creates the sqlite_sequence table does not mess up the database. 512# 513do_test autoinc-8.1 { 514 catch {db2 close} 515 catch {db close} 516 file delete -force test.db 517 sqlite3 db test.db 518 set DB [sqlite3_connection_pointer db] 519 set STMT [sqlite3_prepare $DB { 520 CREATE TABLE t1( 521 x INTEGER PRIMARY KEY AUTOINCREMENT 522 ) 523 } -1 TAIL] 524 sqlite3_finalize $STMT 525 set STMT [sqlite3_prepare $DB { 526 CREATE TABLE t1( 527 x INTEGER PRIMARY KEY AUTOINCREMENT 528 ) 529 } -1 TAIL] 530 sqlite3_step $STMT 531 sqlite3_finalize $STMT 532 execsql { 533 INSERT INTO t1 VALUES(NULL); 534 SELECT * FROM t1; 535 } 536} {1} 537 538finish_test 539