3 # The author disclaims copyright to this source code. In place of
4 # a legal notice, here is a blessing:
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.
10 #***********************************************************************
11 # This file implements regression tests for SQLite library.
13 # This file implements tests for the special processing associated
14 # with INTEGER PRIMARY KEY columns.
16 # $Id: intpkey.test,v 1.24 2007/11/29 17:43:28 danielk1977 Exp $
18 set testdir [file dirname $argv0]
19 source $testdir/tester.tcl
21 # Create a table with a primary key and a datatype other than
26 CREATE TABLE t1(a TEXT PRIMARY KEY, b, c);
30 # There should be an index associated with the primary key
34 SELECT name FROM sqlite_master
35 WHERE type='index' AND tbl_name='t1';
37 } {sqlite_autoindex_t1_1}
39 # Now create a table with an integer primary key and verify that
40 # there is no associated index.
45 CREATE TABLE t1(a INTEGER PRIMARY KEY, b, c);
46 SELECT name FROM sqlite_master
47 WHERE type='index' AND tbl_name='t1';
51 # Insert some records into the new table. Specify the primary key
52 # and verify that the key is used as the record number.
56 INSERT INTO t1 VALUES(5,'hello','world');
67 SELECT rowid, * FROM t1;
71 # Attempting to insert a duplicate primary key should give a constraint
75 set r [catch {execsql {
76 INSERT INTO t1 VALUES(5,'second','entry');
79 } {1 {PRIMARY KEY must be unique}}
82 SELECT rowid, * FROM t1;
86 set r [catch {execsql {
87 INSERT INTO t1 VALUES(6,'second','entry');
91 do_test intpkey-1.8.1 {
96 SELECT rowid, * FROM t1;
98 } {5 5 hello world 6 6 second entry}
100 # A ROWID is automatically generated for new records that do not specify
101 # the integer primary key.
103 do_test intpkey-1.10 {
105 INSERT INTO t1(b,c) VALUES('one','two');
106 SELECT b FROM t1 ORDER BY b;
110 # Try to change the ROWID for the new entry.
112 do_test intpkey-1.11 {
114 UPDATE t1 SET a=4 WHERE b='one';
117 } {4 one two 5 hello world 6 second entry}
119 # Make sure SELECT statements are able to use the primary key column
122 do_test intpkey-1.12.1 {
124 SELECT * FROM t1 WHERE a==4;
127 do_test intpkey-1.12.2 {
128 set sqlite_query_plan
131 # Try to insert a non-integer value into the primary key field. This
132 # should result in a data type mismatch.
134 do_test intpkey-1.13.1 {
135 set r [catch {execsql {
136 INSERT INTO t1 VALUES('x','y','z');
139 } {1 {datatype mismatch}}
140 do_test intpkey-1.13.2 {
141 set r [catch {execsql {
142 INSERT INTO t1 VALUES('','y','z');
145 } {1 {datatype mismatch}}
146 do_test intpkey-1.14 {
147 set r [catch {execsql {
148 INSERT INTO t1 VALUES(3.4,'y','z');
151 } {1 {datatype mismatch}}
152 do_test intpkey-1.15 {
153 set r [catch {execsql {
154 INSERT INTO t1 VALUES(-3,'y','z');
158 do_test intpkey-1.16 {
159 execsql {SELECT * FROM t1}
160 } {-3 y z 4 one two 5 hello world 6 second entry}
163 # Check to make sure indices work correctly with integer primary keys
165 do_test intpkey-2.1 {
167 CREATE INDEX i1 ON t1(b);
168 SELECT * FROM t1 WHERE b=='y'
171 do_test intpkey-2.1.1 {
173 SELECT * FROM t1 WHERE b=='y' AND rowid<0
176 do_test intpkey-2.1.2 {
178 SELECT * FROM t1 WHERE b=='y' AND rowid<0 AND rowid>=-20
181 do_test intpkey-2.1.3 {
183 SELECT * FROM t1 WHERE b>='y'
186 do_test intpkey-2.1.4 {
188 SELECT * FROM t1 WHERE b>='y' AND rowid<10
192 do_test intpkey-2.2 {
194 UPDATE t1 SET a=8 WHERE b=='y';
195 SELECT * FROM t1 WHERE b=='y';
198 do_test intpkey-2.3 {
200 SELECT rowid, * FROM t1;
202 } {4 4 one two 5 5 hello world 6 6 second entry 8 8 y z}
203 do_test intpkey-2.4 {
205 SELECT rowid, * FROM t1 WHERE b<'second'
207 } {5 5 hello world 4 4 one two}
208 do_test intpkey-2.4.1 {
210 SELECT rowid, * FROM t1 WHERE 'second'>b
212 } {5 5 hello world 4 4 one two}
213 do_test intpkey-2.4.2 {
215 SELECT rowid, * FROM t1 WHERE 8>rowid AND 'second'>b
217 } {4 4 one two 5 5 hello world}
218 do_test intpkey-2.4.3 {
220 SELECT rowid, * FROM t1 WHERE 8>rowid AND 'second'>b AND 0<rowid
222 } {4 4 one two 5 5 hello world}
223 do_test intpkey-2.5 {
225 SELECT rowid, * FROM t1 WHERE b>'a'
227 } {5 5 hello world 4 4 one two 6 6 second entry 8 8 y z}
228 do_test intpkey-2.6 {
230 DELETE FROM t1 WHERE rowid=4;
231 SELECT * FROM t1 WHERE b>'a';
233 } {5 hello world 6 second entry 8 y z}
234 do_test intpkey-2.7 {
236 UPDATE t1 SET a=-4 WHERE rowid=8;
237 SELECT * FROM t1 WHERE b>'a';
239 } {5 hello world 6 second entry -4 y z}
240 do_test intpkey-2.7 {
244 } {-4 y z 5 hello world 6 second entry}
246 # Do an SQL statement. Append the search count to the end of the result.
249 set ::sqlite_search_count 0
250 return [concat [execsql $sql] $::sqlite_search_count]
253 # Create indices that include the integer primary key as one of their
256 do_test intpkey-3.1 {
258 CREATE INDEX i2 ON t1(a);
261 do_test intpkey-3.2 {
263 SELECT * FROM t1 WHERE a=5;
266 do_test intpkey-3.3 {
268 SELECT * FROM t1 WHERE a>4 AND a<6;
271 do_test intpkey-3.4 {
273 SELECT * FROM t1 WHERE b>='hello' AND b<'hello2';
276 do_test intpkey-3.5 {
278 CREATE INDEX i3 ON t1(c,a);
281 do_test intpkey-3.6 {
283 SELECT * FROM t1 WHERE c=='world';
286 do_test intpkey-3.7 {
287 execsql {INSERT INTO t1 VALUES(11,'hello','world')}
289 SELECT * FROM t1 WHERE c=='world';
291 } {5 hello world 11 hello world 5}
292 do_test intpkey-3.8 {
294 SELECT * FROM t1 WHERE c=='world' AND a>7;
297 do_test intpkey-3.9 {
299 SELECT * FROM t1 WHERE 7<a;
303 # Test inequality constraints on integer primary keys and rowids
305 do_test intpkey-4.1 {
307 SELECT * FROM t1 WHERE 11=rowid
310 do_test intpkey-4.2 {
312 SELECT * FROM t1 WHERE 11=rowid AND b=='hello'
315 do_test intpkey-4.3 {
317 SELECT * FROM t1 WHERE 11=rowid AND b=='hello' AND c IS NOT NULL;
320 do_test intpkey-4.4 {
322 SELECT * FROM t1 WHERE rowid==11
325 do_test intpkey-4.5 {
327 SELECT * FROM t1 WHERE oid==11 AND b=='hello'
330 do_test intpkey-4.6 {
332 SELECT * FROM t1 WHERE a==11 AND b=='hello' AND c IS NOT NULL;
336 do_test intpkey-4.7 {
338 SELECT * FROM t1 WHERE 8<rowid;
341 do_test intpkey-4.8 {
343 SELECT * FROM t1 WHERE 8<rowid AND 11>=oid;
346 do_test intpkey-4.9 {
348 SELECT * FROM t1 WHERE 11<=_rowid_ AND 12>=a;
351 do_test intpkey-4.10 {
353 SELECT * FROM t1 WHERE 0>=_rowid_;
356 do_test intpkey-4.11 {
358 SELECT * FROM t1 WHERE a<0;
361 do_test intpkey-4.12 {
363 SELECT * FROM t1 WHERE a<0 AND a>10;
367 # Make sure it is OK to insert a rowid of 0
369 do_test intpkey-5.1 {
371 INSERT INTO t1 VALUES(0,'zero','entry');
374 SELECT * FROM t1 WHERE a=0;
377 do_test intpkey-5.2 {
379 SELECT rowid, a FROM t1
381 } {-4 -4 0 0 5 5 6 6 11 11}
383 # Test the ability of the COPY command to put data into a
384 # table that contains an integer primary key.
386 # COPY command has been removed. But we retain these tests so
387 # that the tables will contain the right data for tests that follow.
389 do_test intpkey-6.1 {
392 INSERT INTO t1 VALUES(20,'b-20','c-20');
393 INSERT INTO t1 VALUES(21,'b-21','c-21');
394 INSERT INTO t1 VALUES(22,'b-22','c-22');
396 SELECT * FROM t1 WHERE a>=20;
398 } {20 b-20 c-20 21 b-21 c-21 22 b-22 c-22}
399 do_test intpkey-6.2 {
401 SELECT * FROM t1 WHERE b=='hello'
403 } {5 hello world 11 hello world}
404 do_test intpkey-6.3 {
406 DELETE FROM t1 WHERE b='b-21';
407 SELECT * FROM t1 WHERE b=='b-21';
410 do_test intpkey-6.4 {
412 SELECT * FROM t1 WHERE a>=20
414 } {20 b-20 c-20 22 b-22 c-22}
416 # Do an insert of values with the columns specified out of order.
418 do_test intpkey-7.1 {
420 INSERT INTO t1(c,b,a) VALUES('row','new',30);
421 SELECT * FROM t1 WHERE rowid>=30;
424 do_test intpkey-7.2 {
426 SELECT * FROM t1 WHERE rowid>20;
428 } {22 b-22 c-22 30 new row}
430 # Do an insert from a select statement.
432 do_test intpkey-8.1 {
434 CREATE TABLE t2(x INTEGER PRIMARY KEY, y, z);
435 INSERT INTO t2 SELECT * FROM t1;
436 SELECT rowid FROM t2;
438 } {-4 0 5 6 11 20 22 30}
439 do_test intpkey-8.2 {
443 } {-4 0 5 6 11 20 22 30}
445 do_test intpkey-9.1 {
447 UPDATE t1 SET c='www' WHERE c='world';
448 SELECT rowid, a, c FROM t1 WHERE c=='www';
450 } {5 5 www 11 11 www}
453 # Check insert of NULL for primary key
455 do_test intpkey-10.1 {
458 CREATE TABLE t2(x INTEGER PRIMARY KEY, y, z);
459 INSERT INTO t2 VALUES(NULL, 1, 2);
463 do_test intpkey-10.2 {
465 INSERT INTO t2 VALUES(NULL, 2, 3);
466 SELECT * from t2 WHERE x=2;
469 do_test intpkey-10.3 {
471 INSERT INTO t2 SELECT NULL, z, y FROM t2;
474 } {1 1 2 2 2 3 3 2 1 4 3 2}
476 # This tests checks to see if a floating point number can be used
477 # to reference an integer primary key.
479 do_test intpkey-11.1 {
481 SELECT b FROM t1 WHERE a=2.0+3.0;
484 do_test intpkey-11.1 {
486 SELECT b FROM t1 WHERE a=2.0+3.5;
490 integrity_check intpkey-12.1
492 # Try to use a string that looks like a floating point number as
493 # an integer primary key. This should actually work when the floating
494 # point value can be rounded to an integer without loss of data.
496 do_test intpkey-13.1 {
498 SELECT * FROM t1 WHERE a=1;
501 do_test intpkey-13.2 {
503 INSERT INTO t1 VALUES('1.0',2,3);
504 SELECT * FROM t1 WHERE a=1;
507 do_test intpkey-13.3 {
509 INSERT INTO t1 VALUES('1.5',3,4);
511 } {1 {datatype mismatch}}
512 ifcapable {bloblit} {
513 do_test intpkey-13.4 {
515 INSERT INTO t1 VALUES(x'123456',3,4);
517 } {1 {datatype mismatch}}
519 do_test intpkey-13.5 {
521 INSERT INTO t1 VALUES('+1234567890',3,4);
525 # Compare an INTEGER PRIMARY KEY against a TEXT expression. The INTEGER
526 # affinity should be applied to the text value before the comparison
529 do_test intpkey-14.1 {
531 CREATE TABLE t3(a INTEGER PRIMARY KEY, b INTEGER, c TEXT);
532 INSERT INTO t3 VALUES(1, 1, 'one');
533 INSERT INTO t3 VALUES(2, 2, '2');
534 INSERT INTO t3 VALUES(3, 3, 3);
537 do_test intpkey-14.2 {
539 SELECT * FROM t3 WHERE a>2;
542 do_test intpkey-14.3 {
544 SELECT * FROM t3 WHERE a>'2';
547 do_test intpkey-14.4 {
549 SELECT * FROM t3 WHERE a<'2';
552 do_test intpkey-14.5 {
554 SELECT * FROM t3 WHERE a<c;
557 do_test intpkey-14.6 {
559 SELECT * FROM t3 WHERE a=c;
563 # Check for proper handling of primary keys greater than 2^31.
566 do_test intpkey-15.1 {
568 INSERT INTO t1 VALUES(2147483647, 'big-1', 123);
569 SELECT * FROM t1 WHERE a>2147483648;
572 do_test intpkey-15.2 {
574 INSERT INTO t1 VALUES(NULL, 'big-2', 234);
575 SELECT b FROM t1 WHERE a>=2147483648;
578 do_test intpkey-15.3 {
580 SELECT b FROM t1 WHERE a>2147483648;
583 do_test intpkey-15.4 {
585 SELECT b FROM t1 WHERE a>=2147483647;
588 do_test intpkey-15.5 {
590 SELECT b FROM t1 WHERE a<2147483648;
592 } {y zero 2 hello second hello b-20 b-22 new 3 big-1}
593 do_test intpkey-15.6 {
595 SELECT b FROM t1 WHERE a<12345678901;
597 } {y zero 2 hello second hello b-20 b-22 new 3 big-1 big-2}
598 do_test intpkey-15.7 {
600 SELECT b FROM t1 WHERE a>12345678901;