From: danielk1977 Date: Tue, 1 Jul 2008 14:09:13 +0000 (+0000) Subject: Optimize sub-selects and views that use UNION ALL. This optimization isn't very well... X-Git-Tag: version-3.6.10~846 X-Git-Url: http://git.ipfire.org/?a=commitdiff_plain;h=f23329a221942894f323a6801d4cd94e9e5fc9a2;p=thirdparty%2Fsqlite.git Optimize sub-selects and views that use UNION ALL. This optimization isn't very well tested yet. (CVS 5331) FossilOrigin-Name: 3ef468e7046b2091b5b6880fe19261ef1ee2887b --- diff --git a/manifest b/manifest index 643ffdacdf..7477e81d1b 100644 --- a/manifest +++ b/manifest @@ -1,5 +1,5 @@ -C Call\sthe\squery\sflattener\swhile\sprocessing\sthe\sparent\squery.\sPreviously,\sit\swas\scalled\swhile\sprocessing\sthe\ssub-queries.\s(CVS\s5330) -D 2008-06-30T18:12:28 +C Optimize\ssub-selects\sand\sviews\sthat\suse\sUNION\sALL.\sThis\soptimization\sisn't\svery\swell\stested\syet.\s(CVS\s5331) +D 2008-07-01T14:09:14 F Makefile.arm-wince-mingw32ce-gcc fcd5e9cd67fe88836360bb4f9ef4cb7f8e2fb5a0 F Makefile.in 325dfac0a0dd1cb4d975f1ace6453157892e6042 F Makefile.linux-gcc d53183f4aa6a9192d249731c90dbdffbd2c68654 @@ -140,7 +140,7 @@ F src/pragma.c 9a95f5b3708f6d3ddd987eab5f369a19ffcb6795 F src/prepare.c aba51dad52308e3d9d2074d8ff4e612e7f1cab51 F src/printf.c 8b063da9dcde26b7c500a01444b718d86f21bc6e F src/random.c 5c754319d38abdd6acd74601ee0105504adc508a -F src/select.c afaac3f04b922edb8af07f05763b63c00ddc4a5a +F src/select.c 727e546cd941a336d11a0e21da653ea53da53467 F src/shell.c 484e7297e066f22830f9c15d7abbcdd2acb097b0 F src/sqlite.h.in 76c144d23f8824e8811e837e9396b9f1361f5902 F src/sqlite3ext.h 1e3887c9bd3ae66cb599e922824b04cd0d0f2c3e @@ -449,6 +449,7 @@ F test/select7.test 7906735805cfbee4dddc0bed4c14e68d7f5f9c5f F test/select8.test 391de11bdd52339c30580dabbbbe97e3e9a3c79d F test/select9.test 2f52de9bcca6002ff9ad57b045a023e2dff6438d F test/selectA.test e4501789a1d0fe9d00db15187623fb5b7031357b +F test/selectB.test ade563cde5bc0f384d8b5de99e9aa036cd1a5e7f F test/server1.test f5b790d4c0498179151ca8a7715a65a7802c859c F test/shared.test c6769531e0cb751d46a9838c0532d3786606c0f6 F test/shared2.test 0ee9de8964d70e451936a48c41cb161d9134ccf4 @@ -595,7 +596,7 @@ F tool/speedtest16.c c8a9c793df96db7e4933f0852abb7a03d48f2e81 F tool/speedtest2.tcl ee2149167303ba8e95af97873c575c3e0fab58ff F tool/speedtest8.c 1dbced29de5f59ba2ebf877edcadf171540374d1 F tool/speedtest8inst1.c 293327bc76823f473684d589a8160bde1f52c14e -P 189cd85413a2e00696752bb82e7a442e86e621ac -R d620881f6cbbbbefdfa4e9725f1fbb87 +P 6fcb3bffe26ae1c21c72ce9019f1db1c118094a4 +R a2583ef5b7a521dcade25acc745843b4 U danielk1977 -Z 6869d5a04e97a4a4d7edf1da8de9ca2a +Z ee7031ff29f21965f0690349b2076acb diff --git a/manifest.uuid b/manifest.uuid index a4cb46a6c7..e9c74619cb 100644 --- a/manifest.uuid +++ b/manifest.uuid @@ -1 +1 @@ -6fcb3bffe26ae1c21c72ce9019f1db1c118094a4 \ No newline at end of file +3ef468e7046b2091b5b6880fe19261ef1ee2887b \ No newline at end of file diff --git a/src/select.c b/src/select.c index 55cf08e966..7956dccf47 100644 --- a/src/select.c +++ b/src/select.c @@ -12,7 +12,7 @@ ** This file contains C code routines that are called by the parser ** to handle SELECT statements in SQLite. ** -** $Id: select.c,v 1.440 2008/06/30 18:12:28 danielk1977 Exp $ +** $Id: select.c,v 1.441 2008/07/01 14:09:14 danielk1977 Exp $ */ #include "sqliteInt.h" @@ -1161,6 +1161,10 @@ Table *sqlite3ResultSetOfSelect(Parse *pParse, char *zTabName, Select *pSelect){ Column *aCol, *pCol; sqlite3 *db = pParse->db; + if( sqlite3SelectResolve(pParse, pSelect, 0) ){ + return 0; + } + while( pSelect->pPrior ) pSelect = pSelect->pPrior; if( prepSelectStmt(pParse, pSelect) ){ return 0; @@ -3050,6 +3054,18 @@ static void substSelect( ** not contain ORDER BY. (Ticket #2942) This used to not matter ** until we introduced the group_concat() function. ** +** (17) The sub-query is not a compound select, or it is a UNION ALL +** compound without an ORDER BY, LIMIT or OFFSET clause made up +** entirely of non-aggregate queries, and +** the parent query: +** +** * is not itself part of a compound select, +** * is not an aggregate or DISTINCT query, and +** * has no other tables or sub-selects in the FROM clause. +** +** The parent query may have WHERE, ORDER BY, LIMIT and OFFSET +** clauses. +** ** In this routine, the "p" parameter is a pointer to the outer query. ** The subquery is p->pSrc->a[iFrom]. isAgg is true if the outer query ** uses aggregates and subqueryIsAgg is true if the subquery uses aggregates. @@ -3067,7 +3083,9 @@ static int flattenSubquery( int isAgg, /* True if outer SELECT uses aggregate functions */ int subqueryIsAgg /* True if the subquery uses aggregate functions */ ){ + Select *pParent; Select *pSub; /* The inner query or "subquery" */ + Select *pSub1; /* Pointer to the rightmost select in sub-query */ SrcList *pSrc; /* The FROM clause of the outer query */ SrcList *pSubSrc; /* The FROM clause of the subquery */ ExprList *pList; /* The result set of the outer query */ @@ -3142,41 +3160,93 @@ static int flattenSubquery( return 0; } - /* If we reach this point, it means flattening is permitted for the - ** iFrom-th entry of the FROM clause in the outer query. + /* Restriction 17: If the sub-query is a compound SELECT, then it must + ** use only the UNION ALL operator. And none of the simple select queries + ** that make up the compound SELECT are allowed to be aggregate or distinct + ** queries. + */ + if( pSub->pPrior ){ + if( p->pPrior || isAgg || p->isDistinct || pSrc->nSrc!=1 ){ + return 0; + } + for(pSub1=pSub; pSub1; pSub1=pSub1->pPrior){ + if( pSub1->isAgg || pSub1->isDistinct + || (pSub1->pPrior && pSub1->op!=TK_ALL) ){ + return 0; + } + } + } + + /* If the sub-query is a compound SELECT statement, then it must be + ** a UNION ALL and the parent query must be of the form: + ** + ** SELECT FROM () + ** + ** followed by any ORDER BY, LIMIT and/or OFFSET clauses. This block + ** creates N copies of the parent query without any ORDER BY, LIMIT or + ** OFFSET clauses and joins them to the left-hand-side of the original + ** using UNION ALL operators. In this case N is the number of simple + ** select statements in the compound sub-query. */ + for(pSub=pSub->pPrior; pSub; pSub=pSub->pPrior){ + Select *pNew; + ExprList *pOrderBy = p->pOrderBy; + Select *pPrior = p->pPrior; + p->pOrderBy = 0; + p->pSrc = 0; + p->pPrior = 0; + pNew = sqlite3SelectDup(db, p); + pNew->pPrior = pPrior; + p->pPrior = pNew; + p->pOrderBy = pOrderBy; + p->op = TK_ALL; + p->pSrc = pSrc; + p->pRightmost = 0; + pNew->pRightmost = 0; + } - /* Move all of the FROM elements of the subquery into the - ** the FROM clause of the outer query. Before doing this, remember - ** the cursor number for the original outer query FROM element in - ** iParent. The iParent cursor will never be used. Subsequent code - ** will scan expressions looking for iParent references and replace - ** those references with expressions that resolve to the subquery FROM - ** elements we are now copying in. + /* If we reach this point, it means flattening is permitted for the + ** iFrom-th entry of the FROM clause in the outer query. */ + pSub = pSub1 = pSubitem->pSelect; iParent = pSubitem->iCursor; - { + for(pParent=p; pParent; pParent=pParent->pPrior, pSub=pSub->pPrior){ int nSubSrc = pSubSrc->nSrc; - int jointype = pSubitem->jointype; - - sqlite3DeleteTable(pSubitem->pTab); - sqlite3_free(pSubitem->zDatabase); - sqlite3_free(pSubitem->zName); - sqlite3_free(pSubitem->zAlias); - pSubitem->pTab = 0; - pSubitem->zDatabase = 0; - pSubitem->zName = 0; - pSubitem->zAlias = 0; - if( nSubSrc>1 ){ + int jointype = 0; + pSubSrc = pSub->pSrc; + pSrc = pParent->pSrc; + + /* Move all of the FROM elements of the subquery into the + ** the FROM clause of the outer query. Before doing this, remember + ** the cursor number for the original outer query FROM element in + ** iParent. The iParent cursor will never be used. Subsequent code + ** will scan expressions looking for iParent references and replace + ** those references with expressions that resolve to the subquery FROM + ** elements we are now copying in. + */ + if( pSrc ){ + pSubitem = &pSrc->a[iFrom]; + nSubSrc = pSubSrc->nSrc; + jointype = pSubitem->jointype; + sqlite3DeleteTable(pSubitem->pTab); + sqlite3_free(pSubitem->zDatabase); + sqlite3_free(pSubitem->zName); + sqlite3_free(pSubitem->zAlias); + pSubitem->pTab = 0; + pSubitem->zDatabase = 0; + pSubitem->zName = 0; + pSubitem->zAlias = 0; + } + if( nSubSrc!=1 || !pSrc ){ int extra = nSubSrc - 1; - for(i=1; ipSrc = 0; + pParent->pSrc = 0; return 1; } } - p->pSrc = pSrc; + pParent->pSrc = pSrc; for(i=pSrc->nSrc-1; i-extra>=iFrom; i--){ pSrc->a[i] = pSrc->a[i-extra]; } @@ -3186,79 +3256,80 @@ static int flattenSubquery( memset(&pSubSrc->a[i], 0, sizeof(pSubSrc->a[i])); } pSrc->a[iFrom].jointype = jointype; - } - - /* Now begin substituting subquery result set expressions for - ** references to the iParent in the outer query. - ** - ** Example: - ** - ** SELECT a+5, b*10 FROM (SELECT x*3 AS a, y+10 AS b FROM t1) WHERE a>b; - ** \ \_____________ subquery __________/ / - ** \_____________________ outer query ______________________________/ - ** - ** We look at every expression in the outer query and every place we see - ** "a" we substitute "x*3" and every place we see "b" we substitute "y+10". - */ - pList = p->pEList; - for(i=0; inExpr; i++){ - Expr *pExpr; - if( pList->a[i].zName==0 && (pExpr = pList->a[i].pExpr)->span.z!=0 ){ - pList->a[i].zName = - sqlite3DbStrNDup(db, (char*)pExpr->span.z, pExpr->span.n); + + /* Now begin substituting subquery result set expressions for + ** references to the iParent in the outer query. + ** + ** Example: + ** + ** SELECT a+5, b*10 FROM (SELECT x*3 AS a, y+10 AS b FROM t1) WHERE a>b; + ** \ \_____________ subquery __________/ / + ** \_____________________ outer query ______________________________/ + ** + ** We look at every expression in the outer query and every place we see + ** "a" we substitute "x*3" and every place we see "b" we substitute "y+10". + */ + pList = pParent->pEList; + for(i=0; inExpr; i++){ + Expr *pExpr; + if( pList->a[i].zName==0 && (pExpr = pList->a[i].pExpr)->span.z!=0 ){ + pList->a[i].zName = + sqlite3DbStrNDup(db, (char*)pExpr->span.z, pExpr->span.n); + } + } + substExprList(db, pParent->pEList, iParent, pSub->pEList); + if( isAgg ){ + substExprList(db, pParent->pGroupBy, iParent, pSub->pEList); + substExpr(db, pParent->pHaving, iParent, pSub->pEList); + } + if( pSub->pOrderBy ){ + assert( pParent->pOrderBy==0 ); + pParent->pOrderBy = pSub->pOrderBy; + pSub->pOrderBy = 0; + }else if( pParent->pOrderBy ){ + substExprList(db, pParent->pOrderBy, iParent, pSub->pEList); + } + if( pSub->pWhere ){ + pWhere = sqlite3ExprDup(db, pSub->pWhere); + }else{ + pWhere = 0; + } + if( subqueryIsAgg ){ + assert( pParent->pHaving==0 ); + pParent->pHaving = pParent->pWhere; + pParent->pWhere = pWhere; + substExpr(db, pParent->pHaving, iParent, pSub->pEList); + pParent->pHaving = sqlite3ExprAnd(db, pParent->pHaving, + sqlite3ExprDup(db, pSub->pHaving)); + assert( pParent->pGroupBy==0 ); + pParent->pGroupBy = sqlite3ExprListDup(db, pSub->pGroupBy); + }else{ + substExpr(db, pParent->pWhere, iParent, pSub->pEList); + pParent->pWhere = sqlite3ExprAnd(db, pParent->pWhere, pWhere); + } + + /* The flattened query is distinct if either the inner or the + ** outer query is distinct. + */ + pParent->isDistinct = pParent->isDistinct || pSub->isDistinct; + + /* + ** SELECT ... FROM (SELECT ... LIMIT a OFFSET b) LIMIT x OFFSET y; + ** + ** One is tempted to try to add a and b to combine the limits. But this + ** does not work if either limit is negative. + */ + if( pSub->pLimit ){ + pParent->pLimit = pSub->pLimit; + pSub->pLimit = 0; } - } - substExprList(db, p->pEList, iParent, pSub->pEList); - if( isAgg ){ - substExprList(db, p->pGroupBy, iParent, pSub->pEList); - substExpr(db, p->pHaving, iParent, pSub->pEList); - } - if( pSub->pOrderBy ){ - assert( p->pOrderBy==0 ); - p->pOrderBy = pSub->pOrderBy; - pSub->pOrderBy = 0; - }else if( p->pOrderBy ){ - substExprList(db, p->pOrderBy, iParent, pSub->pEList); - } - if( pSub->pWhere ){ - pWhere = sqlite3ExprDup(db, pSub->pWhere); - }else{ - pWhere = 0; - } - if( subqueryIsAgg ){ - assert( p->pHaving==0 ); - p->pHaving = p->pWhere; - p->pWhere = pWhere; - substExpr(db, p->pHaving, iParent, pSub->pEList); - p->pHaving = sqlite3ExprAnd(db, p->pHaving, - sqlite3ExprDup(db, pSub->pHaving)); - assert( p->pGroupBy==0 ); - p->pGroupBy = sqlite3ExprListDup(db, pSub->pGroupBy); - }else{ - substExpr(db, p->pWhere, iParent, pSub->pEList); - p->pWhere = sqlite3ExprAnd(db, p->pWhere, pWhere); - } - - /* The flattened query is distinct if either the inner or the - ** outer query is distinct. - */ - p->isDistinct = p->isDistinct || pSub->isDistinct; - - /* - ** SELECT ... FROM (SELECT ... LIMIT a OFFSET b) LIMIT x OFFSET y; - ** - ** One is tempted to try to add a and b to combine the limits. But this - ** does not work if either limit is negative. - */ - if( pSub->pLimit ){ - p->pLimit = pSub->pLimit; - pSub->pLimit = 0; } /* Finially, delete what is left of the subquery and return ** success. */ - sqlite3SelectDelete(pSub); + sqlite3SelectDelete(pSub1); + return 1; } #endif /* SQLITE_OMIT_VIEW */ @@ -3671,29 +3742,6 @@ int sqlite3Select( p->pOrderBy = pOrderBy; -#ifndef SQLITE_OMIT_COMPOUND_SELECT - /* If there is are a sequence of queries, do the earlier ones first. - */ - if( p->pPrior ){ - if( p->pRightmost==0 ){ - Select *pLoop, *pRight = 0; - int cnt = 0; - int mxSelect; - for(pLoop=p; pLoop; pLoop=pLoop->pPrior, cnt++){ - pLoop->pRightmost = p; - pLoop->pNext = pRight; - pRight = pLoop; - } - mxSelect = db->aLimit[SQLITE_LIMIT_COMPOUND_SELECT]; - if( mxSelect && cnt>mxSelect ){ - sqlite3ErrorMsg(pParse, "too many terms in compound SELECT"); - return 1; - } - } - return multiSelect(pParse, p, pDest, aff); - } -#endif - /* Make local copies of the parameters for this query. */ pTabList = p->pSrc; @@ -3730,10 +3778,11 @@ int sqlite3Select( /* Generate code for all sub-queries in the FROM clause */ #if !defined(SQLITE_OMIT_SUBQUERY) || !defined(SQLITE_OMIT_VIEW) - for(i=0; inSrc; i++){ + for(i=0; !p->pPrior && inSrc; i++){ struct SrcList_item *pItem = &pTabList->a[i]; SelectDest dest; Select *pSub = pItem->pSelect; + int isAggSub; if( pSub==0 || pItem->isPopulated ) continue; if( pItem->zName!=0 ){ /* An sql view */ @@ -3756,8 +3805,9 @@ int sqlite3Select( pParse->nHeight += sqlite3SelectExprHeight(p); /* Check to see if the subquery can be absorbed into the parent. */ - if( !pSub->pPrior && flattenSubquery(db, p, i, isAgg, pSub->isAgg) ){ - if( pSub->isAgg ){ + isAggSub = pSub->isAgg; + if( flattenSubquery(db, p, i, isAgg, isAggSub) ){ + if( isAggSub ){ p->isAgg = isAgg = 1; } i = -1; @@ -3781,6 +3831,29 @@ int sqlite3Select( pHaving = p->pHaving; isDistinct = p->isDistinct; +#ifndef SQLITE_OMIT_COMPOUND_SELECT + /* If there is are a sequence of queries, do the earlier ones first. + */ + if( p->pPrior ){ + if( p->pRightmost==0 ){ + Select *pLoop, *pRight = 0; + int cnt = 0; + int mxSelect; + for(pLoop=p; pLoop; pLoop=pLoop->pPrior, cnt++){ + pLoop->pRightmost = p; + pLoop->pNext = pRight; + pRight = pLoop; + } + mxSelect = db->aLimit[SQLITE_LIMIT_COMPOUND_SELECT]; + if( mxSelect && cnt>mxSelect ){ + sqlite3ErrorMsg(pParse, "too many terms in compound SELECT"); + return 1; + } + } + return multiSelect(pParse, p, pDest, aff); + } +#endif + /* If possible, rewrite the query to use GROUP BY instead of DISTINCT. ** GROUP BY may use an index, DISTINCT never does. */ diff --git a/test/selectB.test b/test/selectB.test new file mode 100644 index 0000000000..4df6434f19 --- /dev/null +++ b/test/selectB.test @@ -0,0 +1,98 @@ +# 2008 June 24 +# +# 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. +# +#*********************************************************************** +# This file implements regression tests for SQLite library. +# +# $Id: selectB.test,v 1.1 2008/07/01 14:09:14 danielk1977 Exp $ + +set testdir [file dirname $argv0] +source $testdir/tester.tcl + +proc test_transform {testname sql1 sql2 results} { + set ::vdbe1 [list] + set ::vdbe2 [list] + db eval "explain $sql1" { lappend ::vdbe1 $opcode } + db eval "explain $sql2" { lappend ::vdbe2 $opcode } + + do_test $testname.transform { + set ::vdbe1 + } $::vdbe2 + + set ::sql1 $sql1 + do_test $testname.sql1 { + execsql $::sql1 + } $results + + set ::sql2 $sql2 + do_test $testname.sql2 { + execsql $::sql2 + } $results +} + +do_test selectB-1.1 { + execsql { + CREATE TABLE t1(a, b, c); + CREATE TABLE t2(d, e, f); + + INSERT INTO t1 VALUES( 2, 4, 6); + INSERT INTO t1 VALUES( 8, 10, 12); + INSERT INTO t1 VALUES(14, 16, 18); + + INSERT INTO t2 VALUES(3, 6, 9); + INSERT INTO t2 VALUES(12, 15, 18); + INSERT INTO t2 VALUES(21, 24, 27); + } +} {} + +test_transform selectB-1.2 { + SELECT * FROM (SELECT a FROM t1 UNION ALL SELECT d FROM t2) +} { + SELECT a FROM t1 UNION ALL SELECT d FROM t2 +} {2 8 14 3 12 21} + +test_transform selectB-1.3 { + SELECT * FROM (SELECT a FROM t1 UNION ALL SELECT d FROM t2) ORDER BY 1 +} { + SELECT a FROM t1 UNION ALL SELECT d FROM t2 ORDER BY 1 +} {2 3 8 12 14 21} + +test_transform selectB-1.4 { + SELECT * FROM + (SELECT a FROM t1 UNION ALL SELECT d FROM t2) + WHERE a>10 ORDER BY 1 +} { + SELECT a FROM t1 WHERE a>10 UNION ALL SELECT d FROM t2 WHERE d>10 ORDER BY 1 +} {12 14 21} + +test_transform selectB-1.5 { + SELECT * FROM + (SELECT a FROM t1 UNION ALL SELECT d FROM t2) + WHERE a>10 ORDER BY a +} { + SELECT a FROM t1 WHERE a>10 + UNION ALL + SELECT d FROM t2 WHERE d>10 + ORDER BY a +} {12 14 21} + +test_transform selectB-1.6 { + SELECT * FROM + (SELECT a FROM t1 UNION ALL SELECT d FROM t2 WHERE d > 12) + WHERE a>10 ORDER BY a +} { + SELECT a FROM t1 WHERE a>10 + UNION ALL + SELECT d FROM t2 WHERE d>12 AND d>10 + ORDER BY a +} {14 21} + + +finish_test +