xref: /sqlite-3.40.0/test/index7.test (revision 8210233c)
1d269461cSdrh# 2013-11-04
2d269461cSdrh#
3d269461cSdrh# The author disclaims copyright to this source code.  In place of
4d269461cSdrh# a legal notice, here is a blessing:
5d269461cSdrh#
6d269461cSdrh#    May you do good and not evil.
7d269461cSdrh#    May you find forgiveness for yourself and forgive others.
8d269461cSdrh#    May you share freely, never taking more than you give.
9d269461cSdrh#
10d269461cSdrh#***********************************************************************
11d269461cSdrh#
12d269461cSdrh# Test cases for partial indices in WITHOUT ROWID tables
13d269461cSdrh#
14d269461cSdrh
15d269461cSdrh
16d269461cSdrhset testdir [file dirname $argv0]
17d269461cSdrhsource $testdir/tester.tcl
18d269461cSdrh
19d269461cSdrhifcapable !vtab {
20d269461cSdrh  finish_test
21d269461cSdrh  return
22d269461cSdrh}
23d269461cSdrh
247be0fd9cSdrh# Capture the output of a pragma in a TEMP table.
257be0fd9cSdrh#
267be0fd9cSdrhproc capture_pragma {db tabname sql} {
277be0fd9cSdrh  $db eval "DROP TABLE IF EXISTS temp.$tabname"
287be0fd9cSdrh  set once 1
297be0fd9cSdrh  $db eval $sql x {
307be0fd9cSdrh    if {$once} {
317be0fd9cSdrh      set once 0
327be0fd9cSdrh      set ins "INSERT INTO $tabname VALUES"
337be0fd9cSdrh      set crtab "CREATE TEMP TABLE $tabname "
347be0fd9cSdrh      set sep "("
357be0fd9cSdrh      foreach col $x(*) {
367be0fd9cSdrh        append ins ${sep}\$x($col)
377be0fd9cSdrh        append crtab ${sep}\"$col\"
387be0fd9cSdrh        set sep ,
397be0fd9cSdrh      }
407be0fd9cSdrh      append ins )
417be0fd9cSdrh      append crtab )
427be0fd9cSdrh      $db eval $crtab
437be0fd9cSdrh    }
447be0fd9cSdrh    $db eval $ins
457be0fd9cSdrh  }
467be0fd9cSdrh}
477be0fd9cSdrh
487be0fd9cSdrh
49d269461cSdrhload_static_extension db wholenumber;
50d269461cSdrhdo_test index7-1.1 {
51d269461cSdrh  # Able to parse and manage partial indices
52d269461cSdrh  execsql {
53d269461cSdrh    CREATE TABLE t1(a,b,c PRIMARY KEY) WITHOUT rowid;
54d269461cSdrh    CREATE INDEX t1a ON t1(a) WHERE a IS NOT NULL;
55d269461cSdrh    CREATE INDEX t1b ON t1(b) WHERE b>10;
56d269461cSdrh    CREATE VIRTUAL TABLE nums USING wholenumber;
57d269461cSdrh    INSERT INTO t1(a,b,c)
58d269461cSdrh       SELECT CASE WHEN value%3!=0 THEN value END, value, value
59d269461cSdrh         FROM nums WHERE value<=20;
60d269461cSdrh    SELECT count(a), count(b) FROM t1;
61d269461cSdrh    PRAGMA integrity_check;
62d269461cSdrh  }
63d269461cSdrh} {14 20 ok}
64d269461cSdrh
657be0fd9cSdrh# (The "partial" column of the PRAGMA index_list output is...)
667be0fd9cSdrh# EVIDENCE-OF: R-34457-09668 "1" if the index is a partial index and "0"
677be0fd9cSdrh# if not.
687be0fd9cSdrh#
697be0fd9cSdrhdo_test index7-1.1a {
707be0fd9cSdrh  capture_pragma db out {PRAGMA index_list(t1)}
717be0fd9cSdrh  db eval {SELECT "name", "partial", '|' FROM out ORDER BY "name"}
727be0fd9cSdrh} {sqlite_autoindex_t1_1 0 | t1a 1 | t1b 1 |}
737be0fd9cSdrh
74d269461cSdrh# Make sure the count(*) optimization works correctly with
75d269461cSdrh# partial indices.  Ticket [a5c8ed66cae16243be6] 2013-10-03.
76d269461cSdrh#
77d269461cSdrhdo_execsql_test index7-1.1.1 {
78d269461cSdrh  SELECT count(*) FROM t1;
79d269461cSdrh} {20}
80d269461cSdrh
81d269461cSdrh# Error conditions during parsing...
82d269461cSdrh#
83d269461cSdrhdo_test index7-1.2 {
84d269461cSdrh  catchsql {
85d269461cSdrh    CREATE INDEX bad1 ON t1(a,b) WHERE x IS NOT NULL;
86d269461cSdrh  }
87d269461cSdrh} {1 {no such column: x}}
88d269461cSdrhdo_test index7-1.3 {
89d269461cSdrh  catchsql {
90d269461cSdrh    CREATE INDEX bad1 ON t1(a,b) WHERE EXISTS(SELECT * FROM t1);
91d269461cSdrh  }
92d269461cSdrh} {1 {subqueries prohibited in partial index WHERE clauses}}
93d269461cSdrhdo_test index7-1.4 {
94d269461cSdrh  catchsql {
95d269461cSdrh    CREATE INDEX bad1 ON t1(a,b) WHERE a!=?1;
96d269461cSdrh  }
97d269461cSdrh} {1 {parameters prohibited in partial index WHERE clauses}}
98d269461cSdrhdo_test index7-1.5 {
99d269461cSdrh  catchsql {
100d269461cSdrh    CREATE INDEX bad1 ON t1(a,b) WHERE a!=random();
101d269461cSdrh  }
102a71c743aSdrh} {1 {non-deterministic functions prohibited in partial index WHERE clauses}}
103d269461cSdrhdo_test index7-1.6 {
104d269461cSdrh  catchsql {
105d269461cSdrh    CREATE INDEX bad1 ON t1(a,b) WHERE a NOT LIKE 'abc%';
106d269461cSdrh  }
107a71c743aSdrh} {0 {}}
108a71c743aSdrhdo_execsql_test index7-1.7 {
109a71c743aSdrh  INSERT INTO t1(a,b,c)
110a71c743aSdrh     VALUES('abcde',1,101),('abdef',2,102),('xyz',3,103),('abcz',4,104);
111a71c743aSdrh  SELECT c FROM t1 WHERE a NOT LIKE 'abc%' AND a=7 ORDER BY +b;
112a71c743aSdrh} {7}
113a71c743aSdrhdo_execsql_test index7-1.7eqp {
114a71c743aSdrh  EXPLAIN QUERY PLAN
115a71c743aSdrh  SELECT b FROM t1 WHERE a NOT LIKE 'abc%' AND a=7 ORDER BY +b;
116*8210233cSdrh} {/SEARCH t1 USING COVERING INDEX bad1 /}
117a71c743aSdrhdo_execsql_test index7-1.8 {
118a71c743aSdrh  DELETE FROM t1 WHERE c>=101;
119a71c743aSdrh  DROP INDEX IF EXISTS bad1;
120a71c743aSdrh} {}
121d269461cSdrh
122d269461cSdrhdo_test index7-1.10 {
123d269461cSdrh  execsql {
124d269461cSdrh    ANALYZE;
125d269461cSdrh    SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
126d269461cSdrh    PRAGMA integrity_check;
127d269461cSdrh  }
128d269461cSdrh} {t1 {20 1} t1a {14 1} t1b {10 1} ok}
129d269461cSdrh
130d269461cSdrh# STAT1 shows the partial indices have a reduced number of
131d269461cSdrh# rows.
132d269461cSdrh#
133d269461cSdrhdo_test index7-1.11 {
134d269461cSdrh  execsql {
135d269461cSdrh    UPDATE t1 SET a=b;
136d269461cSdrh    ANALYZE;
137d269461cSdrh    SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
138d269461cSdrh    PRAGMA integrity_check;
139d269461cSdrh  }
140d269461cSdrh} {t1 {20 1} t1a {20 1} t1b {10 1} ok}
141d269461cSdrh
142d269461cSdrhdo_test index7-1.11b {
143d269461cSdrh  execsql {
144d269461cSdrh    UPDATE t1 SET a=NULL WHERE b%3!=0;
145d269461cSdrh    UPDATE t1 SET b=b+100;
146d269461cSdrh    ANALYZE;
147d269461cSdrh    SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
148d269461cSdrh    PRAGMA integrity_check;
149d269461cSdrh  }
150d269461cSdrh} {t1 {20 1} t1a {6 1} t1b {20 1} ok}
151d269461cSdrh
152d269461cSdrhdo_test index7-1.12 {
153d269461cSdrh  execsql {
154d269461cSdrh    UPDATE t1 SET a=CASE WHEN b%3!=0 THEN b END;
155d269461cSdrh    UPDATE t1 SET b=b-100;
156d269461cSdrh    ANALYZE;
157d269461cSdrh    SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
158d269461cSdrh    PRAGMA integrity_check;
159d269461cSdrh  }
160d269461cSdrh} {t1 {20 1} t1a {13 1} t1b {10 1} ok}
161d269461cSdrh
162d269461cSdrhdo_test index7-1.13 {
163d269461cSdrh  execsql {
164d269461cSdrh    DELETE FROM t1 WHERE b BETWEEN 8 AND 12;
165d269461cSdrh    ANALYZE;
166d269461cSdrh    SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
167d269461cSdrh    PRAGMA integrity_check;
168d269461cSdrh  }
169d269461cSdrh} {t1 {15 1} t1a {10 1} t1b {8 1} ok}
170d269461cSdrh
171d269461cSdrhdo_test index7-1.14 {
172d269461cSdrh  execsql {
173d269461cSdrh    REINDEX;
174d269461cSdrh    ANALYZE;
175d269461cSdrh    SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
176d269461cSdrh    PRAGMA integrity_check;
177d269461cSdrh  }
178d269461cSdrh} {t1 {15 1} t1a {10 1} t1b {8 1} ok}
179d269461cSdrh
180d269461cSdrhdo_test index7-1.15 {
181d269461cSdrh  execsql {
182d269461cSdrh    CREATE INDEX t1c ON t1(c);
183d269461cSdrh    ANALYZE;
184d269461cSdrh    SELECT idx, stat FROM sqlite_stat1 ORDER BY idx;
185d269461cSdrh    PRAGMA integrity_check;
186d269461cSdrh  }
187d269461cSdrh} {t1 {15 1} t1a {10 1} t1b {8 1} t1c {15 1} ok}
188d269461cSdrh
189664d6d13Sdrh# Queries use partial indices at appropriate times.
190d269461cSdrh#
191d269461cSdrhdo_test index7-2.1 {
192d269461cSdrh  execsql {
193d269461cSdrh    CREATE TABLE t2(a,b PRIMARY KEY) without rowid;
194d269461cSdrh    INSERT INTO t2(a,b) SELECT value, value FROM nums WHERE value<1000;
195d269461cSdrh    UPDATE t2 SET a=NULL WHERE b%5==0;
196d269461cSdrh    CREATE INDEX t2a1 ON t2(a) WHERE a IS NOT NULL;
197d269461cSdrh    SELECT count(*) FROM t2 WHERE a IS NOT NULL;
198d269461cSdrh  }
199d269461cSdrh} {800}
200d269461cSdrhdo_test index7-2.2 {
201d269461cSdrh  execsql {
202d269461cSdrh    EXPLAIN QUERY PLAN
203d269461cSdrh    SELECT * FROM t2 WHERE a=5;
204d269461cSdrh  }
205*8210233cSdrh} {/(SCAN|SEARCH) t2 USING COVERING INDEX t2a1 /}
206175b8f06Sdrhifcapable stat4 {
207d269461cSdrh  do_test index7-2.3stat4 {
208d269461cSdrh    execsql {
209d269461cSdrh      EXPLAIN QUERY PLAN
210d269461cSdrh      SELECT * FROM t2 WHERE a IS NOT NULL;
211d269461cSdrh    }
212*8210233cSdrh  } {/(SCAN|SEARCH) t2 USING COVERING INDEX t2a1 /}
213d269461cSdrh} else {
214d269461cSdrh  do_test index7-2.3stat4 {
215d269461cSdrh    execsql {
216d269461cSdrh      EXPLAIN QUERY PLAN
217d269461cSdrh      SELECT * FROM t2 WHERE a IS NOT NULL AND a>0;
218d269461cSdrh    }
219*8210233cSdrh  } {/(SCAN|SEARCH) t2 USING COVERING INDEX t2a1 /}
220d269461cSdrh}
221d269461cSdrhdo_test index7-2.4 {
222d269461cSdrh  execsql {
223d269461cSdrh    EXPLAIN QUERY PLAN
224d269461cSdrh    SELECT * FROM t2 WHERE a IS NULL;
225d269461cSdrh  }
226*8210233cSdrh} {~/INDEX t2a1/}
227d269461cSdrh
228d269461cSdrhdo_execsql_test index7-2.101 {
229d269461cSdrh  DROP INDEX t2a1;
230d269461cSdrh  UPDATE t2 SET a=b, b=b+10000;
231d269461cSdrh  SELECT b FROM t2 WHERE a=15;
232d269461cSdrh} {10015}
233d269461cSdrhdo_execsql_test index7-2.102 {
234d269461cSdrh  CREATE INDEX t2a2 ON t2(a) WHERE a<100 OR a>200;
235d269461cSdrh  SELECT b FROM t2 WHERE a=15;
236d269461cSdrh  PRAGMA integrity_check;
237d269461cSdrh} {10015 ok}
238d269461cSdrhdo_execsql_test index7-2.102eqp {
239d269461cSdrh  EXPLAIN QUERY PLAN
240d269461cSdrh  SELECT b FROM t2 WHERE a=15;
241d269461cSdrh} {~/.*INDEX t2a2.*/}
242d269461cSdrhdo_execsql_test index7-2.103 {
243d269461cSdrh  SELECT b FROM t2 WHERE a=15 AND a<100;
244d269461cSdrh} {10015}
245d269461cSdrhdo_execsql_test index7-2.103eqp {
246d269461cSdrh  EXPLAIN QUERY PLAN
247d269461cSdrh  SELECT b FROM t2 WHERE a=15 AND a<100;
248d269461cSdrh} {/.*INDEX t2a2.*/}
249d269461cSdrhdo_execsql_test index7-2.104 {
250d269461cSdrh  SELECT b FROM t2 WHERE a=515 AND a>200;
251d269461cSdrh} {10515}
252d269461cSdrhdo_execsql_test index7-2.104eqp {
253d269461cSdrh  EXPLAIN QUERY PLAN
254d269461cSdrh  SELECT b FROM t2 WHERE a=515 AND a>200;
255d269461cSdrh} {/.*INDEX t2a2.*/}
256d269461cSdrh
257d269461cSdrh# Partial UNIQUE indices
258d269461cSdrh#
259d269461cSdrhdo_execsql_test index7-3.1 {
260d269461cSdrh  CREATE TABLE t3(a,b PRIMARY KEY) without rowid;
261d269461cSdrh  INSERT INTO t3 SELECT value, value FROM nums WHERE value<200;
262d269461cSdrh  UPDATE t3 SET a=999 WHERE b%5!=0;
263d269461cSdrh  CREATE UNIQUE INDEX t3a ON t3(a) WHERE a<>999;
264d269461cSdrh} {}
265d269461cSdrhdo_test index7-3.2 {
266d269461cSdrh  # unable to insert a duplicate row a-value that is not 999.
267d269461cSdrh  catchsql {
268d269461cSdrh    INSERT INTO t3(a,b) VALUES(150, 'test1');
269d269461cSdrh  }
270f9c8ce3cSdrh} {1 {UNIQUE constraint failed: t3.a}}
271d269461cSdrhdo_test index7-3.3 {
272d269461cSdrh  # can insert multiple rows with a==999 because such rows are not
273d269461cSdrh  # part of the unique index.
274d269461cSdrh  catchsql {
275d269461cSdrh    INSERT INTO t3(a,b) VALUES(999, 'test1'), (999, 'test2');
276d269461cSdrh  }
277d269461cSdrh} {0 {}}
278d269461cSdrhdo_execsql_test index7-3.4 {
279d269461cSdrh  SELECT count(*) FROM t3 WHERE a=999;
280d269461cSdrh} {162}
281d269461cSdrhintegrity_check index7-3.5
282d269461cSdrh
283d269461cSdrhdo_execsql_test index7-4.0 {
284d269461cSdrh  VACUUM;
285d269461cSdrh  PRAGMA integrity_check;
286d269461cSdrh} {ok}
287d269461cSdrh
288d269461cSdrh# Silently ignore database name qualifiers in partial indices.
289d269461cSdrh#
290d269461cSdrhdo_execsql_test index7-5.0 {
291d269461cSdrh  CREATE INDEX t3b ON t3(b) WHERE xyzzy.t3.b BETWEEN 5 AND 10;
292d269461cSdrh                               /* ^^^^^-- ignored */
293d269461cSdrh  ANALYZE;
294d269461cSdrh  SELECT count(*) FROM t3 WHERE t3.b BETWEEN 5 AND 10;
295d269461cSdrh  SELECT stat+0 FROM sqlite_stat1 WHERE idx='t3b';
296d269461cSdrh} {6 6}
297d269461cSdrh
29854ae4e31Sdan# Verify that the problem identified by ticket [98d973b8f5] has been fixed.
2990829169fSdan#
3000829169fSdando_execsql_test index7-6.1 {
3010829169fSdan  CREATE TABLE t5(a, b);
3020829169fSdan  CREATE TABLE t4(c, d);
3030829169fSdan  INSERT INTO t5 VALUES(1, 'xyz');
3040829169fSdan  INSERT INTO t4 VALUES('abc', 'not xyz');
3050829169fSdan  SELECT * FROM (SELECT * FROM t5 WHERE a=1 AND b='xyz'), t4 WHERE c='abc';
3060829169fSdan} {
3070829169fSdan  1 xyz abc {not xyz}
3080829169fSdan}
3090829169fSdando_execsql_test index7-6.2 {
3100829169fSdan  CREATE INDEX i4 ON t4(c) WHERE d='xyz';
3110829169fSdan  SELECT * FROM (SELECT * FROM t5 WHERE a=1 AND b='xyz'), t4 WHERE c='abc';
3120829169fSdan} {
3130829169fSdan  1 xyz abc {not xyz}
3140829169fSdan}
3150829169fSdando_execsql_test index7-6.3 {
3160829169fSdan  CREATE VIEW v4 AS SELECT * FROM t4;
3170829169fSdan  INSERT INTO t4 VALUES('def', 'xyz');
3180829169fSdan  SELECT * FROM v4 WHERE d='xyz' AND c='def'
3190829169fSdan} {
3200829169fSdan  def xyz
3210829169fSdan}
3220829169fSdando_eqp_test index7-6.4 {
3230829169fSdan  SELECT * FROM v4 WHERE d='xyz' AND c='def'
324*8210233cSdrh} {SEARCH t4 USING INDEX i4 (c=?)}
325b3f0276bSdrh
3267088d501Sdrhdo_catchsql_test index7-6.5 {
3277088d501Sdrh  CREATE INDEX t5a ON t5(a) WHERE a=#1;
3287088d501Sdrh} {1 {near "#1": syntax error}}
3297088d501Sdrh
3308ac02a94Sdando_execsql_test index7-7.0 {
3318ac02a94Sdan  CREATE TABLE t6(x, y);
3328ac02a94Sdan  INSERT INTO t6 VALUES(1, 1);
3338ac02a94Sdan  INSERT INTO t6 VALUES(0, 0);
3348ac02a94Sdan  SELECT * FROM t6 WHERE y IS TRUE ORDER BY x;
3358ac02a94Sdan} {1 1}
3368ac02a94Sdan
3378ac02a94Sdando_execsql_test index7-7.1 {
3388ac02a94Sdan  CREATE INDEX i6 ON t6(x) WHERE y IS NOT TRUE;
3398ac02a94Sdan  SELECT * FROM t6 WHERE y IS TRUE ORDER BY x;
3408ac02a94Sdan} {1 1}
3418ac02a94Sdan
34256c65c92Sdrh# 2020-05-27.  tag-20200527-1.
34356c65c92Sdrh# Incomplete stat1 information on a table with few rows should still use the
34456c65c92Sdrh# index.
34556c65c92Sdrhreset_db
34656c65c92Sdrhdo_execsql_test index7-8.1 {
34756c65c92Sdrh  CREATE TABLE t1(x INTEGER PRIMARY KEY, y);
34856c65c92Sdrh  CREATE INDEX t1y ON t1(y) WHERE y IS NOT NULL;
34956c65c92Sdrh  INSERT INTO t1(x) VALUES(1),(2);
35056c65c92Sdrh  ANALYZE;
35156c65c92Sdrh  EXPLAIN QUERY PLAN SELECT 1 FROM t1 WHERE y=5;
352*8210233cSdrh} {/SEARCH t1 USING COVERING INDEX t1y/}
35356c65c92Sdrh
3540829169fSdan
355d269461cSdrhfinish_test
356