From mboxrd@z Thu Jan 1 00:00:00 1970 Return-Path: Received: from localhost (localhost [127.0.0.1]) by turing.freelists.org (Avenir Technologies Mail Multiplex) with ESMTP id 59E302B459 for ; Mon, 10 Sep 2018 03:51:29 -0400 (EDT) Received: from turing.freelists.org ([127.0.0.1]) by localhost (turing.freelists.org [127.0.0.1]) (amavisd-new, port 10024) with ESMTP id vQl48M1qb9ms for ; Mon, 10 Sep 2018 03:51:29 -0400 (EDT) Received: from smtpng2.m.smailru.net (smtpng2.m.smailru.net [94.100.179.3]) (using TLSv1.2 with cipher ECDHE-RSA-AES256-GCM-SHA384 (256/256 bits)) (No client certificate requested) by turing.freelists.org (Avenir Technologies Mail Multiplex) with ESMTPS id 7B67A2B456 for ; Mon, 10 Sep 2018 03:51:28 -0400 (EDT) Subject: [tarantool-patches] Re: [PATCH v1 1/1] sql: support HAVING without GROUP BY clause References: <16D5B1D2-2DBF-4BAE-9C5D-F23CCCE3723D@tarantool.org> <5f602cc5-9617-6717-c13a-4d5595c23422@tarantool.org> <99A1FBB4-3831-4BB6-A1D6-505D09F792AD@tarantool.org> From: Kirill Shcherbatov Message-ID: <077750b5-7433-6122-5df9-caa6ff462e70@tarantool.org> Date: Mon, 10 Sep 2018 10:51:24 +0300 MIME-Version: 1.0 In-Reply-To: <99A1FBB4-3831-4BB6-A1D6-505D09F792AD@tarantool.org> Content-Type: text/plain; charset=utf-8 Content-Language: en-US Content-Transfer-Encoding: 7bit Sender: tarantool-patches-bounce@freelists.org Errors-to: tarantool-patches-bounce@freelists.org Reply-To: tarantool-patches@freelists.org List-help: List-unsubscribe: List-software: Ecartis version 1.0.0 List-Id: tarantool-patches List-subscribe: List-owner: List-post: List-archive: To: tarantool-patches@freelists.org, Nikita Pettik > db2 => SELECT SUM(a), a from t1 having sum(a) > 0 > SQL0119N An expression starting with "A" specified in a SELECT clause, HAVING > clause, or ORDER BY clause is not specified in the GROUP BY clause or it is in > a SELECT clause, HAVING clause, or ORDER BY clause with a column function and > no GROUP BY clause is specified. SQLSTATE=42803 I am able to handle this for now. > I would re-phrase it like: > > However, it is still possible to drop GROUP BY clause in case both SELECT > and HAVING arguments are aggregate functions Ok, tnx. > Nit: HAVING is rather clause, than expression. Overall, this msg looks > a little bit weird. In Postgres it is like: > > column "t1.a" must appear in the GROUP BY clause or be used in an aggregate function > > So, not HAVING clause must appear, but HAVING argument. ---> HAVING argument > Why 2.1 and not 1.5? The same for tests below. It was totall invalid naming. I've fixed it. ============================================================== >From fd960870f3519d335ee5dc61fbdd950d297fe79c Mon Sep 17 00:00:00 2001 Message-Id: From: Kirill Shcherbatov Date: Wed, 29 Aug 2018 16:24:09 +0300 Subject: [PATCH] sql: support HAVING without GROUP BY Allowed to use HAVING without GROUP BY when both select list and having clause have aggregate function. Closes 2364. @TarantoolBot document Title: HAVING without GROUP BY clause A query with a HAVING clause should also have a GROUP BY clause. Another ability is to use aggregate function both in select list and HAVING clause. Example: SELECT SUM(s1) FROM te40 HAVING SUM(s1) > 0; --- src/box/sql/resolve.c | 45 ++++++++++++++++---- src/box/sql/sqliteInt.h | 3 +- test/sql-tap/count.test.lua | 8 ++-- test/sql-tap/select3.test.lua | 2 +- test/sql-tap/select5.test.lua | 98 ++++++++++++++++++++++++++++++++++++++++++- 5 files changed, 141 insertions(+), 15 deletions(-) diff --git a/src/box/sql/resolve.c b/src/box/sql/resolve.c index 280ecd9..c38374d 100644 --- a/src/box/sql/resolve.c +++ b/src/box/sql/resolve.c @@ -600,6 +600,8 @@ resolveExprStep(Walker * pWalker, Expr * pExpr) /* A lone identifier is the name of a column. */ case TK_ID:{ + if ((pNC->ncFlags & NC_AllowAgg) != 0) + pNC->ncFlags |= NC_HasUnaggregatedId; return lookupName(pParse, 0, pExpr->u.zToken, pNC, pExpr); } @@ -1283,13 +1285,19 @@ resolveSelectStep(Walker * pWalker, Select * p) /* Set up the local name-context to pass to sqlite3ResolveExprNames() to * resolve the result-set expression list. */ + bool all_select_agg = true; sNC.ncFlags = NC_AllowAgg; sNC.pSrcList = p->pSrc; sNC.pNext = pOuterNC; - /* Resolve names in the result set. */ - if (sqlite3ResolveExprListNames(&sNC, p->pEList)) - return WRC_Abort; + for (i = 0; i < p->pEList->nExpr; i++) { + u16 has_agg_flag = sNC.ncFlags & NC_HasAgg; + sNC.ncFlags &= ~NC_HasAgg; + if (sqlite3ResolveExprNames(&sNC, p->pEList->a[i].pExpr)) + return WRC_Abort; + all_select_agg &= (sNC.ncFlags & NC_HasAgg) != 0; + sNC.ncFlags |= has_agg_flag; + } /* If there are no aggregate functions in the result-set, and no GROUP BY * expression, do not allow aggregates in any of the other expressions. @@ -1304,12 +1312,33 @@ resolveSelectStep(Walker * pWalker, Select * p) sNC.ncFlags &= ~NC_AllowAgg; } - /* If a HAVING clause is present, then there must be a GROUP BY clause. + /* + * If a HAVING clause is present, then there must + * be a GROUP BY clause or aggregate function + * should be specified. */ - if (p->pHaving && !pGroupBy) { - sqlite3ErrorMsg(pParse, - "a GROUP BY clause is required before HAVING"); - return WRC_Abort; + if (p->pHaving != NULL && pGroupBy == NULL) { + struct NameContext having_nc; + memset(&having_nc, 0, sizeof(having_nc)); + having_nc.pParse = pParse; + having_nc.ncFlags = NC_AllowAgg; + having_nc.pSrcList = p->pSrc; + if (all_select_agg && + sqlite3ResolveExprNames(&having_nc, + p->pHaving) != 0) + return WRC_Abort; + if ((having_nc.ncFlags & NC_HasAgg) == 0 || + (having_nc.ncFlags & NC_HasUnaggregatedId) != 0) { + const char *err_msg = + tt_sprintf("HAVING argument must " + "appear in the GROUP BY " + "clause or be used in an " + "aggregate function"); + diag_set(ClientError, ER_SQL, err_msg); + pParse->nErr++; + pParse->rc = SQL_TARANTOOL_ERROR; + return WRC_Abort; + } } /* Add the output column list to the name-context before parsing the diff --git a/src/box/sql/sqliteInt.h b/src/box/sql/sqliteInt.h index abb6829..6c08fd1 100644 --- a/src/box/sql/sqliteInt.h +++ b/src/box/sql/sqliteInt.h @@ -2528,7 +2528,8 @@ struct NameContext { #define NC_IdxExpr 0x0020 /* True if resolving columns of CREATE INDEX */ #define NC_VarSelect 0x0040 /* A correlated subquery has been seen */ #define NC_MinMaxAgg 0x1000 /* min/max aggregates seen. See note above */ - +/** One or more identifiers seen without aggregate function. */ +#define NC_HasUnaggregatedId 0x2000 /* * An instance of the following structure contains all information * needed to generate code for a single SELECT statement. diff --git a/test/sql-tap/count.test.lua b/test/sql-tap/count.test.lua index 45808de..700d047 100755 --- a/test/sql-tap/count.test.lua +++ b/test/sql-tap/count.test.lua @@ -172,15 +172,15 @@ test:do_test( return uses_op_count("SELECT count(*) FROM t2 WHERE a IS NOT NULL") end, 0) -test:do_catchsql_test( +test:do_execsql_test( "count-2.9", [[ SELECT count(*) FROM t2 HAVING count(*)>1 - ]], { + ]], -- - 1, "a GROUP BY clause is required before HAVING" + {} -- - }) + ) test:do_test( "count-2.10", diff --git a/test/sql-tap/select3.test.lua b/test/sql-tap/select3.test.lua index d49bb87..c2e901e 100755 --- a/test/sql-tap/select3.test.lua +++ b/test/sql-tap/select3.test.lua @@ -200,7 +200,7 @@ test:do_catchsql_test("select3-3.1", [[ SELECT log, count(*) FROM t1 HAVING log>=4 ]], { -- - 1, "a GROUP BY clause is required before HAVING" + 1, "SQL error: HAVING argument must appear in the GROUP BY clause or be used in an aggregate function" -- }) diff --git a/test/sql-tap/select5.test.lua b/test/sql-tap/select5.test.lua index 7ca25ae..d5bab1d 100755 --- a/test/sql-tap/select5.test.lua +++ b/test/sql-tap/select5.test.lua @@ -1,6 +1,6 @@ #!/usr/bin/env tarantool test = require("sqltester") -test:plan(32) +test:plan(41) --!./tcltestrunner.lua -- 2001 September 15 @@ -412,5 +412,101 @@ test:do_execsql_test( -- }) +-- +-- gh-2364: Support HAVING without GROUP BY clause. +-- +test:do_catchsql_test( + "select5-9.1", + [[ + CREATE TABLE te40 (s1 INT, s2 INT, PRIMARY KEY (s1,s2)); + INSERT INTO te40 VALUES (1,1); + INSERT INTO te40 VALUES (2,2); + SELECT s1 FROM te40 HAVING s1 = 1; + ]], { + -- + 1, "SQL error: HAVING argument must appear in the GROUP BY clause or be used in an aggregate function" + -- +}) + +test:do_catchsql_test( + "select5-9.2", + [[ + SELECT SUM(s1) FROM te40 HAVING s1 = 2; + ]], { + -- + 1, "SQL error: HAVING argument must appear in the GROUP BY clause or be used in an aggregate function" + -- +}) + +test:do_catchsql_test( + "select5-9.3", + [[ + SELECT s1 FROM te40 HAVING SUM(s1) = 2; + ]], { + -- + 1, "SQL error: HAVING argument must appear in the GROUP BY clause or be used in an aggregate function" + -- +}) + +test:do_execsql_test( + "select5-9.4", + [[ + SELECT SUM(s1) FROM te40 HAVING SUM(s1) > 0; + ]], { + -- + 3 + -- +}) + +test:do_execsql_test( + "select5-9.5", + [[ + SELECT MIN(s1) FROM te40 HAVING SUM(s1) > 0; + ]], { + -- + 1 + -- +}) + +test:do_execsql_test( + "select5-9.6", + [[ + SELECT SUM(s1) FROM te40 HAVING SUM(s1) < 0; + ]], + -- + {} + -- +) + +test:do_catchsql_test( + "select5-9.7", + [[ + SELECT SUM(s1),s2 FROM te40 HAVING SUM(s1) > 0; + ]], { + -- + 1, "SQL error: HAVING argument must appear in the GROUP BY clause or be used in an aggregate function" + -- +}) + +test:do_catchsql_test( + "select5-9.8", + [[ + SELECT SUM(s1) FROM te40 HAVING SUM(s1) > 0 and s2 > 0; + ]], { + -- + 1, "SQL error: HAVING argument must appear in the GROUP BY clause or be used in an aggregate function" + -- +}) + +test:do_execsql_test( + "select5-9.9", + [[ + SELECT SUM(s1) FROM te40 HAVING SUM(s1) > 0 and SUM(s2) > 0; + ]], { + -- + 3 + -- +}) + test:finish_test() -- 2.7.4