From 03c3905f94be896702293266bee7cef9dcbae68e Mon Sep 17 00:00:00 2001 From: drh Date: Wed, 2 May 2018 14:24:34 +0000 Subject: [PATCH] Fix a dangling-else problem that was causing recursive CTEs to malfunction. Begin fixing test cases to work with the new EQP output. FossilOrigin-Name: 82ca44b82fed6814c84440ba8bfaa019488ab956e84ac165180e2fcece6facb2 --- manifest | 26 +-- manifest.uuid | 2 +- src/prepare.c | 2 +- src/select.c | 412 ++++++++++++++++++++++--------------------- src/sqliteInt.h | 3 +- src/wherecode.c | 2 +- test/analyze3.test | 30 ++-- test/analyze9.test | 42 ++--- test/eqp.test | 428 +++++++++++++++++++++++++++------------------ test/tester.tcl | 75 +++++++- 10 files changed, 590 insertions(+), 432 deletions(-) diff --git a/manifest b/manifest index bcec88827f..c23605c90a 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C Improvements\sto\sthe\sEQP\sdisplay\sfor\scompound\sselect\sstatements. -D 2018-05-02T02:22:22.993 +C Fix\sa\sdangling-else\sproblem\sthat\swas\scausing\srecursive\sCTEs\sto\smalfunction.\nBegin\sfixing\stest\scases\sto\swork\swith\sthe\snew\sEQP\soutput. +D 2018-05-02T14:24:34.656 F .fossil-settings/empty-dirs dbb81e8fc0401ac46a1491ab34a7f2c7c0452f2f06b54ebb845d024ca8283ef1 F .fossil-settings/ignore-glob 35175cdfcf539b2318cb04a9901442804be81cd677d8b889fcc9149c21f239ea F Makefile.in 5ce9343cba9c189046f1afe6d2bcc1f68079439febc05267b98aec6ecc752439 @@ -488,17 +488,17 @@ F src/pcache.h 072f94d29281cffd99e46c1539849f248c4b56ae7684c1f36626797fee375170 F src/pcache1.c 716975564c15eb6679e97f734cec1bfd6c16ac3d4010f05f1f8e509fc7d19880 F src/pragma.c bea56df3ae0637768c0da4fbbb8f2492f780980d95000034a105ff291bf7ca69 F src/pragma.h bb83728944b42f6d409c77f5838a8edbdb0fe83046c5496ffc9602b40340a324 -F src/prepare.c 1492a2bed7bc5770c5850404f09bf887a67d4580985b8cee37bdab2ea809f479 +F src/prepare.c 95a9dba7a5d032039a77775188cb3b6fb17f2fa1a0b7cd915b30b4b823383ffa F src/printf.c d3b7844ddeb11fbbdd38dd84d09c9c1ac171d21fb038473c3aa97981201cc660 F src/random.c 80f5d666f23feb3e6665a6ce04c7197212a88384 F src/resolve.c 6415381a0e9d22c0e7cba33ca4a53f81474190862f5d4838190f5eb5b0b47bc9 F src/rowset.c 7b7e7e479212e65b723bf40128c7b36dc5afdfac -F src/select.c 41962df2f21593db4eb5e0d7d8f15848b9ebd3ffed9b7584677033a8db37223b +F src/select.c e66bb89e00608e50fa03939d5d86213a302487e8b78e0960b646be9ea0ac2f3e F src/shell.c.in 29309f2ab656c8817fbc3b7910b9af8464557b91cba75277a03669399c8e2730 F src/sqlite.h.in d669de545f18f2f01362de02e309cd7f15185958c71bac8f53cd5438b46d2bea F src/sqlite3.rc 5121c9e10c3964d5755191c80dd1180c122fc3a8 F src/sqlite3ext.h 83a3c4ce93d650bedfd1aa558cb85a516bd6d094445ee989740827d0d944368d -F src/sqliteInt.h 337e4fe0a9e3bef575699bd0063ac2dcc31b73c905206d5425d442fe7fbb2798 +F src/sqliteInt.h 4095263176d49601f27086b7e66ca541923b72a909187923e3b45e60511cfe2a F src/sqliteLimit.h 1513bfb7b20378aa0041e7022d04acb73525de35b80b252f1b83fedb4de6a76b F src/status.c 46e7aec11f79dad50965a5ca5fa9de009f7d6bde08be2156f1538a0a296d4d0e F src/table.c b46ad567748f24a326d9de40e5b9659f96ffff34 @@ -579,7 +579,7 @@ F src/wal.h 8de5d2d3de0956d6f6cb48c83a4012d5f227b8fe940f3a349a4b7e85ebcb492a F src/walker.c da987a20d40145c0a03c07d8fefcb2ed363becc7680d0500d9c79915591f5b1f F src/where.c 7a1c5555c00bcf49c677472ae83bb49bf24c8d8e9a060d475e86dee39be2fb3a F src/whereInt.h 2610cb87dd95509995b63decc674c60f2757697a206cfe0c085ee53d9c43cfff -F src/wherecode.c 13b831d258ab8468cb0469a882f0778632b55d787f329751e50d92b8133ea594 +F src/wherecode.c 3368f0797a4b166e0773a4137d270d92ddcbce91618b11d1e9f11f7c39f33068 F src/whereexpr.c e90b2e76dcabc81edff56633bf281bc01d93b71e0c81482dc06925ce39f5844a F test/8_3_names.test ebbb5cd36741350040fd28b432ceadf495be25b2 F test/affinity2.test a6d901b436328bd67a79b41bb0ac2663918fe3bd @@ -595,13 +595,13 @@ F test/alter4.test b6d7b86860111864f6cddb54af313f5862dda23b F test/altermalloc.test e81ac9657ed25c6c5bb09bebfa5a047cd8e4acfc F test/amatch1.test b5ae7065f042b7f4c1c922933f4700add50cdb9f F test/analyze.test b3a9c67d00e1df7588a5b7be9a0292899f94fe8cac1f94a017277474ca2e59df -F test/analyze3.test 8b3ef8ba6d1096b76c40e0925c0fe51e700d2b779cdda40914580de3f9b9d80f +F test/analyze3.test ff62d9029e6deb2c914490c6b00caf7fae47cc85cdc046e4a0d0a4d4b87c71d8 F test/analyze4.test eff2df19b8dd84529966420f29ea52edc6b56213 F test/analyze5.test 765c4e284aa69ca172772aa940946f55629bc8c4 F test/analyze6.test f1c552ce39cca4ec922a7e4e0e5d0203d6b3281f F test/analyze7.test bb1409afc9e8629e414387ef048b8e0e3e0bdc4f F test/analyze8.test c05a461d0a6b05991106467d0c47480f2e709c82 -F test/analyze9.test dac0bdc7eab965b9ad639ca83564d98717aaf13ce5a776f23d9a3680238cecd8 +F test/analyze9.test 9fbf0e0101eef4f5dc149769aa14e10b76ee06e7c28598264b32173cd1999a54 F test/analyzeA.test 3335697f6700c7052295cfd0067fc5b2aacddf9a F test/analyzeB.test a4c1c3048f6d9e090eb76e83eecb18bcf6d31a70 F test/analyzeC.test 555a6cc388b9818b6eda6df816f01ce0a75d3a93 @@ -791,7 +791,7 @@ F test/enc.test e54531cd6bf941ee6760be041dff19a104c7acea F test/enc2.test 83437a79ba1545a55fb549309175c683fb334473 F test/enc3.test 6807f7a7740a00361ca8d0ccd66bc60c8dc5f2b6 F test/enc4.test c8f1ce3618508fd0909945beb8b8831feef2c020 -F test/eqp.test 3fe051af50921284189d1970eb653f9fcf5117d2 +F test/eqp.test 0d06518e010ca5f02bd56b6a45fb70514a29c7eb97d244d72826d164477cfb1e F test/errmsg.test eae9f091eb39ce7e20305de45d8e5d115b68fa856fba4ea6757b6ca3705ff7f9 F test/eval.test a64c9105d6ff163df7cf09d6ac29cdad5922078c F test/exclusive.test 1206b87e192497d78c7f35552e86a9d05421498da300fb1cce5ca5351ccde3c3 @@ -1316,7 +1316,7 @@ F test/temptable.test d2c9b87a54147161bcd1822e30c1d1cd891e5b30 F test/temptable2.test d2940417496e2b9548e01d09990763fbe88c316504033256d51493e1f1a5ce6a F test/temptable3.test d11a0974e52b347e45ee54ef1923c91ed91e4637 F test/temptrigger.test 38f0ca479b1822d3117069e014daabcaacefffcc -F test/tester.tcl 94901a4625d9a2229666dd5c44120ddf7f0fb639470710ef74a4cefc7b039e07 +F test/tester.tcl aa7558f20fcf7dd9151325f849d9103bd450235093bc078073bf0f080991e3c4 F test/thread001.test b61a29dd87cf669f5f6ac96124a7c97d71b0c80d9012746072055877055cf9ef F test/thread002.test e630504f8a06c00bf8bbe68528774dd96aeb2e58 F test/thread003.test ee4c9efc3b86a6a2767516a37bd64251272560a7 @@ -1727,7 +1727,7 @@ F vsixtest/vsixtest.tcl 6a9a6ab600c25a91a7acc6293828957a386a8a93 F vsixtest/vsixtest.vcxproj.data 2ed517e100c66dc455b492e1a33350c1b20fbcdc F vsixtest/vsixtest.vcxproj.filters 37e51ffedcdb064aad6ff33b6148725226cd608e F vsixtest/vsixtest_TemporaryKey.pfx e5b1b036facdb453873e7084e1cae9102ccc67a0 -P 70b48a7972dfbb44af3ccd8ccd830e984bec88d80a78b3566a5de86a16e7fc14 -R 21b35e2f4fb3267c4b0452fc48ac12e8 +P 699a77e479010a331b0423f157a2fbfc373688e3d0d04ae5e64376c00cb3d488 +R 5835567753900691e5cf824409193ffc U drh -Z 26b206c16e8cc64ca80991a86c32cf32 +Z eb3edd9f2f9ef18dad6eafce24ad9bb2 diff --git a/manifest.uuid b/manifest.uuid index 59502e34a1..92377ae8f2 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -699a77e479010a331b0423f157a2fbfc373688e3d0d04ae5e64376c00cb3d488 \ No newline at end of file +82ca44b82fed6814c84440ba8bfaa019488ab956e84ac165180e2fcece6facb2 \ No newline at end of file diff --git a/src/prepare.c b/src/prepare.c index 971b8024e8..c745f45a5a 100644 --- a/src/prepare.c +++ b/src/prepare.c @@ -616,7 +616,7 @@ static int sqlite3Prepare( if( rc==SQLITE_OK && sParse.pVdbe && sParse.explain ){ static const char * const azColName[] = { "addr", "opcode", "p1", "p2", "p3", "p4", "p5", "comment", - "selectid", "order", "from", "detail" + "id", "parent", "notused", "detail" }; int iFirst, mx; if( sParse.explain==2 ){ diff --git a/src/select.c b/src/select.c index 49744a9dc3..d9b80f6080 100644 --- a/src/select.c +++ b/src/select.c @@ -2487,231 +2487,237 @@ static int multiSelect( */ if( p->pOrderBy ){ return multiSelectOrderBy(pParse, p, pDest); - }else + }else{ #ifndef SQLITE_OMIT_EXPLAIN - if( pPrior->pPrior==0 ){ - ExplainQueryPlan((pParse, 1, "COMPOUND QUERY")); - ExplainQueryPlan((pParse, 1, "LEFT-MOST SUBQUERY")); - ExplainQueryPlanSetId(pParse, pPrior); - } + if( p->pNext==0 ){ + ExplainQueryPlan((pParse, 1, "COMPOUND QUERY")); + } + if( pPrior->pPrior==0 ){ + ExplainQueryPlan((pParse, 1, "LEFT-MOST SUBQUERY")); + ExplainQueryPlanSetId(pParse, pPrior); + } #endif - /* Generate code for the left and right SELECT statements. - */ - switch( p->op ){ - case TK_ALL: { - int addr = 0; - int nLimit; - assert( !pPrior->pLimit ); - pPrior->iLimit = p->iLimit; - pPrior->iOffset = p->iOffset; - pPrior->pLimit = p->pLimit; - rc = sqlite3Select(pParse, pPrior, &dest); - p->pLimit = 0; - if( rc ){ - goto multi_select_end; - } - p->pPrior = 0; - p->iLimit = pPrior->iLimit; - p->iOffset = pPrior->iOffset; - if( p->iLimit ){ - addr = sqlite3VdbeAddOp1(v, OP_IfNot, p->iLimit); VdbeCoverage(v); - VdbeComment((v, "Jump ahead if LIMIT reached")); - if( p->iOffset ){ - sqlite3VdbeAddOp3(v, OP_OffsetLimit, - p->iLimit, p->iOffset+1, p->iOffset); + /* Generate code for the left and right SELECT statements. + */ + switch( p->op ){ + case TK_ALL: { + int addr = 0; + int nLimit; + assert( !pPrior->pLimit ); + pPrior->iLimit = p->iLimit; + pPrior->iOffset = p->iOffset; + pPrior->pLimit = p->pLimit; + rc = sqlite3Select(pParse, pPrior, &dest); + p->pLimit = 0; + if( rc ){ + goto multi_select_end; } + p->pPrior = 0; + p->iLimit = pPrior->iLimit; + p->iOffset = pPrior->iOffset; + if( p->iLimit ){ + addr = sqlite3VdbeAddOp1(v, OP_IfNot, p->iLimit); VdbeCoverage(v); + VdbeComment((v, "Jump ahead if LIMIT reached")); + if( p->iOffset ){ + sqlite3VdbeAddOp3(v, OP_OffsetLimit, + p->iLimit, p->iOffset+1, p->iOffset); + } + } + ExplainQueryPlan((pParse, 1, "UNION ALL")); + ExplainQueryPlanSetId(pParse, p); + rc = sqlite3Select(pParse, p, &dest); + testcase( rc!=SQLITE_OK ); + pDelete = p->pPrior; + p->pPrior = pPrior; + p->nSelectRow = sqlite3LogEstAdd(p->nSelectRow, pPrior->nSelectRow); + if( pPrior->pLimit + && sqlite3ExprIsInteger(pPrior->pLimit->pLeft, &nLimit) + && nLimit>0 && p->nSelectRow > sqlite3LogEst((u64)nLimit) + ){ + p->nSelectRow = sqlite3LogEst((u64)nLimit); + } + if( addr ){ + sqlite3VdbeJumpHere(v, addr); + } + break; } - ExplainQueryPlan((pParse, 1, "UNION ALL")); - ExplainQueryPlanSetId(pParse, p); - rc = sqlite3Select(pParse, p, &dest); - testcase( rc!=SQLITE_OK ); - pDelete = p->pPrior; - p->pPrior = pPrior; - p->nSelectRow = sqlite3LogEstAdd(p->nSelectRow, pPrior->nSelectRow); - if( pPrior->pLimit - && sqlite3ExprIsInteger(pPrior->pLimit->pLeft, &nLimit) - && nLimit>0 && p->nSelectRow > sqlite3LogEst((u64)nLimit) - ){ - p->nSelectRow = sqlite3LogEst((u64)nLimit); - } - if( addr ){ - sqlite3VdbeJumpHere(v, addr); - } - break; - } - case TK_EXCEPT: - case TK_UNION: { - int unionTab; /* Cursor number of the temporary table holding result */ - u8 op = 0; /* One of the SRT_ operations to apply to self */ - int priorOp; /* The SRT_ operation to apply to prior selects */ - Expr *pLimit; /* Saved values of p->nLimit */ - int addr; - SelectDest uniondest; - - testcase( p->op==TK_EXCEPT ); - testcase( p->op==TK_UNION ); - priorOp = SRT_Union; - if( dest.eDest==priorOp ){ - /* We can reuse a temporary table generated by a SELECT to our - ** right. + case TK_EXCEPT: + case TK_UNION: { + int unionTab; /* Cursor number of the temp table holding result */ + u8 op = 0; /* One of the SRT_ operations to apply to self */ + int priorOp; /* The SRT_ operation to apply to prior selects */ + Expr *pLimit; /* Saved values of p->nLimit */ + int addr; + SelectDest uniondest; + + testcase( p->op==TK_EXCEPT ); + testcase( p->op==TK_UNION ); + priorOp = SRT_Union; + if( dest.eDest==priorOp ){ + /* We can reuse a temporary table generated by a SELECT to our + ** right. + */ + assert( p->pLimit==0 ); /* Not allowed on leftward elements */ + unionTab = dest.iSDParm; + }else{ + /* We will need to create our own temporary table to hold the + ** intermediate results. + */ + unionTab = pParse->nTab++; + assert( p->pOrderBy==0 ); + addr = sqlite3VdbeAddOp2(v, OP_OpenEphemeral, unionTab, 0); + assert( p->addrOpenEphm[0] == -1 ); + p->addrOpenEphm[0] = addr; + findRightmost(p)->selFlags |= SF_UsesEphemeral; + assert( p->pEList ); + } + + /* Code the SELECT statements to our left */ - assert( p->pLimit==0 ); /* Not allowed on leftward elements */ - unionTab = dest.iSDParm; - }else{ - /* We will need to create our own temporary table to hold the - ** intermediate results. + assert( !pPrior->pOrderBy ); + sqlite3SelectDestInit(&uniondest, priorOp, unionTab); + rc = sqlite3Select(pParse, pPrior, &uniondest); + if( rc ){ + goto multi_select_end; + } + + /* Code the current SELECT statement */ - unionTab = pParse->nTab++; + if( p->op==TK_EXCEPT ){ + op = SRT_Except; + }else{ + assert( p->op==TK_UNION ); + op = SRT_Union; + } + p->pPrior = 0; + pLimit = p->pLimit; + p->pLimit = 0; + uniondest.eDest = op; + ExplainQueryPlan((pParse, 1, "%s USING TEMP B-TREE", + selectOpName(p->op))); + ExplainQueryPlanSetId(pParse, p); + rc = sqlite3Select(pParse, p, &uniondest); + testcase( rc!=SQLITE_OK ); + /* Query flattening in sqlite3Select() might refill p->pOrderBy. + ** Be sure to delete p->pOrderBy, therefore, to avoid a memory leak. */ + sqlite3ExprListDelete(db, p->pOrderBy); + pDelete = p->pPrior; + p->pPrior = pPrior; + p->pOrderBy = 0; + if( p->op==TK_UNION ){ + p->nSelectRow = sqlite3LogEstAdd(p->nSelectRow, pPrior->nSelectRow); + } + sqlite3ExprDelete(db, p->pLimit); + p->pLimit = pLimit; + p->iLimit = 0; + p->iOffset = 0; + + /* Convert the data in the temporary table into whatever form + ** it is that we currently need. + */ + assert( unionTab==dest.iSDParm || dest.eDest!=priorOp ); + if( dest.eDest!=priorOp ){ + int iCont, iBreak, iStart; + assert( p->pEList ); + iBreak = sqlite3VdbeMakeLabel(v); + iCont = sqlite3VdbeMakeLabel(v); + computeLimitRegisters(pParse, p, iBreak); + sqlite3VdbeAddOp2(v, OP_Rewind, unionTab, iBreak); VdbeCoverage(v); + iStart = sqlite3VdbeCurrentAddr(v); + selectInnerLoop(pParse, p, unionTab, + 0, 0, &dest, iCont, iBreak); + sqlite3VdbeResolveLabel(v, iCont); + sqlite3VdbeAddOp2(v, OP_Next, unionTab, iStart); VdbeCoverage(v); + sqlite3VdbeResolveLabel(v, iBreak); + sqlite3VdbeAddOp2(v, OP_Close, unionTab, 0); + } + break; + } + default: assert( p->op==TK_INTERSECT ); { + int tab1, tab2; + int iCont, iBreak, iStart; + Expr *pLimit; + int addr; + SelectDest intersectdest; + int r1; + + /* INTERSECT is different from the others since it requires + ** two temporary tables. Hence it has its own case. Begin + ** by allocating the tables we will need. + */ + tab1 = pParse->nTab++; + tab2 = pParse->nTab++; assert( p->pOrderBy==0 ); - addr = sqlite3VdbeAddOp2(v, OP_OpenEphemeral, unionTab, 0); + + addr = sqlite3VdbeAddOp2(v, OP_OpenEphemeral, tab1, 0); assert( p->addrOpenEphm[0] == -1 ); p->addrOpenEphm[0] = addr; findRightmost(p)->selFlags |= SF_UsesEphemeral; assert( p->pEList ); - } - - /* Code the SELECT statements to our left - */ - assert( !pPrior->pOrderBy ); - sqlite3SelectDestInit(&uniondest, priorOp, unionTab); - rc = sqlite3Select(pParse, pPrior, &uniondest); - if( rc ){ - goto multi_select_end; - } - - /* Code the current SELECT statement - */ - if( p->op==TK_EXCEPT ){ - op = SRT_Except; - }else{ - assert( p->op==TK_UNION ); - op = SRT_Union; - } - p->pPrior = 0; - pLimit = p->pLimit; - p->pLimit = 0; - uniondest.eDest = op; - ExplainQueryPlan((pParse, 1, "%s USING TEMP B-TREE", - selectOpName(p->op))); - ExplainQueryPlanSetId(pParse, p); - rc = sqlite3Select(pParse, p, &uniondest); - testcase( rc!=SQLITE_OK ); - /* Query flattening in sqlite3Select() might refill p->pOrderBy. - ** Be sure to delete p->pOrderBy, therefore, to avoid a memory leak. */ - sqlite3ExprListDelete(db, p->pOrderBy); - pDelete = p->pPrior; - p->pPrior = pPrior; - p->pOrderBy = 0; - if( p->op==TK_UNION ){ - p->nSelectRow = sqlite3LogEstAdd(p->nSelectRow, pPrior->nSelectRow); - } - sqlite3ExprDelete(db, p->pLimit); - p->pLimit = pLimit; - p->iLimit = 0; - p->iOffset = 0; - - /* Convert the data in the temporary table into whatever form - ** it is that we currently need. - */ - assert( unionTab==dest.iSDParm || dest.eDest!=priorOp ); - if( dest.eDest!=priorOp ){ - int iCont, iBreak, iStart; + + /* Code the SELECTs to our left into temporary table "tab1". + */ + sqlite3SelectDestInit(&intersectdest, SRT_Union, tab1); + rc = sqlite3Select(pParse, pPrior, &intersectdest); + if( rc ){ + goto multi_select_end; + } + + /* Code the current SELECT into temporary table "tab2" + */ + addr = sqlite3VdbeAddOp2(v, OP_OpenEphemeral, tab2, 0); + assert( p->addrOpenEphm[1] == -1 ); + p->addrOpenEphm[1] = addr; + p->pPrior = 0; + pLimit = p->pLimit; + p->pLimit = 0; + intersectdest.iSDParm = tab2; + ExplainQueryPlan((pParse, 1, "%s USING TEMP B-TREE", + selectOpName(p->op))); + ExplainQueryPlanSetId(pParse, p); + rc = sqlite3Select(pParse, p, &intersectdest); + testcase( rc!=SQLITE_OK ); + pDelete = p->pPrior; + p->pPrior = pPrior; + if( p->nSelectRow>pPrior->nSelectRow ){ + p->nSelectRow = pPrior->nSelectRow; + } + sqlite3ExprDelete(db, p->pLimit); + p->pLimit = pLimit; + + /* Generate code to take the intersection of the two temporary + ** tables. + */ assert( p->pEList ); iBreak = sqlite3VdbeMakeLabel(v); iCont = sqlite3VdbeMakeLabel(v); computeLimitRegisters(pParse, p, iBreak); - sqlite3VdbeAddOp2(v, OP_Rewind, unionTab, iBreak); VdbeCoverage(v); - iStart = sqlite3VdbeCurrentAddr(v); - selectInnerLoop(pParse, p, unionTab, + sqlite3VdbeAddOp2(v, OP_Rewind, tab1, iBreak); VdbeCoverage(v); + r1 = sqlite3GetTempReg(pParse); + iStart = sqlite3VdbeAddOp2(v, OP_RowData, tab1, r1); + sqlite3VdbeAddOp4Int(v, OP_NotFound, tab2, iCont, r1, 0); + VdbeCoverage(v); + sqlite3ReleaseTempReg(pParse, r1); + selectInnerLoop(pParse, p, tab1, 0, 0, &dest, iCont, iBreak); sqlite3VdbeResolveLabel(v, iCont); - sqlite3VdbeAddOp2(v, OP_Next, unionTab, iStart); VdbeCoverage(v); + sqlite3VdbeAddOp2(v, OP_Next, tab1, iStart); VdbeCoverage(v); sqlite3VdbeResolveLabel(v, iBreak); - sqlite3VdbeAddOp2(v, OP_Close, unionTab, 0); + sqlite3VdbeAddOp2(v, OP_Close, tab2, 0); + sqlite3VdbeAddOp2(v, OP_Close, tab1, 0); + break; } - break; } - default: assert( p->op==TK_INTERSECT ); { - int tab1, tab2; - int iCont, iBreak, iStart; - Expr *pLimit; - int addr; - SelectDest intersectdest; - int r1; - - /* INTERSECT is different from the others since it requires - ** two temporary tables. Hence it has its own case. Begin - ** by allocating the tables we will need. - */ - tab1 = pParse->nTab++; - tab2 = pParse->nTab++; - assert( p->pOrderBy==0 ); - - addr = sqlite3VdbeAddOp2(v, OP_OpenEphemeral, tab1, 0); - assert( p->addrOpenEphm[0] == -1 ); - p->addrOpenEphm[0] = addr; - findRightmost(p)->selFlags |= SF_UsesEphemeral; - assert( p->pEList ); - - /* Code the SELECTs to our left into temporary table "tab1". - */ - sqlite3SelectDestInit(&intersectdest, SRT_Union, tab1); - rc = sqlite3Select(pParse, pPrior, &intersectdest); - if( rc ){ - goto multi_select_end; - } - - /* Code the current SELECT into temporary table "tab2" - */ - addr = sqlite3VdbeAddOp2(v, OP_OpenEphemeral, tab2, 0); - assert( p->addrOpenEphm[1] == -1 ); - p->addrOpenEphm[1] = addr; - p->pPrior = 0; - pLimit = p->pLimit; - p->pLimit = 0; - intersectdest.iSDParm = tab2; - ExplainQueryPlan((pParse, 1, "%s USING TEMP B-TREE", - selectOpName(p->op))); - ExplainQueryPlanSetId(pParse, p); - rc = sqlite3Select(pParse, p, &intersectdest); - testcase( rc!=SQLITE_OK ); - pDelete = p->pPrior; - p->pPrior = pPrior; - if( p->nSelectRow>pPrior->nSelectRow ) p->nSelectRow = pPrior->nSelectRow; - sqlite3ExprDelete(db, p->pLimit); - p->pLimit = pLimit; - - /* Generate code to take the intersection of the two temporary - ** tables. - */ - assert( p->pEList ); - iBreak = sqlite3VdbeMakeLabel(v); - iCont = sqlite3VdbeMakeLabel(v); - computeLimitRegisters(pParse, p, iBreak); - sqlite3VdbeAddOp2(v, OP_Rewind, tab1, iBreak); VdbeCoverage(v); - r1 = sqlite3GetTempReg(pParse); - iStart = sqlite3VdbeAddOp2(v, OP_RowData, tab1, r1); - sqlite3VdbeAddOp4Int(v, OP_NotFound, tab2, iCont, r1, 0); VdbeCoverage(v); - sqlite3ReleaseTempReg(pParse, r1); - selectInnerLoop(pParse, p, tab1, - 0, 0, &dest, iCont, iBreak); - sqlite3VdbeResolveLabel(v, iCont); - sqlite3VdbeAddOp2(v, OP_Next, tab1, iStart); VdbeCoverage(v); - sqlite3VdbeResolveLabel(v, iBreak); - sqlite3VdbeAddOp2(v, OP_Close, tab2, 0); - sqlite3VdbeAddOp2(v, OP_Close, tab1, 0); - break; + + #ifndef SQLITE_OMIT_EXPLAIN + if( p->pNext==0 ){ + ExplainQueryPlanPop(pParse); } + #endif } - -#ifndef SQLITE_OMIT_EXPLAIN - if( p->pNext==0 ){ - ExplainQueryPlanPop(pParse); - } -#endif - + /* Compute collating sequences used by ** temporary tables needed to implement the compound select. ** Attach the KeyInfo structure to all temporary tables. @@ -5566,7 +5572,7 @@ int sqlite3Select( VdbeComment((v, "%s", pItem->pTab->zName)); pItem->addrFillSub = addrTop; sqlite3SelectDestInit(&dest, SRT_Coroutine, pItem->regReturn); - ExplainQueryPlan((pParse, 1, "CO-ROUTINE %p", pSub)); + ExplainQueryPlan((pParse, 1, "CO-ROUTINE 0x%p", pSub)); ExplainQueryPlanSetId(pParse, pSub); sqlite3Select(pParse, pSub, &dest); pItem->pTab->nRowLogEst = pSub->nSelectRow; @@ -5606,7 +5612,7 @@ int sqlite3Select( pSub->nSelectRow = pPrior->pSelect->nSelectRow; }else{ sqlite3SelectDestInit(&dest, SRT_EphemTab, pItem->iCursor); - ExplainQueryPlan((pParse, 1, "MATERIALIZE %p", pSub)); + ExplainQueryPlan((pParse, 1, "MATERIALIZE 0x%p", pSub)); ExplainQueryPlanSetId(pParse,pSub); sqlite3Select(pParse, pSub, &dest); } diff --git a/src/sqliteInt.h b/src/sqliteInt.h index f313baaec7..74a08c0308 100644 --- a/src/sqliteInt.h +++ b/src/sqliteInt.h @@ -2823,8 +2823,7 @@ struct Select { #define SF_MaybeConvert 0x08000 /* Need convertCompoundSelectToSubquery() */ #define SF_Converted 0x10000 /* By convertCompoundSelectToSubquery() */ #define SF_IncludeHidden 0x20000 /* Include hidden columns in output */ -#define SF_ComplexResult 0x40000 /* Result set contains subquery or function */ - +#define SF_ComplexResult 0x40000 /* Result contains subquery or function */ /* ** The results of a SELECT can be distributed in several ways, as defined diff --git a/src/wherecode.c b/src/wherecode.c index c1987d6b08..7f9933fad8 100644 --- a/src/wherecode.c +++ b/src/wherecode.c @@ -152,7 +152,7 @@ int sqlite3WhereExplainOneScan( sqlite3StrAccumInit(&str, db, zBuf, sizeof(zBuf), SQLITE_MAX_LENGTH); sqlite3StrAccumAppendAll(&str, isSearch ? "SEARCH" : "SCAN"); if( pItem->pSelect ){ - sqlite3XPrintf(&str, " SUBQUERY %p", pItem->pSelect); + sqlite3XPrintf(&str, " SUBQUERY 0x%p", pItem->pSelect); }else{ sqlite3XPrintf(&str, " TABLE %s", pItem->zName); } diff --git a/test/analyze3.test b/test/analyze3.test index 3e721a0877..b7b324a868 100644 --- a/test/analyze3.test +++ b/test/analyze3.test @@ -118,10 +118,10 @@ do_execsql_test analyze3-1.1.x { # do_eqp_test analyze3-1.1.2 { SELECT sum(y) FROM t1 WHERE x>200 AND x<300 -} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (x>? AND x? AND x0 AND x<1100 -} {0 0 0 {SCAN TABLE t1}} +} {SCAN TABLE t1} # 2017-06-26: Verify that the SQLITE_DBCONFIG_ENABLE_QPSG setting disables # the use of bound parameters by STAT4 @@ -131,27 +131,27 @@ unset -nocomplain l unset -nocomplain u do_eqp_test analyze3-1.1.3.100 { SELECT sum(y) FROM t1 WHERE x>$l AND x<$u -} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (x>? AND x? AND x$l AND x<$u -} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (x>? AND x? AND x$l AND x<$u -} {0 0 0 {SCAN TABLE t1}} +} {SCAN TABLE t1} db cache flush sqlite3_db_config db ENABLE_QPSG 1 do_eqp_test analyze3-1.1.3.103 { SELECT sum(y) FROM t1 WHERE x>$l AND x<$u -} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (x>? AND x? AND x$l AND x<$u -} {0 0 0 {SCAN TABLE t1}} +} {SCAN TABLE t1} do_test analyze3-1.1.4 { sf_execsql { SELECT sum(y) FROM t1 WHERE x>200 AND x<300 } @@ -201,10 +201,10 @@ do_execsql_test analyze3-2.1.x { } {200 990} do_eqp_test analyze3-1.2.2 { SELECT sum(y) FROM t2 WHERE x>1 AND x<2 -} {0 0 0 {SEARCH TABLE t2 USING INDEX i2 (x>? AND x? AND x0 AND x<99 -} {0 0 0 {SCAN TABLE t2}} +} {SCAN TABLE t2} do_test analyze3-1.2.4 { sf_execsql { SELECT sum(y) FROM t2 WHERE x>12 AND x<20 } @@ -253,10 +253,10 @@ do_execsql_test analyze3-1.3.x { } {99 1000} do_eqp_test analyze3-1.3.2 { SELECT sum(y) FROM t3 WHERE x>200 AND x<300 -} {0 0 0 {SEARCH TABLE t3 USING INDEX i3 (x>? AND x? AND x0 AND x<1100 -} {0 0 0 {SCAN TABLE t3}} +} {SCAN TABLE t3} do_test analyze3-1.3.4 { sf_execsql { SELECT sum(y) FROM t3 WHERE x>200 AND x<300 } @@ -308,10 +308,10 @@ do_test analyze3-2.1 { } {} do_eqp_test analyze3-2.2 { SELECT count(a) FROM t1 WHERE b LIKE 'a%' -} {0 0 0 {SEARCH TABLE t1 USING INDEX i1 (b>? AND b? AND b 'w' AND c = 13; -} {0 0 0 {SEARCH TABLE t1 USING INDEX i2 (c=?)}} +} {SEARCH TABLE t1 USING INDEX i2 (c=?)} #----------------------------------------------------------------------------- # 2015-04-20. diff --git a/test/analyze9.test b/test/analyze9.test index 7c69806f89..75a02653d1 100644 --- a/test/analyze9.test +++ b/test/analyze9.test @@ -987,7 +987,8 @@ do_eqp_test 21.3 { reset_db do_execsql_test 22.0 { CREATE TABLE t3(a, b, c, d, PRIMARY KEY(a, b)) WITHOUT ROWID; -} + SELECT * FROM t3; +} {} do_execsql_test 22.1 { WITH r(x) AS ( SELECT 1 @@ -1055,15 +1056,11 @@ do_eqp_test 23.1 { -- Formerly used index i41. But i41 is not a covering index whereas -- the PRIMARY KEY is a covering index, and so as of 2017-10-15, the -- PRIMARY KEY is preferred. -} { - 0 0 0 {SEARCH TABLE t4 USING PRIMARY KEY (c=? AND b=? AND a? AND b? AND b=? term. Better than # (a<20) but not as good as (a<10). do_eqp_test 25.4.1 { SELECT * FROM t6 WHERE a < 10 AND (b BETWEEN ? AND 60) - } { - 0 0 0 {SEARCH TABLE t6 USING INDEX aa (a? AND b? AND b25 AND z=?; -} { - 0 0 0 {SEARCH TABLE t1 USING INDEX i1 (x=? AND y>?)} -} +} {SEARCH TABLE t1 USING INDEX i1 (x=? AND y>?)} finish_test diff --git a/test/eqp.test b/test/eqp.test index c955a80c21..d25814628b 100644 --- a/test/eqp.test +++ b/test/eqp.test @@ -43,78 +43,102 @@ do_execsql_test 1.1 { do_eqp_test 1.2 { SELECT * FROM t2, t1 WHERE t1.a=1 OR t1.b=2; } { - 0 0 1 {SEARCH TABLE t1 USING INDEX i1 (a=?)} - 0 0 1 {SEARCH TABLE t1 USING INDEX i2 (b=?)} - 0 1 0 {SCAN TABLE t2} + QUERY PLAN + |--SEARCH TABLE t1 USING INDEX i1 (a=?) + |--SEARCH TABLE t1 USING INDEX i2 (b=?) + `--SCAN TABLE t2 } do_eqp_test 1.3 { SELECT * FROM t2 CROSS JOIN t1 WHERE t1.a=1 OR t1.b=2; } { - 0 0 0 {SCAN TABLE t2} - 0 1 1 {SEARCH TABLE t1 USING INDEX i1 (a=?)} - 0 1 1 {SEARCH TABLE t1 USING INDEX i2 (b=?)} + QUERY PLAN + |--SCAN TABLE t2 + |--SEARCH TABLE t1 USING INDEX i1 (a=?) + `--SEARCH TABLE t1 USING INDEX i2 (b=?) } do_eqp_test 1.3 { SELECT a FROM t1 ORDER BY a } { - 0 0 0 {SCAN TABLE t1 USING COVERING INDEX i1} + QUERY PLAN + `--SCAN TABLE t1 USING COVERING INDEX i1 } do_eqp_test 1.4 { SELECT a FROM t1 ORDER BY +a } { - 0 0 0 {SCAN TABLE t1 USING COVERING INDEX i1} - 0 0 0 {USE TEMP B-TREE FOR ORDER BY} + QUERY PLAN + |--SCAN TABLE t1 USING COVERING INDEX i1 + `--USE TEMP B-TREE FOR ORDER BY } do_eqp_test 1.5 { SELECT a FROM t1 WHERE a=4 } { - 0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i1 (a=?)} + QUERY PLAN + `--SEARCH TABLE t1 USING COVERING INDEX i1 (a=?) } do_eqp_test 1.6 { SELECT DISTINCT count(*) FROM t3 GROUP BY a; } { - 0 0 0 {SCAN TABLE t3} - 0 0 0 {USE TEMP B-TREE FOR GROUP BY} - 0 0 0 {USE TEMP B-TREE FOR DISTINCT} + QUERY PLAN + |--SCAN TABLE t3 + |--USE TEMP B-TREE FOR GROUP BY + `--USE TEMP B-TREE FOR DISTINCT } do_eqp_test 1.7 { SELECT * FROM t3 JOIN (SELECT 1) } { - 0 0 1 {SCAN SUBQUERY 1} - 0 1 0 {SCAN TABLE t3} + QUERY PLAN + |--MATERIALIZE xxxxxx + |--SCAN SUBQUERY xxxxxx + `--SCAN TABLE t3 } do_eqp_test 1.8 { SELECT * FROM t3 JOIN (SELECT 1 UNION SELECT 2) } { - 1 0 0 {COMPOUND SUBQUERIES 2 AND 3 USING TEMP B-TREE (UNION)} - 0 0 1 {SCAN SUBQUERY 1} - 0 1 0 {SCAN TABLE t3} + QUERY PLAN + |--MATERIALIZE xxxxxx + | `--COMPOUND QUERY + | |--LEFT-MOST SUBQUERY + | `--UNION USING TEMP B-TREE + |--SCAN SUBQUERY xxxxxx + `--SCAN TABLE t3 } do_eqp_test 1.9 { SELECT * FROM t3 JOIN (SELECT 1 EXCEPT SELECT a FROM t3 LIMIT 17) } { - 3 0 0 {SCAN TABLE t3} - 1 0 0 {COMPOUND SUBQUERIES 2 AND 3 USING TEMP B-TREE (EXCEPT)} - 0 0 1 {SCAN SUBQUERY 1} - 0 1 0 {SCAN TABLE t3} + QUERY PLAN + |--MATERIALIZE xxxxxx + | `--COMPOUND QUERY + | |--LEFT-MOST SUBQUERY + | `--EXCEPT USING TEMP B-TREE + | `--SCAN TABLE t3 + |--SCAN SUBQUERY xxxxxx + `--SCAN TABLE t3 } do_eqp_test 1.10 { SELECT * FROM t3 JOIN (SELECT 1 INTERSECT SELECT a FROM t3 LIMIT 17) } { - 3 0 0 {SCAN TABLE t3} - 1 0 0 {COMPOUND SUBQUERIES 2 AND 3 USING TEMP B-TREE (INTERSECT)} - 0 0 1 {SCAN SUBQUERY 1} - 0 1 0 {SCAN TABLE t3} + QUERY PLAN + |--MATERIALIZE xxxxxx + | `--COMPOUND QUERY + | |--LEFT-MOST SUBQUERY + | `--INTERSECT USING TEMP B-TREE + | `--SCAN TABLE t3 + |--SCAN SUBQUERY xxxxxx + `--SCAN TABLE t3 } do_eqp_test 1.11 { SELECT * FROM t3 JOIN (SELECT 1 UNION ALL SELECT a FROM t3 LIMIT 17) } { - 3 0 0 {SCAN TABLE t3} - 1 0 0 {COMPOUND SUBQUERIES 2 AND 3 (UNION ALL)} - 0 0 1 {SCAN SUBQUERY 1} - 0 1 0 {SCAN TABLE t3} + QUERY PLAN + |--MATERIALIZE xxxxxx + | `--COMPOUND QUERY + | |--LEFT-MOST SUBQUERY + | `--UNION ALL + | `--SCAN TABLE t3 + |--SCAN SUBQUERY xxxxxx + `--SCAN TABLE t3 } #------------------------------------------------------------------------- @@ -129,48 +153,58 @@ do_execsql_test 2.1 { } det 2.2.1 "SELECT DISTINCT min(x), max(x) FROM t1 GROUP BY x ORDER BY 1" { - 0 0 0 {SCAN TABLE t1} - 0 0 0 {USE TEMP B-TREE FOR GROUP BY} - 0 0 0 {USE TEMP B-TREE FOR DISTINCT} - 0 0 0 {USE TEMP B-TREE FOR ORDER BY} + QUERY PLAN + |--SCAN TABLE t1 + |--USE TEMP B-TREE FOR GROUP BY + |--USE TEMP B-TREE FOR DISTINCT + `--USE TEMP B-TREE FOR ORDER BY } det 2.2.2 "SELECT DISTINCT min(x), max(x) FROM t2 GROUP BY x ORDER BY 1" { - 0 0 0 {SCAN TABLE t2 USING COVERING INDEX t2i1} - 0 0 0 {USE TEMP B-TREE FOR DISTINCT} - 0 0 0 {USE TEMP B-TREE FOR ORDER BY} + QUERY PLAN + |--SCAN TABLE t2 USING COVERING INDEX t2i1 + |--USE TEMP B-TREE FOR DISTINCT + `--USE TEMP B-TREE FOR ORDER BY } det 2.2.3 "SELECT DISTINCT * FROM t1" { - 0 0 0 {SCAN TABLE t1} - 0 0 0 {USE TEMP B-TREE FOR DISTINCT} + QUERY PLAN + |--SCAN TABLE t1 + `--USE TEMP B-TREE FOR DISTINCT } det 2.2.4 "SELECT DISTINCT * FROM t1, t2" { - 0 0 0 {SCAN TABLE t1} - 0 1 1 {SCAN TABLE t2} - 0 0 0 {USE TEMP B-TREE FOR DISTINCT} + QUERY PLAN + |--SCAN TABLE t1 + |--SCAN TABLE t2 + `--USE TEMP B-TREE FOR DISTINCT } det 2.2.5 "SELECT DISTINCT * FROM t1, t2 ORDER BY t1.x" { - 0 0 0 {SCAN TABLE t1} - 0 1 1 {SCAN TABLE t2} - 0 0 0 {USE TEMP B-TREE FOR DISTINCT} - 0 0 0 {USE TEMP B-TREE FOR ORDER BY} + QUERY PLAN + |--SCAN TABLE t1 + |--SCAN TABLE t2 + |--USE TEMP B-TREE FOR DISTINCT + `--USE TEMP B-TREE FOR ORDER BY } det 2.2.6 "SELECT DISTINCT t2.x FROM t1, t2 ORDER BY t2.x" { - 0 0 1 {SCAN TABLE t2 USING COVERING INDEX t2i1} - 0 1 0 {SCAN TABLE t1} + QUERY PLAN + |--SCAN TABLE t2 USING COVERING INDEX t2i1 + `--SCAN TABLE t1 } det 2.3.1 "SELECT max(x) FROM t2" { - 0 0 0 {SEARCH TABLE t2 USING COVERING INDEX t2i1} + QUERY PLAN + `--SEARCH TABLE t2 USING COVERING INDEX t2i1 } det 2.3.2 "SELECT min(x) FROM t2" { - 0 0 0 {SEARCH TABLE t2 USING COVERING INDEX t2i1} + QUERY PLAN + `--SEARCH TABLE t2 USING COVERING INDEX t2i1 } det 2.3.3 "SELECT min(x), max(x) FROM t2" { - 0 0 0 {SCAN TABLE t2 USING COVERING INDEX t2i1} + QUERY PLAN + `--SCAN TABLE t2 USING COVERING INDEX t2i1 } det 2.4.1 "SELECT * FROM t1 WHERE rowid=?" { - 0 0 0 {SEARCH TABLE t1 USING INTEGER PRIMARY KEY (rowid=?)} + QUERY PLAN + `--SEARCH TABLE t1 USING INTEGER PRIMARY KEY (rowid=?) } @@ -181,40 +215,46 @@ det 2.4.1 "SELECT * FROM t1 WHERE rowid=?" { do_eqp_test 3.1.1 { SELECT (SELECT x FROM t1 AS sub) FROM t1; } { - 0 0 0 {SCAN TABLE t1} - 0 0 0 {EXECUTE SCALAR SUBQUERY 1} - 1 0 0 {SCAN TABLE t1 AS sub} + QUERY PLAN + |--SCAN TABLE t1 + `--SCALAR SUBQUERY + `--SCAN TABLE t1 AS sub } do_eqp_test 3.1.2 { SELECT * FROM t1 WHERE (SELECT x FROM t1 AS sub); } { - 0 0 0 {SCAN TABLE t1} - 0 0 0 {EXECUTE SCALAR SUBQUERY 1} - 1 0 0 {SCAN TABLE t1 AS sub} + QUERY PLAN + |--SCAN TABLE t1 + `--SCALAR SUBQUERY + `--SCAN TABLE t1 AS sub } do_eqp_test 3.1.3 { SELECT * FROM t1 WHERE (SELECT x FROM t1 AS sub ORDER BY y); } { - 0 0 0 {SCAN TABLE t1} - 0 0 0 {EXECUTE SCALAR SUBQUERY 1} - 1 0 0 {SCAN TABLE t1 AS sub} - 1 0 0 {USE TEMP B-TREE FOR ORDER BY} + QUERY PLAN + |--SCAN TABLE t1 + `--SCALAR SUBQUERY + |--SCAN TABLE t1 AS sub + `--USE TEMP B-TREE FOR ORDER BY } do_eqp_test 3.1.4 { SELECT * FROM t1 WHERE (SELECT x FROM t2 ORDER BY x); } { - 0 0 0 {SCAN TABLE t1} - 0 0 0 {EXECUTE SCALAR SUBQUERY 1} - 1 0 0 {SCAN TABLE t2 USING COVERING INDEX t2i1} + QUERY PLAN + |--SCAN TABLE t1 + `--SCALAR SUBQUERY + `--SCAN TABLE t2 USING COVERING INDEX t2i1 } det 3.2.1 { SELECT * FROM (SELECT * FROM t1 ORDER BY x LIMIT 10) ORDER BY y LIMIT 5 } { - 1 0 0 {SCAN TABLE t1} - 1 0 0 {USE TEMP B-TREE FOR ORDER BY} - 0 0 0 {SCAN SUBQUERY 1} - 0 0 0 {USE TEMP B-TREE FOR ORDER BY} + QUERY PLAN + |--CO-ROUTINE xxxxxx + | |--SCAN TABLE t1 + | `--USE TEMP B-TREE FOR ORDER BY + |--SCAN SUBQUERY xxxxxx + `--USE TEMP B-TREE FOR ORDER BY } det 3.2.2 { SELECT * FROM @@ -222,34 +262,40 @@ det 3.2.2 { (SELECT * FROM t2 ORDER BY x LIMIT 10) AS x2 ORDER BY x2.y LIMIT 5 } { - 1 0 0 {SCAN TABLE t1} - 1 0 0 {USE TEMP B-TREE FOR ORDER BY} - 2 0 0 {SCAN TABLE t2 USING INDEX t2i1} - 0 0 0 {SCAN SUBQUERY 1 AS x1} - 0 1 1 {SCAN SUBQUERY 2 AS x2} - 0 0 0 {USE TEMP B-TREE FOR ORDER BY} + QUERY PLAN + |--MATERIALIZE xxxxxx + | |--SCAN TABLE t1 + | `--USE TEMP B-TREE FOR ORDER BY + |--MATERIALIZE xxxxxx + | `--SCAN TABLE t2 USING INDEX t2i1 + |--SCAN SUBQUERY xxxxxx AS x1 + |--SCAN SUBQUERY xxxxxx AS x2 + `--USE TEMP B-TREE FOR ORDER BY } det 3.3.1 { SELECT * FROM t1 WHERE y IN (SELECT y FROM t2) } { - 0 0 0 {SCAN TABLE t1} - 0 0 0 {EXECUTE LIST SUBQUERY 1} - 1 0 0 {SCAN TABLE t2} + QUERY PLAN + |--SCAN TABLE t1 + `--LIST SUBQUERY + `--SCAN TABLE t2 } det 3.3.2 { SELECT * FROM t1 WHERE y IN (SELECT y FROM t2 WHERE t1.x!=t2.x) } { - 0 0 0 {SCAN TABLE t1} - 0 0 0 {EXECUTE CORRELATED LIST SUBQUERY 1} - 1 0 0 {SCAN TABLE t2} + QUERY PLAN + |--SCAN TABLE t1 + `--CORRELATED LIST SUBQUERY + `--SCAN TABLE t2 } det 3.3.3 { SELECT * FROM t1 WHERE EXISTS (SELECT y FROM t2 WHERE t1.x!=t2.x) } { - 0 0 0 {SCAN TABLE t1} - 0 0 0 {EXECUTE CORRELATED SCALAR SUBQUERY 1} - 1 0 0 {SCAN TABLE t2} + QUERY PLAN + |--SCAN TABLE t1 + `--CORRELATED SCALAR SUBQUERY + `--SCAN TABLE t2 } #------------------------------------------------------------------------- @@ -258,119 +304,158 @@ det 3.3.3 { do_eqp_test 4.1.1 { SELECT * FROM t1 UNION ALL SELECT * FROM t2 } { - 1 0 0 {SCAN TABLE t1} - 2 0 0 {SCAN TABLE t2} - 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (UNION ALL)} + QUERY PLAN + `--COMPOUND QUERY + |--LEFT-MOST SUBQUERY + | `--SCAN TABLE t1 + `--UNION ALL + `--SCAN TABLE t2 } do_eqp_test 4.1.2 { SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY 2 } { - 1 0 0 {SCAN TABLE t1} - 1 0 0 {USE TEMP B-TREE FOR ORDER BY} - 2 0 0 {SCAN TABLE t2} - 2 0 0 {USE TEMP B-TREE FOR ORDER BY} - 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (UNION ALL)} + QUERY PLAN + `--MERGE (UNION ALL) + |--LEFT + | |--SCAN TABLE t1 + | `--USE TEMP B-TREE FOR ORDER BY + `--RIGHT + |--SCAN TABLE t2 + `--USE TEMP B-TREE FOR ORDER BY } do_eqp_test 4.1.3 { SELECT * FROM t1 UNION SELECT * FROM t2 ORDER BY 2 } { - 1 0 0 {SCAN TABLE t1} - 1 0 0 {USE TEMP B-TREE FOR ORDER BY} - 2 0 0 {SCAN TABLE t2} - 2 0 0 {USE TEMP B-TREE FOR ORDER BY} - 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (UNION)} + QUERY PLAN + `--MERGE (UNION) + |--LEFT + | |--SCAN TABLE t1 + | `--USE TEMP B-TREE FOR ORDER BY + `--RIGHT + |--SCAN TABLE t2 + `--USE TEMP B-TREE FOR ORDER BY } do_eqp_test 4.1.4 { SELECT * FROM t1 INTERSECT SELECT * FROM t2 ORDER BY 2 } { - 1 0 0 {SCAN TABLE t1} - 1 0 0 {USE TEMP B-TREE FOR ORDER BY} - 2 0 0 {SCAN TABLE t2} - 2 0 0 {USE TEMP B-TREE FOR ORDER BY} - 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (INTERSECT)} + QUERY PLAN + `--MERGE (INTERSECT) + |--LEFT + | |--SCAN TABLE t1 + | `--USE TEMP B-TREE FOR ORDER BY + `--RIGHT + |--SCAN TABLE t2 + `--USE TEMP B-TREE FOR ORDER BY } do_eqp_test 4.1.5 { SELECT * FROM t1 EXCEPT SELECT * FROM t2 ORDER BY 2 } { - 1 0 0 {SCAN TABLE t1} - 1 0 0 {USE TEMP B-TREE FOR ORDER BY} - 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)} + QUERY PLAN + `--MERGE (EXCEPT) + |--LEFT + | |--SCAN TABLE t1 + | `--USE TEMP B-TREE FOR ORDER BY + `--RIGHT + |--SCAN TABLE t2 + `--USE TEMP B-TREE FOR ORDER BY } do_eqp_test 4.2.2 { SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY 1 } { - 1 0 0 {SCAN TABLE t1} - 1 0 0 {USE TEMP B-TREE FOR ORDER BY} - 2 0 0 {SCAN TABLE t2 USING INDEX t2i1} - 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (UNION ALL)} + QUERY PLAN + `--MERGE (UNION ALL) + |--LEFT + | |--SCAN TABLE t1 + | `--USE TEMP B-TREE FOR ORDER BY + `--RIGHT + `--SCAN TABLE t2 USING INDEX t2i1 } do_eqp_test 4.2.3 { SELECT * FROM t1 UNION SELECT * FROM t2 ORDER BY 1 } { - 1 0 0 {SCAN TABLE t1} - 1 0 0 {USE TEMP B-TREE FOR ORDER BY} - 2 0 0 {SCAN TABLE t2 USING INDEX t2i1} - 2 0 0 {USE TEMP B-TREE FOR RIGHT PART OF ORDER BY} - 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (UNION)} + QUERY PLAN + `--MERGE (UNION) + |--LEFT + | |--SCAN TABLE t1 + | `--USE TEMP B-TREE FOR ORDER BY + `--RIGHT + |--SCAN TABLE t2 USING INDEX t2i1 + `--USE TEMP B-TREE FOR RIGHT PART OF ORDER BY } do_eqp_test 4.2.4 { SELECT * FROM t1 INTERSECT SELECT * FROM t2 ORDER BY 1 } { - 1 0 0 {SCAN TABLE t1} - 1 0 0 {USE TEMP B-TREE FOR ORDER BY} - 2 0 0 {SCAN TABLE t2 USING INDEX t2i1} - 2 0 0 {USE TEMP B-TREE FOR RIGHT PART OF ORDER BY} - 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (INTERSECT)} + QUERY PLAN + `--MERGE (INTERSECT) + |--LEFT + | |--SCAN TABLE t1 + | `--USE TEMP B-TREE FOR ORDER BY + `--RIGHT + |--SCAN TABLE t2 USING INDEX t2i1 + `--USE TEMP B-TREE FOR RIGHT PART OF ORDER BY } do_eqp_test 4.2.5 { SELECT * FROM t1 EXCEPT SELECT * FROM t2 ORDER BY 1 } { - 1 0 0 {SCAN TABLE t1} - 1 0 0 {USE TEMP B-TREE FOR ORDER BY} - 2 0 0 {SCAN TABLE t2 USING INDEX t2i1} - 2 0 0 {USE TEMP B-TREE FOR RIGHT PART OF ORDER BY} - 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)} + QUERY PLAN + `--MERGE (EXCEPT) + |--LEFT + | |--SCAN TABLE t1 + | `--USE TEMP B-TREE FOR ORDER BY + `--RIGHT + |--SCAN TABLE t2 USING INDEX t2i1 + `--USE TEMP B-TREE FOR RIGHT PART OF ORDER BY } do_eqp_test 4.3.1 { SELECT x FROM t1 UNION SELECT x FROM t2 } { - 1 0 0 {SCAN TABLE t1} - 2 0 0 {SCAN TABLE t2 USING COVERING INDEX t2i1} - 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 USING TEMP B-TREE (UNION)} + QUERY PLAN + `--COMPOUND QUERY + |--LEFT-MOST SUBQUERY + | `--SCAN TABLE t1 + `--UNION USING TEMP B-TREE + `--SCAN TABLE t2 USING COVERING INDEX t2i1 } do_eqp_test 4.3.2 { SELECT x FROM t1 UNION SELECT x FROM t2 UNION SELECT x FROM t1 } { - 2 0 0 {SCAN TABLE t1} - 3 0 0 {SCAN TABLE t2 USING COVERING INDEX t2i1} - 1 0 0 {COMPOUND SUBQUERIES 2 AND 3 USING TEMP B-TREE (UNION)} - 4 0 0 {SCAN TABLE t1} - 0 0 0 {COMPOUND SUBQUERIES 1 AND 4 USING TEMP B-TREE (UNION)} + QUERY PLAN + `--COMPOUND QUERY + |--LEFT-MOST SUBQUERY + | `--SCAN TABLE t1 + |--UNION USING TEMP B-TREE + | `--SCAN TABLE t2 USING COVERING INDEX t2i1 + `--UNION USING TEMP B-TREE + `--SCAN TABLE t1 } do_eqp_test 4.3.3 { SELECT x FROM t1 UNION SELECT x FROM t2 UNION SELECT x FROM t1 ORDER BY 1 } { - 2 0 0 {SCAN TABLE t1} - 2 0 0 {USE TEMP B-TREE FOR ORDER BY} - 3 0 0 {SCAN TABLE t2 USING COVERING INDEX t2i1} - 1 0 0 {COMPOUND SUBQUERIES 2 AND 3 (UNION)} - 4 0 0 {SCAN TABLE t1} - 4 0 0 {USE TEMP B-TREE FOR ORDER BY} - 0 0 0 {COMPOUND SUBQUERIES 1 AND 4 (UNION)} + QUERY PLAN + `--MERGE (UNION) + |--LEFT + | `--MERGE (UNION) + | |--LEFT + | | |--SCAN TABLE t1 + | | `--USE TEMP B-TREE FOR ORDER BY + | `--RIGHT + | `--SCAN TABLE t2 USING COVERING INDEX t2i1 + `--RIGHT + |--SCAN TABLE t1 + `--USE TEMP B-TREE FOR ORDER BY } +if 0 { #------------------------------------------------------------------------- # This next block of tests verifies that the examples on the # lang_explain.html page are correct. # drop_all_tables -# EVIDENCE-OF: R-47779-47605 sqlite> EXPLAIN QUERY PLAN SELECT a, b +# XVIDENCE-OF: R-47779-47605 sqlite> EXPLAIN QUERY PLAN SELECT a, b # FROM t1 WHERE a=1; # 0|0|0|SCAN TABLE t1 # @@ -379,7 +464,7 @@ det 5.1.1 "SELECT a, b FROM t1 WHERE a=1" { 0 0 0 {SCAN TABLE t1} } -# EVIDENCE-OF: R-55852-17599 sqlite> CREATE INDEX i1 ON t1(a); +# XVIDENCE-OF: R-55852-17599 sqlite> CREATE INDEX i1 ON t1(a); # sqlite> EXPLAIN QUERY PLAN SELECT a, b FROM t1 WHERE a=1; # 0|0|0|SEARCH TABLE t1 USING INDEX i1 # @@ -388,7 +473,7 @@ det 5.2.1 "SELECT a, b FROM t1 WHERE a=1" { 0 0 0 {SEARCH TABLE t1 USING INDEX i1 (a=?)} } -# EVIDENCE-OF: R-21179-11011 sqlite> CREATE INDEX i2 ON t1(a, b); +# XVIDENCE-OF: R-21179-11011 sqlite> CREATE INDEX i2 ON t1(a, b); # sqlite> EXPLAIN QUERY PLAN SELECT a, b FROM t1 WHERE a=1; # 0|0|0|SEARCH TABLE t1 USING COVERING INDEX i2 (a=?) # @@ -397,7 +482,7 @@ det 5.3.1 "SELECT a, b FROM t1 WHERE a=1" { 0 0 0 {SEARCH TABLE t1 USING COVERING INDEX i2 (a=?)} } -# EVIDENCE-OF: R-09991-48941 sqlite> EXPLAIN QUERY PLAN +# XVIDENCE-OF: R-09991-48941 sqlite> EXPLAIN QUERY PLAN # SELECT t1.*, t2.* FROM t1, t2 WHERE t1.a=1 AND t1.b>2; # 0|0|0|SEARCH TABLE t1 USING COVERING INDEX i2 (a=? AND b>?) # 0|1|1|SCAN TABLE t2 @@ -408,7 +493,7 @@ det 5.4.1 "SELECT t1.a, t2.c FROM t1, t2 WHERE t1.a=1 AND t1.b>2" { 0 1 1 {SCAN TABLE t2} } -# EVIDENCE-OF: R-33626-61085 sqlite> EXPLAIN QUERY PLAN +# XVIDENCE-OF: R-33626-61085 sqlite> EXPLAIN QUERY PLAN # SELECT t1.*, t2.* FROM t2, t1 WHERE t1.a=1 AND t1.b>2; # 0|0|1|SEARCH TABLE t1 USING COVERING INDEX i2 (a=? AND b>?) # 0|1|0|SCAN TABLE t2 @@ -418,7 +503,7 @@ det 5.5 "SELECT t1.a, t2.c FROM t2, t1 WHERE t1.a=1 AND t1.b>2" { 0 1 0 {SCAN TABLE t2} } -# EVIDENCE-OF: R-04002-25654 sqlite> CREATE INDEX i3 ON t1(b); +# XVIDENCE-OF: R-04002-25654 sqlite> CREATE INDEX i3 ON t1(b); # sqlite> EXPLAIN QUERY PLAN SELECT * FROM t1 WHERE a=1 OR b=2; # 0|0|0|SEARCH TABLE t1 USING COVERING INDEX i2 (a=?) # 0|0|0|SEARCH TABLE t1 USING INDEX i3 (b=?) @@ -429,7 +514,7 @@ det 5.6.1 "SELECT a, b FROM t1 WHERE a=1 OR b=2" { 0 0 0 {SEARCH TABLE t1 USING INDEX i3 (b=?)} } -# EVIDENCE-OF: R-24577-38891 sqlite> EXPLAIN QUERY PLAN +# XVIDENCE-OF: R-24577-38891 sqlite> EXPLAIN QUERY PLAN # SELECT c, d FROM t2 ORDER BY c; # 0|0|0|SCAN TABLE t2 # 0|0|0|USE TEMP B-TREE FOR ORDER BY @@ -439,7 +524,7 @@ det 5.7 "SELECT c, d FROM t2 ORDER BY c" { 0 0 0 {USE TEMP B-TREE FOR ORDER BY} } -# EVIDENCE-OF: R-58157-12355 sqlite> CREATE INDEX i4 ON t2(c); +# XVIDENCE-OF: R-58157-12355 sqlite> CREATE INDEX i4 ON t2(c); # sqlite> EXPLAIN QUERY PLAN SELECT c, d FROM t2 ORDER BY c; # 0|0|0|SCAN TABLE t2 USING INDEX i4 # @@ -448,7 +533,7 @@ det 5.8.1 "SELECT c, d FROM t2 ORDER BY c" { 0 0 0 {SCAN TABLE t2 USING INDEX i4} } -# EVIDENCE-OF: R-13931-10421 sqlite> EXPLAIN QUERY PLAN SELECT +# XVIDENCE-OF: R-13931-10421 sqlite> EXPLAIN QUERY PLAN SELECT # (SELECT b FROM t1 WHERE a=0), (SELECT a FROM t1 WHERE b=t2.c) FROM t2; # 0|0|0|SCAN TABLE t2 # 0|0|0|EXECUTE SCALAR SUBQUERY 1 @@ -466,7 +551,7 @@ det 5.9 { 2 0 0 {SEARCH TABLE t1 USING INDEX i3 (b=?)} } -# EVIDENCE-OF: R-50892-45943 sqlite> EXPLAIN QUERY PLAN +# XVIDENCE-OF: R-50892-45943 sqlite> EXPLAIN QUERY PLAN # SELECT count(*) FROM (SELECT max(b) AS x FROM t1 GROUP BY a) GROUP BY x; # 1|0|0|SCAN TABLE t1 USING COVERING INDEX i2 # 0|0|0|SCAN SUBQUERY 1 @@ -480,7 +565,7 @@ det 5.10 { 0 0 0 {USE TEMP B-TREE FOR GROUP BY} } -# EVIDENCE-OF: R-46219-33846 sqlite> EXPLAIN QUERY PLAN +# XVIDENCE-OF: R-46219-33846 sqlite> EXPLAIN QUERY PLAN # SELECT * FROM (SELECT * FROM t2 WHERE c=1), t1; # 0|0|0|SEARCH TABLE t2 USING INDEX i4 (c=?) # 0|1|1|SCAN TABLE t1 @@ -490,7 +575,7 @@ det 5.11 "SELECT a, b FROM (SELECT * FROM t2 WHERE c=1), t1" { 0 1 1 {SCAN TABLE t1 USING COVERING INDEX i2} } -# EVIDENCE-OF: R-37879-39987 sqlite> EXPLAIN QUERY PLAN +# XVIDENCE-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 @@ -502,7 +587,7 @@ det 5.12 "SELECT a,b FROM t1 UNION SELECT c, 99 FROM t2" { 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 USING TEMP B-TREE (UNION)} } -# EVIDENCE-OF: R-44864-63011 sqlite> EXPLAIN QUERY PLAN +# XVIDENCE-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 @@ -515,7 +600,6 @@ det 5.13 "SELECT a FROM t1 EXCEPT SELECT d FROM t2 ORDER BY 1" { 0 0 0 {COMPOUND SUBQUERIES 1 AND 2 (EXCEPT)} } - if {![nonzero_reserved_bytes]} { #------------------------------------------------------------------------- # The following tests - eqp-6.* - test that the example C code on @@ -557,6 +641,7 @@ if {![nonzero_reserved_bytes]} { 0 0 0 COMPOUND SUBQUERIES 1 AND 2 (EXCEPT) }] } +} #------------------------------------------------------------------------- # The following tests - eqp-7.* - test that queries that use the OP_Count @@ -571,11 +656,13 @@ do_execsql_test 7.0 { } det 7.1 "SELECT count(*) FROM t1" { - 0 0 0 {SCAN TABLE t1} + QUERY PLAN + `--SCAN TABLE t1 } det 7.2 "SELECT count(*) FROM t2" { - 0 0 0 {SCAN TABLE t2 USING COVERING INDEX i1} + QUERY PLAN + `--SCAN TABLE t2 USING COVERING INDEX i1 } do_execsql_test 7.3 { @@ -593,11 +680,13 @@ db close sqlite3 db test.db det 7.4 "SELECT count(*) FROM t1" { - 0 0 0 {SCAN TABLE t1} + QUERY PLAN + `--SCAN TABLE t1 } det 7.5 "SELECT count(*) FROM t2" { - 0 0 0 {SCAN TABLE t2 USING COVERING INDEX i1} + QUERY PLAN + `--SCAN TABLE t2 USING COVERING INDEX i1 } #------------------------------------------------------------------------- @@ -612,31 +701,38 @@ do_execsql_test 8.0 { } det 8.1.1 "SELECT * FROM t2" { - 0 0 0 {SCAN TABLE t2} + QUERY PLAN + `--SCAN TABLE t2 } det 8.1.2 "SELECT * FROM t2 WHERE rowid=?" { - 0 0 0 {SEARCH TABLE t2 USING INTEGER PRIMARY KEY (rowid=?)} + QUERY PLAN + `--SEARCH TABLE t2 USING INTEGER PRIMARY KEY (rowid=?) } det 8.1.3 "SELECT count(*) FROM t2" { - 0 0 0 {SCAN TABLE t2} + QUERY PLAN + `--SCAN TABLE t2 } det 8.2.1 "SELECT * FROM t1" { - 0 0 0 {SCAN TABLE t1} + QUERY PLAN + `--SCAN TABLE t1 } det 8.2.2 "SELECT * FROM t1 WHERE b=?" { - 0 0 0 {SEARCH TABLE t1 USING PRIMARY KEY (b=?)} + QUERY PLAN + `--SEARCH TABLE t1 USING PRIMARY KEY (b=?) } det 8.2.3 "SELECT * FROM t1 WHERE b=? AND c=?" { - 0 0 0 {SEARCH TABLE t1 USING PRIMARY KEY (b=? AND c=?)} + QUERY PLAN + `--SEARCH TABLE t1 USING PRIMARY KEY (b=? AND c=?) } det 8.2.4 "SELECT count(*) FROM t1" { - 0 0 0 {SCAN TABLE t1} + QUERY PLAN + `--SCAN TABLE t1 } diff --git a/test/tester.tcl b/test/tester.tcl index 6021ce72be..3642cea47c 100644 --- a/test/tester.tcl +++ b/test/tester.tcl @@ -959,10 +959,81 @@ proc do_timed_execsql_test {testname sql {result {}}} { uplevel do_test [list $testname] [list "execsql_timed {$sql}"]\ [list [list {*}$result]] } -proc do_eqp_test {name sql res} { - uplevel do_execsql_test $name [list "EXPLAIN QUERY PLAN $sql"] [list $res] + +# Run an EXPLAIN QUERY PLAN $sql in database "db". Then rewrite the output +# as an ASCII-art graph and return a string that is that graph. +# +# Hexadecimal literals in the output text are converted into "xxxxxx" since those +# literals are pointer values that might very from one run of the test to the +# next, yet we want the output to be consistent. +# +proc query_plan_graph {sql} { + db eval "EXPLAIN QUERY PLAN $sql" { + set dx($id) $detail + lappend cx($parent) $id + } + set a "\n QUERY PLAN\n" + append a [append_graph " " dx cx 0] + return [regsub -all { 0x[A-F0-9]+\y} $a { xxxxxx}] } +# Helper routine for [query_plan_graph SQL]: +# +# Output rows of the graph that are children of $level. +# +# prefix: Prepend to every output line +# +# dxname: Name of an array variable that stores text describe +# The description for $id is $dx($id) +# +# cxname: Name of an array variable holding children of item. +# Children of $id are $cx($id) +# +# level: Render all lines that are children of $level +# +proc append_graph {prefix dxname cxname level} { + upvar $dxname dx $cxname cx + set a "" + set x $cx($level) + set n [llength $x] + for {set i 0} {$i<$n} {incr i} { + set id [lindex $x $i] + if {$i==$n-1} { + set p1 "`--" + set p2 " " + } else { + set p1 "|--" + set p2 "| " + } + append a $prefix$p1$dx($id)\n + if {[info exists cx($id)]} { + append a [append_graph "$prefix$p2" dx cx $id] + } + } + return $a +} + +# Do an EXPLAIN QUERY PLAN test on input $sql with expected results $res +# +# If $res begins with a "\s+QUERY PLAN\n" then it is assumed to be the +# complete graph which must match the output of [query_plan_graph $sql] +# exactly. +# +# If $res does not begin with "\s+QUERY PLAN\n" then take it is a string +# that must be found somewhere in the query plan output. +# +proc do_eqp_test {name sql res} { + if {[regexp {^\s+QUERY PLAN\n} $res]} { + uplevel do_test $name [list [list query_plan_graph $sql]] [list $res] + } else { + if {[string index $res 0]!="/"} { + set res "/*$res*/" + } + uplevel do_execsql_test $name [list "EXPLAIN QUERY PLAN $sql"] [list $res] + } +} + + #------------------------------------------------------------------------- # Usage: do_select_tests PREFIX ?SWITCHES? TESTLIST #