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 #***********************************************************************
13 set testdir [file dirname $argv0]
14 source $testdir/tester.tcl
23 #-------------------------------------------------------------------------
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.
30 # eqp-7.*: "SELECT count(*) FROM tbl" statements (VDBE code OP_Count).
33 proc det {args} { uplevel do_eqp_test $args }
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);
44 SELECT * FROM t2, t1 WHERE t1.a=1 OR t1.b=2;
49 | | `--SEARCH TABLE t1 USING INDEX i1 (a=?)
51 | `--SEARCH TABLE t1 USING INDEX i2 (b=?)
55 SELECT * FROM t2 CROSS JOIN t1 WHERE t1.a=1 OR t1.b=2;
61 | `--SEARCH TABLE t1 USING INDEX i1 (a=?)
63 `--SEARCH TABLE t1 USING INDEX i2 (b=?)
66 SELECT a FROM t1 ORDER BY a
69 `--SCAN TABLE t1 USING COVERING INDEX i1
72 SELECT a FROM t1 ORDER BY +a
75 |--SCAN TABLE t1 USING COVERING INDEX i1
76 `--USE TEMP B-TREE FOR ORDER BY
79 SELECT a FROM t1 WHERE a=4
82 `--SEARCH TABLE t1 USING COVERING INDEX i1 (a=?)
85 SELECT DISTINCT count(*) FROM t3 GROUP BY a;
89 |--USE TEMP B-TREE FOR GROUP BY
90 `--USE TEMP B-TREE FOR DISTINCT
94 SELECT * FROM t3 JOIN (SELECT 1)
98 | `--SCAN CONSTANT ROW
99 |--SCAN SUBQUERY xxxxxx
103 SELECT * FROM t3 JOIN (SELECT 1 UNION SELECT 2)
106 |--MATERIALIZE xxxxxx
108 | |--LEFT-MOST SUBQUERY
109 | | `--SCAN CONSTANT ROW
110 | `--UNION USING TEMP B-TREE
111 | `--SCAN CONSTANT ROW
112 |--SCAN SUBQUERY xxxxxx
116 SELECT * FROM t3 JOIN (SELECT 1 EXCEPT SELECT a FROM t3 LIMIT 17)
119 |--MATERIALIZE xxxxxx
121 | |--LEFT-MOST SUBQUERY
122 | | `--SCAN CONSTANT ROW
123 | `--EXCEPT USING TEMP B-TREE
125 |--SCAN SUBQUERY xxxxxx
129 SELECT * FROM t3 JOIN (SELECT 1 INTERSECT SELECT a FROM t3 LIMIT 17)
132 |--MATERIALIZE xxxxxx
134 | |--LEFT-MOST SUBQUERY
135 | | `--SCAN CONSTANT ROW
136 | `--INTERSECT USING TEMP B-TREE
138 |--SCAN SUBQUERY xxxxxx
143 SELECT * FROM t3 JOIN (SELECT 1 UNION ALL SELECT a FROM t3 LIMIT 17)
146 |--MATERIALIZE xxxxxx
148 | |--LEFT-MOST SUBQUERY
149 | | `--SCAN CONSTANT ROW
152 |--SCAN SUBQUERY xxxxxx
156 #-------------------------------------------------------------------------
157 # Test cases eqp-2.* - tests for single select statements.
160 do_execsql_test 2.1 {
161 CREATE TABLE t1(x INT, y INT, ex TEXT);
163 CREATE TABLE t2(x INT, y INT, ex TEXT);
164 CREATE INDEX t2i1 ON t2(x);
167 det 2.2.1 "SELECT DISTINCT min(x), max(x) FROM t1 GROUP BY x ORDER BY 1" {
170 |--USE TEMP B-TREE FOR GROUP BY
171 |--USE TEMP B-TREE FOR DISTINCT
172 `--USE TEMP B-TREE FOR ORDER BY
174 det 2.2.2 "SELECT DISTINCT min(x), max(x) FROM t2 GROUP BY x ORDER BY 1" {
176 |--SCAN TABLE t2 USING COVERING INDEX t2i1
177 |--USE TEMP B-TREE FOR DISTINCT
178 `--USE TEMP B-TREE FOR ORDER BY
180 det 2.2.3 "SELECT DISTINCT * FROM t1" {
183 `--USE TEMP B-TREE FOR DISTINCT
185 det 2.2.4 "SELECT DISTINCT * FROM t1, t2" {
189 `--USE TEMP B-TREE FOR DISTINCT
191 det 2.2.5 "SELECT DISTINCT * FROM t1, t2 ORDER BY t1.x" {
195 |--USE TEMP B-TREE FOR DISTINCT
196 `--USE TEMP B-TREE FOR ORDER BY
198 det 2.2.6 "SELECT DISTINCT t2.x FROM t1, t2 ORDER BY t2.x" {
200 |--SCAN TABLE t2 USING COVERING INDEX t2i1
204 det 2.3.1 "SELECT max(x) FROM t2" {
206 `--SEARCH TABLE t2 USING COVERING INDEX t2i1
208 det 2.3.2 "SELECT min(x) FROM t2" {
210 `--SEARCH TABLE t2 USING COVERING INDEX t2i1
212 det 2.3.3 "SELECT min(x), max(x) FROM t2" {
214 `--SCAN TABLE t2 USING COVERING INDEX t2i1
217 det 2.4.1 "SELECT * FROM t1 WHERE rowid=?" {
219 `--SEARCH TABLE t1 USING INTEGER PRIMARY KEY (rowid=?)
224 #-------------------------------------------------------------------------
225 # Test cases eqp-3.* - tests for select statements that use sub-selects.
228 SELECT (SELECT x FROM t1 AS sub) FROM t1;
232 `--SCALAR SUBQUERY xxxxxx
233 `--SCAN TABLE t1 AS sub
236 SELECT * FROM t1 WHERE (SELECT x FROM t1 AS sub);
240 `--SCALAR SUBQUERY xxxxxx
241 `--SCAN TABLE t1 AS sub
244 SELECT * FROM t1 WHERE (SELECT x FROM t1 AS sub ORDER BY y);
248 `--SCALAR SUBQUERY xxxxxx
249 |--SCAN TABLE t1 AS sub
250 `--USE TEMP B-TREE FOR ORDER BY
253 SELECT * FROM t1 WHERE (SELECT x FROM t2 ORDER BY x);
257 `--SCALAR SUBQUERY xxxxxx
258 `--SCAN TABLE t2 USING COVERING INDEX t2i1
262 SELECT * FROM (SELECT * FROM t1 ORDER BY x LIMIT 10) ORDER BY y LIMIT 5
267 | `--USE TEMP B-TREE FOR ORDER BY
268 |--SCAN SUBQUERY xxxxxx
269 `--USE TEMP B-TREE FOR ORDER BY
273 (SELECT * FROM t1 ORDER BY x LIMIT 10) AS x1,
274 (SELECT * FROM t2 ORDER BY x LIMIT 10) AS x2
275 ORDER BY x2.y LIMIT 5
278 |--MATERIALIZE xxxxxx
280 | `--USE TEMP B-TREE FOR ORDER BY
281 |--MATERIALIZE xxxxxx
282 | `--SCAN TABLE t2 USING INDEX t2i1
283 |--SCAN SUBQUERY xxxxxx AS x1
284 |--SCAN SUBQUERY xxxxxx AS x2
285 `--USE TEMP B-TREE FOR ORDER BY
289 SELECT * FROM t1 WHERE y IN (SELECT y FROM t2)
293 `--LIST SUBQUERY xxxxxx
297 SELECT * FROM t1 WHERE y IN (SELECT y FROM t2 WHERE t1.x!=t2.x)
301 `--CORRELATED LIST SUBQUERY xxxxxx
305 SELECT * FROM t1 WHERE EXISTS (SELECT y FROM t2 WHERE t1.x!=t2.x)
309 `--CORRELATED SCALAR SUBQUERY xxxxxx
313 #-------------------------------------------------------------------------
314 # Test cases eqp-4.* - tests for composite select statements.
317 SELECT * FROM t1 UNION ALL SELECT * FROM t2
321 |--LEFT-MOST SUBQUERY
327 SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY 2
333 | `--USE TEMP B-TREE FOR ORDER BY
336 `--USE TEMP B-TREE FOR ORDER BY
339 SELECT * FROM t1 UNION SELECT * FROM t2 ORDER BY 2
345 | `--USE TEMP B-TREE FOR ORDER BY
348 `--USE TEMP B-TREE FOR ORDER BY
351 SELECT * FROM t1 INTERSECT SELECT * FROM t2 ORDER BY 2
357 | `--USE TEMP B-TREE FOR ORDER BY
360 `--USE TEMP B-TREE FOR ORDER BY
363 SELECT * FROM t1 EXCEPT SELECT * FROM t2 ORDER BY 2
369 | `--USE TEMP B-TREE FOR ORDER BY
372 `--USE TEMP B-TREE FOR ORDER BY
376 SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY 1
382 | `--USE TEMP B-TREE FOR ORDER BY
384 `--SCAN TABLE t2 USING INDEX t2i1
387 SELECT * FROM t1 UNION SELECT * FROM t2 ORDER BY 1
393 | `--USE TEMP B-TREE FOR ORDER BY
395 |--SCAN TABLE t2 USING INDEX t2i1
396 `--USE TEMP B-TREE FOR RIGHT PART OF ORDER BY
399 SELECT * FROM t1 INTERSECT SELECT * FROM t2 ORDER BY 1
405 | `--USE TEMP B-TREE FOR ORDER BY
407 |--SCAN TABLE t2 USING INDEX t2i1
408 `--USE TEMP B-TREE FOR RIGHT PART OF ORDER BY
411 SELECT * FROM t1 EXCEPT SELECT * FROM t2 ORDER BY 1
417 | `--USE TEMP B-TREE FOR ORDER BY
419 |--SCAN TABLE t2 USING INDEX t2i1
420 `--USE TEMP B-TREE FOR RIGHT PART OF ORDER BY
424 SELECT x FROM t1 UNION SELECT x FROM t2
428 |--LEFT-MOST SUBQUERY
430 `--UNION USING TEMP B-TREE
431 `--SCAN TABLE t2 USING COVERING INDEX t2i1
435 SELECT x FROM t1 UNION SELECT x FROM t2 UNION SELECT x FROM t1
439 |--LEFT-MOST SUBQUERY
441 |--UNION USING TEMP B-TREE
442 | `--SCAN TABLE t2 USING COVERING INDEX t2i1
443 `--UNION USING TEMP B-TREE
447 SELECT x FROM t1 UNION SELECT x FROM t2 UNION SELECT x FROM t1 ORDER BY 1
455 | | `--USE TEMP B-TREE FOR ORDER BY
457 | `--SCAN TABLE t2 USING COVERING INDEX t2i1
460 `--USE TEMP B-TREE FOR ORDER BY
464 #-------------------------------------------------------------------------
465 # This next block of tests verifies that the examples on the
466 # lang_explain.html page are correct.
470 # XVIDENCE-OF: R-47779-47605 sqlite> EXPLAIN QUERY PLAN SELECT a, b
472 # 0|0|0|SCAN TABLE t1
474 do_execsql_test 5.1.0 { CREATE TABLE t1(a INT, b INT, ex TEXT) }
475 det 5.1.1 "SELECT a, b FROM t1 WHERE a=1" {
476 0 0 0 {SCAN TABLE t1}
479 # XVIDENCE-OF: R-55852-17599 sqlite> CREATE INDEX i1 ON t1(a);
480 # sqlite> EXPLAIN QUERY PLAN SELECT a, b FROM t1 WHERE a=1;
481 # 0|0|0|SEARCH TABLE t1 USING INDEX i1
483 do_execsql_test 5.2.0 { CREATE INDEX i1 ON t1(a) }
484 det 5.2.1 "SELECT a, b FROM t1 WHERE a=1" {
485 0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?)}
488 # XVIDENCE-OF: R-21179-11011 sqlite> CREATE INDEX i2 ON t1(a, b);
489 # sqlite> EXPLAIN QUERY PLAN SELECT a, b FROM t1 WHERE a=1;
490 # 0|0|0|SEARCH TABLE t1 USING COVERING INDEX i2 (a=?)
492 do_execsql_test 5.3.0 { CREATE INDEX i2 ON t1(a, b) }
493 det 5.3.1 "SELECT a, b FROM t1 WHERE a=1" {
494 0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i2 (a=?)}
497 # XVIDENCE-OF: R-09991-48941 sqlite> EXPLAIN QUERY PLAN
498 # SELECT t1.*, t2.* FROM t1, t2 WHERE t1.a=1 AND t1.b>2;
499 # 0|0|0|SEARCH TABLE t1 USING COVERING INDEX i2 (a=? AND b>?)
500 # 0|1|1|SCAN TABLE t2
502 do_execsql_test 5.4.0 {CREATE TABLE t2(c INT, d INT, ex TEXT)}
503 det 5.4.1 "SELECT t1.a, t2.c FROM t1, t2 WHERE t1.a=1 AND t1.b>2" {
504 0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i2 (a=? AND b>?)}
505 0 1 1 {SCAN TABLE t2}
508 # XVIDENCE-OF: R-33626-61085 sqlite> EXPLAIN QUERY PLAN
509 # SELECT t1.*, t2.* FROM t2, t1 WHERE t1.a=1 AND t1.b>2;
510 # 0|0|1|SEARCH TABLE t1 USING COVERING INDEX i2 (a=? AND b>?)
511 # 0|1|0|SCAN TABLE t2
513 det 5.5 "SELECT t1.a, t2.c FROM t2, t1 WHERE t1.a=1 AND t1.b>2" {
514 0 0 1 {SEARCH TABLE t1 USING COVERING INDEX i2 (a=? AND b>?)}
515 0 1 0 {SCAN TABLE t2}
518 # XVIDENCE-OF: R-04002-25654 sqlite> CREATE INDEX i3 ON t1(b);
519 # sqlite> EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE a=1 OR b=2;
520 # 0|0|0|SEARCH TABLE t1 USING COVERING INDEX i2 (a=?)
521 # 0|0|0|SEARCH TABLE t1 USING INDEX i3 (b=?)
523 do_execsql_test 5.5.0 {CREATE INDEX i3 ON t1(b)}
524 det 5.6.1 "SELECT a, b FROM t1 WHERE a=1 OR b=2" {
525 0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i2 (a=?)}
526 0 0 0 {SEARCH TABLE t1 USING INDEX i3 (b=?)}
529 # XVIDENCE-OF: R-24577-38891 sqlite> EXPLAIN QUERY PLAN
530 # SELECT c, d FROM t2 ORDER BY c;
531 # 0|0|0|SCAN TABLE t2
532 # 0|0|0|USE TEMP B-TREE FOR ORDER BY
534 det 5.7 "SELECT c, d FROM t2 ORDER BY c" {
535 0 0 0 {SCAN TABLE t2}
536 0 0 0 {USE TEMP B-TREE FOR ORDER BY}
539 # XVIDENCE-OF: R-58157-12355 sqlite> CREATE INDEX i4 ON t2(c);
540 # sqlite> EXPLAIN QUERY PLAN SELECT c, d FROM t2 ORDER BY c;
541 # 0|0|0|SCAN TABLE t2 USING INDEX i4
543 do_execsql_test 5.8.0 {CREATE INDEX i4 ON t2(c)}
544 det 5.8.1 "SELECT c, d FROM t2 ORDER BY c" {
545 0 0 0 {SCAN TABLE t2 USING INDEX i4}
548 # XVIDENCE-OF: R-13931-10421 sqlite> EXPLAIN QUERY PLAN SELECT
549 # (SELECT b FROM t1 WHERE a=0), (SELECT a FROM t1 WHERE b=t2.c) FROM t2;
550 # 0|0|0|SCAN TABLE t2
551 # 0|0|0|EXECUTE SCALAR SUBQUERY 1
552 # 1|0|0|SEARCH TABLE t1 USING COVERING INDEX i2 (a=?)
553 # 0|0|0|EXECUTE CORRELATED SCALAR SUBQUERY 2
554 # 2|0|0|SEARCH TABLE t1 USING INDEX i3 (b=?)
557 SELECT (SELECT b FROM t1 WHERE a=0), (SELECT a FROM t1 WHERE b=t2.c) FROM t2
559 0 0 0 {SCAN TABLE t2 USING COVERING INDEX i4}
560 0 0 0 {EXECUTE SCALAR SUBQUERY 1}
561 1 0 0 {SEARCH TABLE t1 USING COVERING INDEX i2 (a=?)}
562 0 0 0 {EXECUTE CORRELATED SCALAR SUBQUERY 2}
563 2 0 0 {SEARCH TABLE t1 USING INDEX i3 (b=?)}
566 # XVIDENCE-OF: R-50892-45943 sqlite> EXPLAIN QUERY PLAN
567 # SELECT count(*) FROM (SELECT max(b) AS x FROM t1 GROUP BY a) GROUP BY x;
568 # 1|0|0|SCAN TABLE t1 USING COVERING INDEX i2
569 # 0|0|0|SCAN SUBQUERY 1
570 # 0|0|0|USE TEMP B-TREE FOR GROUP BY
573 SELECT count(*) FROM (SELECT max(b) AS x FROM t1 GROUP BY a) GROUP BY x
575 1 0 0 {SCAN TABLE t1 USING COVERING INDEX i2}
576 0 0 0 {SCAN SUBQUERY 1}
577 0 0 0 {USE TEMP B-TREE FOR GROUP BY}
580 # XVIDENCE-OF: R-46219-33846 sqlite> EXPLAIN QUERY PLAN
581 # SELECT * FROM (SELECT * FROM t2 WHERE c=1), t1;
582 # 0|0|0|SEARCH TABLE t2 USING INDEX i4 (c=?)
583 # 0|1|1|SCAN TABLE t1
585 det 5.11 "SELECT a, b FROM (SELECT * FROM t2 WHERE c=1), t1" {
586 0 0 0 {SEARCH TABLE t2 USING INDEX i4 (c=?)}
587 0 1 1 {SCAN TABLE t1 USING COVERING INDEX i2}
590 # XVIDENCE-OF: R-37879-39987 sqlite> EXPLAIN QUERY PLAN
591 # SELECT a FROM t1 UNION SELECT c FROM t2;
592 # 1|0|0|SCAN TABLE t1
593 # 2|0|0|SCAN TABLE t2
594 # 0|0|0|COMPOUND SUBQUERIES 1 AND 2 USING TEMP B-TREE (UNION)
596 det 5.12 "SELECT a,b FROM t1 UNION SELECT c, 99 FROM t2" {
597 1 0 0 {SCAN TABLE t1 USING COVERING INDEX i2}
598 2 0 0 {SCAN TABLE t2 USING COVERING INDEX i4}
599 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 USING TEMP B-TREE (UNION)}
602 # XVIDENCE-OF: R-44864-63011 sqlite> EXPLAIN QUERY PLAN
603 # SELECT a FROM t1 EXCEPT SELECT d FROM t2 ORDER BY 1;
604 # 1|0|0|SCAN TABLE t1 USING COVERING INDEX i2
605 # 2|0|0|SCAN TABLE t2 2|0|0|USE TEMP B-TREE FOR ORDER BY
606 # 0|0|0|COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)
608 det 5.13 "SELECT a FROM t1 EXCEPT SELECT d FROM t2 ORDER BY 1" {
609 1 0 0 {SCAN TABLE t1 USING COVERING INDEX i1}
610 2 0 0 {SCAN TABLE t2}
611 2 0 0 {USE TEMP B-TREE FOR ORDER BY}
612 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)}
615 if {![nonzero_reserved_bytes]} {
616 #-------------------------------------------------------------------------
617 # The following tests - eqp-6.* - test that the example C code on
618 # documentation page eqp.html works. The C code is duplicated in test1.c
619 # and wrapped in Tcl command [print_explain_query_plan]
622 proc explain_query_plan {db sql} {
623 set stmt [sqlite3_prepare_v2 db $sql -1 DUMMY]
624 print_explain_query_plan $stmt
625 sqlite3_finalize $stmt
628 explain_query_plan db {%SQL%}
633 # Do a "Print Explain Query Plan" test.
634 proc do_peqp_test {tn sql res} {
635 set fd [open script.tcl w]
636 puts $fd [string map [list %SQL% $sql] $::boilerplate]
639 uplevel do_test $tn [list {
640 set fd [open "|[info nameofexec] script.tcl"]
648 SELECT a, b FROM t1 EXCEPT SELECT d, 99 FROM t2 ORDER BY 1
650 1 0 0 SCAN TABLE t1 USING COVERING INDEX i2
652 2 0 0 USE TEMP B-TREE FOR ORDER BY
653 0 0 0 COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)
658 #-------------------------------------------------------------------------
659 # The following tests - eqp-7.* - test that queries that use the OP_Count
660 # optimization return something sensible with EQP.
664 do_execsql_test 7.0 {
665 CREATE TABLE t1(a INT, b INT, ex CHAR(100));
666 CREATE TABLE t2(a INT, b INT, ex CHAR(100));
667 CREATE INDEX i1 ON t2(a);
670 det 7.1 "SELECT count(*) FROM t1" {
675 det 7.2 "SELECT count(*) FROM t2" {
677 `--SCAN TABLE t2 USING COVERING INDEX i1
680 do_execsql_test 7.3 {
681 INSERT INTO t1(a,b) VALUES(1, 2);
682 INSERT INTO t1(a,b) VALUES(3, 4);
684 INSERT INTO t2(a,b) VALUES(1, 2);
685 INSERT INTO t2(a,b) VALUES(3, 4);
686 INSERT INTO t2(a,b) VALUES(5, 6);
694 det 7.4 "SELECT count(*) FROM t1" {
699 det 7.5 "SELECT count(*) FROM t2" {
701 `--SCAN TABLE t2 USING COVERING INDEX i1
704 #-------------------------------------------------------------------------
705 # The following tests - eqp-8.* - test that queries that use the OP_Count
706 # optimization return something sensible with EQP.
710 do_execsql_test 8.0 {
711 CREATE TABLE t1(a, b, c, PRIMARY KEY(b, c)) WITHOUT ROWID;
712 CREATE TABLE t2(a, b, c);
715 det 8.1.1 "SELECT * FROM t2" {
720 det 8.1.2 "SELECT * FROM t2 WHERE rowid=?" {
722 `--SEARCH TABLE t2 USING INTEGER PRIMARY KEY (rowid=?)
725 det 8.1.3 "SELECT count(*) FROM t2" {
730 det 8.2.1 "SELECT * FROM t1" {
735 det 8.2.2 "SELECT * FROM t1 WHERE b=?" {
737 `--SEARCH TABLE t1 USING PRIMARY KEY (b=?)
740 det 8.2.3 "SELECT * FROM t1 WHERE b=? AND c=?" {
742 `--SEARCH TABLE t1 USING PRIMARY KEY (b=? AND c=?)
745 det 8.2.4 "SELECT count(*) FROM t1" {
750 # 2018-08-16: While working on Fossil I discovered that EXPLAIN QUERY PLAN
751 # did not describe IN operators implemented using a ROWID lookup. These
752 # test cases ensure that problem as been fixed.
754 do_execsql_test 9.0 {
755 -- Schema from Fossil 2018-08-16
756 CREATE TABLE forumpost(
757 fpid INTEGER PRIMARY KEY,
763 CREATE INDEX forumthread ON forumpost(froot,fmtime);
765 rid INTEGER PRIMARY KEY,
768 uuid TEXT UNIQUE NOT NULL,
770 CHECK( length(uuid)>=40 AND rid>0 )
775 objid INTEGER PRIMARY KEY,
777 uid INTEGER REFERENCES user,
786 CREATE INDEX event_i1 ON event(mtime);
787 CREATE TABLE private(rid INTEGER PRIMARY KEY);
790 WITH thread(age,duration,cnt,root,last) AS (
792 julianday('now') - max(fmtime) AS age,
793 max(fmtime) - min(fmtime) AS duration,
794 sum(fprev IS NULL) AS msg_count,
796 (SELECT fpid FROM forumpost
798 AND fpid NOT IN private
799 ORDER BY fmtime DESC LIMIT 1)
801 WHERE fpid NOT IN private --- Ensure this table mentioned in EQP output!
803 ORDER BY 1 LIMIT 26 OFFSET 5
810 substr(event.comment,instr(event.comment,':')+1)
811 FROM thread, blob, event
812 WHERE blob.rid=thread.last
813 AND event.objid=thread.last
817 |--MATERIALIZE xxxxxx
818 | |--SCAN TABLE forumpost AS x USING INDEX forumthread
819 | |--USING ROWID SEARCH ON TABLE private FOR IN-OPERATOR
820 | |--CORRELATED SCALAR SUBQUERY xxxxxx
821 | | |--SEARCH TABLE forumpost USING COVERING INDEX forumthread (froot=?)
822 | | `--USING ROWID SEARCH ON TABLE private FOR IN-OPERATOR
823 | `--USE TEMP B-TREE FOR ORDER BY
824 |--SCAN SUBQUERY xxxxxx
825 |--SEARCH TABLE blob USING INTEGER PRIMARY KEY (rowid=?)
826 |--SEARCH TABLE event USING INTEGER PRIMARY KEY (rowid=?)
827 `--USE TEMP B-TREE FOR ORDER BY