blob: 79fe7d9b879f524fb80d652121e13f636640ef9e [file] [log] [blame]
drhb24fcbe2000-05-29 23:30:50 +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 CREATE INDEX statement.
25#
drh767c2002000-10-19 14:10:08 +000026# $Id: index.test,v 1.8 2000/10/19 14:10:09 drh Exp $
drhb24fcbe2000-05-29 23:30:50 +000027
28set testdir [file dirname $argv0]
29source $testdir/tester.tcl
30
31# Create a basic index and verify it is added to sqlite_master
32#
drh1b6a71f2000-05-29 23:58:11 +000033do_test index-1.1 {
drhb24fcbe2000-05-29 23:30:50 +000034 execsql {CREATE TABLE test1(f1 int, f2 int, f3 int)}
35 execsql {CREATE INDEX index1 ON test1(f1)}
drh28037572000-08-02 13:47:41 +000036 execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
drhb24fcbe2000-05-29 23:30:50 +000037} {index1 test1}
drh1b6a71f2000-05-29 23:58:11 +000038do_test index-1.1b {
drhb24fcbe2000-05-29 23:30:50 +000039 execsql {SELECT name, sql, tbl_name, type FROM sqlite_master
40 WHERE name='index1'}
41} {index1 {CREATE INDEX index1 ON test1(f1)} test1 index}
drh767c2002000-10-19 14:10:08 +000042skipif memory:
drh1b6a71f2000-05-29 23:58:11 +000043do_test index-1.1c {
drhb24fcbe2000-05-29 23:30:50 +000044 db close
45 sqlite db testdb
46 execsql {SELECT name, sql, tbl_name, type FROM sqlite_master
47 WHERE name='index1'}
48} {index1 {CREATE INDEX index1 ON test1(f1)} test1 index}
drh767c2002000-10-19 14:10:08 +000049skipif memory:
drh1b6a71f2000-05-29 23:58:11 +000050do_test index-1.1d {
drhb24fcbe2000-05-29 23:30:50 +000051 db close
52 sqlite db testdb
drh28037572000-08-02 13:47:41 +000053 execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
drhb24fcbe2000-05-29 23:30:50 +000054} {index1 test1}
55
56# Verify that the index dies with the table
57#
drh1b6a71f2000-05-29 23:58:11 +000058do_test index-1.2 {
drhb24fcbe2000-05-29 23:30:50 +000059 execsql {DROP TABLE test1}
drh28037572000-08-02 13:47:41 +000060 execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
drhb24fcbe2000-05-29 23:30:50 +000061} {}
62
63# Try adding an index to a table that does not exist
64#
drh1b6a71f2000-05-29 23:58:11 +000065do_test index-2.1 {
drhb24fcbe2000-05-29 23:30:50 +000066 set v [catch {execsql {CREATE INDEX index1 ON test1(f1)}} msg]
67 lappend v $msg
68} {1 {no such table: test1}}
69
drh1ccde152000-06-17 13:12:39 +000070# Try adding an index on a column of a table where the table
71# exists but the column does not.
drhb24fcbe2000-05-29 23:30:50 +000072#
drh1b6a71f2000-05-29 23:58:11 +000073do_test index-2.1 {
drhb24fcbe2000-05-29 23:30:50 +000074 execsql {CREATE TABLE test1(f1 int, f2 int, f3 int)}
75 set v [catch {execsql {CREATE INDEX index1 ON test1(f4)}} msg]
76 lappend v $msg
drh1ccde152000-06-17 13:12:39 +000077} {1 {table test1 has no column named f4}}
drhb24fcbe2000-05-29 23:30:50 +000078
drh1ccde152000-06-17 13:12:39 +000079# Try an index with some columns that match and others that do now.
drhb24fcbe2000-05-29 23:30:50 +000080#
drh1b6a71f2000-05-29 23:58:11 +000081do_test index-2.2 {
drhb24fcbe2000-05-29 23:30:50 +000082 set v [catch {execsql {CREATE INDEX index1 ON test1(f1, f2, f4, f3)}} msg]
83 execsql {DROP TABLE test1}
84 lappend v $msg
drh1ccde152000-06-17 13:12:39 +000085} {1 {table test1 has no column named f4}}
drhb24fcbe2000-05-29 23:30:50 +000086
87# Try creating a bunch of indices on the same table
88#
89set r {}
90for {set i 1} {$i<100} {incr i} {
91 lappend r index$i
92}
drh1b6a71f2000-05-29 23:58:11 +000093do_test index-3.1 {
drhb24fcbe2000-05-29 23:30:50 +000094 execsql {CREATE TABLE test1(f1 int, f2 int, f3 int, f4 int, f5 int)}
95 for {set i 1} {$i<100} {incr i} {
96 set sql "CREATE INDEX index$i ON test1(f[expr {($i%5)+1}])"
97 execsql $sql
98 }
99 execsql {SELECT name FROM sqlite_master
100 WHERE type='index' AND tbl_name='test1'
101 ORDER BY name}
102} $r
103
104# Add a single entry to the table. Verify that files are created
105# for every index.
106#
107set r {}
108for {set i 1} {$i<100} {incr i} {
109 lappend r testdb/index$i.tbl
110}
drh767c2002000-10-19 14:10:08 +0000111skipif memory:
drh1b6a71f2000-05-29 23:58:11 +0000112do_test index-3.2 {
drhb24fcbe2000-05-29 23:30:50 +0000113 execsql {INSERT INTO test1 VALUES(1,2,3,4,5)}
114 lsort -dictionary [glob testdb/index*.tbl]
115} $r
116
117# Verify that all the indices go away when we drop the table.
118#
drh1b6a71f2000-05-29 23:58:11 +0000119do_test index-3.3 {
drhb24fcbe2000-05-29 23:30:50 +0000120 execsql {DROP TABLE test1}
121 execsql {SELECT name FROM sqlite_master
122 WHERE type='index' AND tbl_name='test1'
123 ORDER BY name}
124} {}
drh1b6a71f2000-05-29 23:58:11 +0000125do_test index-3.4 {
drhb24fcbe2000-05-29 23:30:50 +0000126 lsort -dictionary [glob -nocomplain testdb/index*.tbl]
127} {}
128
129# Create a table and insert values into that table. Then create
130# an index on that table. Verify that we can select values
131# from the table correctly using the index.
132#
drh7020f652000-06-03 18:06:52 +0000133# Note that the index names "index9" and "indext" are chosen because
134# they both have the same hash.
135#
drh1b6a71f2000-05-29 23:58:11 +0000136do_test index-4.1 {
drhb24fcbe2000-05-29 23:30:50 +0000137 execsql {CREATE TABLE test1(cnt int, power int)}
138 for {set i 1} {$i<20} {incr i} {
139 execsql "INSERT INTO test1 VALUES($i,[expr {int(pow(2,$i))}])"
140 }
drh7020f652000-06-03 18:06:52 +0000141 execsql {CREATE INDEX index9 ON test1(cnt)}
142 execsql {CREATE INDEX indext ON test1(power)}
drh28037572000-08-02 13:47:41 +0000143 execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
drh7020f652000-06-03 18:06:52 +0000144} {index9 indext test1}
drh1b6a71f2000-05-29 23:58:11 +0000145do_test index-4.2 {
drhb24fcbe2000-05-29 23:30:50 +0000146 execsql {SELECT cnt FROM test1 WHERE power=4}
147} {2}
drh1b6a71f2000-05-29 23:58:11 +0000148do_test index-4.3 {
drhb24fcbe2000-05-29 23:30:50 +0000149 execsql {SELECT cnt FROM test1 WHERE power=1024}
150} {10}
drh1b6a71f2000-05-29 23:58:11 +0000151do_test index-4.4 {
drhb24fcbe2000-05-29 23:30:50 +0000152 execsql {SELECT power FROM test1 WHERE cnt=6}
153} {64}
drh1b6a71f2000-05-29 23:58:11 +0000154do_test index-4.5 {
drh7020f652000-06-03 18:06:52 +0000155 execsql {DROP INDEX indext}
156 execsql {SELECT power FROM test1 WHERE cnt=6}
157} {64}
158do_test index-4.6 {
159 execsql {SELECT cnt FROM test1 WHERE power=1024}
160} {10}
161do_test index-4.7 {
162 execsql {CREATE INDEX indext ON test1(cnt)}
163 execsql {SELECT power FROM test1 WHERE cnt=6}
164} {64}
165do_test index-4.8 {
166 execsql {SELECT cnt FROM test1 WHERE power=1024}
167} {10}
168do_test index-4.9 {
169 execsql {DROP INDEX index9}
170 execsql {SELECT power FROM test1 WHERE cnt=6}
171} {64}
172do_test index-4.10 {
173 execsql {SELECT cnt FROM test1 WHERE power=1024}
174} {10}
175do_test index-4.11 {
176 execsql {DROP INDEX indext}
177 execsql {SELECT power FROM test1 WHERE cnt=6}
178} {64}
179do_test index-4.12 {
180 execsql {SELECT cnt FROM test1 WHERE power=1024}
181} {10}
182do_test index-4.13 {
drhb24fcbe2000-05-29 23:30:50 +0000183 execsql {DROP TABLE test1}
drh28037572000-08-02 13:47:41 +0000184 execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
drhb24fcbe2000-05-29 23:30:50 +0000185} {}
186
187# Do not allow indices to be added to sqlite_master
188#
drh1b6a71f2000-05-29 23:58:11 +0000189do_test index-5.1 {
drhb24fcbe2000-05-29 23:30:50 +0000190 set v [catch {execsql {CREATE INDEX index1 ON sqlite_master(name)}} msg]
191 lappend v $msg
192} {1 {table sqlite_master may not have new indices added}}
drh1b6a71f2000-05-29 23:58:11 +0000193do_test index-5.2 {
drh28037572000-08-02 13:47:41 +0000194 execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
drhb24fcbe2000-05-29 23:30:50 +0000195} {}
196
197# Do not allow indices with duplicate names to be added
198#
drh1b6a71f2000-05-29 23:58:11 +0000199do_test index-6.1 {
drhb24fcbe2000-05-29 23:30:50 +0000200 execsql {CREATE TABLE test1(f1 int, f2 int)}
201 execsql {CREATE TABLE test2(g1 real, g2 real)}
202 execsql {CREATE INDEX index1 ON test1(f1)}
203 set v [catch {execsql {CREATE INDEX index1 ON test2(g1)}} msg]
204 lappend v $msg
drh1d37e282000-05-30 03:12:21 +0000205} {1 {index index1 already exists}}
drh1b6a71f2000-05-29 23:58:11 +0000206do_test index-6.1b {
drh28037572000-08-02 13:47:41 +0000207 execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
drhb24fcbe2000-05-29 23:30:50 +0000208} {index1 test1 test2}
drh1b6a71f2000-05-29 23:58:11 +0000209do_test index-6.2 {
drhb24fcbe2000-05-29 23:30:50 +0000210 set v [catch {execsql {CREATE INDEX test1 ON test2(g1)}} msg]
211 lappend v $msg
drh1d37e282000-05-30 03:12:21 +0000212} {1 {there is already a table named test1}}
drh1b6a71f2000-05-29 23:58:11 +0000213do_test index-6.2b {
drh28037572000-08-02 13:47:41 +0000214 execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
drhb24fcbe2000-05-29 23:30:50 +0000215} {index1 test1 test2}
drh1b6a71f2000-05-29 23:58:11 +0000216do_test index-6.3 {
drhb24fcbe2000-05-29 23:30:50 +0000217 execsql {DROP TABLE test1}
218 execsql {DROP TABLE test2}
drh28037572000-08-02 13:47:41 +0000219 execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
drhb24fcbe2000-05-29 23:30:50 +0000220} {}
221
222# Create a primary key
223#
drh1b6a71f2000-05-29 23:58:11 +0000224do_test index-7.1 {
drhb24fcbe2000-05-29 23:30:50 +0000225 execsql {CREATE TABLE test1(f1 int, f2 int primary key)}
226 for {set i 1} {$i<20} {incr i} {
227 execsql "INSERT INTO test1 VALUES($i,[expr {int(pow(2,$i))}])"
228 }
drh767c2002000-10-19 14:10:08 +0000229 execsql {SELECT count(*) FROM test1}
230} {19}
231skipif memory:
232do_test index-7.1b {
drhb24fcbe2000-05-29 23:30:50 +0000233 lsort -dictionary [glob testdb/test1*.tbl]
234} {testdb/test1.tbl testdb/test1__primary_key.tbl}
drh1b6a71f2000-05-29 23:58:11 +0000235do_test index-7.2 {
drhb24fcbe2000-05-29 23:30:50 +0000236 execsql {SELECT f1 FROM test1 WHERE f2=65536}
237} {16}
drh1b6a71f2000-05-29 23:58:11 +0000238do_test index-7.3 {
drhb24fcbe2000-05-29 23:30:50 +0000239 set code [execsql {EXPLAIN SELECT f1 FROM test1 WHERE f2=65536}]
240 expr {[lsearch $code test1__primary_key]>0}
241} {1}
drh1b6a71f2000-05-29 23:58:11 +0000242do_test index-7.4 {
243 execsql {DROP table test1}
drh28037572000-08-02 13:47:41 +0000244 execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
drh1b6a71f2000-05-29 23:58:11 +0000245} {}
246
drh7020f652000-06-03 18:06:52 +0000247# Make sure we cannot drop a non-existant index.
drh1b6a71f2000-05-29 23:58:11 +0000248#
249do_test index-8.1 {
250 set v [catch {execsql {DROP INDEX index1}} msg]
251 lappend v $msg
drh1d37e282000-05-30 03:12:21 +0000252} {1 {no such index: index1}}
drh1b6a71f2000-05-29 23:58:11 +0000253
drh7020f652000-06-03 18:06:52 +0000254# Make sure we don't actually create an index when the EXPLAIN keyword
255# is used.
256#
257do_test index-9.1 {
258 execsql {CREATE TABLE tab1(a int)}
259 execsql {EXPLAIN CREATE INDEX idx1 ON tab1(a)}
260 execsql {SELECT name FROM sqlite_master WHERE tbl_name='tab1'}
261} {tab1}
262do_test index-9.2 {
263 execsql {CREATE INDEX idx1 ON tab1(a)}
264 execsql {SELECT name FROM sqlite_master WHERE tbl_name='tab1' ORDER BY name}
265} {idx1 tab1}
drhb24fcbe2000-05-29 23:30:50 +0000266
drhe8409722000-06-08 16:54:40 +0000267# Allow more than one entry with the same key.
268#
269do_test index-10.0 {
270 execsql {
271 CREATE TABLE t1(a int, b int);
272 CREATE INDEX i1 ON t1(a);
273 INSERT INTO t1 VALUES(1,2);
274 INSERT INTO t1 VALUES(2,4);
275 INSERT INTO t1 VALUES(3,8);
276 INSERT INTO t1 VALUES(1,12);
277 SELECT b FROM t1 WHERE a=1 ORDER BY b;
278 }
279} {2 12}
280do_test index-10.1 {
281 execsql {
282 SELECT b FROM t1 WHERE a=2 ORDER BY b;
283 }
284} {4}
285do_test index-10.2 {
286 execsql {
287 DELETE FROM t1 WHERE b=12;
288 SELECT b FROM t1 WHERE a=1 ORDER BY b;
289 }
290} {2}
drh353f57e2000-08-02 12:26:28 +0000291do_test index-10.3 {
drhe8409722000-06-08 16:54:40 +0000292 execsql {
293 DELETE FROM t1 WHERE b=2;
294 SELECT b FROM t1 WHERE a=1 ORDER BY b;
295 }
296} {}
drh353f57e2000-08-02 12:26:28 +0000297do_test index-10.4 {
298 execsql {
299 DELETE FROM t1;
300 INSERT INTO t1 VALUES (1,1);
301 INSERT INTO t1 VALUES (1,2);
302 INSERT INTO t1 VALUES (1,3);
303 INSERT INTO t1 VALUES (1,4);
304 INSERT INTO t1 VALUES (1,5);
305 INSERT INTO t1 VALUES (1,6);
306 INSERT INTO t1 VALUES (1,7);
307 INSERT INTO t1 VALUES (1,8);
308 INSERT INTO t1 VALUES (1,9);
309 INSERT INTO t1 VALUES (2,0);
310 SELECT b FROM t1 WHERE a=1 ORDER BY b;
311 }
312} {1 2 3 4 5 6 7 8 9}
313do_test index-10.5 {
314 execsql {
315 DELETE FROM t1 WHERE b IN (2, 4, 6, 8);
316 SELECT b FROM t1 WHERE a=1 ORDER BY b;
317 }
318} {1 3 5 7 9}
319do_test index-10.6 {
320 execsql {
321 DELETE FROM t1 WHERE b>2;
322 SELECT b FROM t1 WHERE a=1 ORDER BY b;
323 }
324} {1}
325do_test index-10.7 {
326 execsql {
327 DELETE FROM t1 WHERE b=1;
328 SELECT b FROM t1 WHERE a=1 ORDER BY b;
329 }
330} {}
331do_test index-10.8 {
332 execsql {
333 SELECT b FROM t1 ORDER BY b;
334 }
335} {0}
336
drhe8409722000-06-08 16:54:40 +0000337
drhb24fcbe2000-05-29 23:30:50 +0000338finish_test