xref: /sqlite-3.40.0/test/indexexpr1.test (revision 2aa1086c)
147991425Sdrh# 2015-08-31
247991425Sdrh#
347991425Sdrh# The author disclaims copyright to this source code.  In place of
447991425Sdrh# a legal notice, here is a blessing:
547991425Sdrh#
647991425Sdrh#    May you do good and not evil.
747991425Sdrh#    May you find forgiveness for yourself and forgive others.
847991425Sdrh#    May you share freely, never taking more than you give.
947991425Sdrh#
1047991425Sdrh#***********************************************************************
1147991425Sdrh# This file implements regression tests for SQLite library.  The
1247991425Sdrh# focus of this file is testing indexes on expressions.
1347991425Sdrh#
1447991425Sdrh
1547991425Sdrhset testdir [file dirname $argv0]
1647991425Sdrhsource $testdir/tester.tcl
1747991425Sdrh
1847991425Sdrhdo_execsql_test indexexpr1-100 {
1947991425Sdrh  CREATE TABLE t1(a,b,c);
2047991425Sdrh  INSERT INTO t1(a,b,c)
21390b88a4Sdrh      /*  123456789 123456789 123456789 123456789 123456789 123456789 */
221d85e405Sdrh  VALUES('In_the_beginning_was_the_Word',1,1),
231d85e405Sdrh        ('and_the_Word_was_with_God',1,2),
241d85e405Sdrh        ('and_the_Word_was_God',1,3),
251d85e405Sdrh        ('The_same_was_in_the_beginning_with_God',2,1),
261d85e405Sdrh        ('All_things_were_made_by_him',3,1),
271d85e405Sdrh        ('and_without_him_was_not_any_thing_made_that_was_made',3,2);
2847991425Sdrh  CREATE INDEX t1a1 ON t1(substr(a,1,12));
2947991425Sdrh} {}
3047991425Sdrhdo_execsql_test indexexpr1-110 {
311d85e405Sdrh  SELECT b, c, '|' FROM t1 WHERE substr(a,1,12)=='and_the_Word' ORDER BY b, c;
3247991425Sdrh} {1 2 | 1 3 |}
3347991425Sdrhdo_execsql_test indexexpr1-110eqp {
3447991425Sdrh  EXPLAIN QUERY PLAN
351d85e405Sdrh  SELECT b, c, '|' FROM t1 WHERE substr(a,1,12)=='and_the_Word' ORDER BY b, c;
3647991425Sdrh} {/USING INDEX t1a1/}
3747991425Sdrhdo_execsql_test indexexpr1-120 {
381d85e405Sdrh  SELECT b, c, '|' FROM t1 WHERE 'and_the_Word'==substr(a,1,12) ORDER BY b, c;
3947991425Sdrh} {1 2 | 1 3 |}
4047991425Sdrhdo_execsql_test indexexpr1-120eqp {
4147991425Sdrh  EXPLAIN QUERY PLAN
421d85e405Sdrh  SELECT b, c, '|' FROM t1 WHERE 'and_the_Word'==substr(a,1,12) ORDER BY b, c;
4347991425Sdrh} {/USING INDEX t1a1/}
4447991425Sdrh
451d85e405Sdrhdo_execsql_test indexexpr1-130 {
461d85e405Sdrh  CREATE INDEX t1ba ON t1(b,substr(a,2,3),c);
471d85e405Sdrh  SELECT c FROM t1 WHERE b=1 AND substr(a,2,3)='nd_' ORDER BY c;
481d85e405Sdrh} {2 3}
491d85e405Sdrhdo_execsql_test indexexpr1-130eqp {
501d85e405Sdrh  EXPLAIN QUERY PLAN
511d85e405Sdrh  SELECT c FROM t1 WHERE b=1 AND substr(a,2,3)='nd_' ORDER BY c;
521d85e405Sdrh} {/USING INDEX t1ba/}
531d85e405Sdrh
541d85e405Sdrhdo_execsql_test indexexpr1-140 {
551d85e405Sdrh  SELECT rowid, substr(a,b,3), '|' FROM t1 ORDER BY 2;
561d85e405Sdrh} {1 In_ | 2 and | 3 and | 6 d_w | 4 he_ | 5 l_t |}
571d85e405Sdrhdo_execsql_test indexexpr1-141 {
581d85e405Sdrh  CREATE INDEX t1abx ON t1(substr(a,b,3));
591d85e405Sdrh  SELECT rowid FROM t1 WHERE substr(a,b,3)<='and' ORDER BY +rowid;
601d85e405Sdrh} {1 2 3}
611d85e405Sdrhdo_execsql_test indexexpr1-141eqp {
621d85e405Sdrh  EXPLAIN QUERY PLAN
631d85e405Sdrh  SELECT rowid FROM t1 WHERE substr(a,b,3)<='and' ORDER BY +rowid;
641d85e405Sdrh} {/USING INDEX t1abx/}
651d85e405Sdrhdo_execsql_test indexexpr1-142 {
661d85e405Sdrh  SELECT rowid FROM t1 WHERE +substr(a,b,3)<='and' ORDER BY +rowid;
671d85e405Sdrh} {1 2 3}
681d85e405Sdrhdo_execsql_test indexexpr1-150 {
691d85e405Sdrh  SELECT rowid FROM t1 WHERE substr(a,b,3) IN ('and','l_t','xyz')
701d85e405Sdrh   ORDER BY +rowid;
711d85e405Sdrh} {2 3 5}
721d85e405Sdrhdo_execsql_test indexexpr1-150eqp {
731d85e405Sdrh  EXPLAIN QUERY PLAN
741d85e405Sdrh  SELECT rowid FROM t1 WHERE substr(a,b,3) IN ('and','l_t','xyz')
751d85e405Sdrh   ORDER BY +rowid;
761d85e405Sdrh} {/USING INDEX t1abx/}
771d85e405Sdrh
7837f3ac8fSdanifcapable altertable {
79390b88a4Sdrh  do_execsql_test indexexpr1-160 {
80390b88a4Sdrh    ALTER TABLE t1 ADD COLUMN d;
81390b88a4Sdrh    UPDATE t1 SET d=length(a);
82390b88a4Sdrh    CREATE INDEX t1a2 ON t1(SUBSTR(a, 27, 3)) WHERE d>=29;
83390b88a4Sdrh    SELECT rowid, b, c FROM t1
84390b88a4Sdrh      WHERE substr(a,27,3)=='ord' AND d>=29;
85390b88a4Sdrh  } {1 1 1}
86390b88a4Sdrh  do_execsql_test indexexpr1-160eqp {
87390b88a4Sdrh    EXPLAIN QUERY PLAN
88390b88a4Sdrh      SELECT rowid, b, c FROM t1
89390b88a4Sdrh      WHERE substr(a,27,3)=='ord' AND d>=29;
90390b88a4Sdrh  } {/USING INDEX t1a2/}
9137f3ac8fSdan}
92390b88a4Sdrh
93dae26fe5Sdrh# ORDER BY using an indexed expression
94dae26fe5Sdrh#
95dae26fe5Sdrhdo_execsql_test indexexpr1-170 {
96dae26fe5Sdrh  CREATE INDEX t1alen ON t1(length(a));
97dae26fe5Sdrh  SELECT length(a) FROM t1 ORDER BY length(a);
98dae26fe5Sdrh} {20 25 27 29 38 52}
99dae26fe5Sdrhdo_execsql_test indexexpr1-170eqp {
100dae26fe5Sdrh  EXPLAIN QUERY PLAN
101dae26fe5Sdrh  SELECT length(a) FROM t1 ORDER BY length(a);
1028210233cSdrh} {/SCAN t1 USING INDEX t1alen/}
103dae26fe5Sdrhdo_execsql_test indexexpr1-171 {
104dae26fe5Sdrh  SELECT length(a) FROM t1 ORDER BY length(a) DESC;
105dae26fe5Sdrh} {52 38 29 27 25 20}
106dae26fe5Sdrhdo_execsql_test indexexpr1-171eqp {
107dae26fe5Sdrh  EXPLAIN QUERY PLAN
108dae26fe5Sdrh  SELECT length(a) FROM t1 ORDER BY length(a) DESC;
1098210233cSdrh} {/SCAN t1 USING INDEX t1alen/}
110390b88a4Sdrh
1111d85e405Sdrhdo_execsql_test indexexpr1-200 {
1121d85e405Sdrh  DROP TABLE t1;
1131d85e405Sdrh  CREATE TABLE t1(id ANY PRIMARY KEY, a,b,c) WITHOUT ROWID;
1141d85e405Sdrh  INSERT INTO t1(id,a,b,c)
1151d85e405Sdrh  VALUES(1,'In_the_beginning_was_the_Word',1,1),
1161d85e405Sdrh        (2,'and_the_Word_was_with_God',1,2),
1171d85e405Sdrh        (3,'and_the_Word_was_God',1,3),
1181d85e405Sdrh        (4,'The_same_was_in_the_beginning_with_God',2,1),
1191d85e405Sdrh        (5,'All_things_were_made_by_him',3,1),
1201d85e405Sdrh        (6,'and_without_him_was_not_any_thing_made_that_was_made',3,2);
1211d85e405Sdrh  CREATE INDEX t1a1 ON t1(substr(a,1,12));
1221d85e405Sdrh} {}
1231d85e405Sdrhdo_execsql_test indexexpr1-210 {
1241d85e405Sdrh  SELECT b, c, '|' FROM t1 WHERE substr(a,1,12)=='and_the_Word' ORDER BY b, c;
1251d85e405Sdrh} {1 2 | 1 3 |}
1261d85e405Sdrhdo_execsql_test indexexpr1-210eqp {
1271d85e405Sdrh  EXPLAIN QUERY PLAN
1281d85e405Sdrh  SELECT b, c, '|' FROM t1 WHERE substr(a,1,12)=='and_the_Word' ORDER BY b, c;
1291d85e405Sdrh} {/USING INDEX t1a1/}
1301d85e405Sdrhdo_execsql_test indexexpr1-220 {
1311d85e405Sdrh  SELECT b, c, '|' FROM t1 WHERE 'and_the_Word'==substr(a,1,12) ORDER BY b, c;
1321d85e405Sdrh} {1 2 | 1 3 |}
1331d85e405Sdrhdo_execsql_test indexexpr1-220eqp {
1341d85e405Sdrh  EXPLAIN QUERY PLAN
1351d85e405Sdrh  SELECT b, c, '|' FROM t1 WHERE 'and_the_Word'==substr(a,1,12) ORDER BY b, c;
1361d85e405Sdrh} {/USING INDEX t1a1/}
1371d85e405Sdrh
1381d85e405Sdrhdo_execsql_test indexexpr1-230 {
1391d85e405Sdrh  CREATE INDEX t1ba ON t1(b,substr(a,2,3),c);
1401d85e405Sdrh  SELECT c FROM t1 WHERE b=1 AND substr(a,2,3)='nd_' ORDER BY c;
1411d85e405Sdrh} {2 3}
1421d85e405Sdrhdo_execsql_test indexexpr1-230eqp {
1431d85e405Sdrh  EXPLAIN QUERY PLAN
1441d85e405Sdrh  SELECT c FROM t1 WHERE b=1 AND substr(a,2,3)='nd_' ORDER BY c;
1451d85e405Sdrh} {/USING INDEX t1ba/}
1461d85e405Sdrh
1471d85e405Sdrhdo_execsql_test indexexpr1-240 {
1481d85e405Sdrh  SELECT id, substr(a,b,3), '|' FROM t1 ORDER BY 2;
1491d85e405Sdrh} {1 In_ | 2 and | 3 and | 6 d_w | 4 he_ | 5 l_t |}
1501d85e405Sdrhdo_execsql_test indexexpr1-241 {
1511d85e405Sdrh  CREATE INDEX t1abx ON t1(substr(a,b,3));
1521d85e405Sdrh  SELECT id FROM t1 WHERE substr(a,b,3)<='and' ORDER BY +id;
1531d85e405Sdrh} {1 2 3}
1541d85e405Sdrhdo_execsql_test indexexpr1-241eqp {
1551d85e405Sdrh  EXPLAIN QUERY PLAN
1561d85e405Sdrh  SELECT id FROM t1 WHERE substr(a,b,3)<='and' ORDER BY +id;
1571d85e405Sdrh} {/USING INDEX t1abx/}
1581d85e405Sdrhdo_execsql_test indexexpr1-242 {
1591d85e405Sdrh  SELECT id FROM t1 WHERE +substr(a,b,3)<='and' ORDER BY +id;
1601d85e405Sdrh} {1 2 3}
1611d85e405Sdrhdo_execsql_test indexexpr1-250 {
1621d85e405Sdrh  SELECT id FROM t1 WHERE substr(a,b,3) IN ('and','l_t','xyz')
1631d85e405Sdrh   ORDER BY +id;
1641d85e405Sdrh} {2 3 5}
1651d85e405Sdrhdo_execsql_test indexexpr1-250eqp {
1661d85e405Sdrh  EXPLAIN QUERY PLAN
1671d85e405Sdrh  SELECT id FROM t1 WHERE substr(a,b,3) IN ('and','l_t','xyz')
1681d85e405Sdrh   ORDER BY +id;
1691d85e405Sdrh} {/USING INDEX t1abx/}
1701d85e405Sdrh
17137f3ac8fSdanifcapable altertable {
172390b88a4Sdrh  do_execsql_test indexexpr1-260 {
173390b88a4Sdrh    ALTER TABLE t1 ADD COLUMN d;
174390b88a4Sdrh    UPDATE t1 SET d=length(a);
175390b88a4Sdrh    CREATE INDEX t1a2 ON t1(SUBSTR(a, 27, 3)) WHERE d>=29;
176390b88a4Sdrh    SELECT id, b, c FROM t1
177390b88a4Sdrh      WHERE substr(a,27,3)=='ord' AND d>=29;
178390b88a4Sdrh  } {1 1 1}
179390b88a4Sdrh  do_execsql_test indexexpr1-260eqp {
180390b88a4Sdrh    EXPLAIN QUERY PLAN
181390b88a4Sdrh      SELECT id, b, c FROM t1
182390b88a4Sdrh      WHERE substr(a,27,3)=='ord' AND d>=29;
183390b88a4Sdrh  } {/USING INDEX t1a2/}
18437f3ac8fSdan}
185390b88a4Sdrh
186390b88a4Sdrh
1871d85e405Sdrhdo_catchsql_test indexexpr1-300 {
1883e34eabcSdrh  CREATE TABLE t2(a,b,c); INSERT INTO t2 VALUES(1,2,3);
1891d85e405Sdrh  CREATE INDEX t2x1 ON t2(a,b+random());
1901d85e405Sdrh} {1 {non-deterministic functions prohibited in index expressions}}
1911d85e405Sdrhdo_catchsql_test indexexpr1-301 {
1923e34eabcSdrh  CREATE INDEX t2x1 ON t2(julianday('now',a));
19320cee7d0Sdrh} {1 {non-deterministic use of julianday() in an index}}
1941d85e405Sdrhdo_catchsql_test indexexpr1-310 {
1951d85e405Sdrh  CREATE INDEX t2x2 ON t2(a,b+(SELECT 15));
1961d85e405Sdrh} {1 {subqueries prohibited in index expressions}}
197390b88a4Sdrhdo_catchsql_test indexexpr1-320 {
198390b88a4Sdrh  CREATE TABLE e1(x,y,UNIQUE(y,substr(x,1,5)));
199390b88a4Sdrh} {1 {expressions prohibited in PRIMARY KEY and UNIQUE constraints}}
200390b88a4Sdrhdo_catchsql_test indexexpr1-330 {
201390b88a4Sdrh  CREATE TABLE e1(x,y,PRIMARY KEY(y,substr(x,1,5)));
202390b88a4Sdrh} {1 {expressions prohibited in PRIMARY KEY and UNIQUE constraints}}
203390b88a4Sdrhdo_catchsql_test indexexpr1-331 {
204390b88a4Sdrh  CREATE TABLE e1(x,y,PRIMARY KEY(y,substr(x,1,5))) WITHOUT ROWID;
205390b88a4Sdrh} {1 {expressions prohibited in PRIMARY KEY and UNIQUE constraints}}
206390b88a4Sdrhdo_catchsql_test indexexpr1-340 {
207390b88a4Sdrh  CREATE TABLE e1(x,y,FOREIGN KEY(substr(y,1,5)) REFERENCES t1);
208390b88a4Sdrh} {1 {near "(": syntax error}}
20947991425Sdrh
2108b576422Sdrhdo_execsql_test indexexpr1-400 {
2118b576422Sdrh  CREATE TABLE t3(a,b,c);
2128b576422Sdrh  WITH RECURSIVE c(x) AS (VALUES(1) UNION SELECT x+1 FROM c WHERE x<30)
2138b576422Sdrh  INSERT INTO t3(a,b,c)
2148b576422Sdrh    SELECT x, printf('ab%04xyz',x), random() FROM c;
2158b576422Sdrh  CREATE UNIQUE INDEX t3abc ON t3(CAST(a AS text), b, substr(c,1,3));
2168b576422Sdrh  SELECT a FROM t3 WHERE CAST(a AS text)<='10' ORDER BY +a;
21768391acdSdrh  PRAGMA integrity_check;
21868391acdSdrh} {1 10 ok}
2198b576422Sdrhdo_catchsql_test indexexpr1-410 {
2208b576422Sdrh  INSERT INTO t3 SELECT * FROM t3 WHERE rowid=10;
2218b576422Sdrh} {1 {UNIQUE constraint failed: index 't3abc'}}
2228b576422Sdrh
2230b8d255cSdrhdo_execsql_test indexexpr1-500 {
2240b8d255cSdrh  CREATE TABLE t5(a);
2250b8d255cSdrh  CREATE TABLE cnt(x);
2260b8d255cSdrh  WITH RECURSIVE
2270b8d255cSdrh    c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<5)
2280b8d255cSdrh  INSERT INTO cnt(x) SELECT x FROM c;
2290b8d255cSdrh  INSERT INTO t5(a) SELECT printf('abc%03dxyz',x) FROM cnt;
2300b8d255cSdrh  CREATE INDEX t5ax ON t5( substr(a,4,3) );
2310b8d255cSdrh} {}
2320b8d255cSdrhdo_execsql_test indexexpr1-510 {
2330b8d255cSdrh  -- The use of the "k" alias in the WHERE clause is technically
2340b8d255cSdrh  -- illegal, but SQLite allows it for historical reasons.  In this
2350b8d255cSdrh  -- test and the next, verify that "k" can be used by the t5ax index
2360b8d255cSdrh  SELECT substr(a,4,3) AS k FROM cnt, t5 WHERE k=printf('%03d',x);
2370b8d255cSdrh} {001 002 003 004 005}
2380b8d255cSdrhdo_execsql_test indexexpr1-510eqp {
2390b8d255cSdrh  EXPLAIN QUERY PLAN
2400b8d255cSdrh  SELECT substr(a,4,3) AS k FROM cnt, t5 WHERE k=printf('%03d',x);
2410b8d255cSdrh} {/USING INDEX t5ax/}
2420b8d255cSdrh
243e63e8a6cSdrh# Skip-scan on an indexed expression
244e63e8a6cSdrh#
245e63e8a6cSdrhdo_execsql_test indexexpr1-600 {
246e63e8a6cSdrh  DROP TABLE IF EXISTS t4;
247e63e8a6cSdrh  CREATE TABLE t4(a,b,c,d,e,f,g,h,i);
248e63e8a6cSdrh  CREATE INDEX t4all ON t4(a,b,c<d,e,f,i,h);
249e63e8a6cSdrh  INSERT INTO t4 VALUES(1,2,3,4,5,6,7,8,9);
250e63e8a6cSdrh  ANALYZE;
251e63e8a6cSdrh  DELETE FROM sqlite_stat1;
252e63e8a6cSdrh  INSERT INTO sqlite_stat1
253e63e8a6cSdrh    VALUES('t4','t4all','600000 160000 40000 10000 2000 600 100 40 10');
254e63e8a6cSdrh  ANALYZE sqlite_master;
255e63e8a6cSdrh  SELECT i FROM t4 WHERE e=5;
256e63e8a6cSdrh} {9}
257e63e8a6cSdrh
258c5de2d0aSdrh# Indexed expressions on both sides of an == in a WHERE clause.
259c5de2d0aSdrh#
26072694432Sdrhdo_execsql_test indexexpr1-700 {
26172694432Sdrh  DROP TABLE IF EXISTS t7;
26272694432Sdrh  CREATE TABLE t7(a,b,c);
26372694432Sdrh  INSERT INTO t7(a,b,c) VALUES(1,2,2),('abc','def','def'),(4,5,6);
26472694432Sdrh  CREATE INDEX t7b ON t7(+b);
26572694432Sdrh  CREATE INDEX t7c ON t7(+c);
26672694432Sdrh  SELECT *, '|' FROM t7 WHERE +b=+c ORDER BY +a;
26772694432Sdrh} {1 2 2 | abc def def |}
268c5de2d0aSdrhdo_execsql_test indexexpr1-710 {
269c5de2d0aSdrh  CREATE TABLE t71(a,b,c);
270c5de2d0aSdrh  CREATE INDEX t71bc ON t71(b+c);
271c5de2d0aSdrh  CREATE TABLE t72(x,y,z);
272c5de2d0aSdrh  CREATE INDEX t72yz ON t72(y+z);
273c5de2d0aSdrh  INSERT INTO t71(a,b,c) VALUES(1,11,2),(2,7,15),(3,5,4);
274c5de2d0aSdrh  INSERT INTO t72(x,y,z) VALUES(1,10,3),(2,8,14),(3,9,9);
275c5de2d0aSdrh  SELECT a, x, '|' FROM t71, t72
276c5de2d0aSdrh   WHERE b+c=y+z
277c5de2d0aSdrh  ORDER BY +a, +x;
278c5de2d0aSdrh} {1 1 | 2 2 |}
2790b8d255cSdrh
280dae26fe5Sdrh# Collating sequences on indexes of expressions
281dae26fe5Sdrh#
282dae26fe5Sdrhdo_execsql_test indexexpr1-800 {
283dae26fe5Sdrh  DROP TABLE IF EXISTS t8;
284dae26fe5Sdrh  CREATE TABLE t8(a INTEGER PRIMARY KEY, b TEXT);
285dae26fe5Sdrh  CREATE UNIQUE INDEX t8bx ON t8(substr(b,2,4) COLLATE nocase);
286dae26fe5Sdrh  INSERT INTO t8(a,b) VALUES(1,'Alice'),(2,'Bartholemew'),(3,'Cynthia');
287dae26fe5Sdrh  SELECT * FROM t8 WHERE substr(b,2,4)='ARTH' COLLATE nocase;
288dae26fe5Sdrh} {2 Bartholemew}
289dae26fe5Sdrhdo_catchsql_test indexexpr1-810 {
290dae26fe5Sdrh  INSERT INTO t8(a,b) VALUES(4,'BARTHMERE');
291dae26fe5Sdrh} {1 {UNIQUE constraint failed: index 't8bx'}}
292dae26fe5Sdrhdo_catchsql_test indexexpr1-820 {
293dae26fe5Sdrh  DROP INDEX t8bx;
294dae26fe5Sdrh  CREATE UNIQUE INDEX t8bx ON t8(substr(b,2,4) COLLATE rtrim);
295dae26fe5Sdrh  INSERT INTO t8(a,b) VALUES(4,'BARTHMERE');
296dae26fe5Sdrh} {0 {}}
297dae26fe5Sdrh
29868391acdSdrh# Check that PRAGMA integrity_check works correctly on a
29968391acdSdrh# UNIQUE index that includes rowid and expression terms.
30068391acdSdrh#
30168391acdSdrhdo_execsql_test indexexpr1-900 {
30268391acdSdrh  CREATE TABLE t9(a,b,c,d);
30368391acdSdrh  CREATE UNIQUE INDEX t9x1 ON t9(c,abs(d),b);
30468391acdSdrh  INSERT INTO t9(rowid,a,b,c,d) VALUES(1,2,3,4,5);
30568391acdSdrh  INSERT INTO t9(rowid,a,b,c,d) VALUES(2,NULL,NULL,NULL,NULL);
30668391acdSdrh  INSERT INTO t9(rowid,a,b,c,d) VALUES(3,NULL,NULL,NULL,NULL);
30768391acdSdrh  INSERT INTO t9(rowid,a,b,c,d) VALUES(4,5,6,7,8);
30868391acdSdrh  PRAGMA integrity_check;
30968391acdSdrh} {ok}
31068391acdSdrhdo_catchsql_test indexexpr1-910 {
31168391acdSdrh  INSERT INTO t9(a,b,c,d) VALUES(5,6,7,-8);
31268391acdSdrh} {1 {UNIQUE constraint failed: index 't9x1'}}
313dae26fe5Sdrh
3141c75c9d7Sdrh# Test cases derived from a NEVER() maro failure discovered by
3151c75c9d7Sdrh# Jonathan Metzman using AFL
3161c75c9d7Sdrh#
3171c75c9d7Sdrhdo_execsql_test indexexpr1-1000 {
3181c75c9d7Sdrh  DROP TABLE IF EXISTS t0;
3191c75c9d7Sdrh  CREATE TABLE t0(a,b,t);
3201c75c9d7Sdrh  CREATE INDEX i ON t0(a in(0,1));
3211c75c9d7Sdrh  INSERT INTO t0 VALUES(0,1,2),(2,3,4),(5,6,7);
3221c75c9d7Sdrh  UPDATE t0 SET b=99 WHERE (a in(0,1))=0;
3231c75c9d7Sdrh  SELECT *, '|' FROM t0 ORDER BY +a;
3241c75c9d7Sdrh} {0 1 2 | 2 99 4 | 5 99 7 |}
3251c75c9d7Sdrhdo_execsql_test indexexpr1-1010 {
3261c75c9d7Sdrh  UPDATE t0 SET b=88 WHERE (a in(0,1))=1;
3271c75c9d7Sdrh  SELECT *, '|' FROM t0 ORDER BY +a;
3281c75c9d7Sdrh} {0 88 2 | 2 99 4 | 5 99 7 |}
3291c75c9d7Sdrh
33048590fcbSdrh# 2016-10-10
33148590fcbSdrh# Make sure indexes on expressions skip over initial NULL values in the
33248590fcbSdrh# index as they are suppose to do.
33348590fcbSdrh# Ticket https://www.sqlite.org/src/tktview/4baa46491212947
33448590fcbSdrh#
33548590fcbSdrhdo_execsql_test indexexpr1-1100 {
33648590fcbSdrh  DROP TABLE IF EXISTS t1;
33748590fcbSdrh  CREATE TABLE t1(a);
33848590fcbSdrh  INSERT INTO t1 VALUES(NULL),(1);
33948590fcbSdrh  SELECT '1:', typeof(a), a FROM t1 WHERE a<10;
34048590fcbSdrh  SELECT '2:', typeof(a), a FROM t1 WHERE a+0<10;
34148590fcbSdrh  CREATE INDEX t1x1 ON t1(a);
34248590fcbSdrh  CREATE INDEX t1x2 ON t1(a+0);
34348590fcbSdrh  SELECT '3:', typeof(a), a FROM t1 WHERE a<10;
34448590fcbSdrh  SELECT '4:', typeof(a), a FROM t1 WHERE a+0<10;
34548590fcbSdrh} {1: integer 1 2: integer 1 3: integer 1 4: integer 1}
346dae26fe5Sdrh
34790b2fe6bSdando_execsql_test indexexpr1-1200 {
34890b2fe6bSdan  CREATE TABLE t10(a int, b int, c int, d int);
34990b2fe6bSdan  INSERT INTO t10(a, b, c, d) VALUES(0, 0, 2, 2);
35090b2fe6bSdan  INSERT INTO t10(a, b, c, d) VALUES(0, 0, 0, 0);
35190b2fe6bSdan  INSERT INTO t10(a, b, c, d) VALUES(0, 0, 1, 1);
35290b2fe6bSdan  INSERT INTO t10(a, b, c, d) VALUES(1, 1, 1, 1);
35390b2fe6bSdan  INSERT INTO t10(a, b, c, d) VALUES(1, 1, 0, 0);
35490b2fe6bSdan  INSERT INTO t10(a, b, c, d) VALUES(2, 2, 0, 0);
35590b2fe6bSdan
35690b2fe6bSdan  SELECT a+b, c+d FROM t10 ORDER BY a+b, c+d;
35790b2fe6bSdan} {
35890b2fe6bSdan  0 0 0 2 0 4 2 0 2 2 4 0
35990b2fe6bSdan}
36090b2fe6bSdando_execsql_test indexexpr1-1200.1 {
36190b2fe6bSdan  CREATE INDEX t10_ab ON t10(a+b);
36290b2fe6bSdan}
36390b2fe6bSdando_execsql_test indexexpr1-1200.2 {
36490b2fe6bSdan  SELECT a+b, c+d FROM t10 ORDER BY a+b, c+d;
36590b2fe6bSdan} {
36690b2fe6bSdan  0 0 0 2 0 4 2 0 2 2 4 0
36790b2fe6bSdan}
36890b2fe6bSdando_execsql_test indexexpr1-1200.3 {
36990b2fe6bSdan  CREATE INDEX t10_abcd ON t10(a+b,c+d);
37090b2fe6bSdan}
37190b2fe6bSdando_execsql_test indexexpr1-1200.4 {
37290b2fe6bSdan  SELECT a+b, c+d FROM t10 ORDER BY a+b, c+d;
37390b2fe6bSdan} {
37490b2fe6bSdan  0 0 0 2 0 4 2 0 2 2 4 0
37590b2fe6bSdan}
37690b2fe6bSdan
37713ac46eeSdrh# Ticket https://www.sqlite.org/src/tktview/eb703ba7b50c1a
37813ac46eeSdrh# Incorrect result using an index on an expression with a collating function
37913ac46eeSdrh#
38013ac46eeSdrhdo_execsql_test indexexpr1-1300.1 {
38113ac46eeSdrh  CREATE TABLE t1300(a INTEGER PRIMARY KEY, b);
38213ac46eeSdrh  INSERT INTO t1300 VALUES(1,'coffee'),(2,'COFFEE'),(3,'stress'),(4,'STRESS');
38313ac46eeSdrh  CREATE INDEX t1300bexpr ON t1300( substr(b,4) );
38413ac46eeSdrh  SELECT a FROM t1300 WHERE substr(b,4)='ess' COLLATE nocase ORDER BY +a;
38513ac46eeSdrh} {3 4}
38613ac46eeSdrh
3874dd89d5aSdrh# Ticket https://sqlite.org/src/tktview/aa98619a
3884dd89d5aSdrh# Assertion fault using an index on a constant
3894dd89d5aSdrh#
3904dd89d5aSdrhdo_execsql_test indexexpr1-1400 {
3914dd89d5aSdrh  CREATE TABLE t1400(x TEXT);
3924dd89d5aSdrh  CREATE INDEX t1400x ON t1400(1);  -- Index on a constant
3934dd89d5aSdrh  SELECT 1 IN (SELECT 2) FROM t1400;
3944dd89d5aSdrh} {}
3954dd89d5aSdrhdo_execsql_test indexexpr1-1410 {
3964dd89d5aSdrh  INSERT INTO t1400 VALUES('a'),('b');
3974dd89d5aSdrh  SELECT 1 IN (SELECT 2) FROM t1400;
3984dd89d5aSdrh} {0 0}
3994dd89d5aSdrhdo_execsql_test indexexpr1-1420 {
4004dd89d5aSdrh  SELECT 1 IN (SELECT 2 UNION ALL SELECT 1) FROM t1400;
4014dd89d5aSdrh} {1 1}
4024dd89d5aSdrhdo_execsql_test indexexpr1-1430 {
4034dd89d5aSdrh  DROP INDEX t1400x;
4044dd89d5aSdrh  CREATE INDEX t1400x ON t1400(abs(15+3));
4054dd89d5aSdrh  SELECT abs(15+3) IN (SELECT 17 UNION ALL SELECT 18) FROM t1;
4064dd89d5aSdrh} {1 1}
4074dd89d5aSdrh
4084d795ef7Sdrh# 2018-01-02 ticket https://sqlite.org/src/info/dc3f932f5a147771
4094d795ef7Sdrh# A REPLACE into a table that uses an index on an expression causes
4104d795ef7Sdrh# an assertion fault.  Problem discovered by OSSFuzz.
4114d795ef7Sdrh#
4124d795ef7Sdrhdo_execsql_test indexexpr1-1500 {
4134d795ef7Sdrh  CREATE TABLE t1500(a INT PRIMARY KEY, b INT UNIQUE);
4144d795ef7Sdrh  CREATE INDEX t1500ab ON t1500(a*b);
4154d795ef7Sdrh  INSERT INTO t1500(a,b) VALUES(1,2);
4164d795ef7Sdrh  REPLACE INTO t1500(a,b) VALUES(1,3);  -- formerly caused assertion fault
4174d795ef7Sdrh  SELECT * FROM t1500;
4184d795ef7Sdrh} {1 3}
4194dd89d5aSdrh
4209eb8dbadSdrh# 2018-01-03 OSSFuzz discovers another test case for the same problem
4219eb8dbadSdrh# above.
4229eb8dbadSdrh#
4239eb8dbadSdrhdo_execsql_test indexexpr-1510 {
4249eb8dbadSdrh  DROP TABLE IF EXISTS t1;
4259eb8dbadSdrh  CREATE TABLE t1(a PRIMARY KEY,b UNIQUE);
4269eb8dbadSdrh  REPLACE INTO t1 VALUES(2, 1);
4279eb8dbadSdrh  REPLACE INTO t1 SELECT 6,1;
4289eb8dbadSdrh  CREATE INDEX t1aa ON t1(a-a);
4299eb8dbadSdrh  REPLACE INTO t1 SELECT a, randomblob(a) FROM t1
4309eb8dbadSdrh} {}
4319eb8dbadSdrh
43206b3bd5bSdrh# 2018-01-31 https://www.sqlite.org/src/tktview/343634942dd54ab57b702411
43306b3bd5bSdrh# When an index on an expression depends on the string representation of
43406b3bd5bSdrh# a numeric table column, trouble can arise since there are multiple
43506b3bd5bSdrh# string that can map to the same numeric value.  (Ex: 123, 0123, 000123).
43606b3bd5bSdrh#
43706b3bd5bSdrhdo_execsql_test indexexpr-1600 {
43806b3bd5bSdrh  DROP TABLE IF EXISTS t1;
43906b3bd5bSdrh  CREATE TABLE t1 (a INTEGER, b);
44006b3bd5bSdrh  CREATE INDEX idx1 ON t1 (lower(a));
44106b3bd5bSdrh  INSERT INTO t1 VALUES('0001234',3);
44206b3bd5bSdrh  PRAGMA integrity_check;
44306b3bd5bSdrh} {ok}
44406b3bd5bSdrhdo_execsql_test indexexpr-1610 {
44506b3bd5bSdrh  INSERT INTO t1 VALUES('1234',0),('001234',2),('01234',1);
44606b3bd5bSdrh  SELECT b FROM t1 WHERE lower(a)='1234' ORDER BY +b;
44706b3bd5bSdrh} {0 1 2 3}
44806b3bd5bSdrhdo_execsql_test indexexpr-1620 {
44906b3bd5bSdrh  SELECT b FROM t1 WHERE lower(a)='01234' ORDER BY +b;
45006b3bd5bSdrh} {}
45106b3bd5bSdrh
45214c865e8Sdrh# 2019-08-09 https://www.sqlite.org/src/info/9080b6227fabb466
45314c865e8Sdrh# ExprImpliesExpr theorem prover bug:
45414c865e8Sdrh# "(NULL IS FALSE) IS FALSE" does not imply "NULL IS NULL"
45514c865e8Sdrh#
45614c865e8Sdrhdo_execsql_test indexexpr-1700 {
45714c865e8Sdrh  DROP TABLE IF EXISTS t0;
45814c865e8Sdrh  CREATE TABLE t0(c0);
45914c865e8Sdrh  INSERT INTO t0(c0) VALUES (0);
46014c865e8Sdrh  CREATE INDEX i0 ON t0(NULL > c0) WHERE (NULL NOT NULL);
46114c865e8Sdrh  SELECT * FROM t0 WHERE ((NULL IS FALSE) IS FALSE);
46214c865e8Sdrh} {0}
46306b3bd5bSdrh
464bffdd636Sdrh# 2019-09-02 https://www.sqlite.org/src/tktview/57af00b6642ecd6848
465bffdd636Sdrh# When the expression of an an index-on-expression references a
466bffdd636Sdrh# table column of type REAL that is actually holding an MEM_IntReal
467bffdd636Sdrh# value, be sure to use the REAL value and not the INT value when
468bffdd636Sdrh# computing the expression.
469bffdd636Sdrh#
4709d30c8ffSdanifcapable like_match_blobs {
471bffdd636Sdrh  do_execsql_test indexexpr-1800 {
472bffdd636Sdrh    DROP TABLE IF EXISTS t0;
473bffdd636Sdrh    CREATE TABLE t0(c0 REAL, c1 TEXT);
474bffdd636Sdrh    CREATE INDEX i0 ON t0(+c0, c0);
475bffdd636Sdrh    INSERT INTO t0(c0) VALUES(0);
476bffdd636Sdrh    SELECT CAST(+ t0.c0 AS BLOB) LIKE 0 FROM t0;
477bffdd636Sdrh  } {0}
478bffdd636Sdrh  do_execsql_test indexexpr-1810 {
479bffdd636Sdrh    SELECT CAST(+ t0.c0 AS BLOB) LIKE '0.0' FROM t0;
480bffdd636Sdrh  } {1}
481bffdd636Sdrh  do_execsql_test indexexpr-1820 {
482bffdd636Sdrh    DROP TABLE IF EXISTS t1;
483bffdd636Sdrh    CREATE TABLE t1(x REAL);
484bffdd636Sdrh    CREATE INDEX t1x ON t1(x, +x);
485bffdd636Sdrh    INSERT INTO t1(x) VALUES(2);
486bffdd636Sdrh    SELECT +x FROM t1 WHERE x=2;
487bffdd636Sdrh  } {2.0}
4889d30c8ffSdan}
489bffdd636Sdrh
490*2aa1086cSdrh# 2022-04-30 https://sqlite.org/forum/info/7efabf4b03328e57
491*2aa1086cSdrh# Assertion fault during a DELETE INDEXED BY.
492*2aa1086cSdrh#
493*2aa1086cSdrhreset_db
494*2aa1086cSdrhdo_execsql_test indexexpr-1900 {
495*2aa1086cSdrh  CREATE TABLE t1(x TEXT PRIMARY KEY, y TEXT, z INT);
496*2aa1086cSdrh  INSERT INTO t1(x,y,z) VALUES('alpha','ALPHA',1),('bravo','charlie',1);
497*2aa1086cSdrh  CREATE INDEX i1 ON t1(+y COLLATE NOCASE);
498*2aa1086cSdrh  SELECT * FROM t1;
499*2aa1086cSdrh} {alpha ALPHA 1 bravo charlie 1}
500*2aa1086cSdrhdo_execsql_test indexexpr-1910 {
501*2aa1086cSdrh  DELETE FROM t1 INDEXED BY i1
502*2aa1086cSdrh   WHERE x IS +y COLLATE NOCASE IN (SELECT z FROM t1)
503*2aa1086cSdrh  RETURNING *;
504*2aa1086cSdrh} {alpha ALPHA 1}
505*2aa1086cSdrhdo_execsql_test indexexpr-1920 {
506*2aa1086cSdrh  SELECT * FROM t1;
507*2aa1086cSdrh} {bravo charlie 1}
508*2aa1086cSdrh
50947991425Sdrhfinish_test
510