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, b); 37 CREATE INDEX i1 ON t1(a); 38 CREATE INDEX i2 ON t1(b); 39 CREATE TABLE t2(a, b); 40 CREATE TABLE t3(a, b); 41} 42 43do_eqp_test 1.2 { 44 SELECT * FROM t2, t1 WHERE t1.a=1 OR t1.b=2; 45} { 46 0 0 1 {SEARCH TABLE t1 USING INDEX i1 (a=?) (~10 rows)} 47 0 0 1 {SEARCH TABLE t1 USING INDEX i2 (b=?) (~10 rows)} 48 0 1 0 {SCAN TABLE t2 (~1000000 rows)} 49} 50do_eqp_test 1.3 { 51 SELECT * FROM t2 CROSS JOIN t1 WHERE t1.a=1 OR t1.b=2; 52} { 53 0 0 0 {SCAN TABLE t2 (~1000000 rows)} 54 0 1 1 {SEARCH TABLE t1 USING INDEX i1 (a=?) (~10 rows)} 55 0 1 1 {SEARCH TABLE t1 USING INDEX i2 (b=?) (~10 rows)} 56} 57do_eqp_test 1.3 { 58 SELECT a FROM t1 ORDER BY a 59} { 60 0 0 0 {SCAN TABLE t1 USING COVERING INDEX i1 (~1000000 rows)} 61} 62do_eqp_test 1.4 { 63 SELECT a FROM t1 ORDER BY +a 64} { 65 0 0 0 {SCAN TABLE t1 (~1000000 rows)} 66 0 0 0 {USE TEMP B-TREE FOR ORDER BY} 67} 68do_eqp_test 1.5 { 69 SELECT a FROM t1 WHERE a=4 70} { 71 0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i1 (a=?) (~10 rows)} 72} 73do_eqp_test 1.6 { 74 SELECT DISTINCT count(*) FROM t3 GROUP BY a; 75} { 76 0 0 0 {SCAN TABLE t3 (~1000000 rows)} 77 0 0 0 {USE TEMP B-TREE FOR GROUP BY} 78 0 0 0 {USE TEMP B-TREE FOR DISTINCT} 79} 80 81do_eqp_test 1.7 { 82 SELECT * FROM t3 JOIN (SELECT 1) 83} { 84 0 0 1 {SCAN SUBQUERY 1 (~1 rows)} 85 0 1 0 {SCAN TABLE t3 (~1000000 rows)} 86} 87do_eqp_test 1.8 { 88 SELECT * FROM t3 JOIN (SELECT 1 UNION SELECT 2) 89} { 90 1 0 0 {COMPOUND SUBQUERIES 2 AND 3 USING TEMP B-TREE (UNION)} 91 0 0 1 {SCAN SUBQUERY 1 (~2 rows)} 92 0 1 0 {SCAN TABLE t3 (~1000000 rows)} 93} 94do_eqp_test 1.9 { 95 SELECT * FROM t3 JOIN (SELECT 1 EXCEPT SELECT a FROM t3 LIMIT 17) 96} { 97 3 0 0 {SCAN TABLE t3 (~1000000 rows)} 98 1 0 0 {COMPOUND SUBQUERIES 2 AND 3 USING TEMP B-TREE (EXCEPT)} 99 0 0 1 {SCAN SUBQUERY 1 (~17 rows)} 100 0 1 0 {SCAN TABLE t3 (~1000000 rows)} 101} 102do_eqp_test 1.10 { 103 SELECT * FROM t3 JOIN (SELECT 1 INTERSECT SELECT a FROM t3 LIMIT 17) 104} { 105 3 0 0 {SCAN TABLE t3 (~1000000 rows)} 106 1 0 0 {COMPOUND SUBQUERIES 2 AND 3 USING TEMP B-TREE (INTERSECT)} 107 0 0 1 {SCAN SUBQUERY 1 (~1 rows)} 108 0 1 0 {SCAN TABLE t3 (~1000000 rows)} 109} 110 111do_eqp_test 1.11 { 112 SELECT * FROM t3 JOIN (SELECT 1 UNION ALL SELECT a FROM t3 LIMIT 17) 113} { 114 3 0 0 {SCAN TABLE t3 (~1000000 rows)} 115 1 0 0 {COMPOUND SUBQUERIES 2 AND 3 (UNION ALL)} 116 0 0 1 {SCAN SUBQUERY 1 (~17 rows)} 117 0 1 0 {SCAN TABLE t3 (~1000000 rows)} 118} 119 120#------------------------------------------------------------------------- 121# Test cases eqp-2.* - tests for single select statements. 122# 123drop_all_tables 124do_execsql_test 2.1 { 125 CREATE TABLE t1(x, y); 126 127 CREATE TABLE t2(x, y); 128 CREATE INDEX t2i1 ON t2(x); 129} 130 131det 2.2.1 "SELECT DISTINCT min(x), max(x) FROM t1 GROUP BY x ORDER BY 1" { 132 0 0 0 {SCAN TABLE t1 (~1000000 rows)} 133 0 0 0 {USE TEMP B-TREE FOR GROUP BY} 134 0 0 0 {USE TEMP B-TREE FOR DISTINCT} 135 0 0 0 {USE TEMP B-TREE FOR ORDER BY} 136} 137det 2.2.2 "SELECT DISTINCT min(x), max(x) FROM t2 GROUP BY x ORDER BY 1" { 138 0 0 0 {SCAN TABLE t2 USING COVERING INDEX t2i1 (~1000000 rows)} 139 0 0 0 {USE TEMP B-TREE FOR DISTINCT} 140 0 0 0 {USE TEMP B-TREE FOR ORDER BY} 141} 142det 2.2.3 "SELECT DISTINCT * FROM t1" { 143 0 0 0 {SCAN TABLE t1 (~1000000 rows)} 144 0 0 0 {USE TEMP B-TREE FOR DISTINCT} 145} 146det 2.2.4 "SELECT DISTINCT * FROM t1, t2" { 147 0 0 0 {SCAN TABLE t1 (~1000000 rows)} 148 0 1 1 {SCAN TABLE t2 (~1000000 rows)} 149 0 0 0 {USE TEMP B-TREE FOR DISTINCT} 150} 151det 2.2.5 "SELECT DISTINCT * FROM t1, t2 ORDER BY t1.x" { 152 0 0 0 {SCAN TABLE t1 (~1000000 rows)} 153 0 1 1 {SCAN TABLE t2 (~1000000 rows)} 154 0 0 0 {USE TEMP B-TREE FOR DISTINCT} 155 0 0 0 {USE TEMP B-TREE FOR ORDER BY} 156} 157det 2.2.6 "SELECT DISTINCT t2.x FROM t1, t2 ORDER BY t2.x" { 158 0 0 1 {SCAN TABLE t2 USING COVERING INDEX t2i1 (~1000000 rows)} 159 0 1 0 {SCAN TABLE t1 (~1000000 rows)} 160} 161 162det 2.3.1 "SELECT max(x) FROM t2" { 163 0 0 0 {SEARCH TABLE t2 USING COVERING INDEX t2i1 (~1 rows)} 164} 165det 2.3.2 "SELECT min(x) FROM t2" { 166 0 0 0 {SEARCH TABLE t2 USING COVERING INDEX t2i1 (~1 rows)} 167} 168det 2.3.3 "SELECT min(x), max(x) FROM t2" { 169 0 0 0 {SCAN TABLE t2 (~1000000 rows)} 170} 171 172det 2.4.1 "SELECT * FROM t1 WHERE rowid=?" { 173 0 0 0 {SEARCH TABLE t1 USING INTEGER PRIMARY KEY (rowid=?) (~1 rows)} 174} 175 176 177 178#------------------------------------------------------------------------- 179# Test cases eqp-3.* - tests for select statements that use sub-selects. 180# 181do_eqp_test 3.1.1 { 182 SELECT (SELECT x FROM t1 AS sub) FROM t1; 183} { 184 0 0 0 {SCAN TABLE t1 (~1000000 rows)} 185 0 0 0 {EXECUTE SCALAR SUBQUERY 1} 186 1 0 0 {SCAN TABLE t1 AS sub (~1000000 rows)} 187} 188do_eqp_test 3.1.2 { 189 SELECT * FROM t1 WHERE (SELECT x FROM t1 AS sub); 190} { 191 0 0 0 {SCAN TABLE t1 (~1000000 rows)} 192 0 0 0 {EXECUTE SCALAR SUBQUERY 1} 193 1 0 0 {SCAN TABLE t1 AS sub (~1000000 rows)} 194} 195do_eqp_test 3.1.3 { 196 SELECT * FROM t1 WHERE (SELECT x FROM t1 AS sub ORDER BY y); 197} { 198 0 0 0 {SCAN TABLE t1 (~1000000 rows)} 199 0 0 0 {EXECUTE SCALAR SUBQUERY 1} 200 1 0 0 {SCAN TABLE t1 AS sub (~1000000 rows)} 201 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 202} 203do_eqp_test 3.1.4 { 204 SELECT * FROM t1 WHERE (SELECT x FROM t2 ORDER BY x); 205} { 206 0 0 0 {SCAN TABLE t1 (~1000000 rows)} 207 0 0 0 {EXECUTE SCALAR SUBQUERY 1} 208 1 0 0 {SCAN TABLE t2 USING COVERING INDEX t2i1 (~1000000 rows)} 209} 210 211det 3.2.1 { 212 SELECT * FROM (SELECT * FROM t1 ORDER BY x LIMIT 10) ORDER BY y LIMIT 5 213} { 214 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 215 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 216 0 0 0 {SCAN SUBQUERY 1 (~10 rows)} 217 0 0 0 {USE TEMP B-TREE FOR ORDER BY} 218} 219det 3.2.2 { 220 SELECT * FROM 221 (SELECT * FROM t1 ORDER BY x LIMIT 10) AS x1, 222 (SELECT * FROM t2 ORDER BY x LIMIT 10) AS x2 223 ORDER BY x2.y LIMIT 5 224} { 225 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 226 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 227 2 0 0 {SCAN TABLE t2 USING INDEX t2i1 (~1000000 rows)} 228 0 0 0 {SCAN SUBQUERY 1 AS x1 (~10 rows)} 229 0 1 1 {SCAN SUBQUERY 2 AS x2 (~10 rows)} 230 0 0 0 {USE TEMP B-TREE FOR ORDER BY} 231} 232 233det 3.3.1 { 234 SELECT * FROM t1 WHERE y IN (SELECT y FROM t2) 235} { 236 0 0 0 {SCAN TABLE t1 (~100000 rows)} 237 0 0 0 {EXECUTE LIST SUBQUERY 1} 238 1 0 0 {SCAN TABLE t2 (~1000000 rows)} 239} 240det 3.3.2 { 241 SELECT * FROM t1 WHERE y IN (SELECT y FROM t2 WHERE t1.x!=t2.x) 242} { 243 0 0 0 {SCAN TABLE t1 (~500000 rows)} 244 0 0 0 {EXECUTE CORRELATED LIST SUBQUERY 1} 245 1 0 0 {SCAN TABLE t2 (~500000 rows)} 246} 247det 3.3.3 { 248 SELECT * FROM t1 WHERE EXISTS (SELECT y FROM t2 WHERE t1.x!=t2.x) 249} { 250 0 0 0 {SCAN TABLE t1 (~500000 rows)} 251 0 0 0 {EXECUTE CORRELATED SCALAR SUBQUERY 1} 252 1 0 0 {SCAN TABLE t2 (~500000 rows)} 253} 254 255#------------------------------------------------------------------------- 256# Test cases eqp-4.* - tests for composite select statements. 257# 258do_eqp_test 4.1.1 { 259 SELECT * FROM t1 UNION ALL SELECT * FROM t2 260} { 261 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 262 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 263 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (UNION ALL)} 264} 265do_eqp_test 4.1.2 { 266 SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY 2 267} { 268 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 269 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 270 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 271 2 0 0 {USE TEMP B-TREE FOR ORDER BY} 272 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (UNION ALL)} 273} 274do_eqp_test 4.1.3 { 275 SELECT * FROM t1 UNION SELECT * FROM t2 ORDER BY 2 276} { 277 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 278 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 279 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 280 2 0 0 {USE TEMP B-TREE FOR ORDER BY} 281 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (UNION)} 282} 283do_eqp_test 4.1.4 { 284 SELECT * FROM t1 INTERSECT SELECT * FROM t2 ORDER BY 2 285} { 286 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 287 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 288 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 289 2 0 0 {USE TEMP B-TREE FOR ORDER BY} 290 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (INTERSECT)} 291} 292do_eqp_test 4.1.5 { 293 SELECT * FROM t1 EXCEPT SELECT * FROM t2 ORDER BY 2 294} { 295 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 296 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 297 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 298 2 0 0 {USE TEMP B-TREE FOR ORDER BY} 299 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)} 300} 301 302do_eqp_test 4.2.2 { 303 SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY 1 304} { 305 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 306 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 307 2 0 0 {SCAN TABLE t2 USING INDEX t2i1 (~1000000 rows)} 308 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (UNION ALL)} 309} 310do_eqp_test 4.2.3 { 311 SELECT * FROM t1 UNION SELECT * FROM t2 ORDER BY 1 312} { 313 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 314 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 315 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 316 2 0 0 {USE TEMP B-TREE FOR ORDER BY} 317 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (UNION)} 318} 319do_eqp_test 4.2.4 { 320 SELECT * FROM t1 INTERSECT SELECT * FROM t2 ORDER BY 1 321} { 322 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 323 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 324 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 325 2 0 0 {USE TEMP B-TREE FOR ORDER BY} 326 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (INTERSECT)} 327} 328do_eqp_test 4.2.5 { 329 SELECT * FROM t1 EXCEPT SELECT * FROM t2 ORDER BY 1 330} { 331 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 332 1 0 0 {USE TEMP B-TREE FOR ORDER BY} 333 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 334 2 0 0 {USE TEMP B-TREE FOR ORDER BY} 335 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)} 336} 337 338do_eqp_test 4.3.1 { 339 SELECT x FROM t1 UNION SELECT x FROM t2 340} { 341 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 342 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 343 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 USING TEMP B-TREE (UNION)} 344} 345 346do_eqp_test 4.3.2 { 347 SELECT x FROM t1 UNION SELECT x FROM t2 UNION SELECT x FROM t1 348} { 349 2 0 0 {SCAN TABLE t1 (~1000000 rows)} 350 3 0 0 {SCAN TABLE t2 (~1000000 rows)} 351 1 0 0 {COMPOUND SUBQUERIES 2 AND 3 USING TEMP B-TREE (UNION)} 352 4 0 0 {SCAN TABLE t1 (~1000000 rows)} 353 0 0 0 {COMPOUND SUBQUERIES 1 AND 4 USING TEMP B-TREE (UNION)} 354} 355do_eqp_test 4.3.3 { 356 SELECT x FROM t1 UNION SELECT x FROM t2 UNION SELECT x FROM t1 ORDER BY 1 357} { 358 2 0 0 {SCAN TABLE t1 (~1000000 rows)} 359 2 0 0 {USE TEMP B-TREE FOR ORDER BY} 360 3 0 0 {SCAN TABLE t2 USING COVERING INDEX t2i1 (~1000000 rows)} 361 1 0 0 {COMPOUND SUBQUERIES 2 AND 3 (UNION)} 362 4 0 0 {SCAN TABLE t1 (~1000000 rows)} 363 4 0 0 {USE TEMP B-TREE FOR ORDER BY} 364 0 0 0 {COMPOUND SUBQUERIES 1 AND 4 (UNION)} 365} 366 367#------------------------------------------------------------------------- 368# This next block of tests verifies that the examples on the 369# lang_explain.html page are correct. 370# 371drop_all_tables 372 373# EVIDENCE-OF: R-64208-08323 sqlite> EXPLAIN QUERY PLAN SELECT a, b 374# FROM t1 WHERE a=1; 0|0|0|SCAN TABLE t1 (~100000 rows) 375do_execsql_test 5.1.0 { CREATE TABLE t1(a, b) } 376det 5.1.1 "SELECT a, b FROM t1 WHERE a=1" { 377 0 0 0 {SCAN TABLE t1 (~100000 rows)} 378} 379 380# EVIDENCE-OF: R-09022-44606 sqlite> CREATE INDEX i1 ON t1(a); 381# sqlite> EXPLAIN QUERY PLAN SELECT a, b FROM t1 WHERE a=1; 382# 0|0|0|SEARCH TABLE t1 USING INDEX i1 (a=?) (~10 rows) 383do_execsql_test 5.2.0 { CREATE INDEX i1 ON t1(a) } 384det 5.2.1 "SELECT a, b FROM t1 WHERE a=1" { 385 0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?) (~10 rows)} 386} 387 388# EVIDENCE-OF: R-62228-34103 sqlite> CREATE INDEX i2 ON t1(a, b); 389# sqlite> EXPLAIN QUERY PLAN SELECT a, b FROM t1 WHERE a=1; 390# 0|0|0|SEARCH TABLE t1 USING COVERING INDEX i2 (a=?) (~10 rows) 391do_execsql_test 5.3.0 { CREATE INDEX i2 ON t1(a, b) } 392det 5.3.1 "SELECT a, b FROM t1 WHERE a=1" { 393 0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i2 (a=?) (~10 rows)} 394} 395 396# EVIDENCE-OF: R-22253-05302 sqlite> EXPLAIN QUERY PLAN SELECT t1.*, 397# t2.* FROM t1, t2 WHERE t1.a=1 AND t1.b>2; 0|0|0|SEARCH TABLE t1 398# USING COVERING INDEX i2 (a=? AND b>?) (~3 rows) 0|1|1|SCAN TABLE t2 399# (~1000000 rows) 400do_execsql_test 5.4.0 {CREATE TABLE t2(c, d)} 401det 5.4.1 "SELECT t1.*, t2.* FROM t1, t2 WHERE t1.a=1 AND t1.b>2" { 402 0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i2 (a=? AND b>?) (~2 rows)} 403 0 1 1 {SCAN TABLE t2 (~1000000 rows)} 404} 405 406# EVIDENCE-OF: R-21040-07025 sqlite> EXPLAIN QUERY PLAN SELECT t1.*, 407# t2.* FROM t2, t1 WHERE t1.a=1 AND t1.b>2; 0|0|1|SEARCH TABLE t1 408# USING COVERING INDEX i2 (a=? AND b>?) (~3 rows) 0|1|0|SCAN TABLE t2 409# (~1000000 rows) 410det 5.5 "SELECT t1.*, t2.* FROM t2, t1 WHERE t1.a=1 AND t1.b>2" { 411 0 0 1 {SEARCH TABLE t1 USING COVERING INDEX i2 (a=? AND b>?) (~2 rows)} 412 0 1 0 {SCAN TABLE t2 (~1000000 rows)} 413} 414 415# EVIDENCE-OF: R-39007-61103 sqlite> CREATE INDEX i3 ON t1(b); 416# sqlite> EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE a=1 OR b=2; 417# 0|0|0|SEARCH TABLE t1 USING COVERING INDEX i2 (a=?) (~10 rows) 418# 0|0|0|SEARCH TABLE t1 USING INDEX i3 (b=?) (~10 rows) 419do_execsql_test 5.5.0 {CREATE INDEX i3 ON t1(b)} 420det 5.6.1 "SELECT * FROM t1 WHERE a=1 OR b=2" { 421 0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i2 (a=?) (~10 rows)} 422 0 0 0 {SEARCH TABLE t1 USING INDEX i3 (b=?) (~10 rows)} 423} 424 425# EVIDENCE-OF: R-33025-54904 sqlite> EXPLAIN QUERY PLAN SELECT c, d 426# FROM t2 ORDER BY c; 0|0|0|SCAN TABLE t2 (~1000000 rows) 0|0|0|USE TEMP 427# B-TREE FOR ORDER BY 428det 5.7 "SELECT c, d FROM t2 ORDER BY c" { 429 0 0 0 {SCAN TABLE t2 (~1000000 rows)} 430 0 0 0 {USE TEMP B-TREE FOR ORDER BY} 431} 432 433# EVIDENCE-OF: R-38854-22809 sqlite> CREATE INDEX i4 ON t2(c); 434# sqlite> EXPLAIN QUERY PLAN SELECT c, d FROM t2 ORDER BY c; 435# 0|0|0|SCAN TABLE t2 USING INDEX i4 (~1000000 rows) 436do_execsql_test 5.8.0 {CREATE INDEX i4 ON t2(c)} 437det 5.8.1 "SELECT c, d FROM t2 ORDER BY c" { 438 0 0 0 {SCAN TABLE t2 USING INDEX i4 (~1000000 rows)} 439} 440 441# EVIDENCE-OF: R-29884-43993 sqlite> EXPLAIN QUERY PLAN SELECT 442# (SELECT b FROM t1 WHERE a=0), (SELECT a FROM t1 WHERE b=t2.c) FROM t2; 443# 0|0|0|SCAN TABLE t2 (~1000000 rows) 0|0|0|EXECUTE SCALAR SUBQUERY 1 444# 1|0|0|SEARCH TABLE t1 USING COVERING INDEX i2 (a=?) (~10 rows) 445# 0|0|0|EXECUTE CORRELATED SCALAR SUBQUERY 2 2|0|0|SEARCH TABLE t1 USING 446# INDEX i3 (b=?) (~10 rows) 447det 5.9 { 448 SELECT (SELECT b FROM t1 WHERE a=0), (SELECT a FROM t1 WHERE b=t2.c) FROM t2 449} { 450 0 0 0 {SCAN TABLE t2 (~1000000 rows)} 451 0 0 0 {EXECUTE SCALAR SUBQUERY 1} 452 1 0 0 {SEARCH TABLE t1 USING COVERING INDEX i2 (a=?) (~10 rows)} 453 0 0 0 {EXECUTE CORRELATED SCALAR SUBQUERY 2} 454 2 0 0 {SEARCH TABLE t1 USING INDEX i3 (b=?) (~10 rows)} 455} 456 457# EVIDENCE-OF: R-17911-16445 sqlite> EXPLAIN QUERY PLAN SELECT 458# count(*) FROM (SELECT max(b) AS x FROM t1 GROUP BY a) GROUP BY x; 459# 1|0|0|SCAN TABLE t1 USING COVERING INDEX i2 (~1000000 rows) 0|0|0|SCAN 460# SUBQUERY 1 (~1000000 rows) 0|0|0|USE TEMP B-TREE FOR GROUP BY 461det 5.10 { 462 SELECT count(*) FROM (SELECT max(b) AS x FROM t1 GROUP BY a) GROUP BY x 463} { 464 1 0 0 {SCAN TABLE t1 USING COVERING INDEX i2 (~1000000 rows)} 465 0 0 0 {SCAN SUBQUERY 1 (~100 rows)} 466 0 0 0 {USE TEMP B-TREE FOR GROUP BY} 467} 468 469# EVIDENCE-OF: R-18544-33103 sqlite> EXPLAIN QUERY PLAN SELECT * FROM 470# (SELECT * FROM t2 WHERE c=1), t1; 0|0|0|SEARCH TABLE t2 USING INDEX i4 471# (c=?) (~10 rows) 0|1|1|SCAN TABLE t1 (~1000000 rows) 472det 5.11 "SELECT * FROM (SELECT * FROM t2 WHERE c=1), t1" { 473 0 0 0 {SEARCH TABLE t2 USING INDEX i4 (c=?) (~10 rows)} 474 0 1 1 {SCAN TABLE t1 (~1000000 rows)} 475} 476 477# EVIDENCE-OF: R-40701-42164 sqlite> EXPLAIN QUERY PLAN SELECT a FROM 478# t1 UNION SELECT c FROM t2; 1|0|0|SCAN TABLE t1 (~1000000 rows) 479# 2|0|0|SCAN TABLE t2 (~1000000 rows) 0|0|0|COMPOUND SUBQUERIES 1 AND 2 480# USING TEMP B-TREE (UNION) 481det 5.12 "SELECT a FROM t1 UNION SELECT c FROM t2" { 482 1 0 0 {SCAN TABLE t1 (~1000000 rows)} 483 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 484 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 USING TEMP B-TREE (UNION)} 485} 486 487# EVIDENCE-OF: R-61538-24748 sqlite> EXPLAIN QUERY PLAN SELECT a FROM 488# t1 EXCEPT SELECT d FROM t2 ORDER BY 1; 1|0|0|SCAN TABLE t1 USING 489# COVERING INDEX i2 (~1000000 rows) 2|0|0|SCAN TABLE t2 (~1000000 rows) 490# 2|0|0|USE TEMP B-TREE FOR ORDER BY 0|0|0|COMPOUND SUBQUERIES 1 AND 2 491# (EXCEPT) 492det 5.13 "SELECT a FROM t1 EXCEPT SELECT d FROM t2 ORDER BY 1" { 493 1 0 0 {SCAN TABLE t1 USING COVERING INDEX i2 (~1000000 rows)} 494 2 0 0 {SCAN TABLE t2 (~1000000 rows)} 495 2 0 0 {USE TEMP B-TREE FOR ORDER BY} 496 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)} 497} 498 499 500#------------------------------------------------------------------------- 501# The following tests - eqp-6.* - test that the example C code on 502# documentation page eqp.html works. The C code is duplicated in test1.c 503# and wrapped in Tcl command [print_explain_query_plan] 504# 505set boilerplate { 506 proc explain_query_plan {db sql} { 507 set stmt [sqlite3_prepare_v2 db $sql -1 DUMMY] 508 print_explain_query_plan $stmt 509 sqlite3_finalize $stmt 510 } 511 sqlite3 db test.db 512 explain_query_plan db {%SQL%} 513 db close 514 exit 515} 516 517# Do a "Print Explain Query Plan" test. 518proc do_peqp_test {tn sql res} { 519 set fd [open script.tcl w] 520 puts $fd [string map [list %SQL% $sql] $::boilerplate] 521 close $fd 522 523 uplevel do_test $tn [list { 524 set fd [open "|[info nameofexec] script.tcl"] 525 set data [read $fd] 526 close $fd 527 set data 528 }] [list $res] 529} 530 531do_peqp_test 6.1 { 532 SELECT a FROM t1 EXCEPT SELECT d FROM t2 ORDER BY 1 533} [string trimleft { 5341 0 0 SCAN TABLE t1 USING COVERING INDEX i2 (~1000000 rows) 5352 0 0 SCAN TABLE t2 (~1000000 rows) 5362 0 0 USE TEMP B-TREE FOR ORDER BY 5370 0 0 COMPOUND SUBQUERIES 1 AND 2 (EXCEPT) 538}] 539 540#------------------------------------------------------------------------- 541# The following tests - eqp-7.* - test that queries that use the OP_Count 542# optimization return something sensible with EQP. 543# 544drop_all_tables 545 546do_execsql_test 7.0 { 547 CREATE TABLE t1(a, b); 548 CREATE TABLE t2(a, b); 549 CREATE INDEX i1 ON t2(a); 550} 551 552det 7.1 "SELECT count(*) FROM t1" { 553 0 0 0 {SCAN TABLE t1 (~1000000 rows)} 554} 555 556det 7.2 "SELECT count(*) FROM t2" { 557 0 0 0 {SCAN TABLE t2 USING COVERING INDEX i1(~1000000 rows)} 558} 559 560do_execsql_test 7.3 { 561 INSERT INTO t1 VALUES(1, 2); 562 INSERT INTO t1 VALUES(3, 4); 563 564 INSERT INTO t2 VALUES(1, 2); 565 INSERT INTO t2 VALUES(3, 4); 566 INSERT INTO t2 VALUES(5, 6); 567 568 ANALYZE; 569} 570 571db close 572sqlite3 db test.db 573 574det 7.4 "SELECT count(*) FROM t1" { 575 0 0 0 {SCAN TABLE t1 (~2 rows)} 576} 577 578det 7.5 "SELECT count(*) FROM t2" { 579 0 0 0 {SCAN TABLE t2 USING COVERING INDEX i1(~3 rows)} 580} 581 582 583finish_test 584