xref: /sqlite-3.40.0/test/eqp.test (revision da653b89)
12ce22453Sdan# 2010 November 6
22ce22453Sdan#
32ce22453Sdan# The author disclaims copyright to this source code.  In place of
42ce22453Sdan# a legal notice, here is a blessing:
52ce22453Sdan#
62ce22453Sdan#    May you do good and not evil.
72ce22453Sdan#    May you find forgiveness for yourself and forgive others.
82ce22453Sdan#    May you share freely, never taking more than you give.
92ce22453Sdan#
102ce22453Sdan#***********************************************************************
112ce22453Sdan#
122ce22453Sdan
132ce22453Sdanset testdir [file dirname $argv0]
142ce22453Sdansource $testdir/tester.tcl
152ce22453Sdan
162f56da3fSdanifcapable !compound {
172f56da3fSdan  finish_test
182f56da3fSdan  return
192f56da3fSdan}
202f56da3fSdan
212ce22453Sdanset testprefix eqp
222ce22453Sdan
232ce22453Sdan#-------------------------------------------------------------------------
242ce22453Sdan#
252ce22453Sdan# eqp-1.*:        Assorted tests.
262ce22453Sdan# eqp-2.*:        Tests for single select statements.
272ce22453Sdan# eqp-3.*:        Select statements that execute sub-selects.
282ce22453Sdan# eqp-4.*:        Compound select statements.
29ef7075deSdan# ...
30ef7075deSdan# eqp-7.*:        "SELECT count(*) FROM tbl" statements (VDBE code OP_Count).
312ce22453Sdan#
322ce22453Sdan
334a07e3dbSdanproc det {args} { uplevel do_eqp_test $args }
342ce22453Sdan
352ce22453Sdando_execsql_test 1.1 {
36d9e3cad2Sdrh  CREATE TABLE t1(a INT, b INT, ex TEXT);
372ce22453Sdan  CREATE INDEX i1 ON t1(a);
382ce22453Sdan  CREATE INDEX i2 ON t1(b);
39d9e3cad2Sdrh  CREATE TABLE t2(a INT, b INT, ex TEXT);
40d9e3cad2Sdrh  CREATE TABLE t3(a INT, b INT, ex TEXT);
412ce22453Sdan}
422ce22453Sdan
432ce22453Sdando_eqp_test 1.2 {
442ce22453Sdan  SELECT * FROM t2, t1 WHERE t1.a=1 OR t1.b=2;
452ce22453Sdan} {
4603c3905fSdrh  QUERY PLAN
475d72d924Sdrh  |--MULTI-INDEX OR
48bd462bccSdrh  |  |--INDEX 1
498210233cSdrh  |  |  `--SEARCH t1 USING INDEX i1 (a=?)
50bd462bccSdrh  |  `--INDEX 2
518210233cSdrh  |     `--SEARCH t1 USING INDEX i2 (b=?)
528210233cSdrh  `--SCAN t2
532ce22453Sdan}
542ce22453Sdando_eqp_test 1.3 {
552ce22453Sdan  SELECT * FROM t2 CROSS JOIN t1 WHERE t1.a=1 OR t1.b=2;
562ce22453Sdan} {
5703c3905fSdrh  QUERY PLAN
588210233cSdrh  |--SCAN t2
595d72d924Sdrh  `--MULTI-INDEX OR
60bd462bccSdrh     |--INDEX 1
618210233cSdrh     |  `--SEARCH t1 USING INDEX i1 (a=?)
62bd462bccSdrh     `--INDEX 2
638210233cSdrh        `--SEARCH t1 USING INDEX i2 (b=?)
642ce22453Sdan}
652ce22453Sdando_eqp_test 1.3 {
662ce22453Sdan  SELECT a FROM t1 ORDER BY a
672ce22453Sdan} {
6803c3905fSdrh  QUERY PLAN
698210233cSdrh  `--SCAN t1 USING COVERING INDEX i1
702ce22453Sdan}
712ce22453Sdando_eqp_test 1.4 {
722ce22453Sdan  SELECT a FROM t1 ORDER BY +a
732ce22453Sdan} {
7403c3905fSdrh  QUERY PLAN
758210233cSdrh  |--SCAN t1 USING COVERING INDEX i1
7603c3905fSdrh  `--USE TEMP B-TREE FOR ORDER BY
772ce22453Sdan}
782ce22453Sdando_eqp_test 1.5 {
792ce22453Sdan  SELECT a FROM t1 WHERE a=4
802ce22453Sdan} {
8103c3905fSdrh  QUERY PLAN
828210233cSdrh  `--SEARCH t1 USING COVERING INDEX i1 (a=?)
832ce22453Sdan}
842ce22453Sdando_eqp_test 1.6 {
852ce22453Sdan  SELECT DISTINCT count(*) FROM t3 GROUP BY a;
862ce22453Sdan} {
8703c3905fSdrh  QUERY PLAN
888210233cSdrh  |--SCAN t3
8903c3905fSdrh  |--USE TEMP B-TREE FOR GROUP BY
9003c3905fSdrh  `--USE TEMP B-TREE FOR DISTINCT
912ce22453Sdan}
922ce22453Sdan
938210233cSdrhdo_eqp_test 1.7.1 {
9495aa47b1Sdrh  SELECT * FROM t3 JOIN (SELECT 1)
9595aa47b1Sdrh} {
9603c3905fSdrh  QUERY PLAN
97*da653b89Sdrh  |--MATERIALIZE (subquery-xxxxxx)
98fa16f5d9Sdrh  |  `--SCAN CONSTANT ROW
99*da653b89Sdrh  |--SCAN (subquery-xxxxxx)
1008210233cSdrh  `--SCAN t3
10195aa47b1Sdrh}
1028210233cSdrhdo_eqp_test 1.7.2 {
1038210233cSdrh  SELECT * FROM t3 JOIN (SELECT 1) AS v1
1048210233cSdrh} {
1058210233cSdrh  QUERY PLAN
1068210233cSdrh  |--MATERIALIZE v1
1078210233cSdrh  |  `--SCAN CONSTANT ROW
1088210233cSdrh  |--SCAN v1
1098210233cSdrh  `--SCAN t3
1108210233cSdrh}
1118210233cSdrhdo_eqp_test 1.7.3 {
1128210233cSdrh  SELECT * FROM t3 AS xx JOIN (SELECT 1) AS yy
1138210233cSdrh} {
1148210233cSdrh  QUERY PLAN
1158210233cSdrh  |--MATERIALIZE yy
1168210233cSdrh  |  `--SCAN CONSTANT ROW
1178210233cSdrh  |--SCAN yy
1188210233cSdrh  `--SCAN xx
1198210233cSdrh}
1208210233cSdrh
1218210233cSdrh
12295aa47b1Sdrhdo_eqp_test 1.8 {
12395aa47b1Sdrh  SELECT * FROM t3 JOIN (SELECT 1 UNION SELECT 2)
12495aa47b1Sdrh} {
12503c3905fSdrh  QUERY PLAN
126*da653b89Sdrh  |--MATERIALIZE (subquery-xxxxxx)
12703c3905fSdrh  |  `--COMPOUND QUERY
12803c3905fSdrh  |     |--LEFT-MOST SUBQUERY
129fa16f5d9Sdrh  |     |  `--SCAN CONSTANT ROW
13003c3905fSdrh  |     `--UNION USING TEMP B-TREE
131fa16f5d9Sdrh  |        `--SCAN CONSTANT ROW
132*da653b89Sdrh  |--SCAN (subquery-xxxxxx)
1338210233cSdrh  `--SCAN t3
13495aa47b1Sdrh}
13595aa47b1Sdrhdo_eqp_test 1.9 {
1368210233cSdrh  SELECT * FROM t3 JOIN (SELECT 1 EXCEPT SELECT a FROM t3 LIMIT 17) AS abc
13795aa47b1Sdrh} {
13803c3905fSdrh  QUERY PLAN
1398210233cSdrh  |--MATERIALIZE abc
14003c3905fSdrh  |  `--COMPOUND QUERY
14103c3905fSdrh  |     |--LEFT-MOST SUBQUERY
142fa16f5d9Sdrh  |     |  `--SCAN CONSTANT ROW
14303c3905fSdrh  |     `--EXCEPT USING TEMP B-TREE
1448210233cSdrh  |        `--SCAN t3
1458210233cSdrh  |--SCAN abc
1468210233cSdrh  `--SCAN t3
14795aa47b1Sdrh}
14895aa47b1Sdrhdo_eqp_test 1.10 {
1498210233cSdrh  SELECT * FROM t3 JOIN (SELECT 1 INTERSECT SELECT a FROM t3 LIMIT 17) AS abc
15095aa47b1Sdrh} {
15103c3905fSdrh  QUERY PLAN
1528210233cSdrh  |--MATERIALIZE abc
15303c3905fSdrh  |  `--COMPOUND QUERY
15403c3905fSdrh  |     |--LEFT-MOST SUBQUERY
155fa16f5d9Sdrh  |     |  `--SCAN CONSTANT ROW
15603c3905fSdrh  |     `--INTERSECT USING TEMP B-TREE
1578210233cSdrh  |        `--SCAN t3
1588210233cSdrh  |--SCAN abc
1598210233cSdrh  `--SCAN t3
16095aa47b1Sdrh}
16195aa47b1Sdrh
16295aa47b1Sdrhdo_eqp_test 1.11 {
1638210233cSdrh  SELECT * FROM t3 JOIN (SELECT 1 UNION ALL SELECT a FROM t3 LIMIT 17) abc
16495aa47b1Sdrh} {
16503c3905fSdrh  QUERY PLAN
1668210233cSdrh  |--MATERIALIZE abc
16703c3905fSdrh  |  `--COMPOUND QUERY
16803c3905fSdrh  |     |--LEFT-MOST SUBQUERY
169fa16f5d9Sdrh  |     |  `--SCAN CONSTANT ROW
17003c3905fSdrh  |     `--UNION ALL
1718210233cSdrh  |        `--SCAN t3
1728210233cSdrh  |--SCAN abc
1738210233cSdrh  `--SCAN t3
17495aa47b1Sdrh}
17595aa47b1Sdrh
1762ce22453Sdan#-------------------------------------------------------------------------
1772ce22453Sdan# Test cases eqp-2.* - tests for single select statements.
1782ce22453Sdan#
1792ce22453Sdandrop_all_tables
1802ce22453Sdando_execsql_test 2.1 {
181d9e3cad2Sdrh  CREATE TABLE t1(x INT, y INT, ex TEXT);
1822ce22453Sdan
183d9e3cad2Sdrh  CREATE TABLE t2(x INT, y INT, ex TEXT);
1842ce22453Sdan  CREATE INDEX t2i1 ON t2(x);
1852ce22453Sdan}
1862ce22453Sdan
1874a07e3dbSdandet 2.2.1 "SELECT DISTINCT min(x), max(x) FROM t1 GROUP BY x ORDER BY 1" {
18803c3905fSdrh  QUERY PLAN
1898210233cSdrh  |--SCAN t1
19003c3905fSdrh  |--USE TEMP B-TREE FOR GROUP BY
19103c3905fSdrh  |--USE TEMP B-TREE FOR DISTINCT
19203c3905fSdrh  `--USE TEMP B-TREE FOR ORDER BY
1932ce22453Sdan}
1944a07e3dbSdandet 2.2.2 "SELECT DISTINCT min(x), max(x) FROM t2 GROUP BY x ORDER BY 1" {
19503c3905fSdrh  QUERY PLAN
1968210233cSdrh  |--SCAN t2 USING COVERING INDEX t2i1
19703c3905fSdrh  |--USE TEMP B-TREE FOR DISTINCT
19803c3905fSdrh  `--USE TEMP B-TREE FOR ORDER BY
1992ce22453Sdan}
2004a07e3dbSdandet 2.2.3 "SELECT DISTINCT * FROM t1" {
20103c3905fSdrh  QUERY PLAN
2028210233cSdrh  |--SCAN t1
20303c3905fSdrh  `--USE TEMP B-TREE FOR DISTINCT
2044a07e3dbSdan}
2054a07e3dbSdandet 2.2.4 "SELECT DISTINCT * FROM t1, t2" {
20603c3905fSdrh  QUERY PLAN
2078210233cSdrh  |--SCAN t1
2088210233cSdrh  |--SCAN t2
20903c3905fSdrh  `--USE TEMP B-TREE FOR DISTINCT
2104a07e3dbSdan}
2114a07e3dbSdandet 2.2.5 "SELECT DISTINCT * FROM t1, t2 ORDER BY t1.x" {
21203c3905fSdrh  QUERY PLAN
2138210233cSdrh  |--SCAN t1
2148210233cSdrh  |--SCAN t2
21503c3905fSdrh  |--USE TEMP B-TREE FOR DISTINCT
21603c3905fSdrh  `--USE TEMP B-TREE FOR ORDER BY
2174a07e3dbSdan}
2184a07e3dbSdandet 2.2.6 "SELECT DISTINCT t2.x FROM t1, t2 ORDER BY t2.x" {
21903c3905fSdrh  QUERY PLAN
2208210233cSdrh  |--SCAN t2 USING COVERING INDEX t2i1
2218210233cSdrh  `--SCAN t1
2224a07e3dbSdan}
2234a07e3dbSdan
2244a07e3dbSdandet 2.3.1 "SELECT max(x) FROM t2" {
22503c3905fSdrh  QUERY PLAN
2268210233cSdrh  `--SEARCH t2 USING COVERING INDEX t2i1
2274a07e3dbSdan}
2284a07e3dbSdandet 2.3.2 "SELECT min(x) FROM t2" {
22903c3905fSdrh  QUERY PLAN
2308210233cSdrh  `--SEARCH t2 USING COVERING INDEX t2i1
2314a07e3dbSdan}
2324a07e3dbSdandet 2.3.3 "SELECT min(x), max(x) FROM t2" {
23303c3905fSdrh  QUERY PLAN
2348210233cSdrh  `--SCAN t2 USING COVERING INDEX t2i1
2354a07e3dbSdan}
2364a07e3dbSdan
2374a07e3dbSdandet 2.4.1 "SELECT * FROM t1 WHERE rowid=?" {
23803c3905fSdrh  QUERY PLAN
2398210233cSdrh  `--SEARCH t1 USING INTEGER PRIMARY KEY (rowid=?)
2404a07e3dbSdan}
2414a07e3dbSdan
2424a07e3dbSdan
2432ce22453Sdan
2442ce22453Sdan#-------------------------------------------------------------------------
2452ce22453Sdan# Test cases eqp-3.* - tests for select statements that use sub-selects.
2462ce22453Sdan#
2472ce22453Sdando_eqp_test 3.1.1 {
2482ce22453Sdan  SELECT (SELECT x FROM t1 AS sub) FROM t1;
2492ce22453Sdan} {
25003c3905fSdrh  QUERY PLAN
2518210233cSdrh  |--SCAN t1
252bd462bccSdrh  `--SCALAR SUBQUERY xxxxxx
2538210233cSdrh     `--SCAN sub
2544a07e3dbSdan}
2554a07e3dbSdando_eqp_test 3.1.2 {
2564a07e3dbSdan  SELECT * FROM t1 WHERE (SELECT x FROM t1 AS sub);
2574a07e3dbSdan} {
25803c3905fSdrh  QUERY PLAN
2598210233cSdrh  |--SCAN t1
260bd462bccSdrh  `--SCALAR SUBQUERY xxxxxx
2618210233cSdrh     `--SCAN sub
2624a07e3dbSdan}
2634a07e3dbSdando_eqp_test 3.1.3 {
2644a07e3dbSdan  SELECT * FROM t1 WHERE (SELECT x FROM t1 AS sub ORDER BY y);
2654a07e3dbSdan} {
26603c3905fSdrh  QUERY PLAN
2678210233cSdrh  |--SCAN t1
268bd462bccSdrh  `--SCALAR SUBQUERY xxxxxx
2698210233cSdrh     |--SCAN sub
27003c3905fSdrh     `--USE TEMP B-TREE FOR ORDER BY
2714a07e3dbSdan}
2724a07e3dbSdando_eqp_test 3.1.4 {
2734a07e3dbSdan  SELECT * FROM t1 WHERE (SELECT x FROM t2 ORDER BY x);
2744a07e3dbSdan} {
27503c3905fSdrh  QUERY PLAN
2768210233cSdrh  |--SCAN t1
277bd462bccSdrh  `--SCALAR SUBQUERY xxxxxx
2788210233cSdrh     `--SCAN t2 USING COVERING INDEX t2i1
2794a07e3dbSdan}
2804a07e3dbSdan
2814a07e3dbSdandet 3.2.1 {
2824a07e3dbSdan  SELECT * FROM (SELECT * FROM t1 ORDER BY x LIMIT 10) ORDER BY y LIMIT 5
2834a07e3dbSdan} {
28403c3905fSdrh  QUERY PLAN
285*da653b89Sdrh  |--CO-ROUTINE (subquery-xxxxxx)
2868210233cSdrh  |  |--SCAN t1
28703c3905fSdrh  |  `--USE TEMP B-TREE FOR ORDER BY
288*da653b89Sdrh  |--SCAN (subquery-xxxxxx)
28903c3905fSdrh  `--USE TEMP B-TREE FOR ORDER BY
2904a07e3dbSdan}
2914a07e3dbSdandet 3.2.2 {
2924a07e3dbSdan  SELECT * FROM
2934a07e3dbSdan    (SELECT * FROM t1 ORDER BY x LIMIT 10) AS x1,
2944a07e3dbSdan    (SELECT * FROM t2 ORDER BY x LIMIT 10) AS x2
2954a07e3dbSdan  ORDER BY x2.y LIMIT 5
2964a07e3dbSdan} {
29703c3905fSdrh  QUERY PLAN
2988210233cSdrh  |--MATERIALIZE x1
2998210233cSdrh  |  |--SCAN t1
30003c3905fSdrh  |  `--USE TEMP B-TREE FOR ORDER BY
3018210233cSdrh  |--MATERIALIZE x2
3028210233cSdrh  |  `--SCAN t2 USING INDEX t2i1
3038210233cSdrh  |--SCAN x1
3048210233cSdrh  |--SCAN x2
30503c3905fSdrh  `--USE TEMP B-TREE FOR ORDER BY
3062ce22453Sdan}
3072ce22453Sdan
30847eb16d4Sdandet 3.3.1 {
30947eb16d4Sdan  SELECT * FROM t1 WHERE y IN (SELECT y FROM t2)
31047eb16d4Sdan} {
31103c3905fSdrh  QUERY PLAN
3128210233cSdrh  |--SCAN t1
3135198ff57Sdrh  `--LIST SUBQUERY xxxxxx
3148210233cSdrh     `--SCAN t2
31547eb16d4Sdan}
31647eb16d4Sdandet 3.3.2 {
31747eb16d4Sdan  SELECT * FROM t1 WHERE y IN (SELECT y FROM t2 WHERE t1.x!=t2.x)
31847eb16d4Sdan} {
31903c3905fSdrh  QUERY PLAN
3208210233cSdrh  |--SCAN t1
3215198ff57Sdrh  `--CORRELATED LIST SUBQUERY xxxxxx
3228210233cSdrh     `--SCAN t2
32347eb16d4Sdan}
32447eb16d4Sdandet 3.3.3 {
32547eb16d4Sdan  SELECT * FROM t1 WHERE EXISTS (SELECT y FROM t2 WHERE t1.x!=t2.x)
32647eb16d4Sdan} {
32703c3905fSdrh  QUERY PLAN
3288210233cSdrh  |--SCAN t1
329bd462bccSdrh  `--CORRELATED SCALAR SUBQUERY xxxxxx
3308210233cSdrh     `--SCAN t2
33147eb16d4Sdan}
33247eb16d4Sdan
3332ce22453Sdan#-------------------------------------------------------------------------
3344a07e3dbSdan# Test cases eqp-4.* - tests for composite select statements.
3352ce22453Sdan#
3362ce22453Sdando_eqp_test 4.1.1 {
3372ce22453Sdan  SELECT * FROM t1 UNION ALL SELECT * FROM t2
3382ce22453Sdan} {
33903c3905fSdrh  QUERY PLAN
34003c3905fSdrh  `--COMPOUND QUERY
34103c3905fSdrh     |--LEFT-MOST SUBQUERY
3428210233cSdrh     |  `--SCAN t1
34303c3905fSdrh     `--UNION ALL
3448210233cSdrh        `--SCAN t2
3452ce22453Sdan}
3462ce22453Sdando_eqp_test 4.1.2 {
3472ce22453Sdan  SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY 2
3482ce22453Sdan} {
34903c3905fSdrh  QUERY PLAN
35003c3905fSdrh  `--MERGE (UNION ALL)
35103c3905fSdrh     |--LEFT
3528210233cSdrh     |  |--SCAN t1
35303c3905fSdrh     |  `--USE TEMP B-TREE FOR ORDER BY
35403c3905fSdrh     `--RIGHT
3558210233cSdrh        |--SCAN t2
35603c3905fSdrh        `--USE TEMP B-TREE FOR ORDER BY
3572ce22453Sdan}
3582ce22453Sdando_eqp_test 4.1.3 {
3592ce22453Sdan  SELECT * FROM t1 UNION SELECT * FROM t2 ORDER BY 2
3602ce22453Sdan} {
36103c3905fSdrh  QUERY PLAN
36203c3905fSdrh  `--MERGE (UNION)
36303c3905fSdrh     |--LEFT
3648210233cSdrh     |  |--SCAN t1
36503c3905fSdrh     |  `--USE TEMP B-TREE FOR ORDER BY
36603c3905fSdrh     `--RIGHT
3678210233cSdrh        |--SCAN t2
36803c3905fSdrh        `--USE TEMP B-TREE FOR ORDER BY
3692ce22453Sdan}
3702ce22453Sdando_eqp_test 4.1.4 {
3712ce22453Sdan  SELECT * FROM t1 INTERSECT SELECT * FROM t2 ORDER BY 2
3722ce22453Sdan} {
37303c3905fSdrh  QUERY PLAN
37403c3905fSdrh  `--MERGE (INTERSECT)
37503c3905fSdrh     |--LEFT
3768210233cSdrh     |  |--SCAN t1
37703c3905fSdrh     |  `--USE TEMP B-TREE FOR ORDER BY
37803c3905fSdrh     `--RIGHT
3798210233cSdrh        |--SCAN t2
38003c3905fSdrh        `--USE TEMP B-TREE FOR ORDER BY
3812ce22453Sdan}
3822ce22453Sdando_eqp_test 4.1.5 {
3832ce22453Sdan  SELECT * FROM t1 EXCEPT SELECT * FROM t2 ORDER BY 2
3842ce22453Sdan} {
38503c3905fSdrh  QUERY PLAN
38603c3905fSdrh  `--MERGE (EXCEPT)
38703c3905fSdrh     |--LEFT
3888210233cSdrh     |  |--SCAN t1
38903c3905fSdrh     |  `--USE TEMP B-TREE FOR ORDER BY
39003c3905fSdrh     `--RIGHT
3918210233cSdrh        |--SCAN t2
39203c3905fSdrh        `--USE TEMP B-TREE FOR ORDER BY
3932ce22453Sdan}
3942ce22453Sdan
3952ce22453Sdando_eqp_test 4.2.2 {
3962ce22453Sdan  SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY 1
3972ce22453Sdan} {
39803c3905fSdrh  QUERY PLAN
39903c3905fSdrh  `--MERGE (UNION ALL)
40003c3905fSdrh     |--LEFT
4018210233cSdrh     |  |--SCAN t1
40203c3905fSdrh     |  `--USE TEMP B-TREE FOR ORDER BY
40303c3905fSdrh     `--RIGHT
4048210233cSdrh        `--SCAN t2 USING INDEX t2i1
4052ce22453Sdan}
4062ce22453Sdando_eqp_test 4.2.3 {
4072ce22453Sdan  SELECT * FROM t1 UNION SELECT * FROM t2 ORDER BY 1
4082ce22453Sdan} {
40903c3905fSdrh  QUERY PLAN
41003c3905fSdrh  `--MERGE (UNION)
41103c3905fSdrh     |--LEFT
4128210233cSdrh     |  |--SCAN t1
41303c3905fSdrh     |  `--USE TEMP B-TREE FOR ORDER BY
41403c3905fSdrh     `--RIGHT
4158210233cSdrh        |--SCAN t2 USING INDEX t2i1
41603c3905fSdrh        `--USE TEMP B-TREE FOR RIGHT PART OF ORDER BY
4172ce22453Sdan}
4182ce22453Sdando_eqp_test 4.2.4 {
4192ce22453Sdan  SELECT * FROM t1 INTERSECT SELECT * FROM t2 ORDER BY 1
4202ce22453Sdan} {
42103c3905fSdrh  QUERY PLAN
42203c3905fSdrh  `--MERGE (INTERSECT)
42303c3905fSdrh     |--LEFT
4248210233cSdrh     |  |--SCAN t1
42503c3905fSdrh     |  `--USE TEMP B-TREE FOR ORDER BY
42603c3905fSdrh     `--RIGHT
4278210233cSdrh        |--SCAN t2 USING INDEX t2i1
42803c3905fSdrh        `--USE TEMP B-TREE FOR RIGHT PART OF ORDER BY
4292ce22453Sdan}
4302ce22453Sdando_eqp_test 4.2.5 {
4312ce22453Sdan  SELECT * FROM t1 EXCEPT SELECT * FROM t2 ORDER BY 1
4322ce22453Sdan} {
43303c3905fSdrh  QUERY PLAN
43403c3905fSdrh  `--MERGE (EXCEPT)
43503c3905fSdrh     |--LEFT
4368210233cSdrh     |  |--SCAN t1
43703c3905fSdrh     |  `--USE TEMP B-TREE FOR ORDER BY
43803c3905fSdrh     `--RIGHT
4398210233cSdrh        |--SCAN t2 USING INDEX t2i1
44003c3905fSdrh        `--USE TEMP B-TREE FOR RIGHT PART OF ORDER BY
4412ce22453Sdan}
4422ce22453Sdan
4434a07e3dbSdando_eqp_test 4.3.1 {
4444a07e3dbSdan  SELECT x FROM t1 UNION SELECT x FROM t2
4454a07e3dbSdan} {
44603c3905fSdrh  QUERY PLAN
44703c3905fSdrh  `--COMPOUND QUERY
44803c3905fSdrh     |--LEFT-MOST SUBQUERY
4498210233cSdrh     |  `--SCAN t1
45003c3905fSdrh     `--UNION USING TEMP B-TREE
4518210233cSdrh        `--SCAN t2 USING COVERING INDEX t2i1
4527f61e92cSdan}
4537f61e92cSdan
4547f61e92cSdando_eqp_test 4.3.2 {
4557f61e92cSdan  SELECT x FROM t1 UNION SELECT x FROM t2 UNION SELECT x FROM t1
4567f61e92cSdan} {
45703c3905fSdrh  QUERY PLAN
45803c3905fSdrh  `--COMPOUND QUERY
45903c3905fSdrh     |--LEFT-MOST SUBQUERY
4608210233cSdrh     |  `--SCAN t1
46103c3905fSdrh     |--UNION USING TEMP B-TREE
4628210233cSdrh     |  `--SCAN t2 USING COVERING INDEX t2i1
46303c3905fSdrh     `--UNION USING TEMP B-TREE
4648210233cSdrh        `--SCAN t1
4657f61e92cSdan}
4667f61e92cSdando_eqp_test 4.3.3 {
4677f61e92cSdan  SELECT x FROM t1 UNION SELECT x FROM t2 UNION SELECT x FROM t1 ORDER BY 1
4687f61e92cSdan} {
46903c3905fSdrh  QUERY PLAN
47003c3905fSdrh  `--MERGE (UNION)
47103c3905fSdrh     |--LEFT
47203c3905fSdrh     |  `--MERGE (UNION)
47303c3905fSdrh     |     |--LEFT
4748210233cSdrh     |     |  |--SCAN t1
47503c3905fSdrh     |     |  `--USE TEMP B-TREE FOR ORDER BY
47603c3905fSdrh     |     `--RIGHT
4778210233cSdrh     |        `--SCAN t2 USING COVERING INDEX t2i1
47803c3905fSdrh     `--RIGHT
4798210233cSdrh        |--SCAN t1
48003c3905fSdrh        `--USE TEMP B-TREE FOR ORDER BY
4814a07e3dbSdan}
4822ce22453Sdan
48303c3905fSdrhif 0 {
484fa00aa2eSdan#-------------------------------------------------------------------------
485fa00aa2eSdan# This next block of tests verifies that the examples on the
486fa00aa2eSdan# lang_explain.html page are correct.
487fa00aa2eSdan#
488fa00aa2eSdandrop_all_tables
489fa00aa2eSdan
49003c3905fSdrh# XVIDENCE-OF: R-47779-47605 sqlite> EXPLAIN QUERY PLAN SELECT a, b
49139759747Sdrh# FROM t1 WHERE a=1;
4928210233cSdrh# 0|0|0|SCAN t1
49339759747Sdrh#
494d9e3cad2Sdrhdo_execsql_test 5.1.0 { CREATE TABLE t1(a INT, b INT, ex TEXT) }
495fa00aa2eSdandet 5.1.1 "SELECT a, b FROM t1 WHERE a=1" {
4968210233cSdrh  0 0 0 {SCAN t1}
497fa00aa2eSdan}
498fa00aa2eSdan
49903c3905fSdrh# XVIDENCE-OF: R-55852-17599 sqlite> CREATE INDEX i1 ON t1(a);
500fa00aa2eSdan# sqlite> EXPLAIN QUERY PLAN SELECT a, b FROM t1 WHERE a=1;
5018210233cSdrh# 0|0|0|SEARCH t1 USING INDEX i1
50239759747Sdrh#
503fa00aa2eSdando_execsql_test 5.2.0 { CREATE INDEX i1 ON t1(a) }
504fa00aa2eSdandet 5.2.1 "SELECT a, b FROM t1 WHERE a=1" {
5058210233cSdrh  0 0 0 {SEARCH t1 USING INDEX i1 (a=?)}
506fa00aa2eSdan}
507fa00aa2eSdan
50803c3905fSdrh# XVIDENCE-OF: R-21179-11011 sqlite> CREATE INDEX i2 ON t1(a, b);
509fa00aa2eSdan# sqlite> EXPLAIN QUERY PLAN SELECT a, b FROM t1 WHERE a=1;
5108210233cSdrh# 0|0|0|SEARCH t1 USING COVERING INDEX i2 (a=?)
51139759747Sdrh#
512fa00aa2eSdando_execsql_test 5.3.0 { CREATE INDEX i2 ON t1(a, b) }
513fa00aa2eSdandet 5.3.1 "SELECT a, b FROM t1 WHERE a=1" {
5148210233cSdrh  0 0 0 {SEARCH t1 USING COVERING INDEX i2 (a=?)}
515fa00aa2eSdan}
516fa00aa2eSdan
51703c3905fSdrh# XVIDENCE-OF: R-09991-48941 sqlite> EXPLAIN QUERY PLAN
51839759747Sdrh# SELECT t1.*, t2.* FROM t1, t2 WHERE t1.a=1 AND t1.b>2;
5198210233cSdrh# 0|0|0|SEARCH t1 USING COVERING INDEX i2 (a=? AND b>?)
5208210233cSdrh# 0|1|1|SCAN t2
5215822d6feSdrh#
522d9e3cad2Sdrhdo_execsql_test 5.4.0 {CREATE TABLE t2(c INT, d INT, ex TEXT)}
523d9e3cad2Sdrhdet 5.4.1 "SELECT t1.a, t2.c FROM t1, t2 WHERE t1.a=1 AND t1.b>2" {
5248210233cSdrh  0 0 0 {SEARCH t1 USING COVERING INDEX i2 (a=? AND b>?)}
5258210233cSdrh  0 1 1 {SCAN t2}
526fa00aa2eSdan}
527fa00aa2eSdan
52803c3905fSdrh# XVIDENCE-OF: R-33626-61085 sqlite> EXPLAIN QUERY PLAN
52939759747Sdrh# SELECT t1.*, t2.* FROM t2, t1 WHERE t1.a=1 AND t1.b>2;
5308210233cSdrh# 0|0|1|SEARCH t1 USING COVERING INDEX i2 (a=? AND b>?)
5318210233cSdrh# 0|1|0|SCAN t2
5325822d6feSdrh#
533d9e3cad2Sdrhdet 5.5 "SELECT t1.a, t2.c FROM t2, t1 WHERE t1.a=1 AND t1.b>2" {
5348210233cSdrh  0 0 1 {SEARCH t1 USING COVERING INDEX i2 (a=? AND b>?)}
5358210233cSdrh  0 1 0 {SCAN t2}
536fa00aa2eSdan}
537fa00aa2eSdan
53803c3905fSdrh# XVIDENCE-OF: R-04002-25654 sqlite> CREATE INDEX i3 ON t1(b);
539fa00aa2eSdan# sqlite> EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE a=1 OR b=2;
5408210233cSdrh# 0|0|0|SEARCH t1 USING COVERING INDEX i2 (a=?)
5418210233cSdrh# 0|0|0|SEARCH t1 USING INDEX i3 (b=?)
54239759747Sdrh#
543fa00aa2eSdando_execsql_test 5.5.0 {CREATE INDEX i3 ON t1(b)}
544d9e3cad2Sdrhdet 5.6.1 "SELECT a, b FROM t1 WHERE a=1 OR b=2" {
5458210233cSdrh  0 0 0 {SEARCH t1 USING COVERING INDEX i2 (a=?)}
5468210233cSdrh  0 0 0 {SEARCH t1 USING INDEX i3 (b=?)}
547fa00aa2eSdan}
548fa00aa2eSdan
54903c3905fSdrh# XVIDENCE-OF: R-24577-38891 sqlite> EXPLAIN QUERY PLAN
55039759747Sdrh# SELECT c, d FROM t2 ORDER BY c;
5518210233cSdrh# 0|0|0|SCAN t2
55239759747Sdrh# 0|0|0|USE TEMP B-TREE FOR ORDER BY
55339759747Sdrh#
554fa00aa2eSdandet 5.7 "SELECT c, d FROM t2 ORDER BY c" {
5558210233cSdrh  0 0 0 {SCAN t2}
556fa00aa2eSdan  0 0 0 {USE TEMP B-TREE FOR ORDER BY}
557fa00aa2eSdan}
558fa00aa2eSdan
55903c3905fSdrh# XVIDENCE-OF: R-58157-12355 sqlite> CREATE INDEX i4 ON t2(c);
560fa00aa2eSdan# sqlite> EXPLAIN QUERY PLAN SELECT c, d FROM t2 ORDER BY c;
5618210233cSdrh# 0|0|0|SCAN t2 USING INDEX i4
56239759747Sdrh#
563fa00aa2eSdando_execsql_test 5.8.0 {CREATE INDEX i4 ON t2(c)}
564fa00aa2eSdandet 5.8.1 "SELECT c, d FROM t2 ORDER BY c" {
5658210233cSdrh  0 0 0 {SCAN t2 USING INDEX i4}
566fa00aa2eSdan}
567fa00aa2eSdan
56803c3905fSdrh# XVIDENCE-OF: R-13931-10421 sqlite> EXPLAIN QUERY PLAN SELECT
569fa00aa2eSdan# (SELECT b FROM t1 WHERE a=0), (SELECT a FROM t1 WHERE b=t2.c) FROM t2;
5708210233cSdrh# 0|0|0|SCAN t2
57139759747Sdrh# 0|0|0|EXECUTE SCALAR SUBQUERY 1
5728210233cSdrh# 1|0|0|SEARCH t1 USING COVERING INDEX i2 (a=?)
57339759747Sdrh# 0|0|0|EXECUTE CORRELATED SCALAR SUBQUERY 2
5748210233cSdrh# 2|0|0|SEARCH t1 USING INDEX i3 (b=?)
57539759747Sdrh#
576fa00aa2eSdandet 5.9 {
577fa00aa2eSdan  SELECT (SELECT b FROM t1 WHERE a=0), (SELECT a FROM t1 WHERE b=t2.c) FROM t2
578fa00aa2eSdan} {
5798210233cSdrh  0 0 0 {SCAN t2 USING COVERING INDEX i4}
580fa00aa2eSdan  0 0 0 {EXECUTE SCALAR SUBQUERY 1}
5818210233cSdrh  1 0 0 {SEARCH t1 USING COVERING INDEX i2 (a=?)}
582fa00aa2eSdan  0 0 0 {EXECUTE CORRELATED SCALAR SUBQUERY 2}
5838210233cSdrh  2 0 0 {SEARCH t1 USING INDEX i3 (b=?)}
584fa00aa2eSdan}
585fa00aa2eSdan
58603c3905fSdrh# XVIDENCE-OF: R-50892-45943 sqlite> EXPLAIN QUERY PLAN
58739759747Sdrh# SELECT count(*) FROM (SELECT max(b) AS x FROM t1 GROUP BY a) GROUP BY x;
5888210233cSdrh# 1|0|0|SCAN t1 USING COVERING INDEX i2
58939759747Sdrh# 0|0|0|SCAN SUBQUERY 1
59039759747Sdrh# 0|0|0|USE TEMP B-TREE FOR GROUP BY
59139759747Sdrh#
592fa00aa2eSdandet 5.10 {
593fa00aa2eSdan  SELECT count(*) FROM (SELECT max(b) AS x FROM t1 GROUP BY a) GROUP BY x
594fa00aa2eSdan} {
5958210233cSdrh  1 0 0 {SCAN t1 USING COVERING INDEX i2}
5965822d6feSdrh  0 0 0 {SCAN SUBQUERY 1}
597fa00aa2eSdan  0 0 0 {USE TEMP B-TREE FOR GROUP BY}
598fa00aa2eSdan}
599fa00aa2eSdan
60003c3905fSdrh# XVIDENCE-OF: R-46219-33846 sqlite> EXPLAIN QUERY PLAN
60139759747Sdrh# SELECT * FROM (SELECT * FROM t2 WHERE c=1), t1;
6028210233cSdrh# 0|0|0|SEARCH t2 USING INDEX i4 (c=?)
6038210233cSdrh# 0|1|1|SCAN t1
60439759747Sdrh#
605d9e3cad2Sdrhdet 5.11 "SELECT a, b FROM (SELECT * FROM t2 WHERE c=1), t1" {
6068210233cSdrh  0 0 0 {SEARCH t2 USING INDEX i4 (c=?)}
6078210233cSdrh  0 1 1 {SCAN t1 USING COVERING INDEX i2}
608fa00aa2eSdan}
609fa00aa2eSdan
61003c3905fSdrh# XVIDENCE-OF: R-37879-39987 sqlite> EXPLAIN QUERY PLAN
61139759747Sdrh# SELECT a FROM t1 UNION SELECT c FROM t2;
6128210233cSdrh# 1|0|0|SCAN t1
6138210233cSdrh# 2|0|0|SCAN t2
61439759747Sdrh# 0|0|0|COMPOUND SUBQUERIES 1 AND 2 USING TEMP B-TREE (UNION)
61539759747Sdrh#
616165674d8Sdrhdet 5.12 "SELECT a,b FROM t1 UNION SELECT c, 99 FROM t2" {
6178210233cSdrh  1 0 0 {SCAN t1 USING COVERING INDEX i2}
6188210233cSdrh  2 0 0 {SCAN t2 USING COVERING INDEX i4}
619fa00aa2eSdan  0 0 0 {COMPOUND SUBQUERIES 1 AND 2 USING TEMP B-TREE (UNION)}
620fa00aa2eSdan}
621fa00aa2eSdan
62203c3905fSdrh# XVIDENCE-OF: R-44864-63011 sqlite> EXPLAIN QUERY PLAN
62339759747Sdrh# SELECT a FROM t1 EXCEPT SELECT d FROM t2 ORDER BY 1;
6248210233cSdrh# 1|0|0|SCAN t1 USING COVERING INDEX i2
6258210233cSdrh# 2|0|0|SCAN t2 2|0|0|USE TEMP B-TREE FOR ORDER BY
62639759747Sdrh# 0|0|0|COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)
62739759747Sdrh#
628fa00aa2eSdandet 5.13 "SELECT a FROM t1 EXCEPT SELECT d FROM t2 ORDER BY 1" {
6298210233cSdrh  1 0 0 {SCAN t1 USING COVERING INDEX i1}
6308210233cSdrh  2 0 0 {SCAN t2}
631fa00aa2eSdan  2 0 0 {USE TEMP B-TREE FOR ORDER BY}
632fa00aa2eSdan  0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)}
633fa00aa2eSdan}
634fa00aa2eSdan
635af3906a7Sdrhif {![nonzero_reserved_bytes]} {
63691da6b83Sdan  #-------------------------------------------------------------------------
63791da6b83Sdan  # The following tests - eqp-6.* - test that the example C code on
63891da6b83Sdan  # documentation page eqp.html works. The C code is duplicated in test1.c
63991da6b83Sdan  # and wrapped in Tcl command [print_explain_query_plan]
64091da6b83Sdan  #
64191da6b83Sdan  set boilerplate {
64291da6b83Sdan    proc explain_query_plan {db sql} {
64391da6b83Sdan      set stmt [sqlite3_prepare_v2 db $sql -1 DUMMY]
64491da6b83Sdan      print_explain_query_plan $stmt
64591da6b83Sdan      sqlite3_finalize $stmt
64691da6b83Sdan    }
64791da6b83Sdan    sqlite3 db test.db
64891da6b83Sdan    explain_query_plan db {%SQL%}
64991da6b83Sdan    db close
65091da6b83Sdan    exit
65191da6b83Sdan  }
65291da6b83Sdan
653ef7075deSdan  # Do a "Print Explain Query Plan" test.
65491da6b83Sdan  proc do_peqp_test {tn sql res} {
65591da6b83Sdan    set fd [open script.tcl w]
65691da6b83Sdan    puts $fd [string map [list %SQL% $sql] $::boilerplate]
65791da6b83Sdan    close $fd
65891da6b83Sdan
65991da6b83Sdan    uplevel do_test $tn [list {
66091da6b83Sdan      set fd [open "|[info nameofexec] script.tcl"]
66191da6b83Sdan      set data [read $fd]
66291da6b83Sdan      close $fd
66391da6b83Sdan      set data
66491da6b83Sdan    }] [list $res]
66591da6b83Sdan  }
66691da6b83Sdan
66791da6b83Sdan  do_peqp_test 6.1 {
668165674d8Sdrh    SELECT a, b FROM t1 EXCEPT SELECT d, 99 FROM t2 ORDER BY 1
66991da6b83Sdan  } [string trimleft {
6708210233cSdrh1 0 0 SCAN t1 USING COVERING INDEX i2
6718210233cSdrh2 0 0 SCAN t2
67291da6b83Sdan2 0 0 USE TEMP B-TREE FOR ORDER BY
67391da6b83Sdan0 0 0 COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)
67491da6b83Sdan}]
675af3906a7Sdrh}
67603c3905fSdrh}
67791da6b83Sdan
678ef7075deSdan#-------------------------------------------------------------------------
679ef7075deSdan# The following tests - eqp-7.* - test that queries that use the OP_Count
680ef7075deSdan# optimization return something sensible with EQP.
681ef7075deSdan#
682ef7075deSdandrop_all_tables
683fa00aa2eSdan
684ef7075deSdando_execsql_test 7.0 {
685165674d8Sdrh  CREATE TABLE t1(a INT, b INT, ex CHAR(100));
686165674d8Sdrh  CREATE TABLE t2(a INT, b INT, ex CHAR(100));
687ef7075deSdan  CREATE INDEX i1 ON t2(a);
688ef7075deSdan}
689ef7075deSdan
690ef7075deSdandet 7.1 "SELECT count(*) FROM t1" {
69103c3905fSdrh  QUERY PLAN
6928210233cSdrh  `--SCAN t1
693ef7075deSdan}
694ef7075deSdan
695ef7075deSdandet 7.2 "SELECT count(*) FROM t2" {
69603c3905fSdrh  QUERY PLAN
6978210233cSdrh  `--SCAN t2 USING COVERING INDEX i1
698ef7075deSdan}
699ef7075deSdan
700ef7075deSdando_execsql_test 7.3 {
701165674d8Sdrh  INSERT INTO t1(a,b) VALUES(1, 2);
702165674d8Sdrh  INSERT INTO t1(a,b) VALUES(3, 4);
703ef7075deSdan
704165674d8Sdrh  INSERT INTO t2(a,b) VALUES(1, 2);
705165674d8Sdrh  INSERT INTO t2(a,b) VALUES(3, 4);
706165674d8Sdrh  INSERT INTO t2(a,b) VALUES(5, 6);
707ef7075deSdan
708ef7075deSdan  ANALYZE;
709ef7075deSdan}
710ef7075deSdan
711ef7075deSdandb close
712ef7075deSdansqlite3 db test.db
713ef7075deSdan
714ef7075deSdandet 7.4 "SELECT count(*) FROM t1" {
71503c3905fSdrh  QUERY PLAN
7168210233cSdrh  `--SCAN t1
717ef7075deSdan}
718ef7075deSdan
719ef7075deSdandet 7.5 "SELECT count(*) FROM t2" {
72003c3905fSdrh  QUERY PLAN
7218210233cSdrh  `--SCAN t2 USING COVERING INDEX i1
722ef7075deSdan}
723fa00aa2eSdan
724e96f2df3Sdan#-------------------------------------------------------------------------
725e96f2df3Sdan# The following tests - eqp-8.* - test that queries that use the OP_Count
726e96f2df3Sdan# optimization return something sensible with EQP.
727e96f2df3Sdan#
728e96f2df3Sdandrop_all_tables
729e96f2df3Sdan
730e96f2df3Sdando_execsql_test 8.0 {
731e96f2df3Sdan  CREATE TABLE t1(a, b, c, PRIMARY KEY(b, c)) WITHOUT ROWID;
732e96f2df3Sdan  CREATE TABLE t2(a, b, c);
733e96f2df3Sdan}
734e96f2df3Sdan
735e96f2df3Sdandet 8.1.1 "SELECT * FROM t2" {
73603c3905fSdrh  QUERY PLAN
7378210233cSdrh  `--SCAN t2
738e96f2df3Sdan}
739e96f2df3Sdan
740e96f2df3Sdandet 8.1.2 "SELECT * FROM t2 WHERE rowid=?" {
74103c3905fSdrh  QUERY PLAN
7428210233cSdrh  `--SEARCH t2 USING INTEGER PRIMARY KEY (rowid=?)
743e96f2df3Sdan}
744e96f2df3Sdan
745e96f2df3Sdandet 8.1.3 "SELECT count(*) FROM t2" {
74603c3905fSdrh  QUERY PLAN
7478210233cSdrh  `--SCAN t2
748e96f2df3Sdan}
749e96f2df3Sdan
750e96f2df3Sdandet 8.2.1 "SELECT * FROM t1" {
75103c3905fSdrh  QUERY PLAN
7528210233cSdrh  `--SCAN t1
753e96f2df3Sdan}
754e96f2df3Sdan
755e96f2df3Sdandet 8.2.2 "SELECT * FROM t1 WHERE b=?" {
75603c3905fSdrh  QUERY PLAN
7578210233cSdrh  `--SEARCH t1 USING PRIMARY KEY (b=?)
758e96f2df3Sdan}
759e96f2df3Sdan
760e96f2df3Sdandet 8.2.3 "SELECT * FROM t1 WHERE b=? AND c=?" {
76103c3905fSdrh  QUERY PLAN
7628210233cSdrh  `--SEARCH t1 USING PRIMARY KEY (b=? AND c=?)
763e96f2df3Sdan}
764e96f2df3Sdan
765e96f2df3Sdandet 8.2.4 "SELECT count(*) FROM t1" {
76603c3905fSdrh  QUERY PLAN
7678210233cSdrh  `--SCAN t1
768e96f2df3Sdan}
769e96f2df3Sdan
770d8852095Sdrh# 2018-08-16:  While working on Fossil I discovered that EXPLAIN QUERY PLAN
771d8852095Sdrh# did not describe IN operators implemented using a ROWID lookup.  These
772d8852095Sdrh# test cases ensure that problem as been fixed.
773d8852095Sdrh#
774d8852095Sdrhdo_execsql_test 9.0 {
775d8852095Sdrh  -- Schema from Fossil 2018-08-16
776d8852095Sdrh  CREATE TABLE forumpost(
777d8852095Sdrh    fpid INTEGER PRIMARY KEY,
778d8852095Sdrh    froot INT,
779d8852095Sdrh    fprev INT,
780d8852095Sdrh    firt INT,
781d8852095Sdrh    fmtime REAL
782d8852095Sdrh  );
783d8852095Sdrh  CREATE INDEX forumthread ON forumpost(froot,fmtime);
784d8852095Sdrh  CREATE TABLE blob(
785d8852095Sdrh    rid INTEGER PRIMARY KEY,
786d8852095Sdrh    rcvid INTEGER,
787d8852095Sdrh    size INTEGER,
788d8852095Sdrh    uuid TEXT UNIQUE NOT NULL,
789d8852095Sdrh    content BLOB,
790d8852095Sdrh    CHECK( length(uuid)>=40 AND rid>0 )
791d8852095Sdrh  );
792d8852095Sdrh  CREATE TABLE event(
793d8852095Sdrh    type TEXT,
794d8852095Sdrh    mtime DATETIME,
795d8852095Sdrh    objid INTEGER PRIMARY KEY,
796d8852095Sdrh    tagid INTEGER,
797d8852095Sdrh    uid INTEGER REFERENCES user,
798d8852095Sdrh    bgcolor TEXT,
799d8852095Sdrh    euser TEXT,
800d8852095Sdrh    user TEXT,
801d8852095Sdrh    ecomment TEXT,
802d8852095Sdrh    comment TEXT,
803d8852095Sdrh    brief TEXT,
804d8852095Sdrh    omtime DATETIME
805d8852095Sdrh  );
806d8852095Sdrh  CREATE INDEX event_i1 ON event(mtime);
807d8852095Sdrh  CREATE TABLE private(rid INTEGER PRIMARY KEY);
808d8852095Sdrh}
809d8852095Sdrhdo_eqp_test 9.1 {
810d8852095Sdrh  WITH thread(age,duration,cnt,root,last) AS (
811d8852095Sdrh    SELECT
812d8852095Sdrh      julianday('now') - max(fmtime) AS age,
813d8852095Sdrh      max(fmtime) - min(fmtime) AS duration,
814d8852095Sdrh      sum(fprev IS NULL) AS msg_count,
815d8852095Sdrh      froot,
816d8852095Sdrh      (SELECT fpid FROM forumpost
817d8852095Sdrh        WHERE froot=x.froot
818d8852095Sdrh          AND fpid NOT IN private
819d8852095Sdrh        ORDER BY fmtime DESC LIMIT 1)
820d8852095Sdrh    FROM forumpost AS x
821d8852095Sdrh    WHERE fpid NOT IN private  --- Ensure this table mentioned in EQP output!
822d8852095Sdrh    GROUP BY froot
823d8852095Sdrh    ORDER BY 1 LIMIT 26 OFFSET 5
824d8852095Sdrh  )
825d8852095Sdrh  SELECT
826d8852095Sdrh    thread.age,
827d8852095Sdrh    thread.duration,
828d8852095Sdrh    thread.cnt,
829d8852095Sdrh    blob.uuid,
830d8852095Sdrh    substr(event.comment,instr(event.comment,':')+1)
831d8852095Sdrh  FROM thread, blob, event
832d8852095Sdrh  WHERE blob.rid=thread.last
833d8852095Sdrh    AND event.objid=thread.last
834d8852095Sdrh  ORDER BY 1;
835d8852095Sdrh} {
836d8852095Sdrh  QUERY PLAN
8378210233cSdrh  |--MATERIALIZE thread
8388210233cSdrh  |  |--SCAN x USING INDEX forumthread
839d8852095Sdrh  |  |--USING ROWID SEARCH ON TABLE private FOR IN-OPERATOR
840bd462bccSdrh  |  |--CORRELATED SCALAR SUBQUERY xxxxxx
8418210233cSdrh  |  |  |--SEARCH forumpost USING COVERING INDEX forumthread (froot=?)
842d8852095Sdrh  |  |  `--USING ROWID SEARCH ON TABLE private FOR IN-OPERATOR
843d8852095Sdrh  |  `--USE TEMP B-TREE FOR ORDER BY
8448210233cSdrh  |--SCAN thread
8458210233cSdrh  |--SEARCH blob USING INTEGER PRIMARY KEY (rowid=?)
8468210233cSdrh  |--SEARCH event USING INTEGER PRIMARY KEY (rowid=?)
847d8852095Sdrh  `--USE TEMP B-TREE FOR ORDER BY
848d8852095Sdrh}
849fa00aa2eSdan
8502ce22453Sdanfinish_test
851