xref: /sqlite-3.40.0/test/whereL.test (revision 6a9595a7)
1660ee556Sdrh# 2018-07-26
2660ee556Sdrh#
3660ee556Sdrh# The author disclaims copyright to this source code.  In place of
4660ee556Sdrh# a legal notice, here is a blessing:
5660ee556Sdrh#
6660ee556Sdrh#    May you do good and not evil.
7660ee556Sdrh#    May you find forgiveness for yourself and forgive others.
8660ee556Sdrh#    May you share freely, never taking more than you give.
9660ee556Sdrh#
10660ee556Sdrh#***********************************************************************
11660ee556Sdrh# This file implements regression tests for SQLite library.  The
12660ee556Sdrh# focus of this file is testing the WHERE-clause constant propagation
13660ee556Sdrh# optimization.
14660ee556Sdrh#
15660ee556Sdrhset testdir [file dirname $argv0]
16660ee556Sdrhsource $testdir/tester.tcl
17660ee556Sdrhset ::testprefix whereL
18660ee556Sdrh
19660ee556Sdrhdo_execsql_test 100 {
20660ee556Sdrh  CREATE TABLE t1(a INT PRIMARY KEY, b, c, d, e);
21660ee556Sdrh  CREATE TABLE t2(a INT PRIMARY KEY, f, g, h, i);
22660ee556Sdrh  CREATE TABLE t3(a INT PRIMARY KEY, j, k, l, m);
23660ee556Sdrh  CREATE VIEW v4 AS SELECT * FROM t2 UNION ALL SELECT * FROM t3;
24660ee556Sdrh}
25660ee556Sdrhdo_eqp_test 110 {
26660ee556Sdrh  SELECT * FROM t1, v4 WHERE t1.a=?1 AND v4.a=t1.a;
27660ee556Sdrh} {
28660ee556Sdrh  QUERY PLAN
29de9ed629Sdan  `--COMPOUND QUERY
30de9ed629Sdan     |--LEFT-MOST SUBQUERY
31*6a9595a7Sdrh     |  |--SEARCH t1 USING INDEX sqlite_autoindex_t1_1 (a=?)
32*6a9595a7Sdrh     |  `--SEARCH t2 USING INDEX sqlite_autoindex_t2_1 (a=?)
33de9ed629Sdan     `--UNION ALL
34*6a9595a7Sdrh        |--SEARCH t1 USING INDEX sqlite_autoindex_t1_1 (a=?)
35*6a9595a7Sdrh        `--SEARCH t3 USING INDEX sqlite_autoindex_t3_1 (a=?)
36660ee556Sdrh}
37660ee556Sdrh
3824e1116eSdrh# The scan of the t1 table goes first since that enables the ORDER BY
3924e1116eSdrh# sort to be omitted.  This would not be possible without constant
4024e1116eSdrh# propagation because without it the t1 table would depend on t3.
4124e1116eSdrh#
4224e1116eSdrhdo_eqp_test 120 {
4324e1116eSdrh  SELECT * FROM t1, t2, t3
4424e1116eSdrh   WHERE t1.a=t2.a AND t2.a=t3.j AND t3.j=5
4524e1116eSdrh  ORDER BY t1.a;
4624e1116eSdrh} {
4724e1116eSdrh  QUERY PLAN
488210233cSdrh  |--SEARCH t1 USING INDEX sqlite_autoindex_t1_1 (a=?)
498210233cSdrh  |--SEARCH t2 USING INDEX sqlite_autoindex_t2_1 (a=?)
508210233cSdrh  `--SCAN t3
5124e1116eSdrh}
5224e1116eSdrh
537de7602eSdrh# Constant propagation in the face of collating sequences:
547de7602eSdrh#
557de7602eSdrhdo_execsql_test 200 {
567de7602eSdrh  CREATE TABLE c3(x COLLATE binary, y COLLATE nocase, z COLLATE binary);
577de7602eSdrh  CREATE INDEX c3x ON c3(x);
587de7602eSdrh  INSERT INTO c3 VALUES('ABC', 'ABC', 'abc');
597de7602eSdrh  SELECT * FROM c3 WHERE x=y AND y=z AND z='abc';
607de7602eSdrh} {ABC ABC abc}
617de7602eSdrh
627de7602eSdrh# If the constants are blindly propagated, as shown in the following
637de7602eSdrh# query, the wrong answer results:
647de7602eSdrh#
657de7602eSdrhdo_execsql_test 201 {
667de7602eSdrh  SELECT * FROM c3 WHERE x='abc' AND y='abc' AND z='abc';
677de7602eSdrh} {}
687de7602eSdrh
69d98f5324Sdrh# Constant propagation caused an incorrect answer in the following
70d98f5324Sdrh# query.  (Reported by Bentley system on 2018-08-09.)
71d98f5324Sdrh#
72d98f5324Sdrhdo_execsql_test 300 {
73d98f5324Sdrh  CREATE TABLE A(id INTEGER PRIMARY KEY, label TEXT);
74d98f5324Sdrh  CREATE TABLE B(id INTEGER PRIMARY KEY, label TEXT, Aid INTEGER);
75d98f5324Sdrh  CREATE TABLE C(
76d98f5324Sdrh    id INTEGER PRIMARY KEY,
77d98f5324Sdrh    xx INTEGER NOT NULL,
78d98f5324Sdrh    yy INTEGER,
79d98f5324Sdrh    zz INTEGER
80d98f5324Sdrh  );
81d98f5324Sdrh  CREATE UNIQUE INDEX x2 ON C(yy);
82d98f5324Sdrh  CREATE UNIQUE INDEX x4 ON C(yy, zz);
83d98f5324Sdrh  INSERT INTO A(id) VALUES(1);
84d98f5324Sdrh  INSERT INTO B(id) VALUES(2);
85d98f5324Sdrh  INSERT INTO C(id,xx,yy,zz) VALUES(99,50,1,2);
86d98f5324Sdrh  SELECT 1
87d98f5324Sdrh    FROM A,
88d98f5324Sdrh         (SELECT id,xx,yy,zz FROM C) subq,
89d98f5324Sdrh         B
90d98f5324Sdrh   WHERE A.id='1'
91d98f5324Sdrh     AND A.id=subq.yy
92d98f5324Sdrh     AND B.id=subq.zz;
93d98f5324Sdrh} {1}
94d98f5324Sdrhdo_execsql_test 301 {
95d98f5324Sdrh  SELECT 1
96d98f5324Sdrh    FROM A,
97d98f5324Sdrh         (SELECT id,xx,yy,zz FROM C) subq,
98d98f5324Sdrh         B
99d98f5324Sdrh   WHERE A.id=1
100d98f5324Sdrh     AND A.id=subq.yy
101d98f5324Sdrh     AND B.id=subq.zz;
102d98f5324Sdrh} {1}
103d98f5324Sdrhdo_execsql_test 302 {
104d98f5324Sdrh  SELECT 1
105d98f5324Sdrh    FROM A,
106d98f5324Sdrh         (SELECT id,yy,zz FROM C) subq,
107d98f5324Sdrh         B
108d98f5324Sdrh   WHERE A.id='1'
109d98f5324Sdrh     AND A.id=subq.yy
110d98f5324Sdrh     AND B.id=subq.zz;
111d98f5324Sdrh} {1}
112d98f5324Sdrh
1138e5bfeddSdrh# 2018-10-25: Ticket [cf5ed20f]
1148e5bfeddSdrh# Incorrect join result with duplicate WHERE clause constraint.
1158e5bfeddSdrh#
1168e5bfeddSdrhdo_execsql_test 400 {
1178e5bfeddSdrh  CREATE TABLE x(a, b, c);
1188e5bfeddSdrh  CREATE TABLE y(a, b);
1198e5bfeddSdrh  INSERT INTO x VALUES (1, 0, 1);
1208e5bfeddSdrh  INSERT INTO y VALUES (1, 2);
1218e5bfeddSdrh  SELECT x.a FROM x JOIN y ON x.c = y.a WHERE x.b = 1 AND x.b = 1;
1228e5bfeddSdrh} {}
1238e5bfeddSdrh
124c9301e6eSdrh# 2020-01-07: ticket 82ac75ba0093e5dc
125c9301e6eSdrh# Incorrect join result due to mishandling of affinity in constant
126c9301e6eSdrh# propagation.
127c9301e6eSdrh#
128c9301e6eSdrhreset_db
129c9301e6eSdrhdo_execsql_test 500 {
130c9301e6eSdrh  PRAGMA automatic_index=OFF;
131c9301e6eSdrh  CREATE TABLE t0(c0);
132c9301e6eSdrh  INSERT INTO t0 VALUES('0');
133c9301e6eSdrh  CREATE VIEW v0(c0) AS SELECT CAST(0 AS INT) FROM t0;
134c9301e6eSdrh  SELECT 200, * FROM t0, v0 WHERE 0 = t0.c0 AND t0.c0 = v0.c0;
135c9301e6eSdrh} {}
136c9301e6eSdrhdo_execsql_test 510 {
137c9301e6eSdrh  SELECT 200, * FROM t0, v0 WHERE t0.c0 = 0 AND t0.c0 = v0.c0;
138c9301e6eSdrh} {}
139c9301e6eSdrhdo_execsql_test 520 {
140c9301e6eSdrh  SELECT 200, * FROM t0, v0 WHERE 0 = t0.c0 AND v0.c0 = t0.c0;
141c9301e6eSdrh} {}
142c9301e6eSdrhdo_execsql_test 530 {
143c9301e6eSdrh  SELECT 200, * FROM t0, v0 WHERE t0.c0 = 0 AND v0.c0 = t0.c0;
144c9301e6eSdrh} {}
145c9301e6eSdrh
146fdfd45aeSdrh# 2020-02-13: ticket 1dcb4d44964846ad
147fdfd45aeSdrh# A problem introduced while making optimizations on the fixes above.
148fdfd45aeSdrh#
149fdfd45aeSdrhreset_db
150fdfd45aeSdrhdo_execsql_test 600 {
151fdfd45aeSdrh  CREATE TABLE t1(x TEXT);
152fdfd45aeSdrh  CREATE TABLE t2(y TEXT);
153fdfd45aeSdrh  INSERT INTO t1 VALUES('good'),('bad');
154fdfd45aeSdrh  INSERT INTO t2 VALUES('good'),('bad');
155fdfd45aeSdrh  SELECT * FROM t1 JOIN t2 ON x=y
156fdfd45aeSdrh   WHERE x='good' AND y='good';
157fdfd45aeSdrh} {good good}
158c9301e6eSdrh
159742efb67Sdrh# 2020-04-24: Another test case for the previous (1dcb4d44964846ad)
160742efb67Sdrh# ticket.  The test case comes from
161742efb67Sdrh# https://stackoverflow.com/questions/61399253/sqlite3-different-result-in-console-compared-to-python-script/
162742efb67Sdrh# Output verified against postgresql.
163742efb67Sdrh#
164742efb67Sdrhdo_execsql_test 610 {
165742efb67Sdrh  CREATE TABLE tableA(
166742efb67Sdrh    ID           int,
167742efb67Sdrh    RunYearMonth int
168742efb67Sdrh  );
169742efb67Sdrh  INSERT INTO tableA VALUES(1,202003),(2,202003),(3,202003),(4,202004),
170742efb67Sdrh    (5,202004),(6,202004),(7,202004),(8,202004);
171742efb67Sdrh  CREATE TABLE tableB (
172742efb67Sdrh    ID           int,
173742efb67Sdrh    RunYearMonth int
174742efb67Sdrh  );
175742efb67Sdrh  INSERT INTO tableB VALUES(1,202004),(2,202004),(3,202004),(4,202004),
176742efb67Sdrh  (5,202004);
177742efb67Sdrh  SELECT *
178742efb67Sdrh   FROM (
179742efb67Sdrh        SELECT *
180742efb67Sdrh        FROM tableA
181742efb67Sdrh        WHERE RunYearMonth = 202004
182742efb67Sdrh    ) AS A
183742efb67Sdrh    INNER JOIN (
184742efb67Sdrh        SELECT *
185742efb67Sdrh        FROM tableB
186742efb67Sdrh        WHERE RunYearMonth = 202004
187742efb67Sdrh    ) AS B
188742efb67Sdrh    ON A.ID = B.ID
189742efb67Sdrh    AND A.RunYearMonth = B.RunYearMonth;
190742efb67Sdrh} {4 202004 4 202004 5 202004 5 202004}
191742efb67Sdrh
192742efb67Sdrh
193660ee556Sdrhfinish_test
194