blob: 35b820e49df9af6fc5b7853fdab2d8439128b670 [file] [log] [blame]
drhb19a2bc2001-09-16 00:13:26 +00001# 2001 September 15
drhc4a3c772001-04-04 11:48:57 +00002#
drhb19a2bc2001-09-16 00:13:26 +00003# The author disclaims copyright to this source code. In place of
4# a legal notice, here is a blessing:
drhc4a3c772001-04-04 11:48:57 +00005#
drhb19a2bc2001-09-16 00:13:26 +00006# 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.
drhc4a3c772001-04-04 11:48:57 +00009#
10#***********************************************************************
11# This file implements regression tests for SQLite library. The
12# focus of this file is testing the magic ROWID column that is
13# found on all tables.
14#
drh5cf8e8c2002-02-19 22:42:05 +000015# $Id: rowid.test,v 1.8 2002/02/19 22:42:06 drh Exp $
drhc4a3c772001-04-04 11:48:57 +000016
17set testdir [file dirname $argv0]
18source $testdir/tester.tcl
19
20# Basic ROWID functionality tests.
21#
22do_test rowid-1.1 {
23 execsql {
24 CREATE TABLE t1(x int, y int);
25 INSERT INTO t1 VALUES(1,2);
26 INSERT INTO t1 VALUES(3,4);
27 SELECT x FROM t1 ORDER BY y;
28 }
29} {1 3}
30do_test rowid-1.2 {
31 set r [execsql {SELECT rowid FROM t1 ORDER BY x}]
32 global x2rowid rowid2x
33 set x2rowid(1) [lindex $r 0]
34 set x2rowid(3) [lindex $r 1]
35 set rowid2x($x2rowid(1)) 1
36 set rowid2x($x2rowid(3)) 3
37 llength $r
38} {2}
39do_test rowid-1.3 {
40 global x2rowid
41 set sql "SELECT x FROM t1 WHERE rowid==$x2rowid(1)"
42 execsql $sql
43} {1}
44do_test rowid-1.4 {
45 global x2rowid
46 set sql "SELECT x FROM t1 WHERE rowid==$x2rowid(3)"
47 execsql $sql
48} {3}
49do_test rowid-1.5 {
50 global x2rowid
51 set sql "SELECT x FROM t1 WHERE oid==$x2rowid(1)"
52 execsql $sql
53} {1}
54do_test rowid-1.6 {
55 global x2rowid
56 set sql "SELECT x FROM t1 WHERE OID==$x2rowid(3)"
57 execsql $sql
58} {3}
59do_test rowid-1.7 {
60 global x2rowid
61 set sql "SELECT x FROM t1 WHERE _rowid_==$x2rowid(1)"
62 execsql $sql
63} {1}
drh1eaa2692001-09-18 02:02:23 +000064do_test rowid-1.7.1 {
65 while 1 {
66 set norow [expr {int(rand()*1000000)}]
67 if {$norow!=$x2rowid(1) && $norow!=$x2rowid(3)} break
68 }
69 execsql "SELECT x FROM t1 WHERE rowid=$norow"
70} {}
drhc4a3c772001-04-04 11:48:57 +000071do_test rowid-1.8 {
72 global x2rowid
73 set v [execsql {SELECT x, oid FROM t1 order by x}]
74 set v2 [list 1 $x2rowid(1) 3 $x2rowid(3)]
75 expr {$v==$v2}
76} {1}
77do_test rowid-1.9 {
78 global x2rowid
79 set v [execsql {SELECT x, RowID FROM t1 order by x}]
80 set v2 [list 1 $x2rowid(1) 3 $x2rowid(3)]
81 expr {$v==$v2}
82} {1}
83do_test rowid-1.9 {
84 global x2rowid
85 set v [execsql {SELECT x, _rowid_ FROM t1 order by x}]
86 set v2 [list 1 $x2rowid(1) 3 $x2rowid(3)]
87 expr {$v==$v2}
88} {1}
89
90# We cannot update or insert the ROWID column
91#
92do_test rowid-2.1 {
93 set v [catch {execsql {INSERT INTO t1(rowid,x,y) VALUES(1234,5,6)}} msg]
94 lappend v $msg
95} {1 {table t1 has no column named rowid}}
96do_test rowid-2.2 {
97 set v [catch {execsql {UPDATE t1 SET rowid=12345 WHERE x==1}}]
98 lappend v $msg
99} {1 {table t1 has no column named rowid}}
100do_test rowid-2.3 {
101 set v [catch {execsql {INSERT INTO t1(oid,x,y) VALUES(1234,5,6)}} msg]
102 lappend v $msg
103} {1 {table t1 has no column named oid}}
104do_test rowid-2.4 {
105 set v [catch {execsql {UPDATE t1 SET oid=12345 WHERE x==1}}]
106 lappend v $msg
107} {1 {table t1 has no column named oid}}
108do_test rowid-2.5 {
109 set v [catch {execsql {INSERT INTO t1(_rowid_,x,y) VALUES(1234,5,6)}} msg]
110 lappend v $msg
111} {1 {table t1 has no column named _rowid_}}
112do_test rowid-2.6 {
113 set v [catch {execsql {UPDATE t1 SET _rowid_=12345 WHERE x==1}}]
114 lappend v $msg
115} {1 {table t1 has no column named _rowid_}}
116
117# But we can use ROWID in the WHERE clause of an UPDATE that does not
118# change the ROWID.
119#
120do_test rowid-2.7 {
121 global x2rowid
122 set sql "UPDATE t1 SET x=2 WHERE OID==$x2rowid(3)"
123 execsql $sql
124 execsql {SELECT x FROM t1 ORDER BY x}
125} {1 2}
126do_test rowid-2.8 {
127 global x2rowid
128 set sql "UPDATE t1 SET x=3 WHERE _rowid_==$x2rowid(3)"
129 execsql $sql
130 execsql {SELECT x FROM t1 ORDER BY x}
131} {1 3}
132
133# We cannot index by ROWID
134#
135do_test rowid-2.9 {
136 set v [catch {execsql {CREATE INDEX idxt1 ON t1(rowid)}} msg]
137 lappend v $msg
138} {1 {table t1 has no column named rowid}}
139do_test rowid-2.10 {
140 set v [catch {execsql {CREATE INDEX idxt1 ON t1(_rowid_)}} msg]
141 lappend v $msg
142} {1 {table t1 has no column named _rowid_}}
143do_test rowid-2.11 {
144 set v [catch {execsql {CREATE INDEX idxt1 ON t1(oid)}} msg]
145 lappend v $msg
146} {1 {table t1 has no column named oid}}
147do_test rowid-2.12 {
148 set v [catch {execsql {CREATE INDEX idxt1 ON t1(x, rowid)}} msg]
149 lappend v $msg
150} {1 {table t1 has no column named rowid}}
151
152# Columns defined in the CREATE statement override the buildin ROWID
153# column names.
154#
155do_test rowid-3.1 {
156 execsql {
157 CREATE TABLE t2(rowid int, x int, y int);
drh5cf8e8c2002-02-19 22:42:05 +0000158 INSERT INTO t2 VALUES(0,2,3);
drhc4a3c772001-04-04 11:48:57 +0000159 INSERT INTO t2 VALUES(4,5,6);
160 INSERT INTO t2 VALUES(7,8,9);
161 SELECT * FROM t2 ORDER BY x;
162 }
drh5cf8e8c2002-02-19 22:42:05 +0000163} {0 2 3 4 5 6 7 8 9}
drhc4a3c772001-04-04 11:48:57 +0000164do_test rowid-3.2 {
165 execsql {SELECT * FROM t2 ORDER BY rowid}
drh5cf8e8c2002-02-19 22:42:05 +0000166} {0 2 3 4 5 6 7 8 9}
drhc4a3c772001-04-04 11:48:57 +0000167do_test rowid-3.3 {
168 execsql {SELECT rowid, x, y FROM t2 ORDER BY rowid}
drh5cf8e8c2002-02-19 22:42:05 +0000169} {0 2 3 4 5 6 7 8 9}
drhc4a3c772001-04-04 11:48:57 +0000170do_test rowid-3.4 {
171 set r1 [execsql {SELECT _rowid_, rowid FROM t2 ORDER BY rowid}]
172 foreach {a b c d e f} $r1 {}
173 set r2 [execsql {SELECT _rowid_, rowid FROM t2 ORDER BY x DESC}]
174 foreach {u v w x y z} $r2 {}
175 expr {$u==$e && $w==$c && $y==$a}
176} {1}
177do_probtest rowid-3.5 {
178 set r1 [execsql {SELECT _rowid_, rowid FROM t2 ORDER BY rowid}]
179 foreach {a b c d e f} $r1 {}
180 expr {$a!=$b && $c!=$d && $e!=$f}
181} {1}
182
183# Let's try some more complex examples, including some joins.
184#
185do_test rowid-4.1 {
186 execsql {
187 DELETE FROM t1;
188 DELETE FROM t2;
189 }
190 for {set i 1} {$i<=50} {incr i} {
191 execsql "INSERT INTO t1(x,y) VALUES($i,[expr {$i*$i}])"
192 }
193 execsql {INSERT INTO t2 SELECT _rowid_, x*y, y*y FROM t1}
194 execsql {SELECT t2.y FROM t1, t2 WHERE t1.x==4 AND t1.rowid==t2.rowid}
195} {256}
196do_test rowid-4.2 {
197 execsql {SELECT t2.y FROM t2, t1 WHERE t1.x==4 AND t1.rowid==t2.rowid}
198} {256}
199do_test rowid-4.2.1 {
200 execsql {SELECT t2.y FROM t2, t1 WHERE t1.x==4 AND t1.oid==t2.rowid}
201} {256}
202do_test rowid-4.2.2 {
203 execsql {SELECT t2.y FROM t2, t1 WHERE t1.x==4 AND t1._rowid_==t2.rowid}
204} {256}
205do_test rowid-4.2.3 {
206 execsql {SELECT t2.y FROM t2, t1 WHERE t1.x==4 AND t2.rowid==t1.rowid}
207} {256}
208do_test rowid-4.2.4 {
209 execsql {SELECT t2.y FROM t2, t1 WHERE t2.rowid==t1.oid AND t1.x==4}
210} {256}
211do_test rowid-4.2.5 {
212 execsql {SELECT t2.y FROM t1, t2 WHERE t1.x==4 AND t1._rowid_==t2.rowid}
213} {256}
214do_test rowid-4.2.6 {
215 execsql {SELECT t2.y FROM t1, t2 WHERE t1.x==4 AND t2.rowid==t1.rowid}
216} {256}
217do_test rowid-4.2.7 {
218 execsql {SELECT t2.y FROM t1, t2 WHERE t2.rowid==t1.oid AND t1.x==4}
219} {256}
220do_test rowid-4.3 {
221 execsql {CREATE INDEX idxt1 ON t1(x)}
222 execsql {SELECT t2.y FROM t1, t2 WHERE t1.x==4 AND t1.rowid==t2.rowid}
223} {256}
224do_test rowid-4.3.1 {
225 execsql {SELECT t2.y FROM t1, t2 WHERE t1.x==4 AND t1._rowid_==t2.rowid}
226} {256}
227do_test rowid-4.3.2 {
228 execsql {SELECT t2.y FROM t1, t2 WHERE t2.rowid==t1.oid AND 4==t1.x}
229} {256}
230do_test rowid-4.4 {
231 execsql {SELECT t2.y FROM t2, t1 WHERE t1.x==4 AND t1.rowid==t2.rowid}
232} {256}
233do_test rowid-4.4.1 {
234 execsql {SELECT t2.y FROM t2, t1 WHERE t1.x==4 AND t1._rowid_==t2.rowid}
235} {256}
236do_test rowid-4.4.2 {
237 execsql {SELECT t2.y FROM t2, t1 WHERE t2.rowid==t1.oid AND 4==t1.x}
238} {256}
239do_test rowid-4.5 {
240 execsql {CREATE INDEX idxt2 ON t2(y)}
drh487ab3c2001-11-08 00:45:21 +0000241 set sqlite_search_count 0
242 concat [execsql {
243 SELECT t1.x FROM t2, t1
drhc4a3c772001-04-04 11:48:57 +0000244 WHERE t2.y==256 AND t1.rowid==t2.rowid
drh487ab3c2001-11-08 00:45:21 +0000245 }] $sqlite_search_count
246} {4 3}
drhc4a3c772001-04-04 11:48:57 +0000247do_test rowid-4.5.1 {
drh487ab3c2001-11-08 00:45:21 +0000248 set sqlite_search_count 0
249 concat [execsql {
250 SELECT t1.x FROM t2, t1
drhc4a3c772001-04-04 11:48:57 +0000251 WHERE t1.OID==t2.rowid AND t2.y==81
drh487ab3c2001-11-08 00:45:21 +0000252 }] $sqlite_search_count
253} {3 3}
drhc4a3c772001-04-04 11:48:57 +0000254do_test rowid-4.6 {
255 execsql {
256 SELECT t1.x FROM t1, t2
257 WHERE t2.y==256 AND t1.rowid==t2.rowid
258 }
259} {4}
260
261do_test rowid-5.1 {
262 execsql {DELETE FROM t1 WHERE _rowid_ IN (SELECT oid FROM t1 WHERE x>8)}
263 execsql {SELECT max(x) FROM t1}
264} {8}
drh3543b3e2001-09-15 00:57:59 +0000265
drhc6b52df2002-01-04 03:09:29 +0000266# Make sure a "WHERE rowid=X" clause works when there is no ROWID of X.
267#
268do_test rowid-6.1 {
269 execsql {
270 SELECT x FROM t1
271 }
272} {1 2 3 4 5 6 7 8}
273do_test rowid-6.2 {
drh5cf8e8c2002-02-19 22:42:05 +0000274 for {set ::norow 1} {1} {incr ::norow} {
275 if {[execsql "SELECT x FROM t1 WHERE rowid=$::norow"]==""} break
276 }
drhc6b52df2002-01-04 03:09:29 +0000277 execsql [subst {
278 DELETE FROM t1 WHERE rowid=$::norow
279 }]
280} {}
281do_test rowid-6.3 {
282 execsql {
283 SELECT x FROM t1
284 }
285} {1 2 3 4 5 6 7 8}
286
drh5cf8e8c2002-02-19 22:42:05 +0000287# Beginning with version 2.3.4, SQLite computes rowids of new rows by
288# finding the maximum current rowid and adding one. It falls back to
289# the old random algorithm if the maximum rowid is the largest integer.
290# The following tests are for this new behavior.
291#
292do_test rowid-7.0 {
293 execsql {
294 DELETE FROM t1;
295 DROP TABLE t2;
296 DROP INDEX idxt1;
297 INSERT INTO t1 VALUES(1,2);
298 SELECT rowid, * FROM t1;
299 }
300} {1 1 2}
301do_test rowid-7.1 {
302 execsql {
303 INSERT INTO t1 VALUES(99,100);
304 SELECT rowid,* FROM t1
305 }
306} {1 1 2 2 99 100}
307do_test rowid-7.2 {
308 execsql {
309 CREATE TABLE t2(a INTEGER PRIMARY KEY, b);
310 INSERT INTO t2(b) VALUES(55);
311 SELECT * FROM t2;
312 }
313} {1 55}
314do_test rowid-7.3 {
315 execsql {
316 INSERT INTO t2(b) VALUES(66);
317 SELECT * FROM t2;
318 }
319} {1 55 2 66}
320do_test rowid-7.4 {
321 execsql {
322 INSERT INTO t2(a,b) VALUES(1000000,77);
323 INSERT INTO t2(b) VALUES(88);
324 SELECT * FROM t2;
325 }
326} {1 55 2 66 1000000 77 1000001 88}
327do_test rowid-7.5 {
328 execsql {
329 INSERT INTO t2(a,b) VALUES(2147483647,99);
330 INSERT INTO t2(b) VALUES(11);
331 SELECT b FROM t2 ORDER BY b;
332 }
333} {11 55 66 77 88 99}
334do_test rowid-7.6 {
335 execsql {
336 SELECT b FROM t2 WHERE a NOT IN(1,2,1000000,1000001,2147483647);
337 }
338} {11}
339do_test rowid-7.7 {
340 execsql {
341 INSERT INTO t2(b) VALUES(22);
342 INSERT INTO t2(b) VALUES(33);
343 INSERT INTO t2(b) VALUES(44);
344 INSERT INTO t2(b) VALUES(55);
345 SELECT b FROM t2 WHERE a NOT IN(1,2,1000000,1000001,2147483647) ORDER BY b;
346 }
347} {11 22 33 44 55}
348do_test rowid-7.8 {
349 execsql {
350 DELETE FROM t2 WHERE a!=2;
351 INSERT INTO t2(b) VALUES(111);
352 SELECT * FROM t2;
353 }
354} {2 66 3 111}
drhc6b52df2002-01-04 03:09:29 +0000355
drh3543b3e2001-09-15 00:57:59 +0000356finish_test