From: drh <> Date: Mon, 27 May 2024 21:55:01 +0000 (+0000) Subject: Avoid creating an automatic index on a column that is known to be not very X-Git-Tag: version-3.47.0~377^2 X-Git-Url: http://git.ipfire.org/?a=commitdiff_plain;h=refs%2Fheads%2Fauto-index-improvements;p=thirdparty%2Fsqlite.git Avoid creating an automatic index on a column that is known to be not very selective. FossilOrigin-Name: 70409763f70faa2a0f4f072fd318a687b109a0905cc57906ad7f80d2885fe6d9 --- diff --git a/manifest b/manifest index 4e2cea56dd..d844021f66 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C The\sprevious\scheck-in\swas\sa\slittle\stwo\saggressive\sabout\sskipping\sthe\ninitialization\sof\sentries\sin\sthe\sCellArray.ixNx\sarray.\s\sFixed\shere. -D 2024-05-27T19:52:24.258 +C Avoid\screating\san\sautomatic\sindex\son\sa\scolumn\sthat\sis\sknown\sto\sbe\snot\svery\nselective. +D 2024-05-27T21:55:01.258 F .fossil-settings/empty-dirs dbb81e8fc0401ac46a1491ab34a7f2c7c0452f2f06b54ebb845d024ca8283ef1 F .fossil-settings/ignore-glob 35175cdfcf539b2318cb04a9901442804be81cd677d8b889fcc9149c21f239ea F LICENSE.md df5091916dbb40e6e9686186587125e1b2ff51f022cc334e886c19a0e9982724 @@ -840,7 +840,7 @@ F src/vxworks.h d2988f4e5a61a4dfe82c6524dd3d6e4f2ce3cdb9 F src/wal.c 887fc4ca3f020ebb2e376f222069570834ac63bf50111ef0cbf3ae417048ed89 F src/wal.h ba252daaa94f889f4b2c17c027e823d9be47ce39da1d3799886bbd51f0490452 F src/walker.c 7c7ea0115345851c3da4e04e2e239a29983b61fb5b038b94eede6aba462640e2 -F src/where.c 9b2ab23fcc2198ebcee1e6e840a9ff22350668bd3a99195a5dc7299d5908370a +F src/where.c 555c75e91b44b8f575579eea4f2cf86c419ab4e79e44ce546e399a60cd3020e2 F src/whereInt.h 82a13766f13d1a53b05387c2e60726289ef26404bc7b9b1f7770204d97357fb8 F src/wherecode.c d5184620bcb5265d59072cb66e1386bfe0331a9ce7614286f9ab79a4fcd00fb8 F src/whereexpr.c 67d15caf88a1a9528283d68ff578e024cf9fe810b517bb0343e5aaf695ad97dd @@ -910,7 +910,7 @@ F test/autoanalyze1.test b9cc3f32a990fa56669b668d237c6d53e983554ae80c0604992e188 F test/autoinc.test 997d6f185f138229dc4251583a1d04816423dddc2fc034871a01aeb1d728cb39 F test/autoindex1.test d34caffb0384003ee28eae87679214c029e9be4b332d9649a79e0b94ab70502c F test/autoindex2.test 12ef578928102baaa0dc23ad397601a2f4ecb0df -F test/autoindex3.test dcd6b2f8bed2be67b131e2e671f892e971d934e24fd00988952d0e0a67e24aa7 +F test/autoindex3.test ca502c8050166ac6107a7b4fe4e951f4d3270a23a958af02b14f1b962b83c4b6 F test/autoindex4.test 3c2105e9172920e26f950ba3c5823e4972190e022c1e6f260ba476b0af24c593 F test/autoindex5.test 2ee94f033b87ca0160e08d81034c507aff8e230df2627f0304fa309b2fee19a3 F test/autovacuum.test 00671369bbf96c6a49989a9425f5b78b94075d6a4b031e5e00000c2c32f365df @@ -2193,8 +2193,11 @@ F vsixtest/vsixtest.tcl 6a9a6ab600c25a91a7acc6293828957a386a8a93 F vsixtest/vsixtest.vcxproj.data 2ed517e100c66dc455b492e1a33350c1b20fbcdc F vsixtest/vsixtest.vcxproj.filters 37e51ffedcdb064aad6ff33b6148725226cd608e F vsixtest/vsixtest_TemporaryKey.pfx e5b1b036facdb453873e7084e1cae9102ccc67a0 -P 428aadf0c71473ccb0681b2b7146281c62949ee99556873e49895d44eec7aee5 -R 4ca5c510c21258f08a4799ee1f04b980 +P 1b6d1fbcdecf14bc79dc7b5df50e585d2fcc1484a9987b863c190e8f7ba2c39f +R 33d42e8c7f39f01a63aa7a9a3cae7431 +T *branch * auto-index-improvements +T *sym-auto-index-improvements * +T -sym-trunk * U drh -Z e77b6b7828b797641ee06ff1dc47219a +Z ae3dc9b91b8cb58bdaacbf4b44d36f22 # Remove this line to create a well-formed Fossil manifest. diff --git a/manifest.uuid b/manifest.uuid index 1de423f654..0233074f46 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -1b6d1fbcdecf14bc79dc7b5df50e585d2fcc1484a9987b863c190e8f7ba2c39f \ No newline at end of file +70409763f70faa2a0f4f072fd318a687b109a0905cc57906ad7f80d2885fe6d9 \ No newline at end of file diff --git a/src/where.c b/src/where.c index a266b51d03..accad86251 100644 --- a/src/where.c +++ b/src/where.c @@ -840,6 +840,40 @@ static int constraintCompatibleWithOuterJoin( return 1; } +#ifndef SQLITE_OMIT_AUTOMATIC_INDEX +/* +** Return true if column iCol of table pTab seem like it might be a +** good column to use as part of a query-time index. +** +** Current algorithm (subject to improvement!): +** +** 1. If iCol is already the left-most column of some other index, +** then return false. +** +** 2. If iCol is part of an existing index that has an aiRowLogEst of +** more than 20, then return false. +** +** 3. If no disqualifying conditions above are found, return true. +*/ +static SQLITE_NOINLINE int columnIsGoodIndexCandidate( + const Table *pTab, + int iCol +){ + const Index *pIdx; + for(pIdx = pTab->pIndex; pIdx!=0; pIdx=pIdx->pNext){ + int j; + for(j=0; jnKeyCol; j++){ + if( pIdx->aiColumn[j]==iCol ){ + if( j==0 ) return 0; + if( pIdx->hasStat1 && pIdx->aiRowLogEst[j+1]>20 ) return 0; + break; + } + } + } + return 1; +} +#endif /* SQLITE_OMIT_AUTOMATIC_INDEX */ + #ifndef SQLITE_OMIT_AUTOMATIC_INDEX @@ -854,6 +888,8 @@ static int termCanDriveIndex( const Bitmask notReady /* Tables in outer loops of the join */ ){ char aff; + int leftCol; + if( pTerm->leftCursor!=pSrc->iCursor ) return 0; if( (pTerm->eOperator & (WO_EQ|WO_IS))==0 ) return 0; assert( (pSrc->fg.jointype & JT_RIGHT)==0 ); @@ -864,11 +900,12 @@ static int termCanDriveIndex( } if( (pTerm->prereqRight & notReady)!=0 ) return 0; assert( (pTerm->eOperator & (WO_OR|WO_AND))==0 ); - if( pTerm->u.x.leftColumn<0 ) return 0; - aff = pSrc->pTab->aCol[pTerm->u.x.leftColumn].affinity; + leftCol = pTerm->u.x.leftColumn; + if( leftCol<0 ) return 0; + aff = pSrc->pTab->aCol[leftCol].affinity; if( !sqlite3IndexAffinityOk(pTerm->pExpr, aff) ) return 0; testcase( pTerm->pExpr->op==TK_IS ); - return 1; + return columnIsGoodIndexCandidate(pSrc->pTab, leftCol); } #endif diff --git a/test/autoindex3.test b/test/autoindex3.test index 3da7a70586..aa6aa00128 100644 --- a/test/autoindex3.test +++ b/test/autoindex3.test @@ -90,5 +90,40 @@ do_eqp_test 220 { `--SEARCH u USING AUTOMATIC COVERING INDEX (b=?) } +# 2024-05-27 +# ticket https://sqlite.org/src/tktview/8ff324e120 +# forum post https://sqlite.org/forum/forumpost/b21c2101a559be0a +# +# If an index with STAT1 data indicates that a column is not very +# selective, then do not attempt to create an automatic index on +# that column. +# +reset_db +do_execsql_test 300 { + CREATE TABLE t1(id INTEGER PRIMARY KEY); + CREATE TABLE t2(cid INT, pid INT, rx INT, PRIMARY KEY(cid, pid, rx)); + CREATE INDEX x1 ON t2(pid, rx); + ANALYZE sqlite_schema; + REPLACE INTO sqlite_stat1(tbl, idx, stat) VALUES + ('t2', 'x1', '500000 250 250'), + ('t2','sqlite_autoindex_t2_1','500000 1 1 1'); + ANALYZE sqlite_schema; +} +do_eqp_test 310 { + WITH RECURSIVE children(id) AS ( + SELECT cid FROM t2 WHERE pid = ?1 AND rx = ?2 + UNION + SELECT cid FROM t2 JOIN children ON t2.pid = children.id AND rx = ?2 + ) SELECT count(id) FROM children; +} { + QUERY PLAN + |--CO-ROUTINE children + | |--SETUP + | | `--SEARCH t2 USING INDEX x1 (pid=? AND rx=?) + | `--RECURSIVE STEP + | |--SCAN children + | `--SEARCH t2 USING INDEX x1 (pid=? AND rx=?) + `--SCAN children +} finish_test