From 14101a3c28d95680f615a47effad7813a0db353c Mon Sep 17 00:00:00 2001 From: dan Date: Fri, 11 Oct 2024 20:36:26 +0000 Subject: [PATCH] Experimental change to explain query plan to identify covering indexes on expressions. FossilOrigin-Name: 3bb03a2891e30c58b66e3665a8877a8eab4a8bac57ee153d8d31358caeaf4b7c --- manifest | 25 +++++++++-------- manifest.uuid | 2 +- src/where.c | 24 ++++++++++++---- src/whereInt.h | 8 ++++++ src/wherecode.c | 65 ++++++++++++++++++++++++++++++++++---------- test/indexexpr1.test | 24 ++++++++-------- test/indexexpr3.test | 38 ++++++++++++++++++++++++++ 7 files changed, 142 insertions(+), 44 deletions(-) diff --git a/manifest b/manifest index 9e10c216c6..524fb6f6ea 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C Update\scomments\sin\sext/misc/sqlite3_stdio.c\sto\sreflect\sthe\slatest\senhancements.\nNo\schanges\sto\scode. -D 2024-10-11T19:57:41.456 +C Experimental\schange\sto\sexplain\squery\splan\sto\sidentify\scovering\sindexes\son\sexpressions. +D 2024-10-11T20:36:26.974 F .fossil-settings/empty-dirs dbb81e8fc0401ac46a1491ab34a7f2c7c0452f2f06b54ebb845d024ca8283ef1 F .fossil-settings/ignore-glob 35175cdfcf539b2318cb04a9901442804be81cd677d8b889fcc9149c21f239ea F LICENSE.md df5091916dbb40e6e9686186587125e1b2ff51f022cc334e886c19a0e9982724 @@ -855,9 +855,9 @@ F src/vxworks.h d2988f4e5a61a4dfe82c6524dd3d6e4f2ce3cdb9 F src/wal.c a0d42bfdef935e1389737152394d08e59e7c48697f40a9fc2e0552cb19dc731f F src/wal.h ba252daaa94f889f4b2c17c027e823d9be47ce39da1d3799886bbd51f0490452 F src/walker.c d5006d6b005e4ea7302ad390957a8d41ed83faa177e412f89bc5600a7462a014 -F src/where.c 12fe24880901997372b88fd7ca9a21457404ad35201712c02cc57978578abb10 -F src/whereInt.h a5d079c346a658b7a6e9e47bb943d021e02fa1e6aed3b964ca112112a4892192 -F src/wherecode.c 5172d647798134e7c92536ddffe7e530c393d79b5dedd648b88faf2646c65baf +F src/where.c 55defd94b89d6ef9eb9c9a8627a799d1f9ab6f8046c72f97956cd0171e0caa5c +F src/whereInt.h 1e36ec50392f7cc3d93d1152d4338064cd522b87156a0739388b7e273735f0ca +F src/wherecode.c 8a260111af36d827d218118e36ccb8c359f9517f2743f5fe758e51dd9ae4acc7 F src/whereexpr.c 0f93a29cabd3a338d09a1f5c6770620a1ac51ec1157f3229502a7e7767c60b6f F src/window.c 499d48f315a09242dc68f2fac635ed27dcf6bbb0d9ab9084857898c64489e975 F test/8_3_names.test ebbb5cd36741350040fd28b432ceadf495be25b2 @@ -1323,9 +1323,9 @@ F test/index8.test caa097735c91dbc23d8a402f5e63a2a03c83840ba3928733ed7f9a03f8a91 F test/index9.test 2ac891806a4136ef3e91280477e23114e67575207dc331e6797fa0ed9379f997 F test/indexA.test 11d84f6995e6e5b9d8315953fb1b6d29772ee7c7803ee9112715e7e4dd3e4974 F test/indexedby.test f21eca4f7a6ffe14c8500a7ad6cd53166666c99e5ccd311842a28bc94a195fe0 -F test/indexexpr1.test 24fa85a12da384dd1d56f7b24e593c51a8a54b4c5e2e8bbb9e5fdf1099427faf +F test/indexexpr1.test 928671af9d7374bb56ed4dcfbc157f4eeddb1e86ab5615ceb3ac97a713c2dd8f F test/indexexpr2.test 1c382e81ef996d8ae8b834a74f2a9013dddf59214c32201d7c8a656d739f999a -F test/indexexpr3.test 9d893bf440937ebcc1e59c7c9c1505c40c918346a3ddde76a69078f3c733c45d +F test/indexexpr3.test 47b91bc7999805c9a34d356f672259bc49295ecc797448511cae554a309b47cd F test/indexfault.test 98d78a8ff1f5335628b62f886a1cb7c7dac1ef6d48fa39c51ec871c87dce9811 F test/init.test 15c823093fdabbf7b531fe22cf037134d09587a7 F test/insert.test 4e3f0de67aac3c5be1f4aaedbcea11638f1b5cdc9a3115be14d19aa9db7623c6 @@ -2217,8 +2217,11 @@ F vsixtest/vsixtest.tcl 6195aba1f12a5e10efc2b8c0009532167be5e301abe5b31385638080 F vsixtest/vsixtest.vcxproj.data 2ed517e100c66dc455b492e1a33350c1b20fbcdc F vsixtest/vsixtest.vcxproj.filters 37e51ffedcdb064aad6ff33b6148725226cd608e F vsixtest/vsixtest_TemporaryKey.pfx e5b1b036facdb453873e7084e1cae9102ccc67a0 -P a3e16e478b03ccc12888eb5700c2e480a446957368f4b37ed322af2f4c9cd7c4 -R 1291abc09c87e338ea2cfa1281bb85ca -U drh -Z 347c97452247d4e75e184990772431fa +P 9621c3b527702b47799538e028f96945b5697752dbb56078aa7f114c72fd4e1a +R dd12fabe1565dab7ca455bbaabb2f1b1 +T *branch * eqp-covering-index-on-expr +T *sym-eqp-covering-index-on-expr * +T -sym-trunk * +U dan +Z 46f8403a99a7acbc4dd09a2ad01f75a8 # Remove this line to create a well-formed Fossil manifest. diff --git a/manifest.uuid b/manifest.uuid index b9e0ede130..a0470874d6 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -9621c3b527702b47799538e028f96945b5697752dbb56078aa7f114c72fd4e1a +3bb03a2891e30c58b66e3665a8877a8eab4a8bac57ee153d8d31358caeaf4b7c diff --git a/src/where.c b/src/where.c index c2fc338247..e99cdb355b 100644 --- a/src/where.c +++ b/src/where.c @@ -7441,14 +7441,28 @@ void sqlite3WhereEnd(WhereInfo *pWInfo){ pOp->p2 = x; pOp->p1 = pLevel->iIdxCur; OpcodeRewriteTrace(db, k, pOp); - }else{ - /* Unable to translate the table reference into an index - ** reference. Verify that this is harmless - that the - ** table being referenced really is open. - */ + }else if( pLoop->wsFlags & (WHERE_IDX_ONLY|WHERE_EXPRIDX) ){ if( pLoop->wsFlags & WHERE_IDX_ONLY ){ + /* An error. pLoop is supposed to be a covering index loop, + ** and yet the VM code refers to a column of the table that + ** is not part of the index. */ sqlite3ErrorMsg(pParse, "internal query planner error"); pParse->rc = SQLITE_INTERNAL; + }else{ + /* The WHERE_EXPRIDX flag is set by the planner when it is likely + ** that pLoop is a covering index loop, but it is not possible + ** to be 100% sure. In this case, any OP_Explain opcode + ** corresponding to this loop describes the index as a "COVERING + ** INDEX". But, pOp proves that pLoop is not actually a covering + ** index loop. So clear the WHERE_EXPRIDX flag and rewrite the + ** text that accompanies the OP_Explain opcode, if any. */ + pLoop->wsFlags &= ~WHERE_EXPRIDX; + sqlite3WhereAddExplainText(pParse, + pLevel->addrBody-1, + pTabList, + pLevel, + pWInfo->wctrlFlags + ); } } }else if( pOp->opcode==OP_Rowid ){ diff --git a/src/whereInt.h b/src/whereInt.h index 8247528a93..f262b0eebc 100644 --- a/src/whereInt.h +++ b/src/whereInt.h @@ -533,9 +533,17 @@ int sqlite3WhereExplainBloomFilter( const WhereInfo *pWInfo, /* WHERE clause */ const WhereLevel *pLevel /* Bloom filter on this level */ ); +void sqlite3WhereAddExplainText( + Parse *pParse, /* Parse context */ + int addr, + SrcList *pTabList, /* Table list this loop refers to */ + WhereLevel *pLevel, /* Scan to write OP_Explain opcode for */ + u16 wctrlFlags /* Flags passed to sqlite3WhereBegin() */ +); #else # define sqlite3WhereExplainOneScan(u,v,w,x) 0 # define sqlite3WhereExplainBloomFilter(u,v,w) 0 +# define sqlite3WhereAddExplainText(u,v,w,x,y) #endif /* SQLITE_OMIT_EXPLAIN */ #ifdef SQLITE_ENABLE_STMT_SCANSTATUS void sqlite3WhereAddScanStatus( diff --git a/src/wherecode.c b/src/wherecode.c index 0951e5e204..f1c6711af8 100644 --- a/src/wherecode.c +++ b/src/wherecode.c @@ -110,27 +110,24 @@ static void explainIndexRange(StrAccum *pStr, WhereLoop *pLoop){ } /* -** This function is a no-op unless currently processing an EXPLAIN QUERY PLAN -** command, or if stmt_scanstatus_v2() stats are enabled, or if SQLITE_DEBUG -** was defined at compile-time. If it is not a no-op, a single OP_Explain -** opcode is added to the output to describe the table scan strategy in pLevel. -** -** If an OP_Explain opcode is added to the VM, its address is returned. -** Otherwise, if no OP_Explain is coded, zero is returned. +** This function sets the P4 value of an existing OP_Explain opcode to +** text describing the loop in pLevel. If the OP_Explain opcode already has +** a P4 value, it is freed before it is overwritten. */ -int sqlite3WhereExplainOneScan( +void sqlite3WhereAddExplainText( Parse *pParse, /* Parse context */ + int addr, /* Address of OP_Explain opcode */ SrcList *pTabList, /* Table list this loop refers to */ WhereLevel *pLevel, /* Scan to write OP_Explain opcode for */ u16 wctrlFlags /* Flags passed to sqlite3WhereBegin() */ ){ - int ret = 0; #if !defined(SQLITE_DEBUG) if( sqlite3ParseToplevel(pParse)->explain==2 || IS_STMT_SCANSTATUS(pParse->db) ) #endif { + VdbeOp *pOp = sqlite3VdbeGetOp(pParse->pVdbe, addr); + SrcItem *pItem = &pTabList->a[pLevel->iFrom]; - Vdbe *v = pParse->pVdbe; /* VM being constructed */ sqlite3 *db = pParse->db; /* Database handle */ int isSearch; /* True for a SEARCH. False for SCAN. */ WhereLoop *pLoop; /* The controlling WhereLoop object */ @@ -139,9 +136,10 @@ int sqlite3WhereExplainOneScan( StrAccum str; /* EQP output string */ char zBuf[100]; /* Initial space for EQP output string */ + if( db->mallocFailed ) return; + pLoop = pLevel->pWLoop; flags = pLoop->wsFlags; - if( (flags&WHERE_MULTI_OR) || (wctrlFlags&WHERE_OR_SUBCLAUSE) ) return 0; isSearch = (flags&(WHERE_BTM_LIMIT|WHERE_TOP_LIMIT))!=0 || ((flags&WHERE_VIRTUALTABLE)==0 && (pLoop->u.btree.nEq>0)) @@ -165,7 +163,7 @@ int sqlite3WhereExplainOneScan( zFmt = "AUTOMATIC PARTIAL COVERING INDEX"; }else if( flags & WHERE_AUTO_INDEX ){ zFmt = "AUTOMATIC COVERING INDEX"; - }else if( flags & WHERE_IDX_ONLY ){ + }else if( flags & (WHERE_IDX_ONLY|WHERE_EXPRIDX) ){ zFmt = "COVERING INDEX %s"; }else{ zFmt = "INDEX %s"; @@ -219,9 +217,46 @@ int sqlite3WhereExplainOneScan( #endif zMsg = sqlite3StrAccumFinish(&str); sqlite3ExplainBreakpoint("",zMsg); - ret = sqlite3VdbeAddOp4(v, OP_Explain, sqlite3VdbeCurrentAddr(v), - pParse->addrExplain, pLoop->rRun, - zMsg, P4_DYNAMIC); + + assert( pOp->opcode==OP_Explain ); + assert( pOp->p4type==P4_DYNAMIC || pOp->p4.z==0 ); + sqlite3DbFree(db, pOp->p4.z); + pOp->p4type = P4_DYNAMIC; + pOp->p4.z = sqlite3StrAccumFinish(&str); + } +} + + +/* +** This function is a no-op unless currently processing an EXPLAIN QUERY PLAN +** command, or if stmt_scanstatus_v2() stats are enabled, or if SQLITE_DEBUG +** was defined at compile-time. If it is not a no-op, a single OP_Explain +** opcode is added to the output to describe the table scan strategy in pLevel. +** +** If an OP_Explain opcode is added to the VM, its address is returned. +** Otherwise, if no OP_Explain is coded, zero is returned. +*/ +int sqlite3WhereExplainOneScan( + Parse *pParse, /* Parse context */ + SrcList *pTabList, /* Table list this loop refers to */ + WhereLevel *pLevel, /* Scan to write OP_Explain opcode for */ + u16 wctrlFlags /* Flags passed to sqlite3WhereBegin() */ +){ + int ret = 0; +#if !defined(SQLITE_DEBUG) + if( sqlite3ParseToplevel(pParse)->explain==2 || IS_STMT_SCANSTATUS(pParse->db) ) +#endif + { + if( (pLevel->pWLoop->wsFlags & WHERE_MULTI_OR)==0 + && (wctrlFlags & WHERE_OR_SUBCLAUSE)==0 + ){ + Vdbe *v = pParse->pVdbe; + int addr = sqlite3VdbeCurrentAddr(v); + ret = sqlite3VdbeAddOp3( + v, OP_Explain, addr, pParse->addrExplain, pLevel->pWLoop->rRun + ); + sqlite3WhereAddExplainText(pParse, addr, pTabList, pLevel, wctrlFlags); + } } return ret; } diff --git a/test/indexexpr1.test b/test/indexexpr1.test index 3ba59449d5..d5c47e403e 100644 --- a/test/indexexpr1.test +++ b/test/indexexpr1.test @@ -49,7 +49,7 @@ do_execsql_test indexexpr1-130 { do_execsql_test indexexpr1-130eqp { EXPLAIN QUERY PLAN SELECT c FROM t1 WHERE b=1 AND substr(a,2,3)='nd_' ORDER BY c; -} {/USING INDEX t1ba/} +} {/USING COVERING INDEX t1ba/} do_execsql_test indexexpr1-140 { SELECT rowid, substr(a,b,3), '|' FROM t1 ORDER BY 2; @@ -61,7 +61,7 @@ do_execsql_test indexexpr1-141 { do_execsql_test indexexpr1-141eqp { EXPLAIN QUERY PLAN SELECT rowid FROM t1 WHERE substr(a,b,3)<='and' ORDER BY +rowid; -} {/USING INDEX t1abx/} +} {/USING COVERING INDEX t1abx/} do_execsql_test indexexpr1-142 { SELECT rowid FROM t1 WHERE +substr(a,b,3)<='and' ORDER BY +rowid; } {1 2 3} @@ -73,7 +73,7 @@ do_execsql_test indexexpr1-150eqp { EXPLAIN QUERY PLAN SELECT rowid FROM t1 WHERE substr(a,b,3) IN ('and','l_t','xyz') ORDER BY +rowid; -} {/USING INDEX t1abx/} +} {/USING COVERING INDEX t1abx/} ifcapable altertable { do_execsql_test indexexpr1-160 { @@ -99,14 +99,14 @@ do_execsql_test indexexpr1-170 { do_execsql_test indexexpr1-170eqp { EXPLAIN QUERY PLAN SELECT length(a) FROM t1 ORDER BY length(a); -} {/SCAN t1 USING INDEX t1alen/} +} {/SCAN t1 USING COVERING INDEX t1alen/} do_execsql_test indexexpr1-171 { SELECT length(a) FROM t1 ORDER BY length(a) DESC; } {52 38 29 27 25 20} do_execsql_test indexexpr1-171eqp { EXPLAIN QUERY PLAN SELECT length(a) FROM t1 ORDER BY length(a) DESC; -} {/SCAN t1 USING INDEX t1alen/} +} {/SCAN t1 USING COVERING INDEX t1alen/} do_execsql_test indexexpr1-200 { DROP TABLE t1; @@ -142,7 +142,7 @@ do_execsql_test indexexpr1-230 { do_execsql_test indexexpr1-230eqp { EXPLAIN QUERY PLAN SELECT c FROM t1 WHERE b=1 AND substr(a,2,3)='nd_' ORDER BY c; -} {/USING INDEX t1ba/} +} {/USING COVERING INDEX t1ba/} do_execsql_test indexexpr1-240 { SELECT id, substr(a,b,3), '|' FROM t1 ORDER BY 2; @@ -154,7 +154,7 @@ do_execsql_test indexexpr1-241 { do_execsql_test indexexpr1-241eqp { EXPLAIN QUERY PLAN SELECT id FROM t1 WHERE substr(a,b,3)<='and' ORDER BY +id; -} {/USING INDEX t1abx/} +} {/USING COVERING INDEX t1abx/} do_execsql_test indexexpr1-242 { SELECT id FROM t1 WHERE +substr(a,b,3)<='and' ORDER BY +id; } {1 2 3} @@ -166,7 +166,7 @@ do_execsql_test indexexpr1-250eqp { EXPLAIN QUERY PLAN SELECT id FROM t1 WHERE substr(a,b,3) IN ('and','l_t','xyz') ORDER BY +id; -} {/USING INDEX t1abx/} +} {/USING COVERING INDEX t1abx/} ifcapable altertable { do_execsql_test indexexpr1-260 { @@ -238,7 +238,7 @@ do_execsql_test indexexpr1-510 { do_execsql_test indexexpr1-510eqp { EXPLAIN QUERY PLAN SELECT substr(a,4,3) AS k FROM cnt, t5 WHERE k=printf('%03d',x); -} {/USING INDEX t5ax/} +} {/USING COVERING INDEX t5ax/} # Skip-scan on an indexed expression # @@ -547,7 +547,7 @@ do_execsql_test indexexpr1-2030 { (3, '{"x":1}', 6, 7); CREATE INDEX t1x ON t1(d, a, b->>'x', c); } -do_execsql_test indexexpr1-2030 { +do_execsql_test indexexpr1-2040 { SELECT a, SUM(1) AS t1, SUM(CASE WHEN b->>'x'=1 THEN 1 END) AS t2, @@ -555,7 +555,7 @@ do_execsql_test indexexpr1-2030 { SUM(CASE WHEN b->>'x'=1 THEN c END) AS t4 FROM t1; } {1 6 4 54 46} -do_execsql_test indexexpr1-2030 { +do_execsql_test indexexpr1-2050 { explain query plan SELECT a, SUM(1) AS t1, @@ -563,7 +563,7 @@ do_execsql_test indexexpr1-2030 { SUM(c) AS t3, SUM(CASE WHEN b->>'x'=1 THEN c END) AS t4 FROM t1; -} {/.*SCAN t1 USING INDEX t1x.*/} +} {/.*SCAN t1 USING COVERING INDEX t1x.*/} reset_db do_execsql_test indexexpr1-2100 { diff --git a/test/indexexpr3.test b/test/indexexpr3.test index 21e1d329ad..76d3331f75 100644 --- a/test/indexexpr3.test +++ b/test/indexexpr3.test @@ -78,6 +78,44 @@ do_hasfunction_test 1.6 { 2 {{"y":"two"}} } +#------------------------------------------------------------------------- +reset_db +do_execsql_test 2.0 { + CREATE TABLE t1(a, b, j); + CREATE INDEX i1 ON t1( a, json_extract(j, '$.x') ); +} + +do_eqp_test 2.1 { + SELECT json_extract(j, '$.x') FROM t1 WHERE a=? +} { + t1 USING COVERING INDEX i1 +} + +do_eqp_test 2.2 { + SELECT b, json_extract(j, '$.x') FROM t1 WHERE a=? +} { + t1 USING INDEX i1 +} + +do_eqp_test 2.3 { + SELECT json_insert( '{}', json_extract(j, '$.x') ) FROM t1 WHERE a=? +} { + t1 USING INDEX i1 +} + +do_eqp_test 2.4 { + SELECT sum( json_extract(j, '$.x') ) FROM t1 WHERE a=? +} { + t1 USING COVERING INDEX i1 +} + +do_eqp_test 2.5 { + SELECT json_extract(j, '$.x'), sum( json_extract(j, '$.x') ) FROM t1 WHERE a=? +} { + t1 USING INDEX i1 +} + + finish_test