Ban some useage of ROWNUM
1.Ban ROWNUM in INSERT...VALUES() STATEMENT 2.Ban ROWNUM after DEFAULT when creating table 3.Ban ROWNUM in VALUES clause that's being used as a standalone SELECT like select * from (values(rownum,1)), x(a,b)
This commit is contained in:
@ -3442,11 +3442,17 @@ Node* cookDefault(ParseState* pstate, Node* raw_default, Oid atttypid, int32 att
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_INVALID_COLUMN_REFERENCE), errmsg("cannot use column references in default expression")));
|
||||
|
||||
/*
|
||||
* Make sure default expr does not refer to rownum.
|
||||
*/
|
||||
ExcludeRownumExpr(pstate, expr);
|
||||
|
||||
/*
|
||||
* It can't return a set either.
|
||||
*/
|
||||
if (expression_returns_set(expr))
|
||||
ereport(ERROR, (errcode(ERRCODE_DATATYPE_MISMATCH), errmsg("default expression must not return a set")));
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_DATATYPE_MISMATCH), errmsg("default expression must not return a set")));
|
||||
|
||||
/*
|
||||
* No subplans or aggregates, either...
|
||||
|
||||
@ -1383,6 +1383,9 @@ int exprLocation(const Node* expr)
|
||||
/* just use typename's location */
|
||||
loc = exprLocation((Node*)((const FunctionParameter*)expr)->argType);
|
||||
break;
|
||||
case T_Rownum:
|
||||
loc = ((const Rownum*)expr)->location;
|
||||
break;
|
||||
default:
|
||||
/* for any other node type it's just unknown... */
|
||||
loc = -1;
|
||||
|
||||
@ -1536,6 +1536,10 @@ List* transformInsertRow(ParseState* pstate, List* exprlist, List* stmtcols, Lis
|
||||
foreach (lc, exprlist) {
|
||||
Expr* expr = (Expr*)lfirst(lc);
|
||||
ResTarget* col = NULL;
|
||||
/*
|
||||
* Rownum is not allowed in exprlist in INSERT statement.
|
||||
*/
|
||||
ExcludeRownumExpr(pstate, (Node*)expr);
|
||||
|
||||
col = (ResTarget*)lfirst(icols);
|
||||
AssertEreport(IsA(col, ResTarget), MOD_OPT, "nodeType inconsistant");
|
||||
@ -1802,7 +1806,7 @@ static Query* transformValuesClause(ParseState* pstate, SelectStmt* stmt)
|
||||
|
||||
/*
|
||||
* For each row of VALUES, transform the raw expressions. This is also a
|
||||
* handy place to reject DEFAULT nodes, which the grammar allows for
|
||||
* handy place to reject DEFAULT nodes and Rownum, which the grammar allows for
|
||||
* simplicity.
|
||||
*
|
||||
* Note that the intermediate representation we build is column-organized
|
||||
@ -1832,7 +1836,7 @@ static Query* transformValuesClause(ParseState* pstate, SelectStmt* stmt)
|
||||
parser_errposition(pstate, exprLocation((Node*)sublist))));
|
||||
}
|
||||
|
||||
/* Check for DEFAULT and build per-column expression lists */
|
||||
/* Check for DEFAULT and Rownum, then build per-column expression lists */
|
||||
i = 0;
|
||||
foreach (lc2, sublist) {
|
||||
Node* col = (Node*)lfirst(lc2);
|
||||
@ -1842,9 +1846,13 @@ static Query* transformValuesClause(ParseState* pstate, SelectStmt* stmt)
|
||||
(errcode(ERRCODE_SYNTAX_ERROR),
|
||||
errmsg("DEFAULT can only appear in a VALUES list within INSERT"),
|
||||
parser_errposition(pstate, exprLocation(col))));
|
||||
}
|
||||
}
|
||||
|
||||
ExcludeRownumExpr(pstate, col);
|
||||
|
||||
colexprs[i] = lappend(colexprs[i], col);
|
||||
i++;
|
||||
|
||||
}
|
||||
|
||||
/* Release sub-list's cells to save memory */
|
||||
|
||||
@ -15,6 +15,8 @@
|
||||
#define CLAUSES_H
|
||||
|
||||
#include "nodes/relation.h"
|
||||
#include "parser/parse_node.h"
|
||||
#include "nodes/nodeFuncs.h"
|
||||
|
||||
#define is_opclause(clause) ((clause) != NULL && IsA(clause, OpExpr))
|
||||
#define is_funcclause(clause) ((clause) != NULL && IsA(clause, FuncExpr))
|
||||
@ -112,6 +114,16 @@ static inline bool contain_rownum_expr(Node *node)
|
||||
return contain_rownum_walker(node, NULL);
|
||||
}
|
||||
|
||||
/* Check if it includes Rownum */
|
||||
static inline void ExcludeRownumExpr(ParseState* pstate, Node* expr)
|
||||
{
|
||||
if (contain_rownum_expr(expr))
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_SYNTAX_ERROR),
|
||||
errmsg("specified ROWNUM is not allowed here."),
|
||||
parser_errposition(pstate, exprLocation(expr))));
|
||||
}
|
||||
|
||||
extern List* get_quals_lists(Node *jtnode);
|
||||
|
||||
#endif /* CLAUSES_H */
|
||||
|
||||
@ -251,7 +251,29 @@ select rownum rowno2, * from (select rownum rowno1, * from distributors order by
|
||||
ERROR: Alias "rowno2" reference with ROWNUM included is invalid.
|
||||
LINE 1: ...wno1, * from distributors order by id desc) where rowno2 < 2...
|
||||
^
|
||||
|
||||
--test default rownum when creating table
|
||||
create table student(id int default rownum, stuname varchar(5));
|
||||
ERROR: specified ROWNUM is not allowed here.
|
||||
create table student(id int default rownum+1, stuname varchar(5));
|
||||
ERROR: specified ROWNUM is not allowed here.
|
||||
--test insert when values include rownum
|
||||
insert into distributors values (rownum, 'qwer');
|
||||
ERROR: specified ROWNUM is not allowed here.
|
||||
LINE 1: insert into distributors values (rownum, 'qwer');
|
||||
^
|
||||
insert into distributors(id, name) values (2, 'abcd'), (rownum+1, 'qwer');
|
||||
ERROR: specified ROWNUM is not allowed here.
|
||||
LINE 1: ... into distributors(id, name) values (2, 'abcd'), (rownum+1, ...
|
||||
^
|
||||
--test VALUES clause that's being used as a standalone SELECT
|
||||
select * from (values(rownum, 1)) x(a, b);
|
||||
ERROR: specified ROWNUM is not allowed here.
|
||||
LINE 1: select * from (values(rownum, 1)) x(a, b);
|
||||
^
|
||||
select * from (values(rownum+1, 1)) x(a, b);
|
||||
ERROR: specified ROWNUM is not allowed here.
|
||||
LINE 1: select * from (values(rownum+1, 1)) x(a, b);
|
||||
^
|
||||
--test except and minus
|
||||
--create test table
|
||||
create table except_table (a int, b int);
|
||||
|
||||
@ -88,6 +88,15 @@ select rownum + 1 rn from dual group by rn;
|
||||
--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;
|
||||
--test default rownum when creating table
|
||||
create table student(id int default rownum, stuname varchar(5));
|
||||
create table student(id int default rownum+1, stuname varchar(5));
|
||||
--test insert when values include rownum
|
||||
insert into distributors values (rownum, 'qwer');
|
||||
insert into distributors(id, name) values (2, 'abcd'), (rownum+1, 'qwer');
|
||||
--test VALUES clause that's being used as a standalone SELECT
|
||||
select * from (values(rownum, 1)) x(a, b);
|
||||
select * from (values(rownum+1, 1)) x(a, b);
|
||||
|
||||
--test except and minus
|
||||
--create test table
|
||||
|
||||
Reference in New Issue
Block a user