Experimental changes to EXPLAIN QUERY PLAN.

FossilOrigin-Name: f4747eb83dacce6430ad6e5eb20155ffad975514
This commit is contained in:
dan 2010-11-08 19:01:16 +00:00
parent 0596beec9f
commit 2ce224535f
8 changed files with 363 additions and 66 deletions

View File

@ -1,5 +1,5 @@
C Fix\sto\sxTruncate\sand\smore\sjournal\smode\stests\sfor\sthe\smultiplex\sVFS.
D 2010-11-05T20:50:44
C Experimental\schanges\sto\sEXPLAIN\sQUERY\sPLAN.
D 2010-11-08T19:01:16
F Makefile.arm-wince-mingw32ce-gcc d6df77f1f48d690bd73162294bbba7f59507c72f
F Makefile.in e7a59672eaeb04408d1fa8501618d7501a3c5e39
F Makefile.linux-gcc 91d710bdc4998cb015f39edf3cb314ec4f4d7e23
@ -169,16 +169,16 @@ F src/pcache.c 09d38c44ab275db581f7a2f6ff8b9bc7f8c0faaa
F src/pcache.h c683390d50f856d4cd8e24342ae62027d1bb6050
F src/pcache1.c e9578a3beac26f229ee558a4e16c863f2498185f
F src/pragma.c 216d12e4546e65ca6cfcd3221e64573889ae8f34
F src/prepare.c ce4c35a2b1d5fe916e4a46b70d24a6e997d7c4c6
F src/prepare.c c2b318037d626fed27905c9446730b560637217a
F src/printf.c 8ae5082dd38a1b5456030c3755ec3a392cd51506
F src/random.c cd4a67b3953b88019f8cd4ccd81394a8ddfaba50
F src/resolve.c 1c0f32b64f8e3f555fe1f732f9d6f501a7f05706
F src/rowset.c 69afa95a97c524ba6faf3805e717b5b7ae85a697
F src/select.c a03ec6a313ef8311f081ee478f96ae04ff691608
F src/select.c c32d6da90895abe7ede0c18377c756d706f25e41
F src/shell.c 8517fc1f9c59ae4007e6cc8b9af91ab231ea2056
F src/sqlite.h.in f47e09412fc9a129f759fa4d96ef21f4b3d529eb
F src/sqlite3ext.h c90bd5507099f62043832d73f6425d8d5c5da754
F src/sqliteInt.h c63b0340dfdfde18ff255ddccf004edd2d073288
F src/sqliteInt.h 7349903d18e2444e38414aa6da86b9d32ae1af92
F src/sqliteLimit.h a17dcd3fb775d63b64a43a55c54cb282f9726f44
F src/status.c 496913d4e8441195f6f2a75b1c95993a45b9b30b
F src/table.c 2cd62736f845d82200acfa1287e33feb3c15d62e
@ -231,7 +231,7 @@ F src/vdbe.c e1aa917961e69f71c80f46ce231b496d3c841ae1
F src/vdbe.h 4de0efb4b0fdaaa900cf419b35c458933ef1c6d2
F src/vdbeInt.h 7f4cf1b2b69bef3a432b1f23dfebef57275436b4
F src/vdbeapi.c 5368714fa750270cf6430160287c21adff44582d
F src/vdbeaux.c de0b06b11a25293e820a49159eca9f1c51a64716
F src/vdbeaux.c 762c2b146cf5fe7a7f743af1bbfed4a966aa937a
F src/vdbeblob.c e0ce3c54cc0c183af2ec67b63a289acf92251df4
F src/vdbemem.c 23723a12cd3ba7ab3099193094cbb2eb78956aa9
F src/vdbetrace.c 864cef96919323482ebd9986f2132435115e9cc2
@ -239,7 +239,7 @@ F src/vtab.c b297e8fa656ab5e66244ab15680d68db0adbec30
F src/wal.c f26b8d297bd11cb792e609917f9d4c6718ac8e0e
F src/wal.h c1aac6593a0b02b15dc625987e619edeab39292e
F src/walker.c 3112bb3afe1d85dc52317cb1d752055e9a781f8f
F src/where.c d9a31eb3d59466b6c53567c8c9a6c2fe68bbd565
F src/where.c ddfe0e1ac1a2c9d382b1df5bd6f9e2b0282ecc39
F test/aggerror.test a867e273ef9e3d7919f03ef4f0e8c0d2767944f2
F test/alias.test 4529fbc152f190268a15f9384a5651bbbabc9d87
F test/all.test 6745008c144bd2956d58864d21f7b304689c1cce
@ -365,6 +365,7 @@ F test/enc.test e54531cd6bf941ee6760be041dff19a104c7acea
F test/enc2.test 6d91a5286f59add0cfcbb2d0da913b76f2242398
F test/enc3.test 5c550d59ff31dccdba5d1a02ae11c7047d77c041
F test/enc4.test 4b575ef09e0eff896e73bd24076f96c2aa6a42de
F test/eqp.test d8ad22f65ad29c93708e8986c568b5b6ef043dce
F test/eval.test bc269c365ba877554948441e91ad5373f9f91be3
F test/exclusive.test 53e1841b422e554cecf0160f937c473d6d0e3062
F test/exclusive2.test 76e63c05349cb70d09d60b99d2ae625525ff5155
@ -885,7 +886,10 @@ F tool/speedtest2.tcl ee2149167303ba8e95af97873c575c3e0fab58ff
F tool/speedtest8.c 2902c46588c40b55661e471d7a86e4dd71a18224
F tool/speedtest8inst1.c 293327bc76823f473684d589a8160bde1f52c14e
F tool/vdbe-compress.tcl d70ea6d8a19e3571d7ab8c9b75cba86d1173ff0f
P 72ba3e368bec34532ec7b5e856a4daa7e1c8cccb
R 0042c6a8b282a3f9ef09bfa98caed3ba
U shaneh
Z 7b8161cae1f9c054697e43cb6ccb5f60
P 65fa1164f035d270db48db6474da888aacfba3bd
R 5aabb390d1e5d171e6d1ec14ea681c6d
T *branch * experimental
T *sym-experimental *
T -sym-trunk *
U dan
Z 0909e073f28cae2ed26163f9bcbdaa3d

View File

@ -1 +1 @@
65fa1164f035d270db48db6474da888aacfba3bd
f4747eb83dacce6430ad6e5eb20155ffad975514

View File

@ -628,13 +628,13 @@ static int sqlite3Prepare(
if( rc==SQLITE_OK && pParse->pVdbe && pParse->explain ){
static const char * const azColName[] = {
"addr", "opcode", "p1", "p2", "p3", "p4", "p5", "comment",
"order", "from", "detail"
"selectid", "order", "from", "detail"
};
int iFirst, mx;
if( pParse->explain==2 ){
sqlite3VdbeSetNumCols(pParse->pVdbe, 3);
sqlite3VdbeSetNumCols(pParse->pVdbe, 4);
iFirst = 8;
mx = 11;
mx = 12;
}else{
sqlite3VdbeSetNumCols(pParse->pVdbe, 8);
iFirst = 0;

View File

@ -771,6 +771,19 @@ static KeyInfo *keyInfoFromExprList(Parse *pParse, ExprList *pList){
return pInfo;
}
#ifndef SQLITE_OMIT_EXPLAIN
static void explainTempTable(Parse *pParse, const char *zUsage){
if( pParse->explain==2 ){
Vdbe *v = pParse->pVdbe;
char *zMsg = sqlite3MPrintf(pParse->db, "USE TEMP B-TREE FOR %s", zUsage);
sqlite3VdbeAddOp4(v, OP_Explain, pParse->iSelectId, 0, 0, zMsg, P4_DYNAMIC);
}
}
# define explainRestoreSelectId() pParse->iSelectId = iRestoreSelectId
#else
# define explainRestoreSelectId()
# define explainTempTable(y,z)
#endif
/*
** If the inner loop was generated using a non-null pOrderBy argument,
@ -3590,6 +3603,11 @@ int sqlite3Select(
int iEnd; /* Address of the end of the query */
sqlite3 *db; /* The database connection */
#ifndef SQLITE_OMIT_EXPLAIN
int iRestoreSelectId = pParse->iSelectId;
pParse->iSelectId = pParse->iNextSelectId++;
#endif
db = pParse->db;
if( p==0 || db->mallocFailed || pParse->nErr ){
return 1;
@ -3696,9 +3714,10 @@ int sqlite3Select(
mxSelect = db->aLimit[SQLITE_LIMIT_COMPOUND_SELECT];
if( mxSelect && cnt>mxSelect ){
sqlite3ErrorMsg(pParse, "too many terms in compound SELECT");
return 1;
goto select_end;
}
}
explainRestoreSelectId();
return multiSelect(pParse, p, pDest);
}
#endif
@ -3711,7 +3730,6 @@ int sqlite3Select(
p->pGroupBy = sqlite3ExprListDup(db, p->pEList, 0);
pGroupBy = p->pGroupBy;
p->selFlags &= ~SF_Distinct;
isDistinct = 0;
}
/* If there is both a GROUP BY and an ORDER BY clause and they are
@ -3758,7 +3776,7 @@ int sqlite3Select(
/* Open a virtual index to use for the distinct set.
*/
if( isDistinct ){
if( p->selFlags & SF_Distinct ){
KeyInfo *pKeyInfo;
assert( isAgg || pGroupBy );
distinct = pParse->nTab++;
@ -3917,6 +3935,9 @@ int sqlite3Select(
int nCol;
int nGroupBy;
explainTempTable(pParse,
isDistinct && !(p->selFlags&SF_Distinct)?"DISTINCT":"GROUP BY");
groupBySort = 1;
nGroupBy = pGroupBy->nExpr;
nCol = nGroupBy + 1;
@ -4178,10 +4199,15 @@ int sqlite3Select(
} /* endif aggregate query */
if( distinct>=0 ){
explainTempTable(pParse, "DISTINCT");
}
/* If there is an ORDER BY clause, then we need to sort the results
** and send them to the callback one by one.
*/
if( pOrderBy ){
explainTempTable(pParse, "ORDER BY");
generateSortTail(pParse, p, v, pEList->nExpr, pDest);
}
@ -4198,6 +4224,7 @@ int sqlite3Select(
** successful coding of the SELECT.
*/
select_end:
explainRestoreSelectId();
/* Identify column names if results of the SELECT are to be output.
*/

View File

@ -1859,6 +1859,7 @@ struct SrcList {
struct WherePlan {
u32 wsFlags; /* WHERE_* flags that describe the strategy */
u32 nEq; /* Number of == constraints */
double nRow; /* Estimated number of rows (for EQP) */
union {
Index *pIdx; /* Index when WHERE_INDEXED is true */
struct WhereTerm *pTerm; /* WHERE clause term for OR-search */
@ -2213,6 +2214,11 @@ struct Parse {
int nHeight; /* Expression tree height of current sub-select */
Table *pZombieTab; /* List of Table objects to delete after code gen */
TriggerPrg *pTriggerPrg; /* Linked list of coded triggers */
#ifndef SQLITE_OMIT_EXPLAIN
int iSelectId;
int iNextSelectId;
#endif
};
#ifdef SQLITE_OMIT_VIRTUALTABLE

View File

@ -1182,12 +1182,10 @@ int sqlite3VdbeList(
pMem->type = SQLITE_INTEGER;
pMem++;
if( p->explain==1 ){
pMem->flags = MEM_Int;
pMem->u.i = pOp->p3; /* P3 */
pMem->type = SQLITE_INTEGER;
pMem++;
}
pMem->flags = MEM_Int;
pMem->u.i = pOp->p3; /* P3 */
pMem->type = SQLITE_INTEGER;
pMem++;
if( sqlite3VdbeMemGrow(pMem, 32, 0) ){ /* P4 */
assert( p->db->mallocFailed );
@ -1232,7 +1230,7 @@ int sqlite3VdbeList(
}
}
p->nResColumn = 8 - 5*(p->explain-1);
p->nResColumn = 8 - 4*(p->explain-1);
p->rc = SQLITE_OK;
rc = SQLITE_ROW;
}

View File

@ -192,7 +192,6 @@ struct WhereMaskSet {
struct WhereCost {
WherePlan plan; /* The lookup strategy */
double rCost; /* Overall cost of pursuing this search strategy */
double nRow; /* Estimated number of output rows */
Bitmask used; /* Bitmask of cursors used by this plan */
};
@ -1621,7 +1620,7 @@ static void bestOrClauseIndex(
continue;
}
rTotal += sTermCost.rCost;
nRow += sTermCost.nRow;
nRow += sTermCost.plan.nRow;
used |= sTermCost.used;
if( rTotal>=pCost->rCost ) break;
}
@ -1640,8 +1639,8 @@ static void bestOrClauseIndex(
WHERETRACE(("... multi-index OR cost=%.9g nrow=%.9g\n", rTotal, nRow));
if( rTotal<pCost->rCost ){
pCost->rCost = rTotal;
pCost->nRow = nRow;
pCost->used = used;
pCost->plan.nRow = nRow;
pCost->plan.wsFlags = flags;
pCost->plan.u.pTerm = pTerm;
}
@ -1725,7 +1724,7 @@ static void bestAutomaticIndex(
WHERETRACE(("auto-index reduces cost from %.2f to %.2f\n",
pCost->rCost, costTempIdx));
pCost->rCost = costTempIdx;
pCost->nRow = logN + 1;
pCost->plan.nRow = logN + 1;
pCost->plan.wsFlags = WHERE_TEMP_INDEX;
pCost->used = pTerm->prereqRight;
break;
@ -2798,11 +2797,11 @@ static void bestBtreeIndex(
** index and its cost in the pCost structure.
*/
if( (!pIdx || wsFlags)
&& (cost<pCost->rCost || (cost<=pCost->rCost && nRow<pCost->nRow))
&& (cost<pCost->rCost || (cost<=pCost->rCost && nRow<pCost->plan.nRow))
){
pCost->rCost = cost;
pCost->nRow = nRow;
pCost->used = used;
pCost->plan.nRow = nRow;
pCost->plan.wsFlags = (wsFlags&wsFlagMask);
pCost->plan.nEq = nEq;
pCost->plan.u.pIdx = pIdx;
@ -3131,6 +3130,98 @@ static int codeAllEqualityTerms(
return regBase;
}
#ifndef SQLITE_OMIT_EXPLAIN
static char *indexRangeText(sqlite3 *db, WhereLevel *pLevel, Table *pTab){
WherePlan *pPlan = &pLevel->plan;
Index *pIndex = pPlan->u.pIdx;
int nEq = pPlan->nEq;
char *zRet = 0;
int i;
for(i=0; i<nEq; i++){
char *zCol = pTab->aCol[pIndex->aiColumn[i]].zName;
zRet = sqlite3MAppendf(db, zRet,
"%s%s%s=?", (zRet?zRet:""), (zRet?" AND ":""), zCol);
}
if( pPlan->wsFlags&WHERE_BTM_LIMIT ){
zRet = sqlite3MAppendf(db, zRet,
"%s%s%s>?", (zRet?zRet:""), (zRet?" AND ":""), pTab->aCol[nEq].zName);
}
if( pPlan->wsFlags&WHERE_TOP_LIMIT ){
zRet = sqlite3MAppendf(db, zRet,
"%s%s%s<?", (zRet?zRet:""), (zRet?" AND ":""), pTab->aCol[nEq].zName);
}
if( zRet ){
zRet = sqlite3MAppendf(db, zRet, " (%s)", zRet);
}
return zRet;
}
static void codeOneLoopExplain(
Parse *pParse, /* Parse context */
SrcList *pTabList, /* Table list this loop refers to */
WhereLevel *pLevel, /* Scan to write OP_Explain opcode for */
int iLevel, /* Value for "level" column of output */
int iFrom /* Value for "from" column of output */
){
if( pParse->explain==2 ){
u32 flags = pLevel->plan.wsFlags;
struct SrcList_item *pItem = &pTabList->a[pLevel->iFrom];
Vdbe *v = pParse->pVdbe;
sqlite3 *db = pParse->db;
char *zMsg;
if( flags & WHERE_MULTI_OR ) return;
zMsg = sqlite3MPrintf(db, "TABLE %s", pItem->zName);
if( pItem->zAlias ){
zMsg = sqlite3MAppendf(db, zMsg, "%s AS %s", zMsg, pItem->zAlias);
}
if( (flags & WHERE_INDEXED)!=0 ){
char *zWhere = indexRangeText(db, pLevel, pItem->pTab);
zMsg = sqlite3MAppendf(db, zMsg, "%s WITH %s%sINDEX%s%s%s", zMsg,
((flags & WHERE_TEMP_INDEX)?"AUTOMATIC ":""),
((flags & WHERE_IDX_ONLY)?"COVERING ":""),
((flags & WHERE_TEMP_INDEX)?"":" "),
((flags & WHERE_TEMP_INDEX)?"": pLevel->plan.u.pIdx->zName),
zWhere
);
sqlite3DbFree(db, zWhere);
}else if( flags & (WHERE_ROWID_EQ|WHERE_ROWID_RANGE) ){
zMsg = sqlite3MAppendf(db, zMsg, "%s USING INTEGER PRIMARY KEY", zMsg);
if( flags&WHERE_ROWID_EQ ){
zMsg = sqlite3MAppendf(db, zMsg, "%s (rowid=?)", zMsg);
}else if( flags&WHERE_BTM_LIMIT && flags&WHERE_TOP_LIMIT ){
zMsg = sqlite3MAppendf(db, zMsg, "%s (rowid>? AND rowid<?)", zMsg);
}else if( flags&WHERE_BTM_LIMIT ){
zMsg = sqlite3MAppendf(db, zMsg, "%s (rowid>?)", zMsg);
}else if( flags&WHERE_TOP_LIMIT ){
zMsg = sqlite3MAppendf(db, zMsg, "%s (rowid<?)", zMsg);
}
}
#ifndef SQLITE_OMIT_VIRTUALTABLE
else if( (flags & WHERE_VIRTUALTABLE)!=0 ){
sqlite3_index_info *pVtabIdx = pLevel->plan.u.pVtabIdx;
zMsg = sqlite3MAppendf(db, zMsg, "%s VIRTUAL TABLE INDEX %d:%s", zMsg,
pVtabIdx->idxNum, pVtabIdx->idxStr);
}
#endif
zMsg = sqlite3MAppendf(db, zMsg,
"%s (~%lld rows)", zMsg, (sqlite3_int64)(pLevel->plan.nRow)
);
sqlite3VdbeAddOp4(
v, OP_Explain, pParse->iSelectId, iLevel, iFrom, zMsg, P4_DYNAMIC);
}
}
#else
# define codeOneLoopExplain(w,x,y.z)
#endif /* SQLITE_OMIT_EXPLAIN */
/*
** Generate code for the start of the iLevel-th loop in the WHERE clause
** implementation described by pWInfo.
@ -3672,6 +3763,9 @@ static Bitmask codeOneLoopStart(
WHERE_OMIT_OPEN | WHERE_OMIT_CLOSE |
WHERE_FORCE_TABLE | WHERE_ONETABLE_ONLY);
if( pSubWInfo ){
codeOneLoopExplain(
pParse, pOrTab, &pSubWInfo->a[0], iLevel, pLevel->iFrom
);
if( (wctrlFlags & WHERE_DUPLICATES_OK)==0 ){
int iSet = ((ii==pOrWc->nTerm-1)?-1:ii);
int r;
@ -4184,11 +4278,12 @@ WhereInfo *sqlite3WhereBegin(
&& (nUnconstrained==0 || pTabItem->pIndex==0 /* (3) */
|| NEVER((sCost.plan.wsFlags & WHERE_NOT_FULLSCAN)!=0))
&& (bestJ<0 || sCost.rCost<bestPlan.rCost /* (4) */
|| (sCost.rCost<=bestPlan.rCost && sCost.nRow<bestPlan.nRow))
|| (sCost.rCost<=bestPlan.rCost
&& sCost.plan.nRow<bestPlan.plan.nRow))
){
WHERETRACE(("=== table %d is best so far"
" with cost=%g and nRow=%g\n",
j, sCost.rCost, sCost.nRow));
j, sCost.rCost, sCost.plan.nRow));
bestPlan = sCost;
bestJ = j;
}
@ -4199,7 +4294,7 @@ WhereInfo *sqlite3WhereBegin(
assert( notReady & getMask(pMaskSet, pTabList->a[bestJ].iCursor) );
WHERETRACE(("*** Optimizer selects table %d for loop %d"
" with cost=%g and nRow=%g\n",
bestJ, pLevel-pWInfo->a, bestPlan.rCost, bestPlan.nRow));
bestJ, pLevel-pWInfo->a, bestPlan.rCost, bestPlan.plan.nRow));
if( (bestPlan.plan.wsFlags & WHERE_ORDERBY)!=0 ){
*ppOrderBy = 0;
}
@ -4214,7 +4309,9 @@ WhereInfo *sqlite3WhereBegin(
}
notReady &= ~getMask(pMaskSet, pTabList->a[bestJ].iCursor);
pLevel->iFrom = (u8)bestJ;
if( bestPlan.nRow>=(double)1 ) pParse->nQueryLoop *= bestPlan.nRow;
if( bestPlan.plan.nRow>=(double)1 ){
pParse->nQueryLoop *= bestPlan.plan.nRow;
}
/* Check that if the table scanned by this loop iteration had an
** INDEXED BY clause attached to it, that the named index is being
@ -4266,37 +4363,6 @@ WhereInfo *sqlite3WhereBegin(
Table *pTab; /* Table to open */
int iDb; /* Index of database containing table/index */
#ifndef SQLITE_OMIT_EXPLAIN
if( pParse->explain==2 ){
char *zMsg;
struct SrcList_item *pItem = &pTabList->a[pLevel->iFrom];
zMsg = sqlite3MPrintf(db, "TABLE %s", pItem->zName);
if( pItem->zAlias ){
zMsg = sqlite3MAppendf(db, zMsg, "%s AS %s", zMsg, pItem->zAlias);
}
if( (pLevel->plan.wsFlags & WHERE_TEMP_INDEX)!=0 ){
zMsg = sqlite3MAppendf(db, zMsg, "%s WITH AUTOMATIC INDEX", zMsg);
}else if( (pLevel->plan.wsFlags & WHERE_INDEXED)!=0 ){
zMsg = sqlite3MAppendf(db, zMsg, "%s WITH INDEX %s",
zMsg, pLevel->plan.u.pIdx->zName);
}else if( pLevel->plan.wsFlags & WHERE_MULTI_OR ){
zMsg = sqlite3MAppendf(db, zMsg, "%s VIA MULTI-INDEX UNION", zMsg);
}else if( pLevel->plan.wsFlags & (WHERE_ROWID_EQ|WHERE_ROWID_RANGE) ){
zMsg = sqlite3MAppendf(db, zMsg, "%s USING PRIMARY KEY", zMsg);
}
#ifndef SQLITE_OMIT_VIRTUALTABLE
else if( (pLevel->plan.wsFlags & WHERE_VIRTUALTABLE)!=0 ){
sqlite3_index_info *pVtabIdx = pLevel->plan.u.pVtabIdx;
zMsg = sqlite3MAppendf(db, zMsg, "%s VIRTUAL TABLE INDEX %d:%s", zMsg,
pVtabIdx->idxNum, pVtabIdx->idxStr);
}
#endif
if( pLevel->plan.wsFlags & WHERE_ORDERBY ){
zMsg = sqlite3MAppendf(db, zMsg, "%s ORDER BY", zMsg);
}
sqlite3VdbeAddOp4(v, OP_Explain, i, pLevel->iFrom, 0, zMsg, P4_DYNAMIC);
}
#endif /* SQLITE_OMIT_EXPLAIN */
pTabItem = &pTabList->a[pLevel->iFrom];
pTab = pTabItem->pTab;
pLevel->iTabCur = pTabItem->iCursor;
@ -4355,6 +4421,9 @@ WhereInfo *sqlite3WhereBegin(
*/
notReady = ~(Bitmask)0;
for(i=0; i<nTabList; i++){
if( (wctrlFlags&WHERE_ONETABLE_ONLY)==0 ){
codeOneLoopExplain(pParse, pTabList, &pWInfo->a[i],i,pWInfo->a[i].iFrom);
}
notReady = codeOneLoopStart(pWInfo, i, wctrlFlags, notReady);
pWInfo->iContinue = pWInfo->a[i].addrCont;
}

193
test/eqp.test Normal file
View File

@ -0,0 +1,193 @@
# 2010 November 6
#
# The author disclaims copyright to this source code. In place of
# a legal notice, here is a blessing:
#
# May you do good and not evil.
# May you find forgiveness for yourself and forgive others.
# May you share freely, never taking more than you give.
#
#***********************************************************************
#
set testdir [file dirname $argv0]
source $testdir/tester.tcl
set testprefix eqp
#-------------------------------------------------------------------------
#
# eqp-1.*: Assorted tests.
# eqp-2.*: Tests for single select statements.
# eqp-3.*: Select statements that execute sub-selects.
# eqp-4.*: Compound select statements.
#
proc do_eqp_test {name sql res} {
set res [list {*}$res]
uplevel do_execsql_test $name [list "EXPLAIN QUERY PLAN $sql"] [list $res]
}
do_execsql_test 1.1 {
CREATE TABLE t1(a, b);
CREATE INDEX i1 ON t1(a);
CREATE INDEX i2 ON t1(b);
CREATE TABLE t2(a, b);
CREATE TABLE t3(a, b);
}
do_eqp_test 1.2 {
SELECT * FROM t2, t1 WHERE t1.a=1 OR t1.b=2;
} {
0 0 1 {TABLE t1 WITH INDEX i1 (a=?) (~10 rows)}
0 0 1 {TABLE t1 WITH INDEX i2 (b=?) (~10 rows)}
0 1 0 {TABLE t2 (~1000000 rows)}
}
do_eqp_test 1.3 {
SELECT * FROM t2 CROSS JOIN t1 WHERE t1.a=1 OR t1.b=2;
} {
0 0 0 {TABLE t2 (~1000000 rows)}
0 1 1 {TABLE t1 WITH INDEX i1 (a=?) (~10 rows)}
0 1 1 {TABLE t1 WITH INDEX i2 (b=?) (~10 rows)}
}
do_eqp_test 1.3 {
SELECT a FROM t1 ORDER BY a
} {
0 0 0 {TABLE t1 WITH COVERING INDEX i1 (~1000000 rows)}
}
do_eqp_test 1.4 {
SELECT a FROM t1 ORDER BY +a
} {
0 0 0 {TABLE t1 (~1000000 rows)}
0 0 0 {USE TEMP B-TREE FOR ORDER BY}
}
do_eqp_test 1.5 {
SELECT a FROM t1 WHERE a=4
} {
0 0 0 {TABLE t1 WITH COVERING INDEX i1 (a=?) (~10 rows)}
}
do_eqp_test 1.6 {
SELECT DISTINCT count(*) FROM t3 GROUP BY a;
} {
0 0 0 {TABLE t3 (~1000000 rows)}
0 0 0 {USE TEMP B-TREE FOR GROUP BY}
0 0 0 {USE TEMP B-TREE FOR DISTINCT}
}
#-------------------------------------------------------------------------
# Test cases eqp-2.* - tests for single select statements.
#
drop_all_tables
do_execsql_test 2.1 {
CREATE TABLE t1(x, y);
CREATE TABLE t2(x, y);
CREATE INDEX t2i1 ON t2(x);
}
do_eqp_test 2.2.1 {
SELECT DISTINCT min(x), max(x) FROM t1 GROUP BY x ORDER BY 1
} {
0 0 0 {TABLE t1 (~1000000 rows)}
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}
}
do_eqp_test 2.2.2 {
SELECT DISTINCT min(x), max(x) FROM t2 GROUP BY x ORDER BY 1
} {
0 0 0 {TABLE t2 WITH COVERING INDEX t2i1 (~1000000 rows)}
0 0 0 {USE TEMP B-TREE FOR DISTINCT}
0 0 0 {USE TEMP B-TREE FOR ORDER BY}
}
#-------------------------------------------------------------------------
# Test cases eqp-3.* - tests for select statements that use sub-selects.
#
do_eqp_test 3.1.1 {
SELECT (SELECT x FROM t1 AS sub) FROM t1;
} {
0 0 0 {TABLE t1 (~1000000 rows)}
1 0 0 {TABLE t1 AS sub (~1000000 rows)}
}
#-------------------------------------------------------------------------
# Test cases eqp-4.* - tests for select statements that use sub-selects.
#
do_eqp_test 4.1.1 {
SELECT * FROM t1 UNION ALL SELECT * FROM t2
} {
1 0 0 {TABLE t1 (~1000000 rows)}
2 0 0 {TABLE t2 (~1000000 rows)}
}
do_eqp_test 4.1.2 {
SELECT * FROM t1 UNION ALL SELECT * FROM t2 ORDER BY 2
} {
1 0 0 {TABLE t1 (~1000000 rows)}
1 0 0 {USE TEMP B-TREE FOR ORDER BY}
2 0 0 {TABLE t2 (~1000000 rows)}
2 0 0 {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 {TABLE t1 (~1000000 rows)}
1 0 0 {USE TEMP B-TREE FOR ORDER BY}
2 0 0 {TABLE t2 (~1000000 rows)}
2 0 0 {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 {TABLE t1 (~1000000 rows)}
1 0 0 {USE TEMP B-TREE FOR ORDER BY}
2 0 0 {TABLE t2 (~1000000 rows)}
2 0 0 {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 {TABLE t1 (~1000000 rows)}
1 0 0 {USE TEMP B-TREE FOR ORDER BY}
2 0 0 {TABLE t2 (~1000000 rows)}
2 0 0 {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 {TABLE t1 (~1000000 rows)}
1 0 0 {USE TEMP B-TREE FOR ORDER BY}
2 0 0 {TABLE t2 WITH INDEX t2i1 (~1000000 rows)}
}
# Todo: Why are the following not the same as the UNION ALL case above?
do_eqp_test 4.2.3 {
SELECT * FROM t1 UNION SELECT * FROM t2 ORDER BY 1
} {
1 0 0 {TABLE t1 (~1000000 rows)}
1 0 0 {USE TEMP B-TREE FOR ORDER BY}
2 0 0 {TABLE t2 (~1000000 rows)}
2 0 0 {USE TEMP B-TREE FOR ORDER BY}
}
do_eqp_test 4.2.4 {
SELECT * FROM t1 INTERSECT SELECT * FROM t2 ORDER BY 1
} {
1 0 0 {TABLE t1 (~1000000 rows)}
1 0 0 {USE TEMP B-TREE FOR ORDER BY}
2 0 0 {TABLE t2 (~1000000 rows)}
2 0 0 {USE TEMP B-TREE FOR ORDER BY}
}
do_eqp_test 4.2.5 {
SELECT * FROM t1 EXCEPT SELECT * FROM t2 ORDER BY 1
} {
1 0 0 {TABLE t1 (~1000000 rows)}
1 0 0 {USE TEMP B-TREE FOR ORDER BY}
2 0 0 {TABLE t2 (~1000000 rows)}
2 0 0 {USE TEMP B-TREE FOR ORDER BY}
}
finish_test