xref: /sqlite-3.40.0/test/index.test (revision 7d44b22d)
1b19a2bc6Sdrh# 2001 September 15
21b6a71feSdrh#
3b19a2bc6Sdrh# The author disclaims copyright to this source code.  In place of
4b19a2bc6Sdrh# a legal notice, here is a blessing:
51b6a71feSdrh#
6b19a2bc6Sdrh#    May you do good and not evil.
7b19a2bc6Sdrh#    May you find forgiveness for yourself and forgive others.
8b19a2bc6Sdrh#    May you share freely, never taking more than you give.
91b6a71feSdrh#
101b6a71feSdrh#***********************************************************************
111b6a71feSdrh# This file implements regression tests for SQLite library.  The
121b6a71feSdrh# focus of this file is testing the CREATE INDEX statement.
131b6a71feSdrh#
1424acd8f9Sdanielk1977# $Id: index.test,v 1.43 2008/01/16 18:20:42 danielk1977 Exp $
151b6a71feSdrh
161b6a71feSdrhset testdir [file dirname $argv0]
171b6a71feSdrhsource $testdir/tester.tcl
181b6a71feSdrh
191b6a71feSdrh# Create a basic index and verify it is added to sqlite_master
201b6a71feSdrh#
211b6a71feSdrhdo_test index-1.1 {
221b6a71feSdrh  execsql {CREATE TABLE test1(f1 int, f2 int, f3 int)}
231b6a71feSdrh  execsql {CREATE INDEX index1 ON test1(f1)}
242803757aSdrh  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
251b6a71feSdrh} {index1 test1}
261b6a71feSdrhdo_test index-1.1b {
271b6a71feSdrh  execsql {SELECT name, sql, tbl_name, type FROM sqlite_master
281b6a71feSdrh           WHERE name='index1'}
291b6a71feSdrh} {index1 {CREATE INDEX index1 ON test1(f1)} test1 index}
301b6a71feSdrhdo_test index-1.1c {
311b6a71feSdrh  db close
32ef4ac8f9Sdrh  sqlite3 db test.db
331b6a71feSdrh  execsql {SELECT name, sql, tbl_name, type FROM sqlite_master
341b6a71feSdrh           WHERE name='index1'}
351b6a71feSdrh} {index1 {CREATE INDEX index1 ON test1(f1)} test1 index}
361b6a71feSdrhdo_test index-1.1d {
371b6a71feSdrh  db close
38ef4ac8f9Sdrh  sqlite3 db test.db
392803757aSdrh  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
401b6a71feSdrh} {index1 test1}
411b6a71feSdrh
421b6a71feSdrh# Verify that the index dies with the table
431b6a71feSdrh#
441b6a71feSdrhdo_test index-1.2 {
451b6a71feSdrh  execsql {DROP TABLE test1}
462803757aSdrh  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
471b6a71feSdrh} {}
481b6a71feSdrh
491b6a71feSdrh# Try adding an index to a table that does not exist
501b6a71feSdrh#
511b6a71feSdrhdo_test index-2.1 {
521b6a71feSdrh  set v [catch {execsql {CREATE INDEX index1 ON test1(f1)}} msg]
531b6a71feSdrh  lappend v $msg
5448dec7e2Sdanielk1977} {1 {no such table: main.test1}}
551b6a71feSdrh
561ccde15dSdrh# Try adding an index on a column of a table where the table
571ccde15dSdrh# exists but the column does not.
581b6a71feSdrh#
591f9ca2c8Sdrhdo_test index-2.1b {
601b6a71feSdrh  execsql {CREATE TABLE test1(f1 int, f2 int, f3 int)}
611b6a71feSdrh  set v [catch {execsql {CREATE INDEX index1 ON test1(f4)}} msg]
621b6a71feSdrh  lappend v $msg
631f9ca2c8Sdrh} {1 {no such column: f4}}
641b6a71feSdrh
651ccde15dSdrh# Try an index with some columns that match and others that do now.
661b6a71feSdrh#
671b6a71feSdrhdo_test index-2.2 {
681b6a71feSdrh  set v [catch {execsql {CREATE INDEX index1 ON test1(f1, f2, f4, f3)}} msg]
691b6a71feSdrh  execsql {DROP TABLE test1}
701b6a71feSdrh  lappend v $msg
711f9ca2c8Sdrh} {1 {no such column: f4}}
721b6a71feSdrh
731b6a71feSdrh# Try creating a bunch of indices on the same table
741b6a71feSdrh#
751b6a71feSdrhset r {}
761b6a71feSdrhfor {set i 1} {$i<100} {incr i} {
77a9e99aeeSdrh  lappend r [format index%02d $i]
781b6a71feSdrh}
791b6a71feSdrhdo_test index-3.1 {
801b6a71feSdrh  execsql {CREATE TABLE test1(f1 int, f2 int, f3 int, f4 int, f5 int)}
811b6a71feSdrh  for {set i 1} {$i<100} {incr i} {
82a9e99aeeSdrh    set sql "CREATE INDEX [format index%02d $i] ON test1(f[expr {($i%5)+1}])"
831b6a71feSdrh    execsql $sql
841b6a71feSdrh  }
851b6a71feSdrh  execsql {SELECT name FROM sqlite_master
861b6a71feSdrh           WHERE type='index' AND tbl_name='test1'
871b6a71feSdrh           ORDER BY name}
881b6a71feSdrh} $r
89e497f005Sdrhintegrity_check index-3.2.1
90e497f005Sdrhifcapable {reindex} {
91e497f005Sdrh  do_test index-3.2.2 {
92e497f005Sdrh    execsql REINDEX
93e497f005Sdrh  } {}
94e497f005Sdrh}
95e497f005Sdrhintegrity_check index-3.2.3
961b6a71feSdrh
971b6a71feSdrh
981b6a71feSdrh# Verify that all the indices go away when we drop the table.
991b6a71feSdrh#
1001b6a71feSdrhdo_test index-3.3 {
1011b6a71feSdrh  execsql {DROP TABLE test1}
1021b6a71feSdrh  execsql {SELECT name FROM sqlite_master
1031b6a71feSdrh           WHERE type='index' AND tbl_name='test1'
1041b6a71feSdrh           ORDER BY name}
1051b6a71feSdrh} {}
1061b6a71feSdrh
1071b6a71feSdrh# Create a table and insert values into that table.  Then create
1081b6a71feSdrh# an index on that table.  Verify that we can select values
1091b6a71feSdrh# from the table correctly using the index.
1101b6a71feSdrh#
1117020f651Sdrh# Note that the index names "index9" and "indext" are chosen because
1127020f651Sdrh# they both have the same hash.
1137020f651Sdrh#
1141b6a71feSdrhdo_test index-4.1 {
1151b6a71feSdrh  execsql {CREATE TABLE test1(cnt int, power int)}
1161b6a71feSdrh  for {set i 1} {$i<20} {incr i} {
11724acd8f9Sdanielk1977    execsql "INSERT INTO test1 VALUES($i,[expr {1<<$i}])"
1181b6a71feSdrh  }
1197020f651Sdrh  execsql {CREATE INDEX index9 ON test1(cnt)}
1207020f651Sdrh  execsql {CREATE INDEX indext ON test1(power)}
1212803757aSdrh  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
1227020f651Sdrh} {index9 indext test1}
1231b6a71feSdrhdo_test index-4.2 {
1241b6a71feSdrh  execsql {SELECT cnt FROM test1 WHERE power=4}
1251b6a71feSdrh} {2}
1261b6a71feSdrhdo_test index-4.3 {
1271b6a71feSdrh  execsql {SELECT cnt FROM test1 WHERE power=1024}
1281b6a71feSdrh} {10}
1291b6a71feSdrhdo_test index-4.4 {
1301b6a71feSdrh  execsql {SELECT power FROM test1 WHERE cnt=6}
1311b6a71feSdrh} {64}
1321b6a71feSdrhdo_test index-4.5 {
1337020f651Sdrh  execsql {DROP INDEX indext}
1347020f651Sdrh  execsql {SELECT power FROM test1 WHERE cnt=6}
1357020f651Sdrh} {64}
1367020f651Sdrhdo_test index-4.6 {
1377020f651Sdrh  execsql {SELECT cnt FROM test1 WHERE power=1024}
1387020f651Sdrh} {10}
1397020f651Sdrhdo_test index-4.7 {
1407020f651Sdrh  execsql {CREATE INDEX indext ON test1(cnt)}
1417020f651Sdrh  execsql {SELECT power FROM test1 WHERE cnt=6}
1427020f651Sdrh} {64}
1437020f651Sdrhdo_test index-4.8 {
1447020f651Sdrh  execsql {SELECT cnt FROM test1 WHERE power=1024}
1457020f651Sdrh} {10}
1467020f651Sdrhdo_test index-4.9 {
1477020f651Sdrh  execsql {DROP INDEX index9}
1487020f651Sdrh  execsql {SELECT power FROM test1 WHERE cnt=6}
1497020f651Sdrh} {64}
1507020f651Sdrhdo_test index-4.10 {
1517020f651Sdrh  execsql {SELECT cnt FROM test1 WHERE power=1024}
1527020f651Sdrh} {10}
1537020f651Sdrhdo_test index-4.11 {
1547020f651Sdrh  execsql {DROP INDEX indext}
1557020f651Sdrh  execsql {SELECT power FROM test1 WHERE cnt=6}
1567020f651Sdrh} {64}
1577020f651Sdrhdo_test index-4.12 {
1587020f651Sdrh  execsql {SELECT cnt FROM test1 WHERE power=1024}
1597020f651Sdrh} {10}
1607020f651Sdrhdo_test index-4.13 {
1611b6a71feSdrh  execsql {DROP TABLE test1}
1622803757aSdrh  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
1631b6a71feSdrh} {}
164ed717fe3Sdrhintegrity_check index-4.14
1651b6a71feSdrh
1661b6a71feSdrh# Do not allow indices to be added to sqlite_master
1671b6a71feSdrh#
1681b6a71feSdrhdo_test index-5.1 {
1691b6a71feSdrh  set v [catch {execsql {CREATE INDEX index1 ON sqlite_master(name)}} msg]
1701b6a71feSdrh  lappend v $msg
1710be9df07Sdrh} {1 {table sqlite_master may not be indexed}}
1721b6a71feSdrhdo_test index-5.2 {
1732803757aSdrh  execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
1741b6a71feSdrh} {}
1751b6a71feSdrh
1761b6a71feSdrh# Do not allow indices with duplicate names to be added
1771b6a71feSdrh#
1781b6a71feSdrhdo_test index-6.1 {
1791b6a71feSdrh  execsql {CREATE TABLE test1(f1 int, f2 int)}
1801b6a71feSdrh  execsql {CREATE TABLE test2(g1 real, g2 real)}
1811b6a71feSdrh  execsql {CREATE INDEX index1 ON test1(f1)}
1821b6a71feSdrh  set v [catch {execsql {CREATE INDEX index1 ON test2(g1)}} msg]
1831b6a71feSdrh  lappend v $msg
1841d37e284Sdrh} {1 {index index1 already exists}}
185e4df0e74Sdrhdo_test index-6.1.1 {
186e4df0e74Sdrh  catchsql {CREATE INDEX [index1] ON test2(g1)}
187e4df0e74Sdrh} {1 {index index1 already exists}}
1881b6a71feSdrhdo_test index-6.1b {
1892803757aSdrh  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
1901b6a71feSdrh} {index1 test1 test2}
1914d91a701Sdrhdo_test index-6.1c {
1924d91a701Sdrh  catchsql {CREATE INDEX IF NOT EXISTS index1 ON test1(f1)}
1934d91a701Sdrh} {0 {}}
1941b6a71feSdrhdo_test index-6.2 {
1951b6a71feSdrh  set v [catch {execsql {CREATE INDEX test1 ON test2(g1)}} msg]
1961b6a71feSdrh  lappend v $msg
1971d37e284Sdrh} {1 {there is already a table named test1}}
1981b6a71feSdrhdo_test index-6.2b {
1992803757aSdrh  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
2001b6a71feSdrh} {index1 test1 test2}
2011b6a71feSdrhdo_test index-6.3 {
2021b6a71feSdrh  execsql {DROP TABLE test1}
2031b6a71feSdrh  execsql {DROP TABLE test2}
2042803757aSdrh  execsql {SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name}
2051b6a71feSdrh} {}
206f5bf0a78Sdrhdo_test index-6.4 {
207f5bf0a78Sdrh  execsql {
208f5bf0a78Sdrh    CREATE TABLE test1(a,b);
209f5bf0a78Sdrh    CREATE INDEX index1 ON test1(a);
210f5bf0a78Sdrh    CREATE INDEX index2 ON test1(b);
211f5bf0a78Sdrh    CREATE INDEX index3 ON test1(a,b);
212f5bf0a78Sdrh    DROP TABLE test1;
213f5bf0a78Sdrh    SELECT name FROM sqlite_master WHERE type!='meta' ORDER BY name;
214f5bf0a78Sdrh  }
215f5bf0a78Sdrh} {}
216ed717fe3Sdrhintegrity_check index-6.5
217ed717fe3Sdrh
2181b6a71feSdrh
2191b6a71feSdrh# Create a primary key
2201b6a71feSdrh#
2211b6a71feSdrhdo_test index-7.1 {
2221b6a71feSdrh  execsql {CREATE TABLE test1(f1 int, f2 int primary key)}
2231b6a71feSdrh  for {set i 1} {$i<20} {incr i} {
22424acd8f9Sdanielk1977    execsql "INSERT INTO test1 VALUES($i,[expr {1<<$i}])"
2251b6a71feSdrh  }
226767c2001Sdrh  execsql {SELECT count(*) FROM test1}
227767c2001Sdrh} {19}
2281b6a71feSdrhdo_test index-7.2 {
2291b6a71feSdrh  execsql {SELECT f1 FROM test1 WHERE f2=65536}
2301b6a71feSdrh} {16}
2311b6a71feSdrhdo_test index-7.3 {
232adbca9cfSdrh  execsql {
233adbca9cfSdrh    SELECT name FROM sqlite_master
234adbca9cfSdrh    WHERE type='index' AND tbl_name='test1'
235adbca9cfSdrh  }
236d8123366Sdanielk1977} {sqlite_autoindex_test1_1}
2371b6a71feSdrhdo_test index-7.4 {
2381b6a71feSdrh  execsql {DROP table test1}
2392803757aSdrh  execsql {SELECT name FROM sqlite_master WHERE type!='meta'}
2401b6a71feSdrh} {}
241ed717fe3Sdrhintegrity_check index-7.5
2421b6a71feSdrh
2437020f651Sdrh# Make sure we cannot drop a non-existant index.
2441b6a71feSdrh#
2451b6a71feSdrhdo_test index-8.1 {
2461b6a71feSdrh  set v [catch {execsql {DROP INDEX index1}} msg]
2471b6a71feSdrh  lappend v $msg
2481d37e284Sdrh} {1 {no such index: index1}}
2491b6a71feSdrh
2507020f651Sdrh# Make sure we don't actually create an index when the EXPLAIN keyword
2517020f651Sdrh# is used.
2527020f651Sdrh#
2537020f651Sdrhdo_test index-9.1 {
2547020f651Sdrh  execsql {CREATE TABLE tab1(a int)}
2556bf89570Sdrh  ifcapable {explain} {
2567020f651Sdrh    execsql {EXPLAIN CREATE INDEX idx1 ON tab1(a)}
2576bf89570Sdrh  }
2587020f651Sdrh  execsql {SELECT name FROM sqlite_master WHERE tbl_name='tab1'}
2597020f651Sdrh} {tab1}
2607020f651Sdrhdo_test index-9.2 {
2617020f651Sdrh  execsql {CREATE INDEX idx1 ON tab1(a)}
2627020f651Sdrh  execsql {SELECT name FROM sqlite_master WHERE tbl_name='tab1' ORDER BY name}
2637020f651Sdrh} {idx1 tab1}
264ed717fe3Sdrhintegrity_check index-9.3
2651b6a71feSdrh
266e840972fSdrh# Allow more than one entry with the same key.
267e840972fSdrh#
268e840972fSdrhdo_test index-10.0 {
269e840972fSdrh  execsql {
270e840972fSdrh    CREATE TABLE t1(a int, b int);
271e840972fSdrh    CREATE INDEX i1 ON t1(a);
272e840972fSdrh    INSERT INTO t1 VALUES(1,2);
273e840972fSdrh    INSERT INTO t1 VALUES(2,4);
274e840972fSdrh    INSERT INTO t1 VALUES(3,8);
275e840972fSdrh    INSERT INTO t1 VALUES(1,12);
276e840972fSdrh    SELECT b FROM t1 WHERE a=1 ORDER BY b;
277e840972fSdrh  }
278e840972fSdrh} {2 12}
279e840972fSdrhdo_test index-10.1 {
280e840972fSdrh  execsql {
281e840972fSdrh    SELECT b FROM t1 WHERE a=2 ORDER BY b;
282e840972fSdrh  }
283e840972fSdrh} {4}
284e840972fSdrhdo_test index-10.2 {
285e840972fSdrh  execsql {
286e840972fSdrh    DELETE FROM t1 WHERE b=12;
287e840972fSdrh    SELECT b FROM t1 WHERE a=1 ORDER BY b;
288e840972fSdrh  }
289e840972fSdrh} {2}
290353f57e0Sdrhdo_test index-10.3 {
291e840972fSdrh  execsql {
292e840972fSdrh    DELETE FROM t1 WHERE b=2;
293e840972fSdrh    SELECT b FROM t1 WHERE a=1 ORDER BY b;
294e840972fSdrh  }
295e840972fSdrh} {}
296353f57e0Sdrhdo_test index-10.4 {
297353f57e0Sdrh  execsql {
298353f57e0Sdrh    DELETE FROM t1;
299353f57e0Sdrh    INSERT INTO t1 VALUES (1,1);
300353f57e0Sdrh    INSERT INTO t1 VALUES (1,2);
301353f57e0Sdrh    INSERT INTO t1 VALUES (1,3);
302353f57e0Sdrh    INSERT INTO t1 VALUES (1,4);
303353f57e0Sdrh    INSERT INTO t1 VALUES (1,5);
304353f57e0Sdrh    INSERT INTO t1 VALUES (1,6);
305353f57e0Sdrh    INSERT INTO t1 VALUES (1,7);
306353f57e0Sdrh    INSERT INTO t1 VALUES (1,8);
307353f57e0Sdrh    INSERT INTO t1 VALUES (1,9);
308353f57e0Sdrh    INSERT INTO t1 VALUES (2,0);
309353f57e0Sdrh    SELECT b FROM t1 WHERE a=1 ORDER BY b;
310353f57e0Sdrh  }
311353f57e0Sdrh} {1 2 3 4 5 6 7 8 9}
312353f57e0Sdrhdo_test index-10.5 {
3133e8c37e7Sdanielk1977  ifcapable subquery {
3143e8c37e7Sdanielk1977    execsql { DELETE FROM t1 WHERE b IN (2, 4, 6, 8); }
3153e8c37e7Sdanielk1977  } else {
3163e8c37e7Sdanielk1977    execsql { DELETE FROM t1 WHERE b = 2 OR b = 4 OR b = 6 OR b = 8; }
3173e8c37e7Sdanielk1977  }
318353f57e0Sdrh  execsql {
319353f57e0Sdrh    SELECT b FROM t1 WHERE a=1 ORDER BY b;
320353f57e0Sdrh  }
321353f57e0Sdrh} {1 3 5 7 9}
322353f57e0Sdrhdo_test index-10.6 {
323353f57e0Sdrh  execsql {
324353f57e0Sdrh    DELETE FROM t1 WHERE b>2;
325353f57e0Sdrh    SELECT b FROM t1 WHERE a=1 ORDER BY b;
326353f57e0Sdrh  }
327353f57e0Sdrh} {1}
328353f57e0Sdrhdo_test index-10.7 {
329353f57e0Sdrh  execsql {
330353f57e0Sdrh    DELETE FROM t1 WHERE b=1;
331353f57e0Sdrh    SELECT b FROM t1 WHERE a=1 ORDER BY b;
332353f57e0Sdrh  }
333353f57e0Sdrh} {}
334353f57e0Sdrhdo_test index-10.8 {
335353f57e0Sdrh  execsql {
336353f57e0Sdrh    SELECT b FROM t1 ORDER BY b;
337353f57e0Sdrh  }
338353f57e0Sdrh} {0}
339ed717fe3Sdrhintegrity_check index-10.9
340353f57e0Sdrh
341c4a3c779Sdrh# Automatically create an index when we specify a primary key.
342c4a3c779Sdrh#
343c4a3c779Sdrhdo_test index-11.1 {
344c4a3c779Sdrh  execsql {
345c4a3c779Sdrh    CREATE TABLE t3(
346c4a3c779Sdrh      a text,
347c4a3c779Sdrh      b int,
348c4a3c779Sdrh      c float,
349c4a3c779Sdrh      PRIMARY KEY(b)
350c4a3c779Sdrh    );
351c4a3c779Sdrh  }
352c4a3c779Sdrh  for {set i 1} {$i<=50} {incr i} {
353c4a3c779Sdrh    execsql "INSERT INTO t3 VALUES('x${i}x',$i,0.$i)"
354c4a3c779Sdrh  }
355487ab3caSdrh  set sqlite_search_count 0
356487ab3caSdrh  concat [execsql {SELECT c FROM t3 WHERE b==10}] $sqlite_search_count
35795e037baSdrh} {0.1 2}
358ed717fe3Sdrhintegrity_check index-11.2
359ed717fe3Sdrh
360e840972fSdrh
3617a7c7390Sdrh# Numeric strings should compare as if they were numbers.  So even if the
3627a7c7390Sdrh# strings are not character-by-character the same, if they represent the
3637a7c7390Sdrh# same number they should compare equal to one another.  Verify that this
3647a7c7390Sdrh# is true in indices.
3657a7c7390Sdrh#
366ef4ac8f9Sdrh# Updated for sqlite3 v3: SQLite will now store these values as numbers
3673d1bfeaaSdanielk1977# (because the affinity of column a is NUMERIC) so the quirky
3683d1bfeaaSdanielk1977# representations are not retained. i.e. '+1.0' becomes '1'.
3697a7c7390Sdrhdo_test index-12.1 {
3707a7c7390Sdrh  execsql {
37193edea93Sdanielk1977    CREATE TABLE t4(a NUM,b);
3727a7c7390Sdrh    INSERT INTO t4 VALUES('0.0',1);
3737a7c7390Sdrh    INSERT INTO t4 VALUES('0.00',2);
3747a7c7390Sdrh    INSERT INTO t4 VALUES('abc',3);
3757a7c7390Sdrh    INSERT INTO t4 VALUES('-1.0',4);
3767a7c7390Sdrh    INSERT INTO t4 VALUES('+1.0',5);
3777a7c7390Sdrh    INSERT INTO t4 VALUES('0',6);
3787a7c7390Sdrh    INSERT INTO t4 VALUES('00000',7);
3797a7c7390Sdrh    SELECT a FROM t4 ORDER BY b;
3807a7c7390Sdrh  }
3818df447f0Sdrh} {0 0 abc -1 1 0 0}
3827a7c7390Sdrhdo_test index-12.2 {
3837a7c7390Sdrh  execsql {
3847a7c7390Sdrh    SELECT a FROM t4 WHERE a==0 ORDER BY b
3857a7c7390Sdrh  }
3868df447f0Sdrh} {0 0 0 0}
3877a7c7390Sdrhdo_test index-12.3 {
3887a7c7390Sdrh  execsql {
3897a7c7390Sdrh    SELECT a FROM t4 WHERE a<0.5 ORDER BY b
3907a7c7390Sdrh  }
3918df447f0Sdrh} {0 0 -1 0 0}
3927a7c7390Sdrhdo_test index-12.4 {
3937a7c7390Sdrh  execsql {
3947a7c7390Sdrh    SELECT a FROM t4 WHERE a>-0.5 ORDER BY b
3957a7c7390Sdrh  }
3968df447f0Sdrh} {0 0 abc 1 0 0}
3977a7c7390Sdrhdo_test index-12.5 {
3987a7c7390Sdrh  execsql {
3997a7c7390Sdrh    CREATE INDEX t4i1 ON t4(a);
4007a7c7390Sdrh    SELECT a FROM t4 WHERE a==0 ORDER BY b
4017a7c7390Sdrh  }
4028df447f0Sdrh} {0 0 0 0}
4037a7c7390Sdrhdo_test index-12.6 {
4047a7c7390Sdrh  execsql {
4057a7c7390Sdrh    SELECT a FROM t4 WHERE a<0.5 ORDER BY b
4067a7c7390Sdrh  }
4078df447f0Sdrh} {0 0 -1 0 0}
4087a7c7390Sdrhdo_test index-12.7 {
4097a7c7390Sdrh  execsql {
4107a7c7390Sdrh    SELECT a FROM t4 WHERE a>-0.5 ORDER BY b
4117a7c7390Sdrh  }
4128df447f0Sdrh} {0 0 abc 1 0 0}
413ed717fe3Sdrhintegrity_check index-12.8
4147a7c7390Sdrh
415485b39b4Sdrh# Make sure we cannot drop an automatically created index.
416485b39b4Sdrh#
417485b39b4Sdrhdo_test index-13.1 {
418485b39b4Sdrh  execsql {
419485b39b4Sdrh   CREATE TABLE t5(
420485b39b4Sdrh      a int UNIQUE,
421485b39b4Sdrh      b float PRIMARY KEY,
422485b39b4Sdrh      c varchar(10),
423485b39b4Sdrh      UNIQUE(a,c)
424485b39b4Sdrh   );
425485b39b4Sdrh   INSERT INTO t5 VALUES(1,2,3);
426485b39b4Sdrh   SELECT * FROM t5;
427485b39b4Sdrh  }
4288a51256cSdrh} {1 2.0 3}
429485b39b4Sdrhdo_test index-13.2 {
430485b39b4Sdrh  set ::idxlist [execsql {
431*7d44b22dSdrh    SELECT name FROM sqlite_master WHERE type='index' AND tbl_name='t5';
432485b39b4Sdrh  }]
433485b39b4Sdrh  llength $::idxlist
434485b39b4Sdrh} {3}
435485b39b4Sdrhfor {set i 0} {$i<[llength $::idxlist]} {incr i} {
436485b39b4Sdrh  do_test index-13.3.$i {
437485b39b4Sdrh    catchsql "
438485b39b4Sdrh      DROP INDEX '[lindex $::idxlist $i]';
439485b39b4Sdrh    "
440485b39b4Sdrh  } {1 {index associated with UNIQUE or PRIMARY KEY constraint cannot be dropped}}
441485b39b4Sdrh}
442485b39b4Sdrhdo_test index-13.4 {
443485b39b4Sdrh  execsql {
444485b39b4Sdrh    INSERT INTO t5 VALUES('a','b','c');
445485b39b4Sdrh    SELECT * FROM t5;
446485b39b4Sdrh  }
4478a51256cSdrh} {1 2.0 3 a b c}
448ed717fe3Sdrhintegrity_check index-13.5
449485b39b4Sdrh
450491791a8Sdrh# Check the sort order of data in an index.
451491791a8Sdrh#
452491791a8Sdrhdo_test index-14.1 {
453491791a8Sdrh  execsql {
454491791a8Sdrh    CREATE TABLE t6(a,b,c);
455491791a8Sdrh    CREATE INDEX t6i1 ON t6(a,b);
456491791a8Sdrh    INSERT INTO t6 VALUES('','',1);
457491791a8Sdrh    INSERT INTO t6 VALUES('',NULL,2);
458491791a8Sdrh    INSERT INTO t6 VALUES(NULL,'',3);
459491791a8Sdrh    INSERT INTO t6 VALUES('abc',123,4);
460491791a8Sdrh    INSERT INTO t6 VALUES(123,'abc',5);
461491791a8Sdrh    SELECT c FROM t6 ORDER BY a,b;
462491791a8Sdrh  }
463491791a8Sdrh} {3 5 2 1 4}
464491791a8Sdrhdo_test index-14.2 {
465491791a8Sdrh  execsql {
466491791a8Sdrh    SELECT c FROM t6 WHERE a='';
467491791a8Sdrh  }
468491791a8Sdrh} {2 1}
469491791a8Sdrhdo_test index-14.3 {
470491791a8Sdrh  execsql {
471491791a8Sdrh    SELECT c FROM t6 WHERE b='';
472491791a8Sdrh  }
473491791a8Sdrh} {1 3}
474491791a8Sdrhdo_test index-14.4 {
475491791a8Sdrh  execsql {
476491791a8Sdrh    SELECT c FROM t6 WHERE a>'';
477491791a8Sdrh  }
478491791a8Sdrh} {4}
479491791a8Sdrhdo_test index-14.5 {
480491791a8Sdrh  execsql {
481491791a8Sdrh    SELECT c FROM t6 WHERE a>='';
482491791a8Sdrh  }
483491791a8Sdrh} {2 1 4}
484491791a8Sdrhdo_test index-14.6 {
485491791a8Sdrh  execsql {
486491791a8Sdrh    SELECT c FROM t6 WHERE a>123;
487491791a8Sdrh  }
488491791a8Sdrh} {2 1 4}
489491791a8Sdrhdo_test index-14.7 {
490491791a8Sdrh  execsql {
491491791a8Sdrh    SELECT c FROM t6 WHERE a>=123;
492491791a8Sdrh  }
493491791a8Sdrh} {5 2 1 4}
494491791a8Sdrhdo_test index-14.8 {
495491791a8Sdrh  execsql {
496491791a8Sdrh    SELECT c FROM t6 WHERE a<'abc';
497491791a8Sdrh  }
498562528c4Sdrh} {5 2 1}
499491791a8Sdrhdo_test index-14.9 {
500491791a8Sdrh  execsql {
501491791a8Sdrh    SELECT c FROM t6 WHERE a<='abc';
502491791a8Sdrh  }
503562528c4Sdrh} {5 2 1 4}
504491791a8Sdrhdo_test index-14.10 {
505491791a8Sdrh  execsql {
506491791a8Sdrh    SELECT c FROM t6 WHERE a<='';
507491791a8Sdrh  }
508562528c4Sdrh} {5 2 1}
509491791a8Sdrhdo_test index-14.11 {
510491791a8Sdrh  execsql {
511491791a8Sdrh    SELECT c FROM t6 WHERE a<'';
512491791a8Sdrh  }
513562528c4Sdrh} {5}
514ed717fe3Sdrhintegrity_check index-14.12
515491791a8Sdrh
516bb07e9a3Sdrhdo_test index-15.1 {
517bb07e9a3Sdrh  execsql {
518bb07e9a3Sdrh    DELETE FROM t1;
519bb07e9a3Sdrh    SELECT * FROM t1;
520bb07e9a3Sdrh  }
521bb07e9a3Sdrh} {}
522bb07e9a3Sdrhdo_test index-15.2 {
523bb07e9a3Sdrh  execsql {
524bb07e9a3Sdrh    INSERT INTO t1 VALUES('1.234e5',1);
525bb07e9a3Sdrh    INSERT INTO t1 VALUES('12.33e04',2);
526bb07e9a3Sdrh    INSERT INTO t1 VALUES('12.35E4',3);
527bb07e9a3Sdrh    INSERT INTO t1 VALUES('12.34e',4);
528bb07e9a3Sdrh    INSERT INTO t1 VALUES('12.32e+4',5);
529bb07e9a3Sdrh    INSERT INTO t1 VALUES('12.36E+04',6);
530bb07e9a3Sdrh    INSERT INTO t1 VALUES('12.36E+',7);
531bb07e9a3Sdrh    INSERT INTO t1 VALUES('+123.10000E+0003',8);
532bb07e9a3Sdrh    INSERT INTO t1 VALUES('+',9);
533bb07e9a3Sdrh    INSERT INTO t1 VALUES('+12347.E+02',10);
534bb07e9a3Sdrh    INSERT INTO t1 VALUES('+12347E+02',11);
535025586a2Sdrh    INSERT INTO t1 VALUES('+.125E+04',12);
536025586a2Sdrh    INSERT INTO t1 VALUES('-.125E+04',13);
537025586a2Sdrh    INSERT INTO t1 VALUES('.125E+0',14);
538025586a2Sdrh    INSERT INTO t1 VALUES('.125',15);
539025586a2Sdrh    SELECT b FROM t1 ORDER BY a, b;
540bb07e9a3Sdrh  }
541025586a2Sdrh} {13 14 15 12 8 5 2 1 3 6 10 11 9 4 7}
542025586a2Sdrhdo_test index-15.3 {
543025586a2Sdrh  execsql {
544025586a2Sdrh    SELECT b FROM t1 WHERE typeof(a) IN ('integer','real') ORDER BY b;
545025586a2Sdrh  }
546025586a2Sdrh} {1 2 3 5 6 8 10 11 12 13 14 15}
547025586a2Sdrhintegrity_check index-15.4
548491791a8Sdrh
549d8123366Sdanielk1977# The following tests - index-16.* - test that when a table definition
550d8123366Sdanielk1977# includes qualifications that specify the same constraint twice only a
551d8123366Sdanielk1977# single index is generated to enforce the constraint.
552d8123366Sdanielk1977#
553d8123366Sdanielk1977# For example: "CREATE TABLE abc( x PRIMARY KEY, UNIQUE(x) );"
554d8123366Sdanielk1977#
555d8123366Sdanielk1977do_test index-16.1 {
556d8123366Sdanielk1977  execsql {
557d8123366Sdanielk1977    CREATE TABLE t7(c UNIQUE PRIMARY KEY);
558d8123366Sdanielk1977    SELECT count(*) FROM sqlite_master WHERE tbl_name = 't7' AND type = 'index';
559d8123366Sdanielk1977  }
560d8123366Sdanielk1977} {1}
561d8123366Sdanielk1977do_test index-16.2 {
562d8123366Sdanielk1977  execsql {
563d8123366Sdanielk1977    DROP TABLE t7;
564d8123366Sdanielk1977    CREATE TABLE t7(c UNIQUE PRIMARY KEY);
565d8123366Sdanielk1977    SELECT count(*) FROM sqlite_master WHERE tbl_name = 't7' AND type = 'index';
566d8123366Sdanielk1977  }
567d8123366Sdanielk1977} {1}
568d8123366Sdanielk1977do_test index-16.3 {
569d8123366Sdanielk1977  execsql {
570d8123366Sdanielk1977    DROP TABLE t7;
571d8123366Sdanielk1977    CREATE TABLE t7(c PRIMARY KEY, UNIQUE(c) );
572d8123366Sdanielk1977    SELECT count(*) FROM sqlite_master WHERE tbl_name = 't7' AND type = 'index';
573d8123366Sdanielk1977  }
574d8123366Sdanielk1977} {1}
575d8123366Sdanielk1977do_test index-16.4 {
576d8123366Sdanielk1977  execsql {
577d8123366Sdanielk1977    DROP TABLE t7;
578d8123366Sdanielk1977    CREATE TABLE t7(c, d , UNIQUE(c, d), PRIMARY KEY(c, d) );
579d8123366Sdanielk1977    SELECT count(*) FROM sqlite_master WHERE tbl_name = 't7' AND type = 'index';
580d8123366Sdanielk1977  }
581d8123366Sdanielk1977} {1}
582d8123366Sdanielk1977do_test index-16.5 {
583d8123366Sdanielk1977  execsql {
584d8123366Sdanielk1977    DROP TABLE t7;
585d8123366Sdanielk1977    CREATE TABLE t7(c, d , UNIQUE(c), PRIMARY KEY(c, d) );
586d8123366Sdanielk1977    SELECT count(*) FROM sqlite_master WHERE tbl_name = 't7' AND type = 'index';
587d8123366Sdanielk1977  }
588d8123366Sdanielk1977} {2}
589d8123366Sdanielk1977
590d8123366Sdanielk1977# Test that automatically create indices are named correctly. The current
591d8123366Sdanielk1977# convention is: "sqlite_autoindex_<table name>_<integer>"
592d8123366Sdanielk1977#
593d8123366Sdanielk1977# Then check that it is an error to try to drop any automtically created
594d8123366Sdanielk1977# indices.
595d8123366Sdanielk1977do_test index-17.1 {
596d8123366Sdanielk1977  execsql {
597d8123366Sdanielk1977    DROP TABLE t7;
598d8123366Sdanielk1977    CREATE TABLE t7(c, d UNIQUE, UNIQUE(c), PRIMARY KEY(c, d) );
599d8123366Sdanielk1977    SELECT name FROM sqlite_master WHERE tbl_name = 't7' AND type = 'index';
600d8123366Sdanielk1977  }
601d8123366Sdanielk1977} {sqlite_autoindex_t7_1 sqlite_autoindex_t7_2 sqlite_autoindex_t7_3}
602d8123366Sdanielk1977do_test index-17.2 {
603d8123366Sdanielk1977  catchsql {
604d8123366Sdanielk1977    DROP INDEX sqlite_autoindex_t7_1;
605d8123366Sdanielk1977  }
606d8123366Sdanielk1977} {1 {index associated with UNIQUE or PRIMARY KEY constraint cannot be dropped}}
6074d91a701Sdrhdo_test index-17.3 {
6084d91a701Sdrh  catchsql {
6094d91a701Sdrh    DROP INDEX IF EXISTS sqlite_autoindex_t7_1;
6104d91a701Sdrh  }
6114d91a701Sdrh} {1 {index associated with UNIQUE or PRIMARY KEY constraint cannot be dropped}}
6124d91a701Sdrhdo_test index-17.4 {
6134d91a701Sdrh  catchsql {
6144d91a701Sdrh    DROP INDEX IF EXISTS no_such_index;
6154d91a701Sdrh  }
6164d91a701Sdrh} {0 {}}
6174d91a701Sdrh
618d8123366Sdanielk1977
619d8123366Sdanielk1977# The following tests ensure that it is not possible to explicitly name
620d8123366Sdanielk1977# a schema object with a name beginning with "sqlite_". Granted that is a
621d8123366Sdanielk1977# little outside the focus of this test scripts, but this has got to be
622d8123366Sdanielk1977# tested somewhere.
623d8123366Sdanielk1977do_test index-18.1 {
624d8123366Sdanielk1977  catchsql {
625d8123366Sdanielk1977    CREATE TABLE sqlite_t1(a, b, c);
626d8123366Sdanielk1977  }
627d8123366Sdanielk1977} {1 {object name reserved for internal use: sqlite_t1}}
6280f1c2eb5Sdrhdo_test index-18.1.2 {
6290f1c2eb5Sdrh  catchsql {
6300f1c2eb5Sdrh    CREATE TABLE sqlite_t1(a, b, c);
6310f1c2eb5Sdrh  }
6320f1c2eb5Sdrh} {1 {object name reserved for internal use: sqlite_t1}}
6330f1c2eb5Sdrhsqlite3_db_config db DEFENSIVE 0
634d8123366Sdanielk1977do_test index-18.2 {
635d8123366Sdanielk1977  catchsql {
636d8123366Sdanielk1977    CREATE INDEX sqlite_i1 ON t7(c);
637d8123366Sdanielk1977  }
638d8123366Sdanielk1977} {1 {object name reserved for internal use: sqlite_i1}}
6390fa8ddbdSdanielk1977ifcapable view {
640d8123366Sdanielk1977do_test index-18.3 {
641d8123366Sdanielk1977  catchsql {
642d8123366Sdanielk1977    CREATE VIEW sqlite_v1 AS SELECT * FROM t7;
643d8123366Sdanielk1977  }
644d8123366Sdanielk1977} {1 {object name reserved for internal use: sqlite_v1}}
6450fa8ddbdSdanielk1977} ;# ifcapable view
646798da52cSdrhifcapable {trigger} {
647d8123366Sdanielk1977  do_test index-18.4 {
648d8123366Sdanielk1977    catchsql {
649d8123366Sdanielk1977      CREATE TRIGGER sqlite_tr1 BEFORE INSERT ON t7 BEGIN SELECT 1; END;
650d8123366Sdanielk1977    }
651d8123366Sdanielk1977  } {1 {object name reserved for internal use: sqlite_tr1}}
652798da52cSdrh}
653f736b771Sdanielk1977do_test index-18.5 {
654f736b771Sdanielk1977  execsql {
655f736b771Sdanielk1977    DROP TABLE t7;
656f736b771Sdanielk1977  }
657f736b771Sdanielk1977} {}
658f736b771Sdanielk1977
659f736b771Sdanielk1977# These tests ensure that if multiple table definition constraints are
660f736b771Sdanielk1977# implemented by a single indice, the correct ON CONFLICT policy applies.
6613bdca9c9Sdanielk1977ifcapable conflict {
662f736b771Sdanielk1977  do_test index-19.1 {
663f736b771Sdanielk1977    execsql {
664f736b771Sdanielk1977      CREATE TABLE t7(a UNIQUE PRIMARY KEY);
665f736b771Sdanielk1977      CREATE TABLE t8(a UNIQUE PRIMARY KEY ON CONFLICT ROLLBACK);
666f736b771Sdanielk1977      INSERT INTO t7 VALUES(1);
667f736b771Sdanielk1977      INSERT INTO t8 VALUES(1);
668f736b771Sdanielk1977    }
669f736b771Sdanielk1977  } {}
670f736b771Sdanielk1977  do_test index-19.2 {
671f736b771Sdanielk1977    catchsql {
672f736b771Sdanielk1977      BEGIN;
673f736b771Sdanielk1977      INSERT INTO t7 VALUES(1);
674f736b771Sdanielk1977    }
675f9c8ce3cSdrh  } {1 {UNIQUE constraint failed: t7.a}}
676f736b771Sdanielk1977  do_test index-19.3 {
677f736b771Sdanielk1977    catchsql {
678f736b771Sdanielk1977      BEGIN;
679f736b771Sdanielk1977    }
680f736b771Sdanielk1977  } {1 {cannot start a transaction within a transaction}}
681f736b771Sdanielk1977  do_test index-19.4 {
682f736b771Sdanielk1977    catchsql {
683f736b771Sdanielk1977      INSERT INTO t8 VALUES(1);
684f736b771Sdanielk1977    }
685f9c8ce3cSdrh  } {1 {UNIQUE constraint failed: t8.a}}
686f736b771Sdanielk1977  do_test index-19.5 {
687f736b771Sdanielk1977    catchsql {
688f736b771Sdanielk1977      BEGIN;
689f736b771Sdanielk1977      COMMIT;
690f736b771Sdanielk1977    }
691f736b771Sdanielk1977  } {0 {}}
692f736b771Sdanielk1977  do_test index-19.6 {
693f736b771Sdanielk1977    catchsql {
694f736b771Sdanielk1977      DROP TABLE t7;
695f736b771Sdanielk1977      DROP TABLE t8;
696f736b771Sdanielk1977      CREATE TABLE t7(
697f736b771Sdanielk1977         a PRIMARY KEY ON CONFLICT FAIL,
698f736b771Sdanielk1977         UNIQUE(a) ON CONFLICT IGNORE
699f736b771Sdanielk1977      );
700f736b771Sdanielk1977    }
701f736b771Sdanielk1977  } {1 {conflicting ON CONFLICT clauses specified}}
7023bdca9c9Sdanielk1977} ; # end of "ifcapable conflict" block
703d8123366Sdanielk1977
704e497f005Sdrhifcapable {reindex} {
705e497f005Sdrh  do_test index-19.7 {
706e497f005Sdrh    execsql REINDEX
707e497f005Sdrh  } {}
708e497f005Sdrh}
709e497f005Sdrhintegrity_check index-19.8
710e497f005Sdrh
71178d153eeSdrh# Drop index with a quoted name.  Ticket #695.
71278d153eeSdrh#
71378d153eeSdrhdo_test index-20.1 {
71478d153eeSdrh  execsql {
71578d153eeSdrh    CREATE INDEX "t6i2" ON t6(c);
71678d153eeSdrh    DROP INDEX "t6i2";
71778d153eeSdrh  }
71878d153eeSdrh} {}
71978d153eeSdrhdo_test index-20.2 {
72078d153eeSdrh  execsql {
72178d153eeSdrh    DROP INDEX "t6i1";
72278d153eeSdrh  }
72378d153eeSdrh} {}
724989b116aSdrh
725989b116aSdrh# Try to create a TEMP index on a non-TEMP table. */
726989b116aSdrh#
727989b116aSdrhdo_test index-21.1 {
728989b116aSdrh  catchsql {
729989b116aSdrh     CREATE INDEX temp.i21 ON t6(c);
730989b116aSdrh  }
731989b116aSdrh} {1 {cannot create a TEMP index on non-TEMP table "t6"}}
732989b116aSdrhdo_test index-21.2 {
733989b116aSdrh  catchsql {
734989b116aSdrh     CREATE TEMP TABLE t6(x);
735989b116aSdrh     INSERT INTO temp.t6 values(1),(5),(9);
736989b116aSdrh     CREATE INDEX temp.i21 ON t6(x);
737989b116aSdrh     SELECT x FROM t6 ORDER BY x DESC;
738989b116aSdrh  }
739989b116aSdrh} {0 {9 5 1}}
740989b116aSdrh
7418a7e11fbSdrh# 2019-05-01 ticket https://www.sqlite.org/src/info/3be1295b264be2fa
7428a7e11fbSdrhdo_execsql_test index-22.0 {
7438a7e11fbSdrh  DROP TABLE IF EXISTS t1;
7448a7e11fbSdrh  CREATE TABLE t1(a, b TEXT);
7458a7e11fbSdrh  CREATE UNIQUE INDEX IF NOT EXISTS x1 ON t1(b==0);
7468a7e11fbSdrh  CREATE INDEX IF NOT EXISTS x2 ON t1(a || 0) WHERE b;
7478a7e11fbSdrh  INSERT INTO t1(a,b) VALUES('a',1),('a',0);
7488a7e11fbSdrh  SELECT a, b, '|' FROM t1;
7498a7e11fbSdrh} {a 1 | a 0 |}
750d8123366Sdanielk1977
7517d0a3fd3Sdrh# 2019-05-10 ticket https://www.sqlite.org/src/info/ae0f637bddc5290b
7527d0a3fd3Sdrhdo_execsql_test index-23.0 {
7537d0a3fd3Sdrh  DROP TABLE t1;
7547d0a3fd3Sdrh  CREATE TABLE t1(a TEXT, b REAL);
7557d0a3fd3Sdrh  CREATE UNIQUE INDEX t1x1 ON t1(a GLOB b);
7567d0a3fd3Sdrh  INSERT INTO t1(a,b) VALUES('0.0','1'),('1.0','1');
7577d0a3fd3Sdrh  SELECT * FROM t1;
7587d0a3fd3Sdrh  REINDEX;
7597d0a3fd3Sdrh} {0.0 1.0 1.0 1.0}
760de7109e6Sdrhdo_execsql_test index-23.1 {
761de7109e6Sdrh  DROP TABLE t1;
762de7109e6Sdrh  CREATE TABLE t1(a REAL);
763de7109e6Sdrh  CREATE UNIQUE INDEX index_0 ON t1(TYPEOF(a));
764de7109e6Sdrh  INSERT OR IGNORE INTO t1(a) VALUES (0.1),(FALSE);
765de7109e6Sdrh  SELECT * FROM t1;
766de7109e6Sdrh  REINDEX;
767de7109e6Sdrh} {0.1}
76878d153eeSdrh
76978d153eeSdrhfinish_test
770