Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Comment: | Allow an automatic index to be used if the only uses of declared indexes for the same loop use the skip-scan algorithm. |
---|---|
Downloads: | Tarball | ZIP archive | SQL archive |
Timelines: | family | ancestors | descendants | both | trunk |
Files: | files | file ages | folders |
SHA1: |
c52f7971e90cac1058d6b66c9e334cbc |
User & Date: | drh 2014-11-18 21:45:35 |
Context
2014-11-18
| ||
21:54 | Adding the "noskipscan" token to an sqlite_stat1.stat field prevents an index for being used with the skip-scan algorithm. (check-in: 4461bf04 user: drh tags: trunk) | |
21:45 | Allow an automatic index to be used if the only uses of declared indexes for the same loop use the skip-scan algorithm. (check-in: c52f7971 user: drh tags: trunk) | |
20:49 | Merge in all the other ROLLBACK fixes from the branch-3.8.7 branch. I don't know why I was doing them one-by-one. (check-in: 296b0c73 user: drh tags: trunk) | |
2014-11-14
| ||
19:34 | Consider using an automatic-index for a scan even if there exists a possible skip-scan that uses one or more "=" operators. (Closed-Leaf check-in: 93642a65 user: dan tags: experimental-autoindex-fix) | |
Changes
Changes to src/where.c.
︙ | ︙ | |||
4126 4127 4128 4129 4130 4131 4132 | /* whereLoopAddBtree() always generates and inserts the automatic index ** case first. Hence compatible candidate WhereLoops never have a larger ** rSetup. Call this SETUP-INVARIANT */ assert( p->rSetup>=pTemplate->rSetup ); /* Any loop using an appliation-defined index (or PRIMARY KEY or ** UNIQUE constraint) with one or more == constraints is better | | > | 4126 4127 4128 4129 4130 4131 4132 4133 4134 4135 4136 4137 4138 4139 4140 4141 4142 | /* whereLoopAddBtree() always generates and inserts the automatic index ** case first. Hence compatible candidate WhereLoops never have a larger ** rSetup. Call this SETUP-INVARIANT */ assert( p->rSetup>=pTemplate->rSetup ); /* Any loop using an appliation-defined index (or PRIMARY KEY or ** UNIQUE constraint) with one or more == constraints is better ** than an automatic index. Unless it is a skip-scan. */ if( (p->wsFlags & WHERE_AUTO_INDEX)!=0 && (pTemplate->nSkip)==0 && (pTemplate->wsFlags & WHERE_INDEXED)!=0 && (pTemplate->wsFlags & WHERE_COLUMN_EQ)!=0 && (p->prereq & pTemplate->prereq)==pTemplate->prereq ){ break; } |
︙ | ︙ |
Changes to test/autoindex3.test.
︙ | ︙ | |||
13 14 15 16 17 18 19 20 21 22 23 24 25 26 | # focus of this script is testing automatic index creation logic, # and specifically that an automatic index will not be created that # shadows a declared index. # set testdir [file dirname $argv0] source $testdir/tester.tcl # The t1b and t2d indexes are not very selective. It used to be that # the autoindex mechanism would create automatic indexes on t1(b) or # t2(d), make assumptions that they were reasonably selective, and use # them instead of t1b or t2d. But that would be cheating, because the # automatic index cannot be any more selective than the real index. # | > | 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 | # focus of this script is testing automatic index creation logic, # and specifically that an automatic index will not be created that # shadows a declared index. # set testdir [file dirname $argv0] source $testdir/tester.tcl set testprefix autoindex3 # The t1b and t2d indexes are not very selective. It used to be that # the autoindex mechanism would create automatic indexes on t1(b) or # t2(d), make assumptions that they were reasonably selective, and use # them instead of t1b or t2d. But that would be cheating, because the # automatic index cannot be any more selective than the real index. # |
︙ | ︙ | |||
49 50 51 52 53 54 55 56 57 58 | } {/AUTO/} do_execsql_test autoindex3-130 { EXPLAIN QUERY PLAN SELECT * FROM t1, t2 WHERE d IS NULL AND x=y; } {/AUTO/} do_execsql_test autoindex3-140 { EXPLAIN QUERY PLAN SELECT * FROM t1, t2 WHERE d IN (5,b) AND x=y; } {/AUTO/} finish_test | > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > > | 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 | } {/AUTO/} do_execsql_test autoindex3-130 { EXPLAIN QUERY PLAN SELECT * FROM t1, t2 WHERE d IS NULL AND x=y; } {/AUTO/} do_execsql_test autoindex3-140 { EXPLAIN QUERY PLAN SELECT * FROM t1, t2 WHERE d IN (5,b) AND x=y; } {/AUTO/} reset_db do_execsql_test 210 { CREATE TABLE v(b, d, e); CREATE TABLE u(a, b, c); ANALYZE sqlite_master; INSERT INTO "sqlite_stat1" VALUES('u','uab','40000 400 1'); INSERT INTO "sqlite_stat1" VALUES('v','vbde','40000 400 1 1'); INSERT INTO "sqlite_stat1" VALUES('v','ve','40000 21'); CREATE INDEX uab on u(a, b); CREATE INDEX ve on v(e); CREATE INDEX vbde on v(b,d,e); DROP TABLE IF EXISTS sqlite_stat4; ANALYZE sqlite_master; } # At one point, SQLite was using the inferior plan: # # 0|0|1|SEARCH TABLE v USING INDEX ve (e>?) # 0|1|0|SEARCH TABLE u USING COVERING INDEX uab (ANY(a) AND b=?) # # on the basis that the real index "uab" must be better than the automatic # index. This is not right - a skip-scan is not necessarily better than an # automatic index scan. # do_eqp_test 220 { select count(*) from u, v where u.b = v.b and v.e > 34; } { 0 0 1 {SEARCH TABLE v USING INDEX ve (e>?)} 0 1 0 {SEARCH TABLE u USING AUTOMATIC COVERING INDEX (b=?)} } finish_test |