blob: 9c10d821d927c6126c8b0e3faea6e72f8a6411f5 [file] [log] [blame]
dan2dd3cdc2014-04-26 20:21:14 +00001# 2014-04-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#
12
13set testdir [file dirname $argv0]
14source $testdir/tester.tcl
15set testprefix cost
16
17
18do_execsql_test 1.1 {
19 CREATE TABLE t3(id INTEGER PRIMARY KEY, b NOT NULL);
20 CREATE TABLE t4(c, d, e);
21 CREATE UNIQUE INDEX i3 ON t3(b);
22 CREATE UNIQUE INDEX i4 ON t4(c, d);
23}
24do_eqp_test 1.2 {
25 SELECT e FROM t3, t4 WHERE b=c ORDER BY b, d;
26} {
27 0 0 0 {SCAN TABLE t3 USING COVERING INDEX i3}
28 0 1 1 {SEARCH TABLE t4 USING INDEX i4 (c=?)}
29}
30
31
32do_execsql_test 2.1 {
33 CREATE TABLE t1(a, b);
34 CREATE INDEX i1 ON t1(a);
35}
36
37# It is better to use an index for ORDER BY than sort externally, even
38# if the index is a non-covering index.
39do_eqp_test 2.2 {
40 SELECT * FROM t1 ORDER BY a;
41} {
42 0 0 0 {SCAN TABLE t1 USING INDEX i1}
43}
44
45do_execsql_test 3.1 {
46 CREATE TABLE t5(a INTEGER PRIMARY KEY,b,c,d,e,f,g);
47 CREATE INDEX t5b ON t5(b);
48 CREATE INDEX t5c ON t5(c);
49 CREATE INDEX t5d ON t5(d);
50 CREATE INDEX t5e ON t5(e);
51 CREATE INDEX t5f ON t5(f);
52 CREATE INDEX t5g ON t5(g);
53}
54
55do_eqp_test 3.2 {
56 SELECT a FROM t5
57 WHERE b IS NULL OR c IS NULL OR d IS NULL
58 ORDER BY a;
59} {
60 0 0 0 {SEARCH TABLE t5 USING INDEX t5b (b=?)}
61 0 0 0 {SEARCH TABLE t5 USING INDEX t5c (c=?)}
62 0 0 0 {SEARCH TABLE t5 USING INDEX t5d (d=?)}
63 0 0 0 {USE TEMP B-TREE FOR ORDER BY}
64}
65
dan440e6ff2014-04-28 08:49:54 +000066#-------------------------------------------------------------------------
67# If there is no likelihood() or stat3 data, SQLite assumes that a closed
68# range scan (e.g. one constrained by "col BETWEEN ? AND ?" constraint)
dan09e1df62014-04-29 16:10:22 +000069# visits 1/64 of the rows in a table.
dan440e6ff2014-04-28 08:49:54 +000070#
dan09e1df62014-04-29 16:10:22 +000071# Note: 1/63 =~ 0.016
72# Note: 1/65 =~ 0.015
dan440e6ff2014-04-28 08:49:54 +000073#
74reset_db
75do_execsql_test 4.1 {
76 CREATE TABLE t1(a, b);
77 CREATE INDEX i1 ON t1(a);
78 CREATE INDEX i2 ON t1(b);
79}
80do_eqp_test 4.2 {
dan09e1df62014-04-29 16:10:22 +000081 SELECT * FROM t1 WHERE likelihood(a=?, 0.014) AND b BETWEEN ? AND ?;
dan440e6ff2014-04-28 08:49:54 +000082} {
83 0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?)}
84}
85do_eqp_test 4.3 {
dan09e1df62014-04-29 16:10:22 +000086 SELECT * FROM t1 WHERE likelihood(a=?, 0.016) AND b BETWEEN ? AND ?;
dan440e6ff2014-04-28 08:49:54 +000087} {
88 0 0 0 {SEARCH TABLE t1 USING INDEX i2 (b>? AND b<?)}
89}
dan2dd3cdc2014-04-26 20:21:14 +000090
91
dan7de2a1f2014-04-28 20:11:20 +000092#-------------------------------------------------------------------------
93#
94reset_db
95do_execsql_test 5.1 {
96 CREATE TABLE t2(x, y);
97 CREATE INDEX t2i1 ON t2(x);
98}
99
100do_eqp_test 5.2 {
101 SELECT * FROM t2 ORDER BY x, y;
dan75525cb2014-04-30 14:53:21 +0000102} {
103 0 0 0 {SCAN TABLE t2 USING INDEX t2i1}
104 0 0 0 {USE TEMP B-TREE FOR RIGHT PART OF ORDER BY}
105}
dan7de2a1f2014-04-28 20:11:20 +0000106
dan7de2a1f2014-04-28 20:11:20 +0000107do_eqp_test 5.3 {
108 SELECT * FROM t2 WHERE x BETWEEN ? AND ? ORDER BY rowid;
dan09e1df62014-04-29 16:10:22 +0000109} {
110 0 0 0 {SEARCH TABLE t2 USING INDEX t2i1 (x>? AND x<?)}
111 0 0 0 {USE TEMP B-TREE FOR ORDER BY}
112}
dan7de2a1f2014-04-28 20:11:20 +0000113
114# where7.test, where8.test:
115#
116do_execsql_test 6.1 {
117 CREATE TABLE t3(a INTEGER PRIMARY KEY, b, c);
118 CREATE INDEX t3i1 ON t3(b);
119 CREATE INDEX t3i2 ON t3(c);
120}
121
dan7de2a1f2014-04-28 20:11:20 +0000122do_eqp_test 6.2 {
123 SELECT a FROM t3 WHERE (b BETWEEN 2 AND 4) OR c=100 ORDER BY a
124} {
dan09e1df62014-04-29 16:10:22 +0000125 0 0 0 {SEARCH TABLE t3 USING INDEX t3i1 (b>? AND b<?)}
126 0 0 0 {SEARCH TABLE t3 USING INDEX t3i2 (c=?)}
127 0 0 0 {USE TEMP B-TREE FOR ORDER BY}
dan7de2a1f2014-04-28 20:11:20 +0000128}
129
130#-------------------------------------------------------------------------
131#
132reset_db
133do_execsql_test 7.1 {
134 CREATE TABLE t1(a INTEGER PRIMARY KEY,b,c,d,e,f,g);
135 CREATE INDEX t1b ON t1(b);
136 CREATE INDEX t1c ON t1(c);
137 CREATE INDEX t1d ON t1(d);
138 CREATE INDEX t1e ON t1(e);
139 CREATE INDEX t1f ON t1(f);
140 CREATE INDEX t1g ON t1(g);
141}
142
143do_eqp_test 7.2 {
144 SELECT a FROM t1
145 WHERE (b>=950 AND b<=1010) OR (b IS NULL AND c NOT NULL)
146 ORDER BY a
147} {
dan09e1df62014-04-29 16:10:22 +0000148 0 0 0 {SEARCH TABLE t1 USING INDEX t1b (b>? AND b<?)}
149 0 0 0 {SEARCH TABLE t1 USING INDEX t1b (b=?)}
150 0 0 0 {USE TEMP B-TREE FOR ORDER BY}
dan7de2a1f2014-04-28 20:11:20 +0000151}
152
dan7de2a1f2014-04-28 20:11:20 +0000153do_eqp_test 7.3 {
154 SELECT rowid FROM t1
155 WHERE (+b IS NULL AND c NOT NULL AND d NOT NULL)
156 OR (b NOT NULL AND c IS NULL AND d NOT NULL)
157 OR (b NOT NULL AND c NOT NULL AND d IS NULL)
dan09e1df62014-04-29 16:10:22 +0000158} {
159 0 0 0 {SCAN TABLE t1}
160}
dan7de2a1f2014-04-28 20:11:20 +0000161
dan5da73e12014-04-30 18:11:55 +0000162do_eqp_test 7.4 {
163 SELECT rowid FROM t1 WHERE (+b IS NULL AND c NOT NULL) OR c IS NULL
164} {
165 0 0 0 {SCAN TABLE t1}
166}
167
dan7de2a1f2014-04-28 20:11:20 +0000168#-------------------------------------------------------------------------
169#
170reset_db
171do_execsql_test 8.1 {
172 CREATE TABLE composer(
173 cid INTEGER PRIMARY KEY,
174 cname TEXT
175 );
176 CREATE TABLE album(
177 aid INTEGER PRIMARY KEY,
178 aname TEXT
179 );
180 CREATE TABLE track(
181 tid INTEGER PRIMARY KEY,
182 cid INTEGER REFERENCES composer,
183 aid INTEGER REFERENCES album,
184 title TEXT
185 );
186 CREATE INDEX track_i1 ON track(cid);
187 CREATE INDEX track_i2 ON track(aid);
188}
189
190do_eqp_test 8.2 {
191 SELECT DISTINCT aname
192 FROM album, composer, track
193 WHERE cname LIKE '%bach%'
194 AND unlikely(composer.cid=track.cid)
195 AND unlikely(album.aid=track.aid);
196} {
dan09e1df62014-04-29 16:10:22 +0000197 0 0 2 {SCAN TABLE track}
198 0 1 0 {SEARCH TABLE album USING INTEGER PRIMARY KEY (rowid=?)}
199 0 2 1 {SEARCH TABLE composer USING INTEGER PRIMARY KEY (rowid=?)}
200 0 0 0 {USE TEMP B-TREE FOR DISTINCT}
dan7de2a1f2014-04-28 20:11:20 +0000201}
202
dan264d2b92014-04-29 19:01:57 +0000203#-------------------------------------------------------------------------
204#
205do_execsql_test 9.1 {
206 CREATE TABLE t1(
207 a,b,c,d,e, f,g,h,i,j,
208 k,l,m,n,o, p,q,r,s,t
209 );
210 CREATE INDEX i1 ON t1(k,l,m,n,o,p,q,r,s,t);
211}
212do_test 9.2 {
213 for {set i 0} {$i < 100} {incr i} {
214 execsql { INSERT INTO t1 DEFAULT VALUES }
215 }
216 execsql {
217 ANALYZE;
218 CREATE INDEX i2 ON t1(a,b,c,d,e,f,g,h,i,j);
219 }
220} {}
221
222set L [list a=? b=? c=? d=? e=? f=? g=? h=? i=? j=?]
223foreach {tn nTerm nRow} {
224 1 1 10
225 2 2 9
226 3 3 8
227 4 4 7
228 5 5 6
229 6 6 5
230 7 7 5
231 8 8 5
232 9 9 5
233 10 10 5
234} {
235 set w [join [lrange $L 0 [expr $nTerm-1]] " AND "]
236 set p1 [expr ($nRow-1) / 100.0]
237 set p2 [expr ($nRow+1) / 100.0]
238
239 set sql1 "SELECT * FROM t1 WHERE likelihood(k=?, $p1) AND $w"
240 set sql2 "SELECT * FROM t1 WHERE likelihood(k=?, $p2) AND $w"
241
242 do_eqp_test 9.3.$tn.1 $sql1 {/INDEX i1/}
243 do_eqp_test 9.3.$tn.2 $sql2 {/INDEX i2/}
244}
245
246
dan5a0b8b12014-06-03 11:32:38 +0000247#-------------------------------------------------------------------------
248#
249
250ifcapable stat4 {
251 do_execsql_test 10.1 {
252 CREATE TABLE t6(a, b, c);
253 CREATE INDEX t6i1 ON t6(a, b);
254 CREATE INDEX t6i2 ON t6(c);
255 }
256
257 do_test 10.2 {
258 for {set i 0} {$i < 16} {incr i} {
259 execsql { INSERT INTO t6 VALUES($i%4, 'xyz', $i%8) }
260 }
261 execsql ANALYZE
262 } {}
263
264 do_eqp_test 10.3 {
265 SELECT rowid FROM t6 WHERE a=0 AND c=0
266 } {
267 0 0 0 {SEARCH TABLE t6 USING INDEX t6i2 (c=?)}
268 }
269
270 do_eqp_test 10.4 {
271 SELECT rowid FROM t6 WHERE a=0 AND b='xyz' AND c=0
272 } {
273 0 0 0 {SEARCH TABLE t6 USING INDEX t6i2 (c=?)}
274 }
275
276 do_eqp_test 10.5 {
277 SELECT rowid FROM t6 WHERE likelihood(a=0, 0.1) AND c=0
278 } {
279 0 0 0 {SEARCH TABLE t6 USING INDEX t6i1 (a=?)}
280 }
281
282 do_eqp_test 10.6 {
283 SELECT rowid FROM t6 WHERE likelihood(a=0, 0.1) AND b='xyz' AND c=0
284 } {
285 0 0 0 {SEARCH TABLE t6 USING INDEX t6i1 (a=? AND b=?)}
286 }
287}
dan264d2b92014-04-29 19:01:57 +0000288
dan2dd3cdc2014-04-26 20:21:14 +0000289finish_test