3 # The author disclaims copyright to this source code. In place of
4 # a legal notice, here is a blessing:
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.
10 #***********************************************************************
12 # Test cases for query planning decisions and the likely(), unlikely(), and
13 # likelihood() functions.
15 set testdir [file dirname $argv0]
16 source $testdir/tester.tcl
19 do_execsql_test whereG-1.0 {
20 CREATE TABLE composer(
21 cid INTEGER PRIMARY KEY,
25 aid INTEGER PRIMARY KEY,
29 tid INTEGER PRIMARY KEY,
30 cid INTEGER REFERENCES composer,
31 aid INTEGER REFERENCES album,
34 CREATE INDEX track_i1 ON track(cid);
35 CREATE INDEX track_i2 ON track(aid);
36 INSERT INTO composer VALUES(1, 'W. A. Mozart');
37 INSERT INTO composer VALUES(2, 'Beethoven');
38 INSERT INTO composer VALUES(3, 'Thomas Tallis');
39 INSERT INTO composer VALUES(4, 'Joseph Hayden');
40 INSERT INTO composer VALUES(5, 'Thomas Weelkes');
41 INSERT INTO composer VALUES(6, 'J. S. Bach');
42 INSERT INTO composer VALUES(7, 'Orlando Gibbons');
43 INSERT INTO composer VALUES(8, 'Josquin des Prés');
44 INSERT INTO composer VALUES(9, 'Byrd');
45 INSERT INTO composer VALUES(10, 'Francis Poulenc');
46 INSERT INTO composer VALUES(11, 'Mendelsshon');
47 INSERT INTO composer VALUES(12, 'Zoltán Kodály');
48 INSERT INTO composer VALUES(13, 'Handel');
49 INSERT INTO album VALUES(100, 'Kodály: Missa Brevis');
50 INSERT INTO album VALUES(101, 'Messiah');
51 INSERT INTO album VALUES(102, 'Missa Brevis in D-, K.65');
52 INSERT INTO album VALUES(103, 'The complete English anthems');
53 INSERT INTO album VALUES(104, 'Mass in B Minor, BWV 232');
54 INSERT INTO track VALUES(10005, 12, 100, 'Sanctus');
55 INSERT INTO track VALUES(10007, 12, 100, 'Agnus Dei');
56 INSERT INTO track VALUES(10115, 13, 101, 'Surely He Hath Borne Our Griefs');
57 INSERT INTO track VALUES(10129, 13, 101, 'Since By Man Came Death');
58 INSERT INTO track VALUES(10206, 1, 102, 'Agnus Dei');
59 INSERT INTO track VALUES(10301, 3, 103, 'If Ye Love Me');
60 INSERT INTO track VALUES(10402, 6, 104, 'Domine Deus');
61 INSERT INTO track VALUES(10403, 6, 104, 'Qui tollis');
63 do_eqp_test whereG-1.1 {
65 FROM album, composer, track
66 WHERE unlikely(cname LIKE '%bach%')
67 AND composer.cid=track.cid
68 AND album.aid=track.aid;
69 } {composer*track*album}
70 do_execsql_test whereG-1.2 {
72 FROM album, composer, track
73 WHERE unlikely(cname LIKE '%bach%')
74 AND composer.cid=track.cid
75 AND album.aid=track.aid;
76 } {{Mass in B Minor, BWV 232}}
78 do_eqp_test whereG-1.3 {
80 FROM album, composer, track
81 WHERE likelihood(cname LIKE '%bach%', 0.5)
82 AND composer.cid=track.cid
83 AND album.aid=track.aid;
84 } {/.*track.*composer.*album.*/}
85 do_execsql_test whereG-1.4 {
87 FROM album, composer, track
88 WHERE likelihood(cname LIKE '%bach%', 0.5)
89 AND composer.cid=track.cid
90 AND album.aid=track.aid;
91 } {{Mass in B Minor, BWV 232}}
93 do_eqp_test whereG-1.5 {
95 FROM album, composer, track
96 WHERE cname LIKE '%bach%'
97 AND composer.cid=track.cid
98 AND album.aid=track.aid;
99 } {/.*track.*(composer.*album|album.*composer).*/}
100 do_execsql_test whereG-1.6 {
101 SELECT DISTINCT aname
102 FROM album, composer, track
103 WHERE cname LIKE '%bach%'
104 AND composer.cid=track.cid
105 AND album.aid=track.aid;
106 } {{Mass in B Minor, BWV 232}}
108 do_eqp_test whereG-1.7 {
109 SELECT DISTINCT aname
110 FROM album, composer, track
111 WHERE cname LIKE '%bach%'
112 AND unlikely(composer.cid=track.cid)
113 AND unlikely(album.aid=track.aid);
114 } {/.*track.*(composer.*album|album.*composer).*/}
115 do_execsql_test whereG-1.8 {
116 SELECT DISTINCT aname
117 FROM album, composer, track
118 WHERE cname LIKE '%bach%'
119 AND unlikely(composer.cid=track.cid)
120 AND unlikely(album.aid=track.aid);
121 } {{Mass in B Minor, BWV 232}}
125 SELECT DISTINCT aname
126 FROM album, composer, track
127 WHERE likelihood(cname LIKE '%bach%', -0.01)
128 AND composer.cid=track.cid
129 AND album.aid=track.aid;
131 } {1 {second argument to likelihood() must be a constant between 0.0 and 1.0}}
134 SELECT DISTINCT aname
135 FROM album, composer, track
136 WHERE likelihood(cname LIKE '%bach%', 1.01)
137 AND composer.cid=track.cid
138 AND album.aid=track.aid;
140 } {1 {second argument to likelihood() must be a constant between 0.0 and 1.0}}
143 SELECT DISTINCT aname
144 FROM album, composer, track
145 WHERE likelihood(cname LIKE '%bach%', track.cid)
146 AND composer.cid=track.cid
147 AND album.aid=track.aid;
149 } {1 {second argument to likelihood() must be a constant between 0.0 and 1.0}}
151 # Commuting a term of the WHERE clause should not change the query plan
153 do_execsql_test whereG-3.0 {
154 CREATE TABLE a(a1 PRIMARY KEY, a2);
155 CREATE TABLE b(b1 PRIMARY KEY, b2);
157 do_eqp_test whereG-3.1 {
158 SELECT * FROM a, b WHERE b1=a1 AND a2=5;
159 } {/.*SCAN TABLE a.*SEARCH TABLE b USING INDEX .*b_1 .b1=..*/}
160 do_eqp_test whereG-3.2 {
161 SELECT * FROM a, b WHERE a1=b1 AND a2=5;
162 } {/.*SCAN TABLE a.*SEARCH TABLE b USING INDEX .*b_1 .b1=..*/}
163 do_eqp_test whereG-3.3 {
164 SELECT * FROM a, b WHERE a2=5 AND b1=a1;
165 } {/.*SCAN TABLE a.*SEARCH TABLE b USING INDEX .*b_1 .b1=..*/}
166 do_eqp_test whereG-3.4 {
167 SELECT * FROM a, b WHERE a2=5 AND a1=b1;
168 } {/.*SCAN TABLE a.*SEARCH TABLE b USING INDEX .*b_1 .b1=..*/}
170 # Ticket [1e64dd782a126f48d78c43a664844a41d0e6334e]:
171 # Incorrect result in a nested GROUP BY/DISTINCT due to the use of an OP_SCopy
172 # where an OP_Copy was needed.
174 do_execsql_test whereG-4.0 {
176 INSERT INTO t4 VALUES('right'),('wrong');
178 FROM (SELECT x FROM t4 GROUP BY x)
183 #-------------------------------------------------------------------------
184 # Test that likelihood() specifications on indexed terms are taken into
185 # account by various forms of loops.
187 # 5.1.*: open ended range scans
192 do_execsql_test 5.1 {
193 CREATE TABLE t1(a, b, c);
194 CREATE INDEX i1 ON t1(a, b);
197 SELECT * FROM t1 WHERE a>?
198 } {SEARCH TABLE t1 USING INDEX i1 (a>?)}
200 SELECT * FROM t1 WHERE likelihood(a>?, 0.9)
203 SELECT * FROM t1 WHERE likely(a>?)
207 for {set i 0} {$i < 100} {incr i} {
208 execsql { INSERT INTO t1 VALUES('abc', $i, $i); }
210 execsql { INSERT INTO t1 SELECT 'def', b, c FROM t1; }
214 SELECT * FROM t1 WHERE likelihood(b>?, 0.01)
215 } {SEARCH TABLE t1 USING INDEX i1 (ANY(a) AND b>?)}
217 SELECT * FROM t1 WHERE likelihood(b>?, 0.9)
220 SELECT * FROM t1 WHERE likely(b>?)
224 SELECT * FROM t1 WHERE a=?
225 } {SEARCH TABLE t1 USING INDEX i1 (a=?)}
227 SELECT * FROM t1 WHERE likelihood(a=?, 0.9)
230 SELECT * FROM t1 WHERE likely(a=?)
234 # Ticket [https://www.sqlite.org/see/tktview/472f0742a1868fb58862bc588ed70]
236 do_execsql_test 6.0 {
237 DROP TABLE IF EXISTS t1;
238 CREATE TABLE t1(i int, x, y, z);
239 INSERT INTO t1 VALUES (1,1,1,1), (2,2,2,2), (3,3,3,3), (4,4,4,4);
240 DROP TABLE IF EXISTS t2;
241 CREATE TABLE t2(i int, bool char);
242 INSERT INTO t2 VALUES(1,'T'), (2,'F');
243 SELECT count(*) FROM t1 LEFT JOIN t2 ON t1.i=t2.i AND bool='T';
244 SELECT count(*) FROM t1 LEFT JOIN t2 ON likely(t1.i=t2.i) AND bool='T';
248 # Crash discovered by AFL
250 do_execsql_test 7.0 {
251 DROP TABLE IF EXISTS t1;
252 CREATE TABLE t1(a, b, PRIMARY KEY(a,b));
253 INSERT INTO t1 VALUES(9,1),(1,2);
254 DROP TABLE IF EXISTS t2;
255 CREATE TABLE t2(x, y, PRIMARY KEY(x,y));
256 INSERT INTO t2 VALUES(3,3),(4,4);
257 SELECT likely(a), x FROM t1, t2 ORDER BY 1, 2;
259 do_execsql_test 7.1 {
260 SELECT unlikely(a), x FROM t1, t2 ORDER BY 1, 2;
262 do_execsql_test 7.2 {
263 SELECT likelihood(a,0.5), x FROM t1, t2 ORDER BY 1, 2;
265 do_execsql_test 7.3 {
266 SELECT coalesce(a,a), x FROM t1, t2 ORDER BY 1, 2;