blob: a12b31a11e77182ef6b9fb2d476dfc0ef0604ebe [file] [log] [blame]
drhc4a3c772001-04-04 11:48:57 +00001# Copyright (c) 1999, 2000 D. Richard Hipp
2#
3# This program is free software; you can redistribute it and/or
4# modify it under the terms of the GNU General Public
5# License as published by the Free Software Foundation; either
6# version 2 of the License, or (at your option) any later version.
7#
8# This program is distributed in the hope that it will be useful,
9# but WITHOUT ANY WARRANTY; without even the implied warranty of
10# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU
11# General Public License for more details.
12#
13# You should have received a copy of the GNU General Public
14# License along with this library; if not, write to the
15# Free Software Foundation, Inc., 59 Temple Place - Suite 330,
16# Boston, MA 02111-1307, USA.
17#
18# Author contact information:
19# drh@hwaci.com
20# http://www.hwaci.com/drh/
21#
22#***********************************************************************
23# This file implements regression tests for SQLite library. The
24# focus of this file is testing the magic ROWID column that is
25# found on all tables.
26#
27# $Id: rowid.test,v 1.1 2001/04/04 11:48:58 drh Exp $
28
29set testdir [file dirname $argv0]
30source $testdir/tester.tcl
31
32# Basic ROWID functionality tests.
33#
34do_test rowid-1.1 {
35 execsql {
36 CREATE TABLE t1(x int, y int);
37 INSERT INTO t1 VALUES(1,2);
38 INSERT INTO t1 VALUES(3,4);
39 SELECT x FROM t1 ORDER BY y;
40 }
41} {1 3}
42do_test rowid-1.2 {
43 set r [execsql {SELECT rowid FROM t1 ORDER BY x}]
44 global x2rowid rowid2x
45 set x2rowid(1) [lindex $r 0]
46 set x2rowid(3) [lindex $r 1]
47 set rowid2x($x2rowid(1)) 1
48 set rowid2x($x2rowid(3)) 3
49 llength $r
50} {2}
51do_test rowid-1.3 {
52 global x2rowid
53 set sql "SELECT x FROM t1 WHERE rowid==$x2rowid(1)"
54 execsql $sql
55} {1}
56do_test rowid-1.4 {
57 global x2rowid
58 set sql "SELECT x FROM t1 WHERE rowid==$x2rowid(3)"
59 execsql $sql
60} {3}
61do_test rowid-1.5 {
62 global x2rowid
63 set sql "SELECT x FROM t1 WHERE oid==$x2rowid(1)"
64 execsql $sql
65} {1}
66do_test rowid-1.6 {
67 global x2rowid
68 set sql "SELECT x FROM t1 WHERE OID==$x2rowid(3)"
69 execsql $sql
70} {3}
71do_test rowid-1.7 {
72 global x2rowid
73 set sql "SELECT x FROM t1 WHERE _rowid_==$x2rowid(1)"
74 execsql $sql
75} {1}
76do_test rowid-1.8 {
77 global x2rowid
78 set v [execsql {SELECT x, oid FROM t1 order by x}]
79 set v2 [list 1 $x2rowid(1) 3 $x2rowid(3)]
80 expr {$v==$v2}
81} {1}
82do_test rowid-1.9 {
83 global x2rowid
84 set v [execsql {SELECT x, RowID FROM t1 order by x}]
85 set v2 [list 1 $x2rowid(1) 3 $x2rowid(3)]
86 expr {$v==$v2}
87} {1}
88do_test rowid-1.9 {
89 global x2rowid
90 set v [execsql {SELECT x, _rowid_ FROM t1 order by x}]
91 set v2 [list 1 $x2rowid(1) 3 $x2rowid(3)]
92 expr {$v==$v2}
93} {1}
94
95# We cannot update or insert the ROWID column
96#
97do_test rowid-2.1 {
98 set v [catch {execsql {INSERT INTO t1(rowid,x,y) VALUES(1234,5,6)}} msg]
99 lappend v $msg
100} {1 {table t1 has no column named rowid}}
101do_test rowid-2.2 {
102 set v [catch {execsql {UPDATE t1 SET rowid=12345 WHERE x==1}}]
103 lappend v $msg
104} {1 {table t1 has no column named rowid}}
105do_test rowid-2.3 {
106 set v [catch {execsql {INSERT INTO t1(oid,x,y) VALUES(1234,5,6)}} msg]
107 lappend v $msg
108} {1 {table t1 has no column named oid}}
109do_test rowid-2.4 {
110 set v [catch {execsql {UPDATE t1 SET oid=12345 WHERE x==1}}]
111 lappend v $msg
112} {1 {table t1 has no column named oid}}
113do_test rowid-2.5 {
114 set v [catch {execsql {INSERT INTO t1(_rowid_,x,y) VALUES(1234,5,6)}} msg]
115 lappend v $msg
116} {1 {table t1 has no column named _rowid_}}
117do_test rowid-2.6 {
118 set v [catch {execsql {UPDATE t1 SET _rowid_=12345 WHERE x==1}}]
119 lappend v $msg
120} {1 {table t1 has no column named _rowid_}}
121
122# But we can use ROWID in the WHERE clause of an UPDATE that does not
123# change the ROWID.
124#
125do_test rowid-2.7 {
126 global x2rowid
127 set sql "UPDATE t1 SET x=2 WHERE OID==$x2rowid(3)"
128 execsql $sql
129 execsql {SELECT x FROM t1 ORDER BY x}
130} {1 2}
131do_test rowid-2.8 {
132 global x2rowid
133 set sql "UPDATE t1 SET x=3 WHERE _rowid_==$x2rowid(3)"
134 execsql $sql
135 execsql {SELECT x FROM t1 ORDER BY x}
136} {1 3}
137
138# We cannot index by ROWID
139#
140do_test rowid-2.9 {
141 set v [catch {execsql {CREATE INDEX idxt1 ON t1(rowid)}} msg]
142 lappend v $msg
143} {1 {table t1 has no column named rowid}}
144do_test rowid-2.10 {
145 set v [catch {execsql {CREATE INDEX idxt1 ON t1(_rowid_)}} msg]
146 lappend v $msg
147} {1 {table t1 has no column named _rowid_}}
148do_test rowid-2.11 {
149 set v [catch {execsql {CREATE INDEX idxt1 ON t1(oid)}} msg]
150 lappend v $msg
151} {1 {table t1 has no column named oid}}
152do_test rowid-2.12 {
153 set v [catch {execsql {CREATE INDEX idxt1 ON t1(x, rowid)}} msg]
154 lappend v $msg
155} {1 {table t1 has no column named rowid}}
156
157# Columns defined in the CREATE statement override the buildin ROWID
158# column names.
159#
160do_test rowid-3.1 {
161 execsql {
162 CREATE TABLE t2(rowid int, x int, y int);
163 INSERT INTO t2 VALUES(1,2,3);
164 INSERT INTO t2 VALUES(4,5,6);
165 INSERT INTO t2 VALUES(7,8,9);
166 SELECT * FROM t2 ORDER BY x;
167 }
168} {1 2 3 4 5 6 7 8 9}
169do_test rowid-3.2 {
170 execsql {SELECT * FROM t2 ORDER BY rowid}
171} {1 2 3 4 5 6 7 8 9}
172do_test rowid-3.3 {
173 execsql {SELECT rowid, x, y FROM t2 ORDER BY rowid}
174} {1 2 3 4 5 6 7 8 9}
175do_test rowid-3.4 {
176 set r1 [execsql {SELECT _rowid_, rowid FROM t2 ORDER BY rowid}]
177 foreach {a b c d e f} $r1 {}
178 set r2 [execsql {SELECT _rowid_, rowid FROM t2 ORDER BY x DESC}]
179 foreach {u v w x y z} $r2 {}
180 expr {$u==$e && $w==$c && $y==$a}
181} {1}
182do_probtest rowid-3.5 {
183 set r1 [execsql {SELECT _rowid_, rowid FROM t2 ORDER BY rowid}]
184 foreach {a b c d e f} $r1 {}
185 expr {$a!=$b && $c!=$d && $e!=$f}
186} {1}
187
188# Let's try some more complex examples, including some joins.
189#
190do_test rowid-4.1 {
191 execsql {
192 DELETE FROM t1;
193 DELETE FROM t2;
194 }
195 for {set i 1} {$i<=50} {incr i} {
196 execsql "INSERT INTO t1(x,y) VALUES($i,[expr {$i*$i}])"
197 }
198 execsql {INSERT INTO t2 SELECT _rowid_, x*y, y*y FROM t1}
199 execsql {SELECT t2.y FROM t1, t2 WHERE t1.x==4 AND t1.rowid==t2.rowid}
200} {256}
201do_test rowid-4.2 {
202 execsql {SELECT t2.y FROM t2, t1 WHERE t1.x==4 AND t1.rowid==t2.rowid}
203} {256}
204do_test rowid-4.2.1 {
205 execsql {SELECT t2.y FROM t2, t1 WHERE t1.x==4 AND t1.oid==t2.rowid}
206} {256}
207do_test rowid-4.2.2 {
208 execsql {SELECT t2.y FROM t2, t1 WHERE t1.x==4 AND t1._rowid_==t2.rowid}
209} {256}
210do_test rowid-4.2.3 {
211 execsql {SELECT t2.y FROM t2, t1 WHERE t1.x==4 AND t2.rowid==t1.rowid}
212} {256}
213do_test rowid-4.2.4 {
214 execsql {SELECT t2.y FROM t2, t1 WHERE t2.rowid==t1.oid AND t1.x==4}
215} {256}
216do_test rowid-4.2.5 {
217 execsql {SELECT t2.y FROM t1, t2 WHERE t1.x==4 AND t1._rowid_==t2.rowid}
218} {256}
219do_test rowid-4.2.6 {
220 execsql {SELECT t2.y FROM t1, t2 WHERE t1.x==4 AND t2.rowid==t1.rowid}
221} {256}
222do_test rowid-4.2.7 {
223 execsql {SELECT t2.y FROM t1, t2 WHERE t2.rowid==t1.oid AND t1.x==4}
224} {256}
225do_test rowid-4.3 {
226 execsql {CREATE INDEX idxt1 ON t1(x)}
227 execsql {SELECT t2.y FROM t1, t2 WHERE t1.x==4 AND t1.rowid==t2.rowid}
228} {256}
229do_test rowid-4.3.1 {
230 execsql {SELECT t2.y FROM t1, t2 WHERE t1.x==4 AND t1._rowid_==t2.rowid}
231} {256}
232do_test rowid-4.3.2 {
233 execsql {SELECT t2.y FROM t1, t2 WHERE t2.rowid==t1.oid AND 4==t1.x}
234} {256}
235do_test rowid-4.4 {
236 execsql {SELECT t2.y FROM t2, t1 WHERE t1.x==4 AND t1.rowid==t2.rowid}
237} {256}
238do_test rowid-4.4.1 {
239 execsql {SELECT t2.y FROM t2, t1 WHERE t1.x==4 AND t1._rowid_==t2.rowid}
240} {256}
241do_test rowid-4.4.2 {
242 execsql {SELECT t2.y FROM t2, t1 WHERE t2.rowid==t1.oid AND 4==t1.x}
243} {256}
244do_test rowid-4.5 {
245 execsql {CREATE INDEX idxt2 ON t2(y)}
246 execsql {
247 SELECT t1.x, fcnt() FROM t2, t1
248 WHERE t2.y==256 AND t1.rowid==t2.rowid
249 }
250} {4 3}
251do_test rowid-4.5.1 {
252 execsql {
253 SELECT t1.x, fcnt() FROM t2, t1
254 WHERE t1.OID==t2.rowid AND t2.y==81
255 }
256} {3 3}
257do_test rowid-4.6 {
258 execsql {
259 SELECT t1.x FROM t1, t2
260 WHERE t2.y==256 AND t1.rowid==t2.rowid
261 }
262} {4}
263
264do_test rowid-5.1 {
265 execsql {DELETE FROM t1 WHERE _rowid_ IN (SELECT oid FROM t1 WHERE x>8)}
266 execsql {SELECT max(x) FROM t1}
267} {8}