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