# 2015-08-31 # # The author disclaims copyright to this source code. In place of # a legal notice, here is a blessing: # # May you do good and not evil. # May you find forgiveness for yourself and forgive others. # May you share freely, never taking more than you give. # #*********************************************************************** # This file implements regression tests for SQLite library. The # focus of this file is testing indexes on expressions. # set testdir [file dirname $argv0] source $testdir/tester.tcl do_execsql_test indexexpr1-100 { CREATE TABLE t1(a,b,c); INSERT INTO t1(a,b,c) /* 123456789 123456789 123456789 123456789 123456789 123456789 */ VALUES('In_the_beginning_was_the_Word',1,1), ('and_the_Word_was_with_God',1,2), ('and_the_Word_was_God',1,3), ('The_same_was_in_the_beginning_with_God',2,1), ('All_things_were_made_by_him',3,1), ('and_without_him_was_not_any_thing_made_that_was_made',3,2); CREATE INDEX t1a1 ON t1(substr(a,1,12)); } {} do_execsql_test indexexpr1-110 { SELECT b, c, '|' FROM t1 WHERE substr(a,1,12)=='and_the_Word' ORDER BY b, c; } {1 2 | 1 3 |} do_execsql_test indexexpr1-110eqp { EXPLAIN QUERY PLAN SELECT b, c, '|' FROM t1 WHERE substr(a,1,12)=='and_the_Word' ORDER BY b, c; } {/USING INDEX t1a1/} do_execsql_test indexexpr1-120 { SELECT b, c, '|' FROM t1 WHERE 'and_the_Word'==substr(a,1,12) ORDER BY b, c; } {1 2 | 1 3 |} do_execsql_test indexexpr1-120eqp { EXPLAIN QUERY PLAN SELECT b, c, '|' FROM t1 WHERE 'and_the_Word'==substr(a,1,12) ORDER BY b, c; } {/USING INDEX t1a1/} do_execsql_test indexexpr1-130 { CREATE INDEX t1ba ON t1(b,substr(a,2,3),c); SELECT c FROM t1 WHERE b=1 AND substr(a,2,3)='nd_' ORDER BY c; } {2 3} do_execsql_test indexexpr1-130eqp { EXPLAIN QUERY PLAN SELECT c FROM t1 WHERE b=1 AND substr(a,2,3)='nd_' ORDER BY c; } {/USING INDEX t1ba/} do_execsql_test indexexpr1-140 { SELECT rowid, substr(a,b,3), '|' FROM t1 ORDER BY 2; } {1 In_ | 2 and | 3 and | 6 d_w | 4 he_ | 5 l_t |} do_execsql_test indexexpr1-141 { CREATE INDEX t1abx ON t1(substr(a,b,3)); SELECT rowid FROM t1 WHERE substr(a,b,3)<='and' ORDER BY +rowid; } {1 2 3} do_execsql_test indexexpr1-141eqp { EXPLAIN QUERY PLAN SELECT rowid FROM t1 WHERE substr(a,b,3)<='and' ORDER BY +rowid; } {/USING INDEX t1abx/} do_execsql_test indexexpr1-142 { SELECT rowid FROM t1 WHERE +substr(a,b,3)<='and' ORDER BY +rowid; } {1 2 3} do_execsql_test indexexpr1-150 { SELECT rowid FROM t1 WHERE substr(a,b,3) IN ('and','l_t','xyz') ORDER BY +rowid; } {2 3 5} do_execsql_test indexexpr1-150eqp { EXPLAIN QUERY PLAN SELECT rowid FROM t1 WHERE substr(a,b,3) IN ('and','l_t','xyz') ORDER BY +rowid; } {/USING INDEX t1abx/} ifcapable altertable { do_execsql_test indexexpr1-160 { ALTER TABLE t1 ADD COLUMN d; UPDATE t1 SET d=length(a); CREATE INDEX t1a2 ON t1(SUBSTR(a, 27, 3)) WHERE d>=29; SELECT rowid, b, c FROM t1 WHERE substr(a,27,3)=='ord' AND d>=29; } {1 1 1} do_execsql_test indexexpr1-160eqp { EXPLAIN QUERY PLAN SELECT rowid, b, c FROM t1 WHERE substr(a,27,3)=='ord' AND d>=29; } {/USING INDEX t1a2/} } # ORDER BY using an indexed expression # do_execsql_test indexexpr1-170 { CREATE INDEX t1alen ON t1(length(a)); SELECT length(a) FROM t1 ORDER BY length(a); } {20 25 27 29 38 52} do_execsql_test indexexpr1-170eqp { EXPLAIN QUERY PLAN SELECT length(a) FROM t1 ORDER BY length(a); } {/SCAN t1 USING INDEX t1alen/} do_execsql_test indexexpr1-171 { SELECT length(a) FROM t1 ORDER BY length(a) DESC; } {52 38 29 27 25 20} do_execsql_test indexexpr1-171eqp { EXPLAIN QUERY PLAN SELECT length(a) FROM t1 ORDER BY length(a) DESC; } {/SCAN t1 USING INDEX t1alen/} do_execsql_test indexexpr1-200 { DROP TABLE t1; CREATE TABLE t1(id ANY PRIMARY KEY, a,b,c) WITHOUT ROWID; INSERT INTO t1(id,a,b,c) VALUES(1,'In_the_beginning_was_the_Word',1,1), (2,'and_the_Word_was_with_God',1,2), (3,'and_the_Word_was_God',1,3), (4,'The_same_was_in_the_beginning_with_God',2,1), (5,'All_things_were_made_by_him',3,1), (6,'and_without_him_was_not_any_thing_made_that_was_made',3,2); CREATE INDEX t1a1 ON t1(substr(a,1,12)); } {} do_execsql_test indexexpr1-210 { SELECT b, c, '|' FROM t1 WHERE substr(a,1,12)=='and_the_Word' ORDER BY b, c; } {1 2 | 1 3 |} do_execsql_test indexexpr1-210eqp { EXPLAIN QUERY PLAN SELECT b, c, '|' FROM t1 WHERE substr(a,1,12)=='and_the_Word' ORDER BY b, c; } {/USING INDEX t1a1/} do_execsql_test indexexpr1-220 { SELECT b, c, '|' FROM t1 WHERE 'and_the_Word'==substr(a,1,12) ORDER BY b, c; } {1 2 | 1 3 |} do_execsql_test indexexpr1-220eqp { EXPLAIN QUERY PLAN SELECT b, c, '|' FROM t1 WHERE 'and_the_Word'==substr(a,1,12) ORDER BY b, c; } {/USING INDEX t1a1/} do_execsql_test indexexpr1-230 { CREATE INDEX t1ba ON t1(b,substr(a,2,3),c); SELECT c FROM t1 WHERE b=1 AND substr(a,2,3)='nd_' ORDER BY c; } {2 3} do_execsql_test indexexpr1-230eqp { EXPLAIN QUERY PLAN SELECT c FROM t1 WHERE b=1 AND substr(a,2,3)='nd_' ORDER BY c; } {/USING INDEX t1ba/} do_execsql_test indexexpr1-240 { SELECT id, substr(a,b,3), '|' FROM t1 ORDER BY 2; } {1 In_ | 2 and | 3 and | 6 d_w | 4 he_ | 5 l_t |} do_execsql_test indexexpr1-241 { CREATE INDEX t1abx ON t1(substr(a,b,3)); SELECT id FROM t1 WHERE substr(a,b,3)<='and' ORDER BY +id; } {1 2 3} do_execsql_test indexexpr1-241eqp { EXPLAIN QUERY PLAN SELECT id FROM t1 WHERE substr(a,b,3)<='and' ORDER BY +id; } {/USING INDEX t1abx/} do_execsql_test indexexpr1-242 { SELECT id FROM t1 WHERE +substr(a,b,3)<='and' ORDER BY +id; } {1 2 3} do_execsql_test indexexpr1-250 { SELECT id FROM t1 WHERE substr(a,b,3) IN ('and','l_t','xyz') ORDER BY +id; } {2 3 5} do_execsql_test indexexpr1-250eqp { EXPLAIN QUERY PLAN SELECT id FROM t1 WHERE substr(a,b,3) IN ('and','l_t','xyz') ORDER BY +id; } {/USING INDEX t1abx/} ifcapable altertable { do_execsql_test indexexpr1-260 { ALTER TABLE t1 ADD COLUMN d; UPDATE t1 SET d=length(a); CREATE INDEX t1a2 ON t1(SUBSTR(a, 27, 3)) WHERE d>=29; SELECT id, b, c FROM t1 WHERE substr(a,27,3)=='ord' AND d>=29; } {1 1 1} do_execsql_test indexexpr1-260eqp { EXPLAIN QUERY PLAN SELECT id, b, c FROM t1 WHERE substr(a,27,3)=='ord' AND d>=29; } {/USING INDEX t1a2/} } do_catchsql_test indexexpr1-300 { CREATE TABLE t2(a,b,c); INSERT INTO t2 VALUES(1,2,3); CREATE INDEX t2x1 ON t2(a,b+random()); } {1 {non-deterministic functions prohibited in index expressions}} do_catchsql_test indexexpr1-301 { CREATE INDEX t2x1 ON t2(julianday('now',a)); } {1 {non-deterministic use of julianday() in an index}} do_catchsql_test indexexpr1-310 { CREATE INDEX t2x2 ON t2(a,b+(SELECT 15)); } {1 {subqueries prohibited in index expressions}} do_catchsql_test indexexpr1-320 { CREATE TABLE e1(x,y,UNIQUE(y,substr(x,1,5))); } {1 {expressions prohibited in PRIMARY KEY and UNIQUE constraints}} do_catchsql_test indexexpr1-330 { CREATE TABLE e1(x,y,PRIMARY KEY(y,substr(x,1,5))); } {1 {expressions prohibited in PRIMARY KEY and UNIQUE constraints}} do_catchsql_test indexexpr1-331 { CREATE TABLE e1(x,y,PRIMARY KEY(y,substr(x,1,5))) WITHOUT ROWID; } {1 {expressions prohibited in PRIMARY KEY and UNIQUE constraints}} do_catchsql_test indexexpr1-340 { CREATE TABLE e1(x,y,FOREIGN KEY(substr(y,1,5)) REFERENCES t1); } {1 {near "(": syntax error}} do_execsql_test indexexpr1-400 { CREATE TABLE t3(a,b,c); WITH RECURSIVE c(x) AS (VALUES(1) UNION SELECT x+1 FROM c WHERE x<30) INSERT INTO t3(a,b,c) SELECT x, printf('ab%04xyz',x), random() FROM c; CREATE UNIQUE INDEX t3abc ON t3(CAST(a AS text), b, substr(c,1,3)); SELECT a FROM t3 WHERE CAST(a AS text)<='10' ORDER BY +a; PRAGMA integrity_check; } {1 10 ok} do_catchsql_test indexexpr1-410 { INSERT INTO t3 SELECT * FROM t3 WHERE rowid=10; } {1 {UNIQUE constraint failed: index 't3abc'}} do_execsql_test indexexpr1-500 { CREATE TABLE t5(a); CREATE TABLE cnt(x); WITH RECURSIVE c(x) AS (VALUES(1) UNION ALL SELECT x+1 FROM c WHERE x<5) INSERT INTO cnt(x) SELECT x FROM c; INSERT INTO t5(a) SELECT printf('abc%03dxyz',x) FROM cnt; CREATE INDEX t5ax ON t5( substr(a,4,3) ); } {} do_execsql_test indexexpr1-510 { -- The use of the "k" alias in the WHERE clause is technically -- illegal, but SQLite allows it for historical reasons. In this -- test and the next, verify that "k" can be used by the t5ax index SELECT substr(a,4,3) AS k FROM cnt, t5 WHERE k=printf('%03d',x); } {001 002 003 004 005} do_execsql_test indexexpr1-510eqp { EXPLAIN QUERY PLAN SELECT substr(a,4,3) AS k FROM cnt, t5 WHERE k=printf('%03d',x); } {/USING INDEX t5ax/} # Skip-scan on an indexed expression # do_execsql_test indexexpr1-600 { DROP TABLE IF EXISTS t4; CREATE TABLE t4(a,b,c,d,e,f,g,h,i); CREATE INDEX t4all ON t4(a,b,c<d,e,f,i,h); INSERT INTO t4 VALUES(1,2,3,4,5,6,7,8,9); ANALYZE; DELETE FROM sqlite_stat1; INSERT INTO sqlite_stat1 VALUES('t4','t4all','600000 160000 40000 10000 2000 600 100 40 10'); ANALYZE sqlite_master; SELECT i FROM t4 WHERE e=5; } {9} # Indexed expressions on both sides of an == in a WHERE clause. # do_execsql_test indexexpr1-700 { DROP TABLE IF EXISTS t7; CREATE TABLE t7(a,b,c); INSERT INTO t7(a,b,c) VALUES(1,2,2),('abc','def','def'),(4,5,6); CREATE INDEX t7b ON t7(+b); CREATE INDEX t7c ON t7(+c); SELECT *, '|' FROM t7 WHERE +b=+c ORDER BY +a; } {1 2 2 | abc def def |} do_execsql_test indexexpr1-710 { CREATE TABLE t71(a,b,c); CREATE INDEX t71bc ON t71(b+c); CREATE TABLE t72(x,y,z); CREATE INDEX t72yz ON t72(y+z); INSERT INTO t71(a,b,c) VALUES(1,11,2),(2,7,15),(3,5,4); INSERT INTO t72(x,y,z) VALUES(1,10,3),(2,8,14),(3,9,9); SELECT a, x, '|' FROM t71, t72 WHERE b+c=y+z ORDER BY +a, +x; } {1 1 | 2 2 |} # Collating sequences on indexes of expressions # do_execsql_test indexexpr1-800 { DROP TABLE IF EXISTS t8; CREATE TABLE t8(a INTEGER PRIMARY KEY, b TEXT); CREATE UNIQUE INDEX t8bx ON t8(substr(b,2,4) COLLATE nocase); INSERT INTO t8(a,b) VALUES(1,'Alice'),(2,'Bartholemew'),(3,'Cynthia'); SELECT * FROM t8 WHERE substr(b,2,4)='ARTH' COLLATE nocase; } {2 Bartholemew} do_catchsql_test indexexpr1-810 { INSERT INTO t8(a,b) VALUES(4,'BARTHMERE'); } {1 {UNIQUE constraint failed: index 't8bx'}} do_catchsql_test indexexpr1-820 { DROP INDEX t8bx; CREATE UNIQUE INDEX t8bx ON t8(substr(b,2,4) COLLATE rtrim); INSERT INTO t8(a,b) VALUES(4,'BARTHMERE'); } {0 {}} # Check that PRAGMA integrity_check works correctly on a # UNIQUE index that includes rowid and expression terms. # do_execsql_test indexexpr1-900 { CREATE TABLE t9(a,b,c,d); CREATE UNIQUE INDEX t9x1 ON t9(c,abs(d),b); INSERT INTO t9(rowid,a,b,c,d) VALUES(1,2,3,4,5); INSERT INTO t9(rowid,a,b,c,d) VALUES(2,NULL,NULL,NULL,NULL); INSERT INTO t9(rowid,a,b,c,d) VALUES(3,NULL,NULL,NULL,NULL); INSERT INTO t9(rowid,a,b,c,d) VALUES(4,5,6,7,8); PRAGMA integrity_check; } {ok} do_catchsql_test indexexpr1-910 { INSERT INTO t9(a,b,c,d) VALUES(5,6,7,-8); } {1 {UNIQUE constraint failed: index 't9x1'}} # Test cases derived from a NEVER() maro failure discovered by # Jonathan Metzman using AFL # do_execsql_test indexexpr1-1000 { DROP TABLE IF EXISTS t0; CREATE TABLE t0(a,b,t); CREATE INDEX i ON t0(a in(0,1)); INSERT INTO t0 VALUES(0,1,2),(2,3,4),(5,6,7); UPDATE t0 SET b=99 WHERE (a in(0,1))=0; SELECT *, '|' FROM t0 ORDER BY +a; } {0 1 2 | 2 99 4 | 5 99 7 |} do_execsql_test indexexpr1-1010 { UPDATE t0 SET b=88 WHERE (a in(0,1))=1; SELECT *, '|' FROM t0 ORDER BY +a; } {0 88 2 | 2 99 4 | 5 99 7 |} # 2016-10-10 # Make sure indexes on expressions skip over initial NULL values in the # index as they are suppose to do. # Ticket https://www.sqlite.org/src/tktview/4baa46491212947 # do_execsql_test indexexpr1-1100 { DROP TABLE IF EXISTS t1; CREATE TABLE t1(a); INSERT INTO t1 VALUES(NULL),(1); SELECT '1:', typeof(a), a FROM t1 WHERE a<10; SELECT '2:', typeof(a), a FROM t1 WHERE a+0<10; CREATE INDEX t1x1 ON t1(a); CREATE INDEX t1x2 ON t1(a+0); SELECT '3:', typeof(a), a FROM t1 WHERE a<10; SELECT '4:', typeof(a), a FROM t1 WHERE a+0<10; } {1: integer 1 2: integer 1 3: integer 1 4: integer 1} do_execsql_test indexexpr1-1200 { CREATE TABLE t10(a int, b int, c int, d int); INSERT INTO t10(a, b, c, d) VALUES(0, 0, 2, 2); INSERT INTO t10(a, b, c, d) VALUES(0, 0, 0, 0); INSERT INTO t10(a, b, c, d) VALUES(0, 0, 1, 1); INSERT INTO t10(a, b, c, d) VALUES(1, 1, 1, 1); INSERT INTO t10(a, b, c, d) VALUES(1, 1, 0, 0); INSERT INTO t10(a, b, c, d) VALUES(2, 2, 0, 0); SELECT a+b, c+d FROM t10 ORDER BY a+b, c+d; } { 0 0 0 2 0 4 2 0 2 2 4 0 } do_execsql_test indexexpr1-1200.1 { CREATE INDEX t10_ab ON t10(a+b); } do_execsql_test indexexpr1-1200.2 { SELECT a+b, c+d FROM t10 ORDER BY a+b, c+d; } { 0 0 0 2 0 4 2 0 2 2 4 0 } do_execsql_test indexexpr1-1200.3 { CREATE INDEX t10_abcd ON t10(a+b,c+d); } do_execsql_test indexexpr1-1200.4 { SELECT a+b, c+d FROM t10 ORDER BY a+b, c+d; } { 0 0 0 2 0 4 2 0 2 2 4 0 } # Ticket https://www.sqlite.org/src/tktview/eb703ba7b50c1a # Incorrect result using an index on an expression with a collating function # do_execsql_test indexexpr1-1300.1 { CREATE TABLE t1300(a INTEGER PRIMARY KEY, b); INSERT INTO t1300 VALUES(1,'coffee'),(2,'COFFEE'),(3,'stress'),(4,'STRESS'); CREATE INDEX t1300bexpr ON t1300( substr(b,4) ); SELECT a FROM t1300 WHERE substr(b,4)='ess' COLLATE nocase ORDER BY +a; } {3 4} # Ticket https://sqlite.org/src/tktview/aa98619a # Assertion fault using an index on a constant # do_execsql_test indexexpr1-1400 { CREATE TABLE t1400(x TEXT); CREATE INDEX t1400x ON t1400(1); -- Index on a constant SELECT 1 IN (SELECT 2) FROM t1400; } {} do_execsql_test indexexpr1-1410 { INSERT INTO t1400 VALUES('a'),('b'); SELECT 1 IN (SELECT 2) FROM t1400; } {0 0} do_execsql_test indexexpr1-1420 { SELECT 1 IN (SELECT 2 UNION ALL SELECT 1) FROM t1400; } {1 1} do_execsql_test indexexpr1-1430 { DROP INDEX t1400x; CREATE INDEX t1400x ON t1400(abs(15+3)); SELECT abs(15+3) IN (SELECT 17 UNION ALL SELECT 18) FROM t1; } {1 1} # 2018-01-02 ticket https://sqlite.org/src/info/dc3f932f5a147771 # A REPLACE into a table that uses an index on an expression causes # an assertion fault. Problem discovered by OSSFuzz. # do_execsql_test indexexpr1-1500 { CREATE TABLE t1500(a INT PRIMARY KEY, b INT UNIQUE); CREATE INDEX t1500ab ON t1500(a*b); INSERT INTO t1500(a,b) VALUES(1,2); REPLACE INTO t1500(a,b) VALUES(1,3); -- formerly caused assertion fault SELECT * FROM t1500; } {1 3} # 2018-01-03 OSSFuzz discovers another test case for the same problem # above. # do_execsql_test indexexpr1-1510 { DROP TABLE IF EXISTS t1; CREATE TABLE t1(a PRIMARY KEY,b UNIQUE); REPLACE INTO t1 VALUES(2, 1); REPLACE INTO t1 SELECT 6,1; CREATE INDEX t1aa ON t1(a-a); REPLACE INTO t1 SELECT a, randomblob(a) FROM t1 } {} # 2018-01-31 https://www.sqlite.org/src/tktview/343634942dd54ab57b702411 # When an index on an expression depends on the string representation of # a numeric table column, trouble can arise since there are multiple # string that can map to the same numeric value. (Ex: 123, 0123, 000123). # do_execsql_test indexexpr1-1600 { DROP TABLE IF EXISTS t1; CREATE TABLE t1 (a INTEGER, b); CREATE INDEX idx1 ON t1 (lower(a)); INSERT INTO t1 VALUES('0001234',3); PRAGMA integrity_check; } {ok} do_execsql_test indexexpr1-1610 { INSERT INTO t1 VALUES('1234',0),('001234',2),('01234',1); SELECT b FROM t1 WHERE lower(a)='1234' ORDER BY +b; } {0 1 2 3} do_execsql_test indexexpr1-1620 { SELECT b FROM t1 WHERE lower(a)='01234' ORDER BY +b; } {} # 2019-08-09 https://www.sqlite.org/src/info/9080b6227fabb466 # ExprImpliesExpr theorem prover bug: # "(NULL IS FALSE) IS FALSE" does not imply "NULL IS NULL" # do_execsql_test indexexpr1-1700 { DROP TABLE IF EXISTS t0; CREATE TABLE t0(c0); INSERT INTO t0(c0) VALUES (0); CREATE INDEX i0 ON t0(NULL > c0) WHERE (NULL NOT NULL); SELECT * FROM t0 WHERE ((NULL IS FALSE) IS FALSE); } {0} # 2019-09-02 https://www.sqlite.org/src/tktview/57af00b6642ecd6848 # When the expression of an an index-on-expression references a # table column of type REAL that is actually holding an MEM_IntReal # value, be sure to use the REAL value and not the INT value when # computing the expression. # ifcapable like_match_blobs { do_execsql_test indexexpr1-1800 { DROP TABLE IF EXISTS t0; CREATE TABLE t0(c0 REAL, c1 TEXT); CREATE INDEX i0 ON t0(+c0, c0); INSERT INTO t0(c0) VALUES(0); SELECT CAST(+ t0.c0 AS BLOB) LIKE 0 FROM t0; } {0} do_execsql_test indexexpr1-1810 { SELECT CAST(+ t0.c0 AS BLOB) LIKE '0.0' FROM t0; } {1} do_execsql_test indexexpr1-1820 { DROP TABLE IF EXISTS t1; CREATE TABLE t1(x REAL); CREATE INDEX t1x ON t1(x, +x); INSERT INTO t1(x) VALUES(2); SELECT +x FROM t1 WHERE x=2; } {2.0} } # 2022-04-30 https://sqlite.org/forum/info/7efabf4b03328e57 # Assertion fault during a DELETE INDEXED BY. # reset_db do_execsql_test indexexpr1-1900 { CREATE TABLE t1(x TEXT PRIMARY KEY, y TEXT, z INT); INSERT INTO t1(x,y,z) VALUES('alpha','ALPHA',1),('bravo','charlie',1); CREATE INDEX i1 ON t1(+y COLLATE NOCASE); SELECT * FROM t1; } {alpha ALPHA 1 bravo charlie 1} do_execsql_test indexexpr1-1910 { DELETE FROM t1 INDEXED BY i1 WHERE x IS +y COLLATE NOCASE IN (SELECT z FROM t1) RETURNING *; } {alpha ALPHA 1} do_execsql_test indexexpr1-1920 { SELECT * FROM t1; } {bravo charlie 1} # 2022-11-28 Ticket 695a1a53de # Improved ability to recognize that an index on an expression is a # covering index. # reset_db do_execsql_test indexexpr1-2000 { CREATE TABLE t1(a INT, b TEXT); INSERT INTO t1(a,b) VALUES (10, '{"one":5,"two":6}'), (10, '{"one":50,"two":60}'), (10, '{"three":99}'), (11, '{"one":100,"two":200}'); CREATE INDEX t1_one ON t1(a, b->>'one'); CREATE INDEX t1_two ON t1(a, b->>'two'); } do_execsql_test indexexpr1-2010 { EXPLAIN QUERY PLAN SELECT sum(b->>'one') FROM t1 WHERE a=10; /* Query AA */ } {/.* t1_one .*/} do_execsql_test indexexpr1-2011 { SELECT sum(b->>'one') FROM t1 WHERE a=10; /* Query AA */ } {55} do_execsql_test indexexpr1-2020 { EXPLAIN QUERY PLAN SELECT sum(b->>'two') FROM t1 WHERE a=10; /* Query BB */ } {/.* t1_two .*/} do_execsql_test indexexpr1-2021 { SELECT sum(b->>'two') FROM t1 WHERE a=10; /* Query BB */ } {66} do_execsql_test indexexpr1-2030 { DROP TABLE t1; CREATE TABLE t1(a INT, b TEXT, c INT, d INT); INSERT INTO t1(a,b,c,d) VALUES (1, '{"x":1}', 12, 3), (1, '{"x":2}', 4, 5), (1, '{"x":1}', 6, 11), (2, '{"x":1}', 22, 3), (2, '{"x":2}', 4, 5), (3, '{"x":1}', 6, 7); CREATE INDEX t1x ON t1(d, a, b->>'x', c); } do_execsql_test indexexpr1-2030 { SELECT a, SUM(1) AS t1, SUM(CASE WHEN b->>'x'=1 THEN 1 END) AS t2, SUM(c) AS t3, SUM(CASE WHEN b->>'x'=1 THEN c END) AS t4 FROM t1; } {1 6 4 54 46} do_execsql_test indexexpr1-2030 { explain query plan SELECT a, SUM(1) AS t1, SUM(CASE WHEN b->>'x'=1 THEN 1 END) AS t2, SUM(c) AS t3, SUM(CASE WHEN b->>'x'=1 THEN c END) AS t4 FROM t1; } {/.*SCAN t1 USING INDEX t1x.*/} reset_db do_execsql_test indexexpr1-2100 { CREATE TABLE t1(a INTEGER PRIMARY KEY, b INT); INSERT INTO t1(a,b) VALUES(1,0); CREATE INDEX x1 ON t1( "y" ); CREATE INDEX x2 ON t1( +"y" ); CREATE INDEX x3 ON t1( +'y' ); CREATE INDEX x4 ON t1( "y*" ); } do_execsql_test indexexpr1-2110 { UPDATE t1 SET b=100 WHERE (SELECT 'y') GLOB "y"; SELECT b FROM t1; } 100 do_execsql_test indexexpr1-2120 { UPDATE t1 SET b=200 WHERE (SELECT 'y') GLOB +"y"; SELECT b FROM t1; } 200 do_execsql_test indexexpr1-2130 { UPDATE t1 SET b=300 WHERE (SELECT 'y') GLOB +'y'; SELECT b FROM t1; } 300 do_execsql_test indexexpr1-2140 { UPDATE t1 SET b=400 WHERE (SELECT 'y') GLOB "y*"; SELECT b FROM t1; } 400 # 2023-04-18 Forum post https://sqlite.org/forum/forumpost/f34e32d120 from # Alexis King. # # This problem originates at check-in b9190d3da70c4171 (2022-11-25). # A similar problem arose on 2023-03-04 at # https://sqlite.org/forum/forumpost/a68313d054 and was fixed at # check-in e06973876993926f. See the test case tkt-99378-400. # reset_db do_execsql_test indexexpr1-2200 { CREATE TABLE t1(id INTEGER PRIMARY KEY, tag INT); INSERT INTO t1 VALUES (0, 7), (1, 8); CREATE TABLE t2(type INT, t1_id INT, value INT); INSERT INTO t2 VALUES (0, 0, 100), (0, 1, 101); CREATE INDEX t1x ON t1(-tag); SELECT u.tag, v.max_value FROM (SELECT tag FROM t1 GROUP BY -tag) u JOIN (SELECT t1.tag AS "tag", t2.type AS "type", MAX(t2.value) AS "max_value" FROM t1 JOIN t2 ON t2.t1_id = t1.id GROUP BY t2.type, t1.tag ) v ON v.type = 0 AND v.tag = u.tag; } {7 100 8 101} finish_test