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 t1 USING INDEX i1 (a=?)
51 | `--SEARCH t1 USING INDEX i2 (b=?)
55 SELECT * FROM t2 CROSS JOIN t1 WHERE t1.a=1 OR t1.b=2;
61 | `--SEARCH t1 USING INDEX i1 (a=?)
63 `--SEARCH t1 USING INDEX i2 (b=?)
66 SELECT a FROM t1 ORDER BY a
69 `--SCAN t1 USING COVERING INDEX i1
72 SELECT a FROM t1 ORDER BY +a
75 |--SCAN t1 USING COVERING INDEX i1
76 `--USE TEMP B-TREE FOR ORDER BY
79 SELECT a FROM t1 WHERE a=4
82 `--SEARCH 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)
97 |--MATERIALIZE SUBQUERY xxxxxx
98 | `--SCAN CONSTANT ROW
99 |--SCAN SUBQUERY xxxxxx
103 SELECT * FROM t3 JOIN (SELECT 1) AS v1
107 | `--SCAN CONSTANT ROW
112 SELECT * FROM t3 AS xx JOIN (SELECT 1) AS yy
116 | `--SCAN CONSTANT ROW
123 SELECT * FROM t3 JOIN (SELECT 1 UNION SELECT 2)
126 |--MATERIALIZE SUBQUERY xxxxxx
128 | |--LEFT-MOST SUBQUERY
129 | | `--SCAN CONSTANT ROW
130 | `--UNION USING TEMP B-TREE
131 | `--SCAN CONSTANT ROW
132 |--SCAN SUBQUERY xxxxxx
136 SELECT * FROM t3 JOIN (SELECT 1 EXCEPT SELECT a FROM t3 LIMIT 17) AS abc
141 | |--LEFT-MOST SUBQUERY
142 | | `--SCAN CONSTANT ROW
143 | `--EXCEPT USING TEMP B-TREE
149 SELECT * FROM t3 JOIN (SELECT 1 INTERSECT SELECT a FROM t3 LIMIT 17) AS abc
154 | |--LEFT-MOST SUBQUERY
155 | | `--SCAN CONSTANT ROW
156 | `--INTERSECT USING TEMP B-TREE
163 SELECT * FROM t3 JOIN (SELECT 1 UNION ALL SELECT a FROM t3 LIMIT 17) abc
168 | |--LEFT-MOST SUBQUERY
169 | | `--SCAN CONSTANT ROW
176 #-------------------------------------------------------------------------
177 # Test cases eqp-2.* - tests for single select statements.
180 do_execsql_test 2.1 {
181 CREATE TABLE t1(x INT, y INT, ex TEXT);
183 CREATE TABLE t2(x INT, y INT, ex TEXT);
184 CREATE INDEX t2i1 ON t2(x);
187 det 2.2.1 "SELECT DISTINCT min(x), max(x) FROM t1 GROUP BY x ORDER BY 1" {
190 |--USE TEMP B-TREE FOR GROUP BY
191 |--USE TEMP B-TREE FOR DISTINCT
192 `--USE TEMP B-TREE FOR ORDER BY
194 det 2.2.2 "SELECT DISTINCT min(x), max(x) FROM t2 GROUP BY x ORDER BY 1" {
196 |--SCAN t2 USING COVERING INDEX t2i1
197 |--USE TEMP B-TREE FOR DISTINCT
198 `--USE TEMP B-TREE FOR ORDER BY
200 det 2.2.3 "SELECT DISTINCT * FROM t1" {
203 `--USE TEMP B-TREE FOR DISTINCT
205 det 2.2.4 "SELECT DISTINCT * FROM t1, t2" {
209 `--USE TEMP B-TREE FOR DISTINCT
211 det 2.2.5 "SELECT DISTINCT * FROM t1, t2 ORDER BY t1.x" {
215 |--USE TEMP B-TREE FOR DISTINCT
216 `--USE TEMP B-TREE FOR ORDER BY
218 det 2.2.6 "SELECT DISTINCT t2.x FROM t1, t2 ORDER BY t2.x" {
220 |--SCAN t2 USING COVERING INDEX t2i1
224 det 2.3.1 "SELECT max(x) FROM t2" {
226 `--SEARCH t2 USING COVERING INDEX t2i1
228 det 2.3.2 "SELECT min(x) FROM t2" {
230 `--SEARCH t2 USING COVERING INDEX t2i1
232 det 2.3.3 "SELECT min(x), max(x) FROM t2" {
234 `--SCAN t2 USING COVERING INDEX t2i1
237 det 2.4.1 "SELECT * FROM t1 WHERE rowid=?" {
239 `--SEARCH t1 USING INTEGER PRIMARY KEY (rowid=?)
244 #-------------------------------------------------------------------------
245 # Test cases eqp-3.* - tests for select statements that use sub-selects.
248 SELECT (SELECT x FROM t1 AS sub) FROM t1;
252 `--SCALAR SUBQUERY xxxxxx
256 SELECT * FROM t1 WHERE (SELECT x FROM t1 AS sub);
260 `--SCALAR SUBQUERY xxxxxx
264 SELECT * FROM t1 WHERE (SELECT x FROM t1 AS sub ORDER BY y);
268 `--SCALAR SUBQUERY xxxxxx
270 `--USE TEMP B-TREE FOR ORDER BY
273 SELECT * FROM t1 WHERE (SELECT x FROM t2 ORDER BY x);
277 `--SCALAR SUBQUERY xxxxxx
278 `--SCAN t2 USING COVERING INDEX t2i1
282 SELECT * FROM (SELECT * FROM t1 ORDER BY x LIMIT 10) ORDER BY y LIMIT 5
285 |--CO-ROUTINE SUBQUERY xxxxxx
287 | `--USE TEMP B-TREE FOR ORDER BY
288 |--SCAN SUBQUERY xxxxxx
289 `--USE TEMP B-TREE FOR ORDER BY
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
300 | `--USE TEMP B-TREE FOR ORDER BY
302 | `--SCAN t2 USING INDEX t2i1
305 `--USE TEMP B-TREE FOR ORDER BY
309 SELECT * FROM t1 WHERE y IN (SELECT y FROM t2)
313 `--LIST SUBQUERY xxxxxx
317 SELECT * FROM t1 WHERE y IN (SELECT y FROM t2 WHERE t1.x!=t2.x)
321 `--CORRELATED LIST SUBQUERY xxxxxx
325 SELECT * FROM t1 WHERE EXISTS (SELECT y FROM t2 WHERE t1.x!=t2.x)
329 `--CORRELATED SCALAR SUBQUERY xxxxxx
333 #-------------------------------------------------------------------------
334 # Test cases eqp-4.* - tests for composite select statements.
337 SELECT * FROM t1 UNION ALL SELECT * FROM t2
341 |--LEFT-MOST SUBQUERY
347 SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY 2
353 | `--USE TEMP B-TREE FOR ORDER BY
356 `--USE TEMP B-TREE FOR ORDER BY
359 SELECT * FROM t1 UNION SELECT * FROM t2 ORDER BY 2
365 | `--USE TEMP B-TREE FOR ORDER BY
368 `--USE TEMP B-TREE FOR ORDER BY
371 SELECT * FROM t1 INTERSECT SELECT * FROM t2 ORDER BY 2
377 | `--USE TEMP B-TREE FOR ORDER BY
380 `--USE TEMP B-TREE FOR ORDER BY
383 SELECT * FROM t1 EXCEPT SELECT * FROM t2 ORDER BY 2
389 | `--USE TEMP B-TREE FOR ORDER BY
392 `--USE TEMP B-TREE FOR ORDER BY
396 SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY 1
402 | `--USE TEMP B-TREE FOR ORDER BY
404 `--SCAN t2 USING INDEX t2i1
407 SELECT * FROM t1 UNION SELECT * FROM t2 ORDER BY 1
413 | `--USE TEMP B-TREE FOR ORDER BY
415 |--SCAN t2 USING INDEX t2i1
416 `--USE TEMP B-TREE FOR RIGHT PART OF ORDER BY
419 SELECT * FROM t1 INTERSECT SELECT * FROM t2 ORDER BY 1
425 | `--USE TEMP B-TREE FOR ORDER BY
427 |--SCAN t2 USING INDEX t2i1
428 `--USE TEMP B-TREE FOR RIGHT PART OF ORDER BY
431 SELECT * FROM t1 EXCEPT SELECT * FROM t2 ORDER BY 1
437 | `--USE TEMP B-TREE FOR ORDER BY
439 |--SCAN t2 USING INDEX t2i1
440 `--USE TEMP B-TREE FOR RIGHT PART OF ORDER BY
444 SELECT x FROM t1 UNION SELECT x FROM t2
448 |--LEFT-MOST SUBQUERY
450 `--UNION USING TEMP B-TREE
451 `--SCAN t2 USING COVERING INDEX t2i1
455 SELECT x FROM t1 UNION SELECT x FROM t2 UNION SELECT x FROM t1
459 |--LEFT-MOST SUBQUERY
461 |--UNION USING TEMP B-TREE
462 | `--SCAN t2 USING COVERING INDEX t2i1
463 `--UNION USING TEMP B-TREE
467 SELECT x FROM t1 UNION SELECT x FROM t2 UNION SELECT x FROM t1 ORDER BY 1
475 | | `--USE TEMP B-TREE FOR ORDER BY
477 | `--SCAN t2 USING COVERING INDEX t2i1
480 `--USE TEMP B-TREE FOR ORDER BY
484 #-------------------------------------------------------------------------
485 # This next block of tests verifies that the examples on the
486 # lang_explain.html page are correct.
490 # XVIDENCE-OF: R-47779-47605 sqlite> EXPLAIN QUERY PLAN SELECT a, b
494 do_execsql_test 5.1.0 { CREATE TABLE t1(a INT, b INT, ex TEXT) }
495 det 5.1.1 "SELECT a, b FROM t1 WHERE a=1" {
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
503 do_execsql_test 5.2.0 { CREATE INDEX i1 ON t1(a) }
504 det 5.2.1 "SELECT a, b FROM t1 WHERE a=1" {
505 0 0 0 {SEARCH t1 USING INDEX i1 (a=?)}
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=?)
512 do_execsql_test 5.3.0 { CREATE INDEX i2 ON t1(a, b) }
513 det 5.3.1 "SELECT a, b FROM t1 WHERE a=1" {
514 0 0 0 {SEARCH t1 USING COVERING INDEX i2 (a=?)}
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>?)
522 do_execsql_test 5.4.0 {CREATE TABLE t2(c INT, d INT, ex TEXT)}
523 det 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>?)}
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>?)
533 det 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>?)}
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=?)
543 do_execsql_test 5.5.0 {CREATE INDEX i3 ON t1(b)}
544 det 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=?)}
549 # XVIDENCE-OF: R-24577-38891 sqlite> EXPLAIN QUERY PLAN
550 # SELECT c, d FROM t2 ORDER BY c;
552 # 0|0|0|USE TEMP B-TREE FOR ORDER BY
554 det 5.7 "SELECT c, d FROM t2 ORDER BY c" {
556 0 0 0 {USE TEMP B-TREE FOR ORDER BY}
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
563 do_execsql_test 5.8.0 {CREATE INDEX i4 ON t2(c)}
564 det 5.8.1 "SELECT c, d FROM t2 ORDER BY c" {
565 0 0 0 {SCAN t2 USING INDEX i4}
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;
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=?)
577 SELECT (SELECT b FROM t1 WHERE a=0), (SELECT a FROM t1 WHERE b=t2.c) FROM t2
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=?)}
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
593 SELECT count(*) FROM (SELECT max(b) AS x FROM t1 GROUP BY a) GROUP BY x
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}
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=?)
605 det 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}
610 # XVIDENCE-OF: R-37879-39987 sqlite> EXPLAIN QUERY PLAN
611 # SELECT a FROM t1 UNION SELECT c FROM t2;
614 # 0|0|0|COMPOUND SUBQUERIES 1 AND 2 USING TEMP B-TREE (UNION)
616 det 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)}
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)
628 det 5.13 "SELECT a FROM t1 EXCEPT SELECT d FROM t2 ORDER BY 1" {
629 1 0 0 {SCAN t1 USING COVERING INDEX i1}
631 2 0 0 {USE TEMP B-TREE FOR ORDER BY}
632 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)}
635 if {![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]
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
648 explain_query_plan db {%SQL%}
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]
659 uplevel do_test $tn [list {
660 set fd [open "|[info nameofexec] script.tcl"]
668 SELECT a, b FROM t1 EXCEPT SELECT d, 99 FROM t2 ORDER BY 1
670 1 0 0 SCAN t1 USING COVERING INDEX i2
672 2 0 0 USE TEMP B-TREE FOR ORDER BY
673 0 0 0 COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)
678 #-------------------------------------------------------------------------
679 # The following tests - eqp-7.* - test that queries that use the OP_Count
680 # optimization return something sensible with EQP.
684 do_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);
690 det 7.1 "SELECT count(*) FROM t1" {
695 det 7.2 "SELECT count(*) FROM t2" {
697 `--SCAN t2 USING COVERING INDEX i1
700 do_execsql_test 7.3 {
701 INSERT INTO t1(a,b) VALUES(1, 2);
702 INSERT INTO t1(a,b) VALUES(3, 4);
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);
714 det 7.4 "SELECT count(*) FROM t1" {
719 det 7.5 "SELECT count(*) FROM t2" {
721 `--SCAN t2 USING COVERING INDEX i1
724 #-------------------------------------------------------------------------
725 # The following tests - eqp-8.* - test that queries that use the OP_Count
726 # optimization return something sensible with EQP.
730 do_execsql_test 8.0 {
731 CREATE TABLE t1(a, b, c, PRIMARY KEY(b, c)) WITHOUT ROWID;
732 CREATE TABLE t2(a, b, c);
735 det 8.1.1 "SELECT * FROM t2" {
740 det 8.1.2 "SELECT * FROM t2 WHERE rowid=?" {
742 `--SEARCH t2 USING INTEGER PRIMARY KEY (rowid=?)
745 det 8.1.3 "SELECT count(*) FROM t2" {
750 det 8.2.1 "SELECT * FROM t1" {
755 det 8.2.2 "SELECT * FROM t1 WHERE b=?" {
757 `--SEARCH t1 USING PRIMARY KEY (b=?)
760 det 8.2.3 "SELECT * FROM t1 WHERE b=? AND c=?" {
762 `--SEARCH t1 USING PRIMARY KEY (b=? AND c=?)
765 det 8.2.4 "SELECT count(*) FROM t1" {
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.
774 do_execsql_test 9.0 {
775 -- Schema from Fossil 2018-08-16
776 CREATE TABLE forumpost(
777 fpid INTEGER PRIMARY KEY,
783 CREATE INDEX forumthread ON forumpost(froot,fmtime);
785 rid INTEGER PRIMARY KEY,
788 uuid TEXT UNIQUE NOT NULL,
790 CHECK( length(uuid)>=40 AND rid>0 )
795 objid INTEGER PRIMARY KEY,
797 uid INTEGER REFERENCES user,
806 CREATE INDEX event_i1 ON event(mtime);
807 CREATE TABLE private(rid INTEGER PRIMARY KEY);
810 WITH thread(age,duration,cnt,root,last) AS (
812 julianday('now') - max(fmtime) AS age,
813 max(fmtime) - min(fmtime) AS duration,
814 sum(fprev IS NULL) AS msg_count,
816 (SELECT fpid FROM forumpost
818 AND fpid NOT IN private
819 ORDER BY fmtime DESC LIMIT 1)
821 WHERE fpid NOT IN private --- Ensure this table mentioned in EQP output!
823 ORDER BY 1 LIMIT 26 OFFSET 5
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
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
845 |--SEARCH blob USING INTEGER PRIMARY KEY (rowid=?)
846 |--SEARCH event USING INTEGER PRIMARY KEY (rowid=?)
847 `--USE TEMP B-TREE FOR ORDER BY