1# 2018-07-26 2# 3# The author disclaims copyright to this source code. In place of 4# a legal notice, here is a blessing: 5# 6# May you do good and not evil. 7# May you find forgiveness for yourself and forgive others. 8# May you share freely, never taking more than you give. 9# 10#*********************************************************************** 11# This file implements regression tests for SQLite library. The 12# focus of this file is testing the WHERE-clause constant propagation 13# optimization. 14# 15set testdir [file dirname $argv0] 16source $testdir/tester.tcl 17set ::testprefix whereL 18 19do_execsql_test 100 { 20 CREATE TABLE t1(a INT PRIMARY KEY, b, c, d, e); 21 CREATE TABLE t2(a INT PRIMARY KEY, f, g, h, i); 22 CREATE TABLE t3(a INT PRIMARY KEY, j, k, l, m); 23 CREATE VIEW v4 AS SELECT * FROM t2 UNION ALL SELECT * FROM t3; 24} 25do_eqp_test 110 { 26 SELECT * FROM t1, v4 WHERE t1.a=?1 AND v4.a=t1.a; 27} { 28 QUERY PLAN 29 |--MATERIALIZE xxxxxx 30 | `--COMPOUND QUERY 31 | |--LEFT-MOST SUBQUERY 32 | | `--SEARCH TABLE t2 USING INDEX sqlite_autoindex_t2_1 (a=?) 33 | `--UNION ALL 34 | `--SEARCH TABLE t3 USING INDEX sqlite_autoindex_t3_1 (a=?) 35 |--SCAN SUBQUERY xxxxxx 36 `--SEARCH TABLE t1 USING INDEX sqlite_autoindex_t1_1 (a=?) 37} 38 39# The scan of the t1 table goes first since that enables the ORDER BY 40# sort to be omitted. This would not be possible without constant 41# propagation because without it the t1 table would depend on t3. 42# 43do_eqp_test 120 { 44 SELECT * FROM t1, t2, t3 45 WHERE t1.a=t2.a AND t2.a=t3.j AND t3.j=5 46 ORDER BY t1.a; 47} { 48 QUERY PLAN 49 |--SEARCH TABLE t1 USING INDEX sqlite_autoindex_t1_1 (a=?) 50 |--SEARCH TABLE t2 USING INDEX sqlite_autoindex_t2_1 (a=?) 51 `--SCAN TABLE t3 52} 53 54# Constant propagation in the face of collating sequences: 55# 56do_execsql_test 200 { 57 CREATE TABLE c3(x COLLATE binary, y COLLATE nocase, z COLLATE binary); 58 CREATE INDEX c3x ON c3(x); 59 INSERT INTO c3 VALUES('ABC', 'ABC', 'abc'); 60 SELECT * FROM c3 WHERE x=y AND y=z AND z='abc'; 61} {ABC ABC abc} 62 63# If the constants are blindly propagated, as shown in the following 64# query, the wrong answer results: 65# 66do_execsql_test 201 { 67 SELECT * FROM c3 WHERE x='abc' AND y='abc' AND z='abc'; 68} {} 69 70# Constant propagation caused an incorrect answer in the following 71# query. (Reported by Bentley system on 2018-08-09.) 72# 73do_execsql_test 300 { 74 CREATE TABLE A(id INTEGER PRIMARY KEY, label TEXT); 75 CREATE TABLE B(id INTEGER PRIMARY KEY, label TEXT, Aid INTEGER); 76 CREATE TABLE C( 77 id INTEGER PRIMARY KEY, 78 xx INTEGER NOT NULL, 79 yy INTEGER, 80 zz INTEGER 81 ); 82 CREATE UNIQUE INDEX x2 ON C(yy); 83 CREATE UNIQUE INDEX x4 ON C(yy, zz); 84 INSERT INTO A(id) VALUES(1); 85 INSERT INTO B(id) VALUES(2); 86 INSERT INTO C(id,xx,yy,zz) VALUES(99,50,1,2); 87 SELECT 1 88 FROM A, 89 (SELECT id,xx,yy,zz FROM C) subq, 90 B 91 WHERE A.id='1' 92 AND A.id=subq.yy 93 AND B.id=subq.zz; 94} {1} 95do_execsql_test 301 { 96 SELECT 1 97 FROM A, 98 (SELECT id,xx,yy,zz FROM C) subq, 99 B 100 WHERE A.id=1 101 AND A.id=subq.yy 102 AND B.id=subq.zz; 103} {1} 104do_execsql_test 302 { 105 SELECT 1 106 FROM A, 107 (SELECT id,yy,zz FROM C) subq, 108 B 109 WHERE A.id='1' 110 AND A.id=subq.yy 111 AND B.id=subq.zz; 112} {1} 113 114# 2018-10-25: Ticket [cf5ed20f] 115# Incorrect join result with duplicate WHERE clause constraint. 116# 117do_execsql_test 400 { 118 CREATE TABLE x(a, b, c); 119 CREATE TABLE y(a, b); 120 INSERT INTO x VALUES (1, 0, 1); 121 INSERT INTO y VALUES (1, 2); 122 SELECT x.a FROM x JOIN y ON x.c = y.a WHERE x.b = 1 AND x.b = 1; 123} {} 124 125# 2020-01-07: ticket 82ac75ba0093e5dc 126# Incorrect join result due to mishandling of affinity in constant 127# propagation. 128# 129reset_db 130do_execsql_test 500 { 131 PRAGMA automatic_index=OFF; 132 CREATE TABLE t0(c0); 133 INSERT INTO t0 VALUES('0'); 134 CREATE VIEW v0(c0) AS SELECT CAST(0 AS INT) FROM t0; 135 SELECT 200, * FROM t0, v0 WHERE 0 = t0.c0 AND t0.c0 = v0.c0; 136} {} 137do_execsql_test 510 { 138 SELECT 200, * FROM t0, v0 WHERE t0.c0 = 0 AND t0.c0 = v0.c0; 139} {} 140do_execsql_test 520 { 141 SELECT 200, * FROM t0, v0 WHERE 0 = t0.c0 AND v0.c0 = t0.c0; 142} {} 143do_execsql_test 530 { 144 SELECT 200, * FROM t0, v0 WHERE t0.c0 = 0 AND v0.c0 = t0.c0; 145} {} 146 147# 2020-02-13: ticket 1dcb4d44964846ad 148# A problem introduced while making optimizations on the fixes above. 149# 150reset_db 151do_execsql_test 600 { 152 CREATE TABLE t1(x TEXT); 153 CREATE TABLE t2(y TEXT); 154 INSERT INTO t1 VALUES('good'),('bad'); 155 INSERT INTO t2 VALUES('good'),('bad'); 156 SELECT * FROM t1 JOIN t2 ON x=y 157 WHERE x='good' AND y='good'; 158} {good good} 159 160# 2020-04-24: Another test case for the previous (1dcb4d44964846ad) 161# ticket. The test case comes from 162# https://stackoverflow.com/questions/61399253/sqlite3-different-result-in-console-compared-to-python-script/ 163# Output verified against postgresql. 164# 165do_execsql_test 610 { 166 CREATE TABLE tableA( 167 ID int, 168 RunYearMonth int 169 ); 170 INSERT INTO tableA VALUES(1,202003),(2,202003),(3,202003),(4,202004), 171 (5,202004),(6,202004),(7,202004),(8,202004); 172 CREATE TABLE tableB ( 173 ID int, 174 RunYearMonth int 175 ); 176 INSERT INTO tableB VALUES(1,202004),(2,202004),(3,202004),(4,202004), 177 (5,202004); 178 SELECT * 179 FROM ( 180 SELECT * 181 FROM tableA 182 WHERE RunYearMonth = 202004 183 ) AS A 184 INNER JOIN ( 185 SELECT * 186 FROM tableB 187 WHERE RunYearMonth = 202004 188 ) AS B 189 ON A.ID = B.ID 190 AND A.RunYearMonth = B.RunYearMonth; 191} {4 202004 4 202004 5 202004 5 202004} 192 193 194finish_test 195