修复了关于rownum的4个bug。

1.最大值只有255,正常应该是无限大。
2.group by跟where rownum < n同时存在时,禁止将rownum优化成limit
3.groupy by后面没有rownum,而having后面有rownum时,会正常运行,正常应该报错。
4.union前后的子句如果有where rownum < n,并且还有含有order by的子查询时,禁止将order by优化删除掉。
This commit is contained in:
zhouxiongjia
2020-10-21 17:45:44 +08:00
parent 916c0cfbe0
commit dc80b79cc0
6 changed files with 89 additions and 3 deletions

View File

@ -740,6 +740,26 @@ static bool check_ungrouped_columns_walker(Node* node, check_ungrouped_columns_c
}
}
/* If There is ROWNUM, it must appear in the GROUP BY clause or be used in an aggregate function. */
if (IsA(node, Rownum)) {
Rownum *rownumVar = (Rownum *)node;
bool haveRownum = false;
if (!context->have_non_var_grouping || context->sublevels_up != 0) {
foreach (gl, context->groupClauses) {
Node *gnode = (Node *)((TargetEntry *)lfirst(gl))->expr;
if (IsA(gnode, Rownum)) {
haveRownum = true;
break;
}
}
if (haveRownum == false) {
ereport(ERROR, (errcode(ERRCODE_GROUPING_ERROR),
errmsg("ROWNUM must appear in the GROUP BY clause or be used in an aggregate function"),
parser_errposition(context->pstate, rownumVar->location)));
}
}
}
/*
* If we have an ungrouped Var of the original query level, we have a
* failure. Vars below the original query level are not a problem, and

View File

@ -2963,8 +2963,8 @@ void preprocess_rownum(PlannerInfo *root, Query *parse)
if (quals == NULL) {
return;
}
/* If it includes {order by}, can not be rewrited */
if (parse->sortClause != NULL) {
/* If it includes {order by} or {group by}, can not be rewrited */
if ((parse->sortClause != NULL) || (parse->groupClause != NULL)) {
return;
}
if (parse->limitCount != NULL) {

View File

@ -1941,6 +1941,10 @@ static void reduce_orderby_recurse(Query* query, Node* jtnode, bool reduce)
/* Reduce orderby clause in subquery for join or from clause of more than one rte */
reduce_orderby_final(rte, reduce);
} else if (IsA(jtnode, FromExpr)) {
/* If there is ROWNUM, can not reduce orderby clause in subquery */
if (contain_rownum_walker(jtnode, NULL)) {
return;
}
FromExpr* f = (FromExpr*)jtnode;
ListCell* l = NULL;
bool flag = false;

View File

@ -979,7 +979,7 @@ static Datum ExecEvalRownum(RownumState* exprstate, ExprContext* econtext, bool*
*isDone = ExprSingleResult;
*isNull = false;
return Int8GetDatum(exprstate->ps->ps_rownum + 1);
return Int64GetDatum(exprstate->ps->ps_rownum + 1);
}
/* ----------------------------------------------------------------

View File

@ -241,7 +241,31 @@ select rownum + 1 rn from dual group by rn;
----
2
(1 row)
--test having
select id from distributors group by rownum,id having rownum < 5;
id
----
1
1
1
1
(4 rows)
select rownum from distributors group by rownum having rownum < 5;
rownum
--------
3
1
2
4
(4 rows)
select id from distributors group by id having rownum < 5;
ERROR: ROWNUM must appear in the GROUP BY clause or be used in an aggregate function
LINE 1: select id from distributors group by id having rownum < 5;
^
--test alias name after where
select rownum rn, name from distributors where rn<3;
ERROR: Alias "rn" reference with ROWNUM included is invalid.
@ -1645,5 +1669,32 @@ explain select * from test where rownum < 5 order by 1;
(4 rows)
-- ROWNUM with GROUP BY
explain select id from test where rownum < 5 group by id;
QUERY PLAN
-------------------------------------------------------------
HashAggregate (cost=25.12..25.79 rows=67 width=4)
Group By Key: id
-> Seq Scan on test (cost=0.00..24.18 rows=378 width=4)
Filter: (ROWNUM < 5)
(4 rows)
-- ROWNUM with UNION and ORDER BY
explain select id from student where rownum < 3 union select id from (select id from student order by 1) where rownum < 5;
QUERY PLAN
-----------------------------------------------------------------------------------
HashAggregate (cost=79.04..79.10 rows=6 width=4)
Group By Key: public.student.id
-> Append (cost=0.00..79.02 rows=6 width=4)
-> Limit (cost=0.00..0.04 rows=2 width=4)
-> Seq Scan on student (cost=0.00..21.34 rows=1134 width=4)
-> Limit (cost=78.87..78.92 rows=4 width=4)
-> Sort (cost=78.87..81.71 rows=1134 width=4)
Sort Key: public.student.id
-> Seq Scan on student (cost=0.00..21.34 rows=1134 width=4)
(9 rows)
drop table student;
drop table test;

View File

@ -85,6 +85,11 @@ select rownum from distributors group by rownum;
select rownum rn from distributors group by rn;
select rownum + 1 from dual group by rownum;
select rownum + 1 rn from dual group by rn;
--test having
select id from distributors group by rownum,id having rownum < 5;
select rownum from distributors group by rownum having rownum < 5;
select id from distributors group by id having rownum < 5;
--test alias name after where
select rownum rn, name from distributors where rn<3;
select rownum rowno2, * from (select rownum rowno1, * from distributors order by id desc) where rowno2 < 2;
@ -447,5 +452,11 @@ explain select * from student where not(rownum > 3 or id = 1);
-- ROWNUM with ORDER BY
explain select * from test where rownum < 5 order by 1;
-- ROWNUM with GROUP BY
explain select id from test where rownum < 5 group by id;
-- ROWNUM with UNION and ORDER BY
explain select id from student where rownum < 3 union select id from (select id from student order by 1) where rownum < 5;
drop table student;
drop table test;