Automatically transfer terms from the HAVING clause to the WHERE clause of an

aggregate query in cases where the result of evaluating the term depends only
one one or more of the GROUP BY expressions (and on no other inputs).

FossilOrigin-Name: 5375a3ce56f1d993b13b469fe33ec7679948f53940f62a15ddbaeb8aaa26a22c
This commit is contained in:
dan 2017-04-29 20:53:09 +00:00
parent bc43995f99
commit ab31a8450b
6 changed files with 243 additions and 20 deletions

View File

@ -1,5 +1,5 @@
C Evaluate\sWHERE\sclause\sterms\sthat\sreference\sonly\sthe\sindex\sbefore\sevaluating\nterms\sthat\srequire\sthe\stable,\sand\sthereby\savoid\sseeking\sthe\stable\srow\sif\nindex\sterms\sare\sfalse.\nThis\sis\scalled\sthe\s"push-down"\soptimization\sin\sthe\sMySQL\sworld,\swe\sare\stold.
D 2017-04-29T15:27:04.896
C Automatically\stransfer\sterms\sfrom\sthe\sHAVING\sclause\sto\sthe\sWHERE\sclause\sof\san\naggregate\squery\sin\scases\swhere\sthe\sresult\sof\sevaluating\sthe\sterm\sdepends\sonly\none\sone\sor\smore\sof\sthe\sGROUP\sBY\sexpressions\s(and\son\sno\sother\sinputs).
D 2017-04-29T20:53:09.360
F Makefile.in 1cc758ce3374a32425e4d130c2fe7b026b20de5b8843243de75f087c0a2661fb
F Makefile.linux-gcc 7bc79876b875010e8c8f9502eb935ca92aa3c434
F Makefile.msc 6a8c838220f7c00820e1fc0ac1bccaaa8e5676067e1dbfa1bafa7a4ffecf8ae6
@ -355,7 +355,7 @@ F src/ctime.c 47d91a25ad8f199a71a5b1b7b169d6dd0d6e98c5719eca801568798743d1161c
F src/date.c cc42a41c7422389860d40419a5e3bce5eaf6e7835c3ba2677751dc653550a5c7
F src/dbstat.c 19ee7a4e89979d4df8e44cfac7a8f905ec89b77d
F src/delete.c 0d9d5549d42e79ce4d82ff1db1e6c81e36d2f67c
F src/expr.c f10e35dc50be4c8f82eb99bf5d8530229d1d60957cc3c9473ffe584d0444087c
F src/expr.c ed8914c001a24ab25aee965f498c96de577bf2c4a6145022b3688c11c2b29c82
F src/fault.c 460f3e55994363812d9d60844b2a6de88826e007
F src/fkey.c db65492ae549c3b548c9ef1f279ce1684f1c473b116e1c56a90878cd5dcf968d
F src/func.c 9d52522cc8ae7f5cdadfe14594262f1618bc1f86083c4cd6da861b4cf5af6174
@ -402,12 +402,12 @@ F src/printf.c 8757834f1b54dae512fb25eb1acc8e94a0d15dd2290b58f2563f65973265adb2
F src/random.c 80f5d666f23feb3e6665a6ce04c7197212a88384
F src/resolve.c 3e518b962d932a997fae373366880fc028c75706
F src/rowset.c 7b7e7e479212e65b723bf40128c7b36dc5afdfac
F src/select.c bf8ab605e49717c222136380453cfb7eda564f8e500d5ff6a01341ea59fefe80
F src/select.c a2b839b8cfa75d154490839ee80bad3452b9810ad39862ad044d154211292866
F src/shell.c 21b79c0e1b93f8e35fd7b4087d6ba438326c3d7e285d0dd51dfd741475f858a1
F src/sqlite.h.in 40233103e3e4e10f8a63523498d0259d232e42aba478e2d3fb914799185aced6
F src/sqlite3.rc 5121c9e10c3964d5755191c80dd1180c122fc3a8
F src/sqlite3ext.h 58fd0676d3111d02e62e5a35992a7d3da5d3f88753acc174f2d37b774fbbdd28
F src/sqliteInt.h 9affb53bb405dcea1d86e85198ebaf6232a684cc2b2af6b3c181869f1c8f3e93
F src/sqliteInt.h aea3aa1b81e0d07d5b1c39b8c5a54a1dc5e4f10136cb63da392aef9eb2a5108b
F src/sqliteLimit.h 1513bfb7b20378aa0041e7022d04acb73525de35b80b252f1b83fedb4de6a76b
F src/status.c a9e66593dfb28a9e746cba7153f84d49c1ddc4b1
F src/table.c b46ad567748f24a326d9de40e5b9659f96ffff34
@ -850,6 +850,7 @@ F test/fuzzer2.test a85ef814ce071293bce1ad8dffa217cbbaad4c14
F test/fuzzerfault.test 8792cd77fd5bce765b05d0c8e01b9edcf8af8536
F test/gcfault.test dd28c228a38976d6336a3fc42d7e5f1ad060cb8c
F test/genesis.tcl 1e2e2e8e5cc4058549a154ff1892fe5c9de19f98
F test/having.test a03676a754815628a08d3b96d506dd9eda8ffbdd356cd8ea9c2e5368286fbe6a
F test/hexlit.test 4a6a5f46e3c65c4bf1fa06f5dd5a9507a5627751
F test/hidden.test 23c1393a79e846d68fd902d72c85d5e5dcf98711
F test/hook.test dbc0b87756e1e20e7497b56889c9e9cd2f8cc2b5
@ -1577,8 +1578,10 @@ F vsixtest/vsixtest.tcl 6a9a6ab600c25a91a7acc6293828957a386a8a93
F vsixtest/vsixtest.vcxproj.data 2ed517e100c66dc455b492e1a33350c1b20fbcdc
F vsixtest/vsixtest.vcxproj.filters 37e51ffedcdb064aad6ff33b6148725226cd608e
F vsixtest/vsixtest_TemporaryKey.pfx e5b1b036facdb453873e7084e1cae9102ccc67a0
P 2d0b64316d66a362f5891ceb71a1fd8e4607732274b09b0a8472b97eef68ebc2 91dfb61a1a25763bb0b5c1e353a9d584bc6de3f6eb445f54202ffe7f6fee6e8d
R d3fbd82e46a4092d676255e41f20df5b
T +closed 91dfb61a1a25763bb0b5c1e353a9d584bc6de3f6eb445f54202ffe7f6fee6e8d
U drh
Z d8af2da2fe4450264227719b4f172b61
P d7bb79ed3a40419d143fbe35c310e51fe7b384a22f082a61ad788671d2d33ee0
R bd50b7d1e9edcc2d5d20fca02c02c5c7
T *branch * having-where-optimization
T *sym-having-where-optimization *
T -sym-trunk *
U dan
Z 94cbfc69ef14a78710cd01b746487e79

View File

@ -1 +1 @@
d7bb79ed3a40419d143fbe35c310e51fe7b384a22f082a61ad788671d2d33ee0
5375a3ce56f1d993b13b469fe33ec7679948f53940f62a15ddbaeb8aaa26a22c

View File

@ -1815,6 +1815,51 @@ int sqlite3ExprIsTableConstant(Expr *p, int iCur){
return exprIsConst(p, 3, iCur);
}
/*
** sqlite3WalkExpr() callback used by sqlite3ExprIsConstantOrGroupBy().
*/
static int exprNodeIsConstantOrGroupBy(Walker *pWalker, Expr *pExpr){
ExprList *pGroupBy = pWalker->u.pGroupBy;
int i;
/* Check if pExpr is identical to any GROUP BY term. If so, consider
** it constant. */
for(i=0; i<pGroupBy->nExpr; i++){
Expr *p = pGroupBy->a[i].pExpr;
if( sqlite3ExprCompare(pExpr, p, -1)<2 ){
CollSeq *pColl = sqlite3ExprCollSeq(pWalker->pParse, p);
if( pColl==0 || sqlite3_stricmp("BINARY", pColl->zName)==0 ){
return WRC_Prune;
}
}
}
/* Check if pExpr is a sub-select. If so, consider it variable. */
if( ExprHasProperty(pExpr, EP_xIsSelect) ){
pWalker->eCode = 0;
return WRC_Abort;
}
return exprNodeIsConstant(pWalker, pExpr);
}
/*
** Walk the expression tree passed as the first argument. Return non-zero
** if the expression consists entirely of constants or copies of terms
** in pGroupBy that sort with the BINARY collation sequence.
*/
int sqlite3ExprIsConstantOrGroupBy(Parse *pParse, Expr *p, ExprList *pGroupBy){
Walker w;
memset(&w, 0, sizeof(w));
w.eCode = 1;
w.xExprCallback = exprNodeIsConstantOrGroupBy;
w.u.pGroupBy = pGroupBy;
w.pParse = pParse;
sqlite3WalkExpr(&w, p);
return w.eCode;
}
/*
** Walk an expression tree. Return non-zero if the expression is constant
** or a function call with constant arguments. Return and 0 if there

View File

@ -4879,6 +4879,79 @@ static void explainSimpleCount(
# define explainSimpleCount(a,b,c)
#endif
/*
** Context object for havingToWhereExprCb().
*/
struct HavingToWhereCtx {
Expr **ppWhere;
ExprList *pGroupBy;
};
/*
** sqlite3WalkExpr() callback used by havingToWhere().
**
** If the node passed to the callback is a TK_AND node, return
** WRC_Continue to tell sqlite3WalkExpr() to iterate through child nodes.
**
** Otherwise, return WRC_Prune. In this case, also check if the
** sub-expression matches the criteria for being moved to the WHERE
** clause. If so, add it to the WHERE clause and replace the sub-expression
** within the HAVING expression with a constant "1".
*/
static int havingToWhereExprCb(Walker *pWalker, Expr *pExpr){
if( pExpr->op!=TK_AND ){
struct HavingToWhereCtx *p = pWalker->u.pHavingCtx;
if( sqlite3ExprIsConstantOrGroupBy(pWalker->pParse, pExpr, p->pGroupBy) ){
sqlite3 *db = pWalker->pParse->db;
Expr *pNew = sqlite3ExprAlloc(db, TK_INTEGER, &sqlite3IntTokens[1], 0);
if( pNew ){
Expr *pWhere = *(p->ppWhere);
SWAP(Expr, *pNew, *pExpr);
if( pWhere ){
pNew = sqlite3ExprAnd(db, pWhere, pNew);
}
*(p->ppWhere) = pNew;
}
}
return WRC_Prune;
}
return WRC_Continue;
}
/*
** Transfer eligible terms from the HAVING clause of a query, which is
** processed after grouping, to the WHERE clause, which is processed before
** grouping. For example, the query:
**
** SELECT * FROM <tables> WHERE a=? GROUP BY b HAVING b=? AND c=?
**
** can be rewritten as:
**
** SELECT * FROM <tables> WHERE a=? AND b=? GROUP BY b HAVING c=?
**
** A term of the HAVING expression is eligible for transfer if it consists
** entirely of constants and expressions that are also GROUP BY terms that
** use the "BINARY" collation sequence.
*/
static void havingToWhere(
Parse *pParse,
ExprList *pGroupBy,
Expr *pHaving,
Expr **ppWhere
){
struct HavingToWhereCtx sCtx;
Walker sWalker;
sCtx.ppWhere = ppWhere;
sCtx.pGroupBy = pGroupBy;
memset(&sWalker, 0, sizeof(sWalker));
sWalker.pParse = pParse;
sWalker.xExprCallback = havingToWhereExprCb;
sWalker.u.pHavingCtx = &sCtx;
sqlite3WalkExpr(&sWalker, pHaving);
}
/*
** Generate code for the SELECT statement given in the p argument.
**
@ -5343,6 +5416,11 @@ int sqlite3Select(
sqlite3ExprAnalyzeAggList(&sNC, pEList);
sqlite3ExprAnalyzeAggList(&sNC, sSort.pOrderBy);
if( pHaving ){
if( pGroupBy ){
assert( pWhere==p->pWhere );
havingToWhere(pParse, pGroupBy, pHaving, &p->pWhere);
pWhere = p->pWhere;
}
sqlite3ExprAnalyzeAggregates(&sNC, pHaving);
}
sAggInfo.nAccumulator = sAggInfo.nColumn;

View File

@ -3316,15 +3316,17 @@ struct Walker {
int walkerDepth; /* Number of subqueries */
u8 eCode; /* A small processing code */
union { /* Extra data for callback */
NameContext *pNC; /* Naming context */
int n; /* A counter */
int iCur; /* A cursor number */
SrcList *pSrcList; /* FROM clause */
struct SrcCount *pSrcCount; /* Counting column references */
struct CCurHint *pCCurHint; /* Used by codeCursorHint() */
int *aiCol; /* array of column indexes */
struct IdxCover *pIdxCover; /* Check for index coverage */
struct IdxExprTrans *pIdxTrans; /* Convert indexed expr to column */
NameContext *pNC; /* Naming context */
int n; /* A counter */
int iCur; /* A cursor number */
SrcList *pSrcList; /* FROM clause */
struct SrcCount *pSrcCount; /* Counting column references */
struct CCurHint *pCCurHint; /* Used by codeCursorHint() */
int *aiCol; /* array of column indexes */
struct IdxCover *pIdxCover; /* Check for index coverage */
struct IdxExprTrans *pIdxTrans; /* Convert indexed expr to column */
ExprList *pGroupBy; /* GROUP BY clause */
struct HavingToWhereCtx *pHavingCtx; /* HAVING to WHERE clause ctx */
} u;
};
@ -3794,6 +3796,7 @@ void sqlite3LeaveMutexAndCloseZombie(sqlite3*);
int sqlite3ExprIsConstant(Expr*);
int sqlite3ExprIsConstantNotJoin(Expr*);
int sqlite3ExprIsConstantOrFunction(Expr*, u8);
int sqlite3ExprIsConstantOrGroupBy(Parse*, Expr*, ExprList*);
int sqlite3ExprIsTableConstant(Expr*,int);
#ifdef SQLITE_ENABLE_CURSOR_HINTS
int sqlite3ExprContainsSubquery(Expr*);

94
test/having.test Normal file
View File

@ -0,0 +1,94 @@
# 2017 April 30
#
# 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.
#
#***********************************************************************
#
# Test the HAVING->WHERE optimization.
#
set testdir [file dirname $argv0]
source $testdir/tester.tcl
set testprefix having
do_execsql_test 1.0 {
CREATE TABLE t1(a, b);
INSERT INTO t1 VALUES(1, 1);
INSERT INTO t1 VALUES(2, 2);
INSERT INTO t1 VALUES(1, 3);
INSERT INTO t1 VALUES(2, 4);
INSERT INTO t1 VALUES(1, 5);
INSERT INTO t1 VALUES(2, 6);
} {}
foreach {tn sql res} {
1 "SELECT a, sum(b) FROM t1 GROUP BY a HAVING a=2" {2 12}
2 "SELECT a, sum(b) FROM t1 GROUP BY a HAVING a=2 AND sum(b)>10" {2 12}
3 "SELECT a, sum(b) FROM t1 GROUP BY a HAVING sum(b)>12" {}
} {
do_execsql_test 1.$tn $sql $res
}
proc compare_vdbe {sql1 sql2} {
set r1 [list]
set r2 [list]
db eval "explain $sql1" { lappend r1 $opcode $p1 $p2 $p3}
db eval "explain $sql2" { lappend r2 $opcode $p1 $p2 $p3}
return [expr {$r1==$r2}]
}
proc do_compare_vdbe_test {tn sql1 sql2 res} {
uplevel [list do_test $tn [list compare_vdbe $sql1 $sql2] $res]
}
do_compare_vdbe_test 2.1 {
SELECT a, sum(b) FROM t1 GROUP BY a HAVING a=2
} {
SELECT a, sum(b) FROM t1 WHERE a=2 GROUP BY a
} 1
do_compare_vdbe_test 2.2 {
SELECT a, sum(b) FROM t1 GROUP BY a+1 HAVING a=2
} {
SELECT a, sum(b) FROM t1 GROUP BY a+1 HAVING a=2
} 1
foreach {tn sql1 sql2} {
1 "SELECT a, sum(b) FROM t1 GROUP BY a HAVING a=2"
"SELECT a, sum(b) FROM t1 WHERE a=2 GROUP BY a"
2 "SELECT a, sum(b) FROM t1 GROUP BY a HAVING sum(b)>5 AND a=2"
"SELECT a, sum(b) FROM t1 WHERE a=2 GROUP BY a HAVING sum(b)>5"
3 "SELECT a, sum(b) FROM t1 GROUP BY a COLLATE binary HAVING a=2"
"SELECT a, sum(b) FROM t1 WHERE a=2 GROUP BY a COLLATE binary"
4 {
SELECT x,y FROM (
SELECT a AS x, sum(b) AS y FROM t1
GROUP BY a
) WHERE x BETWEEN 8888 AND 9999
} {
SELECT x,y FROM (
SELECT a AS x, sum(b) AS y FROM t1
WHERE x BETWEEN 8888 AND 9999
GROUP BY a
)
}
} {
do_compare_vdbe_test 3.$tn $sql1 $sql2 1
}
foreach {tn sql1 sql2} {
1 "SELECT a, sum(b) FROM t1 GROUP BY a COLLATE nocase HAVING a=2"
"SELECT a, sum(b) FROM t1 WHERE a=2 GROUP BY a COLLATE nocase"
} {
do_compare_vdbe_test 4.$tn $sql1 $sql2 0
}
finish_test