Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Fix test cases so that they work when the query planner uses index size estimates to determine whether or not to try an covering index scan. |
---|---|
Downloads: | Tarball | ZIP archive |
Timelines: | family | ancestors | descendants | both | index-scan-rate |
Files: | files | file ages | folders |
SHA1: |
2f394de88f23dacd3c61e586a4214ffc |
User & Date: | drh 2013-10-04 15:58:59.585 |
Context
2013-10-04
| ||
18:29 | Further refinements of the index scanning speed logic. (check-in: e5d9371da9 user: drh tags: index-scan-rate) | |
15:58 | Fix test cases so that they work when the query planner uses index size estimates to determine whether or not to try an covering index scan. (check-in: 2f394de88f user: drh tags: index-scan-rate) | |
15:30 | Improved estimates of the relative speed of index scans based on declared datatypes of columns in the table. Add "r" column to PRAGMA index_info, showing the estimated relative scan rate. (check-in: 07462bb605 user: drh tags: index-scan-rate) | |
Changes
Changes to test/eqp.test.
︙ | ︙ | |||
492 493 494 495 496 497 498 | # EVIDENCE-OF: R-37879-39987 sqlite> EXPLAIN QUERY PLAN # SELECT a FROM t1 UNION SELECT c FROM t2; # 1|0|0|SCAN TABLE t1 # 2|0|0|SCAN TABLE t2 # 0|0|0|COMPOUND SUBQUERIES 1 AND 2 USING TEMP B-TREE (UNION) # | | | | 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 | # EVIDENCE-OF: R-37879-39987 sqlite> EXPLAIN QUERY PLAN # SELECT a FROM t1 UNION SELECT c FROM t2; # 1|0|0|SCAN TABLE t1 # 2|0|0|SCAN TABLE t2 # 0|0|0|COMPOUND SUBQUERIES 1 AND 2 USING TEMP B-TREE (UNION) # det 5.12 "SELECT a,b FROM t1 UNION SELECT c, 99 FROM t2" { 1 0 0 {SCAN TABLE t1 USING COVERING INDEX i2} 2 0 0 {SCAN TABLE t2 USING COVERING INDEX i4} 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 USING TEMP B-TREE (UNION)} } # EVIDENCE-OF: R-44864-63011 sqlite> EXPLAIN QUERY PLAN # SELECT a FROM t1 EXCEPT SELECT d FROM t2 ORDER BY 1; # 1|0|0|SCAN TABLE t1 USING COVERING INDEX i2 # 2|0|0|SCAN TABLE t2 2|0|0|USE TEMP B-TREE FOR ORDER BY # 0|0|0|COMPOUND SUBQUERIES 1 AND 2 (EXCEPT) # det 5.13 "SELECT a FROM t1 EXCEPT SELECT d FROM t2 ORDER BY 1" { 1 0 0 {SCAN TABLE t1 USING COVERING INDEX i1} 2 0 0 {SCAN TABLE t2} 2 0 0 {USE TEMP B-TREE FOR ORDER BY} 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)} } #------------------------------------------------------------------------- |
︙ | ︙ | |||
544 545 546 547 548 549 550 | set data [read $fd] close $fd set data }] [list $res] } do_peqp_test 6.1 { | | | | | | | | | | 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 | set data [read $fd] close $fd set data }] [list $res] } do_peqp_test 6.1 { SELECT a, b FROM t1 EXCEPT SELECT d, 99 FROM t2 ORDER BY 1 } [string trimleft { 1 0 0 SCAN TABLE t1 USING COVERING INDEX i2 2 0 0 SCAN TABLE t2 2 0 0 USE TEMP B-TREE FOR ORDER BY 0 0 0 COMPOUND SUBQUERIES 1 AND 2 (EXCEPT) }] #------------------------------------------------------------------------- # The following tests - eqp-7.* - test that queries that use the OP_Count # optimization return something sensible with EQP. # drop_all_tables do_execsql_test 7.0 { CREATE TABLE t1(a INT, b INT, ex CHAR(100)); CREATE TABLE t2(a INT, b INT, ex CHAR(100)); CREATE INDEX i1 ON t2(a); } det 7.1 "SELECT count(*) FROM t1" { 0 0 0 {SCAN TABLE t1} } det 7.2 "SELECT count(*) FROM t2" { 0 0 0 {SCAN TABLE t2 USING COVERING INDEX i1} } do_execsql_test 7.3 { INSERT INTO t1(a,b) VALUES(1, 2); INSERT INTO t1(a,b) VALUES(3, 4); INSERT INTO t2(a,b) VALUES(1, 2); INSERT INTO t2(a,b) VALUES(3, 4); INSERT INTO t2(a,b) VALUES(5, 6); ANALYZE; } db close sqlite3 db test.db |
︙ | ︙ |
Changes to test/subquery.test.
︙ | ︙ | |||
241 242 243 244 245 246 247 | } {10.0} do_test subquery-2.5.3.2 { # Verify that the t4i index was not used in the previous query execsql { EXPLAIN QUERY PLAN SELECT * FROM t4 WHERE x IN (SELECT a FROM t3); } | | | 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 | } {10.0} do_test subquery-2.5.3.2 { # Verify that the t4i index was not used in the previous query execsql { EXPLAIN QUERY PLAN SELECT * FROM t4 WHERE x IN (SELECT a FROM t3); } } {~/t4i/} do_test subquery-2.5.4 { execsql { DROP TABLE t3; DROP TABLE t4; } } {} |
︙ | ︙ |
Changes to test/tkt-78e04e52ea.test.
︙ | ︙ | |||
14 15 16 17 18 19 20 | # set testdir [file dirname $argv0] source $testdir/tester.tcl do_test tkt-78e04-1.0 { execsql { | | | | | | | | 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 | # set testdir [file dirname $argv0] source $testdir/tester.tcl do_test tkt-78e04-1.0 { execsql { CREATE TABLE ""("" UNIQUE, x CHAR(100)); CREATE TABLE t2(x); INSERT INTO ""("") VALUES(1); INSERT INTO t2 VALUES(2); SELECT * FROM "", t2; } } {1 {} 2} do_test tkt-78e04-1.1 { catchsql { INSERT INTO ""("") VALUES(1); } } {1 {column is not unique}} do_test tkt-78e04-1.2 { execsql { PRAGMA table_info(""); } } {0 {} {} 0 {} 0 1 x CHAR(100) 0 {} 0} do_test tkt-78e04-1.3 { execsql { CREATE INDEX i1 ON ""("" COLLATE nocase); } } {} do_test tkt-78e04-1.4 { execsql { EXPLAIN QUERY PLAN SELECT "" FROM "" WHERE "" LIKE 'abc%'; } } {0 0 0 {SCAN TABLE USING COVERING INDEX i1}} do_test tkt-78e04-1.5 { execsql { DROP TABLE ""; SELECT name FROM sqlite_master; } |
︙ | ︙ |
Changes to test/where.test.
︙ | ︙ | |||
1121 1122 1123 1124 1125 1126 1127 | # # When optimizing out ORDER BY clauses, make sure that trailing terms # of the ORDER BY clause do not reference other tables in a join. # if {[permutation] != "no_optimization"} { do_test where-14.1 { execsql { | | | | | 1121 1122 1123 1124 1125 1126 1127 1128 1129 1130 1131 1132 1133 1134 1135 1136 1137 | # # When optimizing out ORDER BY clauses, make sure that trailing terms # of the ORDER BY clause do not reference other tables in a join. # if {[permutation] != "no_optimization"} { do_test where-14.1 { execsql { CREATE TABLE t8(a INTEGER PRIMARY KEY, b TEXT UNIQUE, c CHAR(100)); INSERT INTO t8(a,b) VALUES(1,'one'); INSERT INTO t8(a,b) VALUES(4,'four'); } cksort { SELECT x.a || '/' || y.a FROM t8 x, t8 y ORDER BY x.a, y.b } } {1/4 1/1 4/4 4/1 nosort} do_test where-14.2 { cksort { |
︙ | ︙ |
Changes to test/where2.test.
︙ | ︙ | |||
310 311 312 313 314 315 316 | if {[permutation] != "no_optimization"} { # Ticket #2249. Make sure the OR optimization is not attempted if # comparisons between columns of different affinities are needed. # do_test where2-6.7 { execsql { | | | | | | | | | | | | | | | | > | > | > | | 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 | if {[permutation] != "no_optimization"} { # Ticket #2249. Make sure the OR optimization is not attempted if # comparisons between columns of different affinities are needed. # do_test where2-6.7 { execsql { CREATE TABLE t2249a(a TEXT UNIQUE, x CHAR(100)); CREATE TABLE t2249b(b INTEGER); INSERT INTO t2249a(a) VALUES('0123'); INSERT INTO t2249b VALUES(123); } queryplan { -- Because a is type TEXT and b is type INTEGER, both a and b -- will attempt to convert to NUMERIC before the comparison. -- They will thus compare equal. -- SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=b; } } {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1} do_test where2-6.9 { queryplan { -- The + operator removes affinity from the rhs. No conversions -- occur and the comparison is false. The result is an empty set. -- SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=+b; } } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1} do_test where2-6.9.2 { # The same thing but with the expression flipped around. queryplan { SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE +b=a } } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1} do_test where2-6.10 { queryplan { -- Use + on both sides of the comparison to disable indices -- completely. Make sure we get the same result. -- SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE +a=+b; } } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1} do_test where2-6.11 { # This will not attempt the OR optimization because of the a=b # comparison. queryplan { SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=b OR a='hello'; } } {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1} do_test where2-6.11.2 { # Permutations of the expression terms. queryplan { SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE b=a OR a='hello'; } } {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1} do_test where2-6.11.3 { # Permutations of the expression terms. queryplan { SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE 'hello'=a OR b=a; } } {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1} do_test where2-6.11.4 { # Permutations of the expression terms. queryplan { SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a='hello' OR b=a; } } {123 0123 nosort t2249b * t2249a sqlite_autoindex_t2249a_1} ifcapable explain&&subquery { # These tests are not run if subquery support is not included in the # build. This is because these tests test the "a = 1 OR a = 2" to # "a IN (1, 2)" optimisation transformation, which is not enabled if # subqueries and the IN operator is not available. # do_test where2-6.12 { # In this case, the +b disables the affinity conflict and allows # the OR optimization to be used again. The result is now an empty # set, the same as in where2-6.9. queryplan { SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=+b OR a='hello'; } } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1} do_test where2-6.12.2 { # In this case, the +b disables the affinity conflict and allows # the OR optimization to be used again. The result is now an empty # set, the same as in where2-6.9. queryplan { SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a='hello' OR +b=a; } } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1} do_test where2-6.12.3 { # In this case, the +b disables the affinity conflict and allows # the OR optimization to be used again. The result is now an empty # set, the same as in where2-6.9. queryplan { SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE +b=a OR a='hello'; } } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1} do_test where2-6.13 { # The addition of +a on the second term disabled the OR optimization. # But we should still get the same empty-set result as in where2-6.9. queryplan { SELECT b,a FROM t2249b CROSS JOIN t2249a WHERE a=+b OR +a='hello'; } } {nosort t2249b * t2249a sqlite_autoindex_t2249a_1} } # Variations on the order of terms in a WHERE clause in order # to make sure the OR optimizer can recognize them all. do_test where2-6.20 { queryplan { SELECT x.a, y.a FROM t2249a x CROSS JOIN t2249a y WHERE x.a=y.a } } {0123 0123 nosort x sqlite_autoindex_t2249a_1 y sqlite_autoindex_t2249a_1} ifcapable explain&&subquery { # These tests are not run if subquery support is not included in the # build. This is because these tests test the "a = 1 OR a = 2" to # "a IN (1, 2)" optimisation transformation, which is not enabled if # subqueries and the IN operator is not available. # do_test where2-6.21 { queryplan { SELECT x.a,y.a FROM t2249a x CROSS JOIN t2249a y WHERE x.a=y.a OR y.a='hello' } } {0123 0123 nosort x sqlite_autoindex_t2249a_1 y sqlite_autoindex_t2249a_1} do_test where2-6.22 { queryplan { SELECT x.a,y.a FROM t2249a x CROSS JOIN t2249a y WHERE y.a=x.a OR y.a='hello' } } {0123 0123 nosort x sqlite_autoindex_t2249a_1 y sqlite_autoindex_t2249a_1} do_test where2-6.23 { queryplan { SELECT x.a,y.a FROM t2249a x CROSS JOIN t2249a y WHERE y.a='hello' OR x.a=y.a } } {0123 0123 nosort x sqlite_autoindex_t2249a_1 y sqlite_autoindex_t2249a_1} } # Unique queries (queries that are guaranteed to return only a single # row of result) do not call the sorter. But all tables must give # a unique result. If any one table in the join does not give a unique |
︙ | ︙ | |||
699 700 701 702 703 704 705 | } } {4 8 10} # Verify that the OR clause is used in an outer loop even when # the OR clause scores slightly better on an inner loop. if {[permutation] != "no_optimization"} { do_execsql_test where2-12.1 { | | | 702 703 704 705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 | } } {4 8 10} # Verify that the OR clause is used in an outer loop even when # the OR clause scores slightly better on an inner loop. if {[permutation] != "no_optimization"} { do_execsql_test where2-12.1 { CREATE TABLE t12(x INTEGER PRIMARY KEY, y INT, z CHAR(100)); CREATE INDEX t12y ON t12(y); EXPLAIN QUERY PLAN SELECT a.x, b.x FROM t12 AS a JOIN t12 AS b ON a.y=b.x WHERE (b.x=$abc OR b.y=$abc); } {/.*SEARCH TABLE t12 AS b .*SEARCH TABLE t12 AS b .*/} } finish_test |