xref: /sqlite-3.40.0/test/eqp.test (revision 9cffb0ff)
1# 2010 November 6
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
15
16ifcapable !compound {
17  finish_test
18  return
19}
20
21set testprefix eqp
22
23#-------------------------------------------------------------------------
24#
25# eqp-1.*:        Assorted tests.
26# eqp-2.*:        Tests for single select statements.
27# eqp-3.*:        Select statements that execute sub-selects.
28# eqp-4.*:        Compound select statements.
29# ...
30# eqp-7.*:        "SELECT count(*) FROM tbl" statements (VDBE code OP_Count).
31#
32
33proc det {args} { uplevel do_eqp_test $args }
34
35do_execsql_test 1.1 {
36  CREATE TABLE t1(a INT, b INT, ex TEXT);
37  CREATE INDEX i1 ON t1(a);
38  CREATE INDEX i2 ON t1(b);
39  CREATE TABLE t2(a INT, b INT, ex TEXT);
40  CREATE TABLE t3(a INT, b INT, ex TEXT);
41}
42
43do_eqp_test 1.2 {
44  SELECT * FROM t2, t1 WHERE t1.a=1 OR t1.b=2;
45} {
46  QUERY PLAN
47  |--MULTI-INDEX OR
48  |  |--INDEX 1
49  |  |  `--SEARCH t1 USING INDEX i1 (a=?)
50  |  `--INDEX 2
51  |     `--SEARCH t1 USING INDEX i2 (b=?)
52  `--SCAN t2
53}
54do_eqp_test 1.3 {
55  SELECT * FROM t2 CROSS JOIN t1 WHERE t1.a=1 OR t1.b=2;
56} {
57  QUERY PLAN
58  |--SCAN t2
59  `--MULTI-INDEX OR
60     |--INDEX 1
61     |  `--SEARCH t1 USING INDEX i1 (a=?)
62     `--INDEX 2
63        `--SEARCH t1 USING INDEX i2 (b=?)
64}
65do_eqp_test 1.3 {
66  SELECT a FROM t1 ORDER BY a
67} {
68  QUERY PLAN
69  `--SCAN t1 USING COVERING INDEX i1
70}
71do_eqp_test 1.4 {
72  SELECT a FROM t1 ORDER BY +a
73} {
74  QUERY PLAN
75  |--SCAN t1 USING COVERING INDEX i1
76  `--USE TEMP B-TREE FOR ORDER BY
77}
78do_eqp_test 1.5 {
79  SELECT a FROM t1 WHERE a=4
80} {
81  QUERY PLAN
82  `--SEARCH t1 USING COVERING INDEX i1 (a=?)
83}
84do_eqp_test 1.6 {
85  SELECT DISTINCT count(*) FROM t3 GROUP BY a;
86} {
87  QUERY PLAN
88  |--SCAN t3
89  |--USE TEMP B-TREE FOR GROUP BY
90  `--USE TEMP B-TREE FOR DISTINCT
91}
92
93do_eqp_test 1.7.1 {
94  SELECT * FROM t3 JOIN (SELECT 1)
95} {
96  QUERY PLAN
97  |--MATERIALIZE SUBQUERY xxxxxx
98  |  `--SCAN CONSTANT ROW
99  |--SCAN SUBQUERY xxxxxx
100  `--SCAN t3
101}
102do_eqp_test 1.7.2 {
103  SELECT * FROM t3 JOIN (SELECT 1) AS v1
104} {
105  QUERY PLAN
106  |--MATERIALIZE v1
107  |  `--SCAN CONSTANT ROW
108  |--SCAN v1
109  `--SCAN t3
110}
111do_eqp_test 1.7.3 {
112  SELECT * FROM t3 AS xx JOIN (SELECT 1) AS yy
113} {
114  QUERY PLAN
115  |--MATERIALIZE yy
116  |  `--SCAN CONSTANT ROW
117  |--SCAN yy
118  `--SCAN xx
119}
120
121
122do_eqp_test 1.8 {
123  SELECT * FROM t3 JOIN (SELECT 1 UNION SELECT 2)
124} {
125  QUERY PLAN
126  |--MATERIALIZE SUBQUERY xxxxxx
127  |  `--COMPOUND QUERY
128  |     |--LEFT-MOST SUBQUERY
129  |     |  `--SCAN CONSTANT ROW
130  |     `--UNION USING TEMP B-TREE
131  |        `--SCAN CONSTANT ROW
132  |--SCAN SUBQUERY xxxxxx
133  `--SCAN t3
134}
135do_eqp_test 1.9 {
136  SELECT * FROM t3 JOIN (SELECT 1 EXCEPT SELECT a FROM t3 LIMIT 17) AS abc
137} {
138  QUERY PLAN
139  |--MATERIALIZE abc
140  |  `--COMPOUND QUERY
141  |     |--LEFT-MOST SUBQUERY
142  |     |  `--SCAN CONSTANT ROW
143  |     `--EXCEPT USING TEMP B-TREE
144  |        `--SCAN t3
145  |--SCAN abc
146  `--SCAN t3
147}
148do_eqp_test 1.10 {
149  SELECT * FROM t3 JOIN (SELECT 1 INTERSECT SELECT a FROM t3 LIMIT 17) AS abc
150} {
151  QUERY PLAN
152  |--MATERIALIZE abc
153  |  `--COMPOUND QUERY
154  |     |--LEFT-MOST SUBQUERY
155  |     |  `--SCAN CONSTANT ROW
156  |     `--INTERSECT USING TEMP B-TREE
157  |        `--SCAN t3
158  |--SCAN abc
159  `--SCAN t3
160}
161
162do_eqp_test 1.11 {
163  SELECT * FROM t3 JOIN (SELECT 1 UNION ALL SELECT a FROM t3 LIMIT 17) abc
164} {
165  QUERY PLAN
166  |--MATERIALIZE abc
167  |  `--COMPOUND QUERY
168  |     |--LEFT-MOST SUBQUERY
169  |     |  `--SCAN CONSTANT ROW
170  |     `--UNION ALL
171  |        `--SCAN t3
172  |--SCAN abc
173  `--SCAN t3
174}
175
176#-------------------------------------------------------------------------
177# Test cases eqp-2.* - tests for single select statements.
178#
179drop_all_tables
180do_execsql_test 2.1 {
181  CREATE TABLE t1(x INT, y INT, ex TEXT);
182
183  CREATE TABLE t2(x INT, y INT, ex TEXT);
184  CREATE INDEX t2i1 ON t2(x);
185}
186
187det 2.2.1 "SELECT DISTINCT min(x), max(x) FROM t1 GROUP BY x ORDER BY 1" {
188  QUERY PLAN
189  |--SCAN t1
190  |--USE TEMP B-TREE FOR GROUP BY
191  |--USE TEMP B-TREE FOR DISTINCT
192  `--USE TEMP B-TREE FOR ORDER BY
193}
194det 2.2.2 "SELECT DISTINCT min(x), max(x) FROM t2 GROUP BY x ORDER BY 1" {
195  QUERY PLAN
196  |--SCAN t2 USING COVERING INDEX t2i1
197  |--USE TEMP B-TREE FOR DISTINCT
198  `--USE TEMP B-TREE FOR ORDER BY
199}
200det 2.2.3 "SELECT DISTINCT * FROM t1" {
201  QUERY PLAN
202  |--SCAN t1
203  `--USE TEMP B-TREE FOR DISTINCT
204}
205det 2.2.4 "SELECT DISTINCT * FROM t1, t2" {
206  QUERY PLAN
207  |--SCAN t1
208  |--SCAN t2
209  `--USE TEMP B-TREE FOR DISTINCT
210}
211det 2.2.5 "SELECT DISTINCT * FROM t1, t2 ORDER BY t1.x" {
212  QUERY PLAN
213  |--SCAN t1
214  |--SCAN t2
215  |--USE TEMP B-TREE FOR DISTINCT
216  `--USE TEMP B-TREE FOR ORDER BY
217}
218det 2.2.6 "SELECT DISTINCT t2.x FROM t1, t2 ORDER BY t2.x" {
219  QUERY PLAN
220  |--SCAN t2 USING COVERING INDEX t2i1
221  `--SCAN t1
222}
223
224det 2.3.1 "SELECT max(x) FROM t2" {
225  QUERY PLAN
226  `--SEARCH t2 USING COVERING INDEX t2i1
227}
228det 2.3.2 "SELECT min(x) FROM t2" {
229  QUERY PLAN
230  `--SEARCH t2 USING COVERING INDEX t2i1
231}
232det 2.3.3 "SELECT min(x), max(x) FROM t2" {
233  QUERY PLAN
234  `--SCAN t2 USING COVERING INDEX t2i1
235}
236
237det 2.4.1 "SELECT * FROM t1 WHERE rowid=?" {
238  QUERY PLAN
239  `--SEARCH t1 USING INTEGER PRIMARY KEY (rowid=?)
240}
241
242
243
244#-------------------------------------------------------------------------
245# Test cases eqp-3.* - tests for select statements that use sub-selects.
246#
247do_eqp_test 3.1.1 {
248  SELECT (SELECT x FROM t1 AS sub) FROM t1;
249} {
250  QUERY PLAN
251  |--SCAN t1
252  `--SCALAR SUBQUERY xxxxxx
253     `--SCAN sub
254}
255do_eqp_test 3.1.2 {
256  SELECT * FROM t1 WHERE (SELECT x FROM t1 AS sub);
257} {
258  QUERY PLAN
259  |--SCAN t1
260  `--SCALAR SUBQUERY xxxxxx
261     `--SCAN sub
262}
263do_eqp_test 3.1.3 {
264  SELECT * FROM t1 WHERE (SELECT x FROM t1 AS sub ORDER BY y);
265} {
266  QUERY PLAN
267  |--SCAN t1
268  `--SCALAR SUBQUERY xxxxxx
269     |--SCAN sub
270     `--USE TEMP B-TREE FOR ORDER BY
271}
272do_eqp_test 3.1.4 {
273  SELECT * FROM t1 WHERE (SELECT x FROM t2 ORDER BY x);
274} {
275  QUERY PLAN
276  |--SCAN t1
277  `--SCALAR SUBQUERY xxxxxx
278     `--SCAN t2 USING COVERING INDEX t2i1
279}
280
281det 3.2.1 {
282  SELECT * FROM (SELECT * FROM t1 ORDER BY x LIMIT 10) ORDER BY y LIMIT 5
283} {
284  QUERY PLAN
285  |--CO-ROUTINE SUBQUERY xxxxxx
286  |  |--SCAN t1
287  |  `--USE TEMP B-TREE FOR ORDER BY
288  |--SCAN SUBQUERY xxxxxx
289  `--USE TEMP B-TREE FOR ORDER BY
290}
291det 3.2.2 {
292  SELECT * FROM
293    (SELECT * FROM t1 ORDER BY x LIMIT 10) AS x1,
294    (SELECT * FROM t2 ORDER BY x LIMIT 10) AS x2
295  ORDER BY x2.y LIMIT 5
296} {
297  QUERY PLAN
298  |--MATERIALIZE x1
299  |  |--SCAN t1
300  |  `--USE TEMP B-TREE FOR ORDER BY
301  |--MATERIALIZE x2
302  |  `--SCAN t2 USING INDEX t2i1
303  |--SCAN x1
304  |--SCAN x2
305  `--USE TEMP B-TREE FOR ORDER BY
306}
307
308det 3.3.1 {
309  SELECT * FROM t1 WHERE y IN (SELECT y FROM t2)
310} {
311  QUERY PLAN
312  |--SCAN t1
313  `--LIST SUBQUERY xxxxxx
314     `--SCAN t2
315}
316det 3.3.2 {
317  SELECT * FROM t1 WHERE y IN (SELECT y FROM t2 WHERE t1.x!=t2.x)
318} {
319  QUERY PLAN
320  |--SCAN t1
321  `--CORRELATED LIST SUBQUERY xxxxxx
322     `--SCAN t2
323}
324det 3.3.3 {
325  SELECT * FROM t1 WHERE EXISTS (SELECT y FROM t2 WHERE t1.x!=t2.x)
326} {
327  QUERY PLAN
328  |--SCAN t1
329  `--CORRELATED SCALAR SUBQUERY xxxxxx
330     `--SCAN t2
331}
332
333#-------------------------------------------------------------------------
334# Test cases eqp-4.* - tests for composite select statements.
335#
336do_eqp_test 4.1.1 {
337  SELECT * FROM t1 UNION ALL SELECT * FROM t2
338} {
339  QUERY PLAN
340  `--COMPOUND QUERY
341     |--LEFT-MOST SUBQUERY
342     |  `--SCAN t1
343     `--UNION ALL
344        `--SCAN t2
345}
346do_eqp_test 4.1.2 {
347  SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY 2
348} {
349  QUERY PLAN
350  `--MERGE (UNION ALL)
351     |--LEFT
352     |  |--SCAN t1
353     |  `--USE TEMP B-TREE FOR ORDER BY
354     `--RIGHT
355        |--SCAN t2
356        `--USE TEMP B-TREE FOR ORDER BY
357}
358do_eqp_test 4.1.3 {
359  SELECT * FROM t1 UNION SELECT * FROM t2 ORDER BY 2
360} {
361  QUERY PLAN
362  `--MERGE (UNION)
363     |--LEFT
364     |  |--SCAN t1
365     |  `--USE TEMP B-TREE FOR ORDER BY
366     `--RIGHT
367        |--SCAN t2
368        `--USE TEMP B-TREE FOR ORDER BY
369}
370do_eqp_test 4.1.4 {
371  SELECT * FROM t1 INTERSECT SELECT * FROM t2 ORDER BY 2
372} {
373  QUERY PLAN
374  `--MERGE (INTERSECT)
375     |--LEFT
376     |  |--SCAN t1
377     |  `--USE TEMP B-TREE FOR ORDER BY
378     `--RIGHT
379        |--SCAN t2
380        `--USE TEMP B-TREE FOR ORDER BY
381}
382do_eqp_test 4.1.5 {
383  SELECT * FROM t1 EXCEPT SELECT * FROM t2 ORDER BY 2
384} {
385  QUERY PLAN
386  `--MERGE (EXCEPT)
387     |--LEFT
388     |  |--SCAN t1
389     |  `--USE TEMP B-TREE FOR ORDER BY
390     `--RIGHT
391        |--SCAN t2
392        `--USE TEMP B-TREE FOR ORDER BY
393}
394
395do_eqp_test 4.2.2 {
396  SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY 1
397} {
398  QUERY PLAN
399  `--MERGE (UNION ALL)
400     |--LEFT
401     |  |--SCAN t1
402     |  `--USE TEMP B-TREE FOR ORDER BY
403     `--RIGHT
404        `--SCAN t2 USING INDEX t2i1
405}
406do_eqp_test 4.2.3 {
407  SELECT * FROM t1 UNION SELECT * FROM t2 ORDER BY 1
408} {
409  QUERY PLAN
410  `--MERGE (UNION)
411     |--LEFT
412     |  |--SCAN t1
413     |  `--USE TEMP B-TREE FOR ORDER BY
414     `--RIGHT
415        |--SCAN t2 USING INDEX t2i1
416        `--USE TEMP B-TREE FOR RIGHT PART OF ORDER BY
417}
418do_eqp_test 4.2.4 {
419  SELECT * FROM t1 INTERSECT SELECT * FROM t2 ORDER BY 1
420} {
421  QUERY PLAN
422  `--MERGE (INTERSECT)
423     |--LEFT
424     |  |--SCAN t1
425     |  `--USE TEMP B-TREE FOR ORDER BY
426     `--RIGHT
427        |--SCAN t2 USING INDEX t2i1
428        `--USE TEMP B-TREE FOR RIGHT PART OF ORDER BY
429}
430do_eqp_test 4.2.5 {
431  SELECT * FROM t1 EXCEPT SELECT * FROM t2 ORDER BY 1
432} {
433  QUERY PLAN
434  `--MERGE (EXCEPT)
435     |--LEFT
436     |  |--SCAN t1
437     |  `--USE TEMP B-TREE FOR ORDER BY
438     `--RIGHT
439        |--SCAN t2 USING INDEX t2i1
440        `--USE TEMP B-TREE FOR RIGHT PART OF ORDER BY
441}
442
443do_eqp_test 4.3.1 {
444  SELECT x FROM t1 UNION SELECT x FROM t2
445} {
446  QUERY PLAN
447  `--COMPOUND QUERY
448     |--LEFT-MOST SUBQUERY
449     |  `--SCAN t1
450     `--UNION USING TEMP B-TREE
451        `--SCAN t2 USING COVERING INDEX t2i1
452}
453
454do_eqp_test 4.3.2 {
455  SELECT x FROM t1 UNION SELECT x FROM t2 UNION SELECT x FROM t1
456} {
457  QUERY PLAN
458  `--COMPOUND QUERY
459     |--LEFT-MOST SUBQUERY
460     |  `--SCAN t1
461     |--UNION USING TEMP B-TREE
462     |  `--SCAN t2 USING COVERING INDEX t2i1
463     `--UNION USING TEMP B-TREE
464        `--SCAN t1
465}
466do_eqp_test 4.3.3 {
467  SELECT x FROM t1 UNION SELECT x FROM t2 UNION SELECT x FROM t1 ORDER BY 1
468} {
469  QUERY PLAN
470  `--MERGE (UNION)
471     |--LEFT
472     |  `--MERGE (UNION)
473     |     |--LEFT
474     |     |  |--SCAN t1
475     |     |  `--USE TEMP B-TREE FOR ORDER BY
476     |     `--RIGHT
477     |        `--SCAN t2 USING COVERING INDEX t2i1
478     `--RIGHT
479        |--SCAN t1
480        `--USE TEMP B-TREE FOR ORDER BY
481}
482
483if 0 {
484#-------------------------------------------------------------------------
485# This next block of tests verifies that the examples on the
486# lang_explain.html page are correct.
487#
488drop_all_tables
489
490# XVIDENCE-OF: R-47779-47605 sqlite> EXPLAIN QUERY PLAN SELECT a, b
491# FROM t1 WHERE a=1;
492# 0|0|0|SCAN t1
493#
494do_execsql_test 5.1.0 { CREATE TABLE t1(a INT, b INT, ex TEXT) }
495det 5.1.1 "SELECT a, b FROM t1 WHERE a=1" {
496  0 0 0 {SCAN t1}
497}
498
499# XVIDENCE-OF: R-55852-17599 sqlite> CREATE INDEX i1 ON t1(a);
500# sqlite> EXPLAIN QUERY PLAN SELECT a, b FROM t1 WHERE a=1;
501# 0|0|0|SEARCH t1 USING INDEX i1
502#
503do_execsql_test 5.2.0 { CREATE INDEX i1 ON t1(a) }
504det 5.2.1 "SELECT a, b FROM t1 WHERE a=1" {
505  0 0 0 {SEARCH t1 USING INDEX i1 (a=?)}
506}
507
508# XVIDENCE-OF: R-21179-11011 sqlite> CREATE INDEX i2 ON t1(a, b);
509# sqlite> EXPLAIN QUERY PLAN SELECT a, b FROM t1 WHERE a=1;
510# 0|0|0|SEARCH t1 USING COVERING INDEX i2 (a=?)
511#
512do_execsql_test 5.3.0 { CREATE INDEX i2 ON t1(a, b) }
513det 5.3.1 "SELECT a, b FROM t1 WHERE a=1" {
514  0 0 0 {SEARCH t1 USING COVERING INDEX i2 (a=?)}
515}
516
517# XVIDENCE-OF: R-09991-48941 sqlite> EXPLAIN QUERY PLAN
518# SELECT t1.*, t2.* FROM t1, t2 WHERE t1.a=1 AND t1.b>2;
519# 0|0|0|SEARCH t1 USING COVERING INDEX i2 (a=? AND b>?)
520# 0|1|1|SCAN t2
521#
522do_execsql_test 5.4.0 {CREATE TABLE t2(c INT, d INT, ex TEXT)}
523det 5.4.1 "SELECT t1.a, t2.c FROM t1, t2 WHERE t1.a=1 AND t1.b>2" {
524  0 0 0 {SEARCH t1 USING COVERING INDEX i2 (a=? AND b>?)}
525  0 1 1 {SCAN t2}
526}
527
528# XVIDENCE-OF: R-33626-61085 sqlite> EXPLAIN QUERY PLAN
529# SELECT t1.*, t2.* FROM t2, t1 WHERE t1.a=1 AND t1.b>2;
530# 0|0|1|SEARCH t1 USING COVERING INDEX i2 (a=? AND b>?)
531# 0|1|0|SCAN t2
532#
533det 5.5 "SELECT t1.a, t2.c FROM t2, t1 WHERE t1.a=1 AND t1.b>2" {
534  0 0 1 {SEARCH t1 USING COVERING INDEX i2 (a=? AND b>?)}
535  0 1 0 {SCAN t2}
536}
537
538# XVIDENCE-OF: R-04002-25654 sqlite> CREATE INDEX i3 ON t1(b);
539# sqlite> EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE a=1 OR b=2;
540# 0|0|0|SEARCH t1 USING COVERING INDEX i2 (a=?)
541# 0|0|0|SEARCH t1 USING INDEX i3 (b=?)
542#
543do_execsql_test 5.5.0 {CREATE INDEX i3 ON t1(b)}
544det 5.6.1 "SELECT a, b FROM t1 WHERE a=1 OR b=2" {
545  0 0 0 {SEARCH t1 USING COVERING INDEX i2 (a=?)}
546  0 0 0 {SEARCH t1 USING INDEX i3 (b=?)}
547}
548
549# XVIDENCE-OF: R-24577-38891 sqlite> EXPLAIN QUERY PLAN
550# SELECT c, d FROM t2 ORDER BY c;
551# 0|0|0|SCAN t2
552# 0|0|0|USE TEMP B-TREE FOR ORDER BY
553#
554det 5.7 "SELECT c, d FROM t2 ORDER BY c" {
555  0 0 0 {SCAN t2}
556  0 0 0 {USE TEMP B-TREE FOR ORDER BY}
557}
558
559# XVIDENCE-OF: R-58157-12355 sqlite> CREATE INDEX i4 ON t2(c);
560# sqlite> EXPLAIN QUERY PLAN SELECT c, d FROM t2 ORDER BY c;
561# 0|0|0|SCAN t2 USING INDEX i4
562#
563do_execsql_test 5.8.0 {CREATE INDEX i4 ON t2(c)}
564det 5.8.1 "SELECT c, d FROM t2 ORDER BY c" {
565  0 0 0 {SCAN t2 USING INDEX i4}
566}
567
568# XVIDENCE-OF: R-13931-10421 sqlite> EXPLAIN QUERY PLAN SELECT
569# (SELECT b FROM t1 WHERE a=0), (SELECT a FROM t1 WHERE b=t2.c) FROM t2;
570# 0|0|0|SCAN t2
571# 0|0|0|EXECUTE SCALAR SUBQUERY 1
572# 1|0|0|SEARCH t1 USING COVERING INDEX i2 (a=?)
573# 0|0|0|EXECUTE CORRELATED SCALAR SUBQUERY 2
574# 2|0|0|SEARCH t1 USING INDEX i3 (b=?)
575#
576det 5.9 {
577  SELECT (SELECT b FROM t1 WHERE a=0), (SELECT a FROM t1 WHERE b=t2.c) FROM t2
578} {
579  0 0 0 {SCAN t2 USING COVERING INDEX i4}
580  0 0 0 {EXECUTE SCALAR SUBQUERY 1}
581  1 0 0 {SEARCH t1 USING COVERING INDEX i2 (a=?)}
582  0 0 0 {EXECUTE CORRELATED SCALAR SUBQUERY 2}
583  2 0 0 {SEARCH t1 USING INDEX i3 (b=?)}
584}
585
586# XVIDENCE-OF: R-50892-45943 sqlite> EXPLAIN QUERY PLAN
587# SELECT count(*) FROM (SELECT max(b) AS x FROM t1 GROUP BY a) GROUP BY x;
588# 1|0|0|SCAN t1 USING COVERING INDEX i2
589# 0|0|0|SCAN SUBQUERY 1
590# 0|0|0|USE TEMP B-TREE FOR GROUP BY
591#
592det 5.10 {
593  SELECT count(*) FROM (SELECT max(b) AS x FROM t1 GROUP BY a) GROUP BY x
594} {
595  1 0 0 {SCAN t1 USING COVERING INDEX i2}
596  0 0 0 {SCAN SUBQUERY 1}
597  0 0 0 {USE TEMP B-TREE FOR GROUP BY}
598}
599
600# XVIDENCE-OF: R-46219-33846 sqlite> EXPLAIN QUERY PLAN
601# SELECT * FROM (SELECT * FROM t2 WHERE c=1), t1;
602# 0|0|0|SEARCH t2 USING INDEX i4 (c=?)
603# 0|1|1|SCAN t1
604#
605det 5.11 "SELECT a, b FROM (SELECT * FROM t2 WHERE c=1), t1" {
606  0 0 0 {SEARCH t2 USING INDEX i4 (c=?)}
607  0 1 1 {SCAN t1 USING COVERING INDEX i2}
608}
609
610# XVIDENCE-OF: R-37879-39987 sqlite> EXPLAIN QUERY PLAN
611# SELECT a FROM t1 UNION SELECT c FROM t2;
612# 1|0|0|SCAN t1
613# 2|0|0|SCAN t2
614# 0|0|0|COMPOUND SUBQUERIES 1 AND 2 USING TEMP B-TREE (UNION)
615#
616det 5.12 "SELECT a,b FROM t1 UNION SELECT c, 99 FROM t2" {
617  1 0 0 {SCAN t1 USING COVERING INDEX i2}
618  2 0 0 {SCAN t2 USING COVERING INDEX i4}
619  0 0 0 {COMPOUND SUBQUERIES 1 AND 2 USING TEMP B-TREE (UNION)}
620}
621
622# XVIDENCE-OF: R-44864-63011 sqlite> EXPLAIN QUERY PLAN
623# SELECT a FROM t1 EXCEPT SELECT d FROM t2 ORDER BY 1;
624# 1|0|0|SCAN t1 USING COVERING INDEX i2
625# 2|0|0|SCAN t2 2|0|0|USE TEMP B-TREE FOR ORDER BY
626# 0|0|0|COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)
627#
628det 5.13 "SELECT a FROM t1 EXCEPT SELECT d FROM t2 ORDER BY 1" {
629  1 0 0 {SCAN t1 USING COVERING INDEX i1}
630  2 0 0 {SCAN t2}
631  2 0 0 {USE TEMP B-TREE FOR ORDER BY}
632  0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)}
633}
634
635if {![nonzero_reserved_bytes]} {
636  #-------------------------------------------------------------------------
637  # The following tests - eqp-6.* - test that the example C code on
638  # documentation page eqp.html works. The C code is duplicated in test1.c
639  # and wrapped in Tcl command [print_explain_query_plan]
640  #
641  set boilerplate {
642    proc explain_query_plan {db sql} {
643      set stmt [sqlite3_prepare_v2 db $sql -1 DUMMY]
644      print_explain_query_plan $stmt
645      sqlite3_finalize $stmt
646    }
647    sqlite3 db test.db
648    explain_query_plan db {%SQL%}
649    db close
650    exit
651  }
652
653  # Do a "Print Explain Query Plan" test.
654  proc do_peqp_test {tn sql res} {
655    set fd [open script.tcl w]
656    puts $fd [string map [list %SQL% $sql] $::boilerplate]
657    close $fd
658
659    uplevel do_test $tn [list {
660      set fd [open "|[info nameofexec] script.tcl"]
661      set data [read $fd]
662      close $fd
663      set data
664    }] [list $res]
665  }
666
667  do_peqp_test 6.1 {
668    SELECT a, b FROM t1 EXCEPT SELECT d, 99 FROM t2 ORDER BY 1
669  } [string trimleft {
6701 0 0 SCAN t1 USING COVERING INDEX i2
6712 0 0 SCAN t2
6722 0 0 USE TEMP B-TREE FOR ORDER BY
6730 0 0 COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)
674}]
675}
676}
677
678#-------------------------------------------------------------------------
679# The following tests - eqp-7.* - test that queries that use the OP_Count
680# optimization return something sensible with EQP.
681#
682drop_all_tables
683
684do_execsql_test 7.0 {
685  CREATE TABLE t1(a INT, b INT, ex CHAR(100));
686  CREATE TABLE t2(a INT, b INT, ex CHAR(100));
687  CREATE INDEX i1 ON t2(a);
688}
689
690det 7.1 "SELECT count(*) FROM t1" {
691  QUERY PLAN
692  `--SCAN t1
693}
694
695det 7.2 "SELECT count(*) FROM t2" {
696  QUERY PLAN
697  `--SCAN t2 USING COVERING INDEX i1
698}
699
700do_execsql_test 7.3 {
701  INSERT INTO t1(a,b) VALUES(1, 2);
702  INSERT INTO t1(a,b) VALUES(3, 4);
703
704  INSERT INTO t2(a,b) VALUES(1, 2);
705  INSERT INTO t2(a,b) VALUES(3, 4);
706  INSERT INTO t2(a,b) VALUES(5, 6);
707
708  ANALYZE;
709}
710
711db close
712sqlite3 db test.db
713
714det 7.4 "SELECT count(*) FROM t1" {
715  QUERY PLAN
716  `--SCAN t1
717}
718
719det 7.5 "SELECT count(*) FROM t2" {
720  QUERY PLAN
721  `--SCAN t2 USING COVERING INDEX i1
722}
723
724#-------------------------------------------------------------------------
725# The following tests - eqp-8.* - test that queries that use the OP_Count
726# optimization return something sensible with EQP.
727#
728drop_all_tables
729
730do_execsql_test 8.0 {
731  CREATE TABLE t1(a, b, c, PRIMARY KEY(b, c)) WITHOUT ROWID;
732  CREATE TABLE t2(a, b, c);
733}
734
735det 8.1.1 "SELECT * FROM t2" {
736  QUERY PLAN
737  `--SCAN t2
738}
739
740det 8.1.2 "SELECT * FROM t2 WHERE rowid=?" {
741  QUERY PLAN
742  `--SEARCH t2 USING INTEGER PRIMARY KEY (rowid=?)
743}
744
745det 8.1.3 "SELECT count(*) FROM t2" {
746  QUERY PLAN
747  `--SCAN t2
748}
749
750det 8.2.1 "SELECT * FROM t1" {
751  QUERY PLAN
752  `--SCAN t1
753}
754
755det 8.2.2 "SELECT * FROM t1 WHERE b=?" {
756  QUERY PLAN
757  `--SEARCH t1 USING PRIMARY KEY (b=?)
758}
759
760det 8.2.3 "SELECT * FROM t1 WHERE b=? AND c=?" {
761  QUERY PLAN
762  `--SEARCH t1 USING PRIMARY KEY (b=? AND c=?)
763}
764
765det 8.2.4 "SELECT count(*) FROM t1" {
766  QUERY PLAN
767  `--SCAN t1
768}
769
770# 2018-08-16:  While working on Fossil I discovered that EXPLAIN QUERY PLAN
771# did not describe IN operators implemented using a ROWID lookup.  These
772# test cases ensure that problem as been fixed.
773#
774do_execsql_test 9.0 {
775  -- Schema from Fossil 2018-08-16
776  CREATE TABLE forumpost(
777    fpid INTEGER PRIMARY KEY,
778    froot INT,
779    fprev INT,
780    firt INT,
781    fmtime REAL
782  );
783  CREATE INDEX forumthread ON forumpost(froot,fmtime);
784  CREATE TABLE blob(
785    rid INTEGER PRIMARY KEY,
786    rcvid INTEGER,
787    size INTEGER,
788    uuid TEXT UNIQUE NOT NULL,
789    content BLOB,
790    CHECK( length(uuid)>=40 AND rid>0 )
791  );
792  CREATE TABLE event(
793    type TEXT,
794    mtime DATETIME,
795    objid INTEGER PRIMARY KEY,
796    tagid INTEGER,
797    uid INTEGER REFERENCES user,
798    bgcolor TEXT,
799    euser TEXT,
800    user TEXT,
801    ecomment TEXT,
802    comment TEXT,
803    brief TEXT,
804    omtime DATETIME
805  );
806  CREATE INDEX event_i1 ON event(mtime);
807  CREATE TABLE private(rid INTEGER PRIMARY KEY);
808}
809do_eqp_test 9.1 {
810  WITH thread(age,duration,cnt,root,last) AS (
811    SELECT
812      julianday('now') - max(fmtime) AS age,
813      max(fmtime) - min(fmtime) AS duration,
814      sum(fprev IS NULL) AS msg_count,
815      froot,
816      (SELECT fpid FROM forumpost
817        WHERE froot=x.froot
818          AND fpid NOT IN private
819        ORDER BY fmtime DESC LIMIT 1)
820    FROM forumpost AS x
821    WHERE fpid NOT IN private  --- Ensure this table mentioned in EQP output!
822    GROUP BY froot
823    ORDER BY 1 LIMIT 26 OFFSET 5
824  )
825  SELECT
826    thread.age,
827    thread.duration,
828    thread.cnt,
829    blob.uuid,
830    substr(event.comment,instr(event.comment,':')+1)
831  FROM thread, blob, event
832  WHERE blob.rid=thread.last
833    AND event.objid=thread.last
834  ORDER BY 1;
835} {
836  QUERY PLAN
837  |--MATERIALIZE thread
838  |  |--SCAN x USING INDEX forumthread
839  |  |--USING ROWID SEARCH ON TABLE private FOR IN-OPERATOR
840  |  |--CORRELATED SCALAR SUBQUERY xxxxxx
841  |  |  |--SEARCH forumpost USING COVERING INDEX forumthread (froot=?)
842  |  |  `--USING ROWID SEARCH ON TABLE private FOR IN-OPERATOR
843  |  `--USE TEMP B-TREE FOR ORDER BY
844  |--SCAN thread
845  |--SEARCH blob USING INTEGER PRIMARY KEY (rowid=?)
846  |--SEARCH event USING INTEGER PRIMARY KEY (rowid=?)
847  `--USE TEMP B-TREE FOR ORDER BY
848}
849
850finish_test
851