From b70b84d1443107eca55a100b8246ae12f280e883 Mon Sep 17 00:00:00 2001 From: pufuan Date: Sat, 25 Jul 2020 14:11:19 +0800 Subject: [PATCH] [PATCH] support ROWNUM in openGauss Signed-off-by: pufuan --- src/common/backend/catalog/system_views.sql | 2 +- src/common/backend/nodes/copyfuncs.cpp | 17 + src/common/backend/nodes/nodeFuncs.cpp | 16 + src/common/backend/nodes/outfuncs.cpp | 11 + src/common/backend/nodes/readfuncs.cpp | 14 + src/common/backend/parser/gram.y | 9 +- src/common/backend/parser/parse_expr.cpp | 1 + src/common/backend/parser/parse_target.cpp | 3 + src/common/backend/utils/adt/ruleutils.cpp | 4 + src/gausskernel/optimizer/path/allpaths.cpp | 7 +- src/gausskernel/optimizer/plan/initsplan.cpp | 1 - src/gausskernel/optimizer/plan/planner.cpp | 1 + .../optimizer/prep/prepjointree.cpp | 43 +- src/gausskernel/optimizer/util/clauses.cpp | 48 ++- src/gausskernel/runtime/executor/execAmi.cpp | 3 + .../runtime/executor/execProcnode.cpp | 4 + src/gausskernel/runtime/executor/execQual.cpp | 19 + src/include/nodes/execnodes.h | 14 +- src/include/nodes/nodes.h | 2 + src/include/nodes/primnodes.h | 11 + src/include/nodes/relation.h | 2 + src/include/optimizer/clauses.h | 3 + src/include/parser/kwlist.h | 1 + src/test/regress/expected/xc_rownum.out | 367 ++++++++++++++++++ src/test/regress/input/copy_error_log.source | 8 +- src/test/regress/output/copy_error_log.source | 12 +- src/test/regress/parallel_schedule0 | 2 +- src/test/regress/sql/xc_rownum.sql | 167 ++++++++ 28 files changed, 774 insertions(+), 18 deletions(-) create mode 100644 src/test/regress/expected/xc_rownum.out create mode 100644 src/test/regress/sql/xc_rownum.sql diff --git a/src/common/backend/catalog/system_views.sql b/src/common/backend/catalog/system_views.sql index f3de939c7..979474336 100644 --- a/src/common/backend/catalog/system_views.sql +++ b/src/common/backend/catalog/system_views.sql @@ -2752,7 +2752,7 @@ DECLARE query_str_do_revoke text; BEGIN query_str_create_table := 'CREATE TABLE public.pgxc_copy_error_log - (relname varchar, begintime timestamptz, filename varchar, rownum int8, rawrecord text, detail text)'; + (relname varchar, begintime timestamptz, filename varchar, lineno int8, rawrecord text, detail text)'; EXECUTE query_str_create_table; query_str_create_index := 'CREATE INDEX copy_error_log_relname_idx ON public.pgxc_copy_error_log(relname)'; diff --git a/src/common/backend/nodes/copyfuncs.cpp b/src/common/backend/nodes/copyfuncs.cpp index b59d404e9..da6068bb0 100644 --- a/src/common/backend/nodes/copyfuncs.cpp +++ b/src/common/backend/nodes/copyfuncs.cpp @@ -2267,6 +2267,20 @@ static Param* _copyParam(const Param* from) return newnode; } +/* + * _copyRownum + */ +static Rownum* _copyRownum(const Rownum* from) +{ + Rownum* newnode = (Rownum*)makeNode(Rownum); + + COPY_SCALAR_FIELD(rownumcollid); + COPY_LOCATION_FIELD(location); + + return newnode; +} + + /* * _copyAggref */ @@ -6011,6 +6025,9 @@ void* copyObject(const void* from) case T_Param: retval = _copyParam((Param*)from); break; + case T_Rownum: + retval = _copyRownum((Rownum*)from); + break; case T_Aggref: retval = _copyAggref((Aggref*)from); break; diff --git a/src/common/backend/nodes/nodeFuncs.cpp b/src/common/backend/nodes/nodeFuncs.cpp index e7f9085bc..be725270e 100755 --- a/src/common/backend/nodes/nodeFuncs.cpp +++ b/src/common/backend/nodes/nodeFuncs.cpp @@ -223,6 +223,9 @@ Oid exprType(const Node* expr) case T_GroupingId: type = INT4OID; break; + case T_Rownum: + type = INT8OID; + break; default: ereport(ERROR, (errcode(ERRCODE_UNRECOGNIZED_NODE_TYPE), errmsg("unrecognized node type: %d", (int)nodeTag(expr)))); @@ -673,6 +676,9 @@ Oid exprCollation(const Node* expr) case T_Const: coll = ((const Const*)expr)->constcollid; break; + case T_Rownum: + coll = ((const Rownum*)expr)->rownumcollid; + break; case T_Param: coll = ((const Param*)expr)->paramcollid; break; @@ -900,6 +906,9 @@ void exprSetCollation(Node* expr, Oid collation) case T_Const: ((Const*)expr)->constcollid = collation; break; + case T_Rownum: + ((Rownum*)expr)->rownumcollid = collation; + break; case T_Param: ((Param*)expr)->paramcollid = collation; break; @@ -1528,6 +1537,7 @@ bool expression_tree_walker(Node* node, bool (*walker)(), void* context) case T_BitString: case T_Null: case T_PgFdwRemoteInfo: + case T_Rownum: /* primitive node types with no expression subnodes */ break; case T_Aggref: { @@ -2085,6 +2095,12 @@ Node* expression_tree_mutator(Node* node, Node* (*mutator)(Node*, void*), void* /* XXX we don't bother with datumCopy; should we? */ return (Node*)newnode; } break; + case T_Rownum: { + Rownum* oldnode = (Rownum*)node; + Rownum* newnode = NULL; + FLATCOPY(newnode, oldnode, Rownum, isCopy); + return (Node*)newnode; + } break; case T_Param: case T_CoerceToDomainValue: case T_CaseTestExpr: diff --git a/src/common/backend/nodes/outfuncs.cpp b/src/common/backend/nodes/outfuncs.cpp index 6cce0a67b..bfe7eed9b 100755 --- a/src/common/backend/nodes/outfuncs.cpp +++ b/src/common/backend/nodes/outfuncs.cpp @@ -1952,6 +1952,14 @@ static void _outParam(StringInfo str, Param* node) WRITE_TYPEINFO_FIELD(paramtype); } +static void _outRownum(StringInfo str, const Rownum* node) +{ + WRITE_NODE_TYPE("ROWNUM"); + WRITE_OID_FIELD(rownumcollid); + WRITE_LOCATION_FIELD(location); +} + + static void _outAggref(StringInfo str, Aggref* node) { WRITE_NODE_TYPE("AGGREF"); @@ -4975,6 +4983,9 @@ static void _outNode(StringInfo str, const void* obj) case T_Param: _outParam(str, (Param*)obj); break; + case T_Rownum: + _outRownum(str, (Rownum*)obj); + break; case T_Aggref: _outAggref(str, (Aggref*)obj); break; diff --git a/src/common/backend/nodes/readfuncs.cpp b/src/common/backend/nodes/readfuncs.cpp index 824adba79..025cd2f4b 100644 --- a/src/common/backend/nodes/readfuncs.cpp +++ b/src/common/backend/nodes/readfuncs.cpp @@ -1541,6 +1541,18 @@ static Var* _readVar(void) READ_DONE(); } +/* + * _readRownum + */ +static Rownum* _readRownum(void) +{ + READ_LOCALS(Rownum); + + READ_OID_FIELD(rownumcollid); + READ_LOCATION_FIELD(location); + READ_DONE(); +} + /* * _readConst */ @@ -5182,6 +5194,8 @@ Node* parseNodeString(void) return_value = _readSplitPartitionState(); } else if (MATCH("ADDPARTITIONSTATE", 17)) { return_value = _readAddPartitionState(); + } else if (MATCH("ROWNUM", 6)) { + return_value = _readRownum(); } else { ereport(ERROR, (errcode(ERRCODE_UNRECOGNIZED_NODE_TYPE), diff --git a/src/common/backend/parser/gram.y b/src/common/backend/parser/gram.y index b3b9714ad..e1f7bff51 100755 --- a/src/common/backend/parser/gram.y +++ b/src/common/backend/parser/gram.y @@ -681,7 +681,7 @@ static void ParseUpdateMultiSet(List *set_target_list, SelectStmt *stmt, core_yy RANGE RAW READ REAL REASSIGN REBUILD RECHECK RECURSIVE REF REFERENCES REINDEX REJECT_P RELATIVE_P RELEASE RELOPTIONS REMOTE_P RENAME REPEATABLE REPLACE REPLICA RESET RESIZE RESOURCE RESTART RESTRICT RETURN RETURNING RETURNS REUSE REVOKE RIGHT ROLE ROLLBACK ROLLUP - ROW ROWS RULE + ROW ROWNUM ROWS RULE SAVEPOINT SCHEMA SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES SERIALIZABLE SERVER SESSION SESSION_USER SET SETS SETOF SHARE SHIPPABLE SHOW SHUTDOWN @@ -16109,6 +16109,12 @@ func_expr_common_subexpr: n->call_func = false; $$ = (Node *)n; } + | ROWNUM + { + Rownum *r = makeNode(Rownum); + r->location = @1; + $$ = (Node *)r; + } | CURRENT_ROLE { FuncCall *n = makeNode(FuncCall); @@ -18148,6 +18154,7 @@ reserved_keyword: | WHERE | WINDOW | WITH + | ROWNUM ; %% diff --git a/src/common/backend/parser/parse_expr.cpp b/src/common/backend/parser/parse_expr.cpp index f1b0d28ad..e1312395e 100644 --- a/src/common/backend/parser/parse_expr.cpp +++ b/src/common/backend/parser/parse_expr.cpp @@ -301,6 +301,7 @@ Node* transformExpr(ParseState* pstate, Node* expr) case T_WindowFunc: case T_ArrayRef: case T_FuncExpr: + case T_Rownum: case T_OpExpr: case T_DistinctExpr: case T_NullIfExpr: diff --git a/src/common/backend/parser/parse_target.cpp b/src/common/backend/parser/parse_target.cpp index 3e41b6256..144ae7abd 100755 --- a/src/common/backend/parser/parse_target.cpp +++ b/src/common/backend/parser/parse_target.cpp @@ -1482,6 +1482,9 @@ static int FigureColnameInternal(Node* node, char** name) /* make GROUPING() act like a regular function */ *name = "grouping"; return 2; + case T_Rownum: + *name = "rownum"; + return 2; case T_SubLink: switch (((SubLink*)node)->subLinkType) { case EXISTS_SUBLINK: diff --git a/src/common/backend/utils/adt/ruleutils.cpp b/src/common/backend/utils/adt/ruleutils.cpp index be6ccf39e..0dedcbc6f 100755 --- a/src/common/backend/utils/adt/ruleutils.cpp +++ b/src/common/backend/utils/adt/ruleutils.cpp @@ -7445,6 +7445,10 @@ static void get_rule_expr(Node* node, deparse_context* context, bool showimplici pfree_ext(tmp); } break; + + case T_Rownum: + appendStringInfo(buf, "ROWNUM"); + break; case T_Const: get_const_expr((Const*)node, context, 0); diff --git a/src/gausskernel/optimizer/path/allpaths.cpp b/src/gausskernel/optimizer/path/allpaths.cpp index 45b60fc02..986a10ef2 100755 --- a/src/gausskernel/optimizer/path/allpaths.cpp +++ b/src/gausskernel/optimizer/path/allpaths.cpp @@ -2394,8 +2394,13 @@ static bool qual_is_pushdown_safe(Query* subquery, Index rti, Node* qual, const ListCell* vl = NULL; /* Refuse subselects (point 1) */ - if (contain_subplans(qual)) + if (contain_subplans(qual)) { return false; + } + + if(contain_volatile_functions(qual)) { + return false; + } /* * It would be unsafe to push down window function calls, but at least for diff --git a/src/gausskernel/optimizer/plan/initsplan.cpp b/src/gausskernel/optimizer/plan/initsplan.cpp index e5b569356..7379025b0 100755 --- a/src/gausskernel/optimizer/plan/initsplan.cpp +++ b/src/gausskernel/optimizer/plan/initsplan.cpp @@ -350,7 +350,6 @@ static List* deconstruct_recurse( */ foreach (l, (List*)f->quals) { Node* qual = (Node*)lfirst(l); - distribute_qual_to_rels( root, qual, false, below_outer_join, JOIN_INNER, root->qualSecurityLevel, *qualscope, NULL, NULL, NULL); } diff --git a/src/gausskernel/optimizer/plan/planner.cpp b/src/gausskernel/optimizer/plan/planner.cpp index b191a181e..6553eb7ef 100644 --- a/src/gausskernel/optimizer/plan/planner.cpp +++ b/src/gausskernel/optimizer/plan/planner.cpp @@ -1018,6 +1018,7 @@ Plan* subquery_planner(PlannerGlobal* glob, Query* parse, PlannerInfo* parent_ro root->rowMarks = NIL; root->hasInheritedTarget = false; root->grouping_map = NULL; + root->hasRownumQual = false; /* * Apply memory context for query rewrite in optimizer. diff --git a/src/gausskernel/optimizer/prep/prepjointree.cpp b/src/gausskernel/optimizer/prep/prepjointree.cpp index 22ab3bc39..e3dd08871 100755 --- a/src/gausskernel/optimizer/prep/prepjointree.cpp +++ b/src/gausskernel/optimizer/prep/prepjointree.cpp @@ -89,6 +89,8 @@ static Node* find_jointree_node_for_rel(Node* jtnode, int relid); static Node* deleteRelatedNullTest(Node* node, PlannerInfo* root); static Node* reduce_inequality_fulljoins_jointree_recurse(PlannerInfo* root, Node* jtnode); +static bool find_rownum_in_quals(PlannerInfo *root); + /* * pull_up_sublinks * Attempt to pull up ANY and EXISTS SubLinks to be treated as @@ -122,6 +124,11 @@ void pull_up_sublinks(PlannerInfo* root) Node* jtnode = NULL; Relids relids; + /* if quals include rownum, forbid pulling up sublinks */ + if (find_rownum_in_quals(root)) { + return; + } + /* Begin recursion through the jointree */ jtnode = pull_up_sublinks_jointree_recurse(root, (Node*)root->parse->jointree, &relids); /* @@ -744,6 +751,12 @@ Node* pull_up_subqueries( { if (jtnode == NULL) return NULL; + + /* if quals include rownum, set hasRownumQual to true */ + if(find_rownum_in_quals(root)) { + root->hasRownumQual = true; + } + if (IsA(jtnode, RangeTblRef)) { int varno = ((RangeTblRef*)jtnode)->rtindex; RangeTblEntry* rte = rt_fetch(varno, root->parse->rtable); @@ -775,7 +788,7 @@ Node* pull_up_subqueries( * the branchs may be in different node group, we could not determine the * group for append path */ - if (rte->rtekind == RTE_SUBQUERY && is_simple_union_all(rte->subquery) && + if (rte->rtekind == RTE_SUBQUERY && is_simple_union_all(rte->subquery) && !root->hasRownumQual && (!ng_is_multiple_nodegroup_scenario())) return pull_up_simple_union_all(root, jtnode, rte); @@ -924,6 +937,7 @@ static Node* pull_up_simple_subquery(PlannerInfo* root, Node* jtnode, RangeTblEn subroot->qualSecurityLevel = 0; subroot->wt_param_id = -1; subroot->non_recursive_plan = NULL; + subroot->hasRownumQual = root->hasRownumQual; /* No CTEs to worry about */ AssertEreport( @@ -2886,3 +2900,30 @@ static Node* reduce_inequality_fulljoins_jointree_recurse(PlannerInfo* root, Nod return jtnode; } +static bool find_rownum_in_quals(PlannerInfo *root) +{ + if (root->parse == NULL) { + return false; + } + + if(root->hasRownumQual) { + return true; + } + + bool hasRownum = false; + ListCell *qualcell = NULL; + List *quallist = get_quals_lists((Node *)root->parse->jointree); + foreach (qualcell, quallist) { + Node *clause = (Node *)lfirst(qualcell); + if (contain_rownum_walker(clause, NULL)) { + hasRownum = true; + break; + } + } + + if (quallist) { + list_free(quallist); + } + + return hasRownum; +} diff --git a/src/gausskernel/optimizer/util/clauses.cpp b/src/gausskernel/optimizer/util/clauses.cpp index 95e1182db..e23e379fc 100644 --- a/src/gausskernel/optimizer/util/clauses.cpp +++ b/src/gausskernel/optimizer/util/clauses.cpp @@ -1119,6 +1119,9 @@ static bool contain_specified_functions_walker(Node* node, check_function_contex return true; } /* else fall through to check args */ + } else if (IsA(node, Rownum)) { + /* ROWNUM is volatile */ + return context->checktype == CONTAIN_VOLATILE_FUNTION; } return expression_tree_walker(node, (bool (*)())contain_specified_functions_walker, context); } @@ -5161,8 +5164,51 @@ static Node* convert_equalsimplevar_to_nulltest(Oid opno, List* args) rarg = (Node*)lsecond(args); if (_equalSimpleVar(larg, rarg) && ((Var*)larg)->varlevelsup == ((Var*)rarg)->varlevelsup && - (get_oprrest(opno) == EQSELRETURNOID)) + (get_oprrest(opno) == EQSELRETURNOID)) { nullTest = (Node*)makeNullTest(IS_NOT_NULL, (Expr*)larg); + } return nullTest; } + + + +/* + * check whether the node have rownum expr or not, test all kinds of nodes, + * check if it has the volatile rownum. If the node include rownum + * function, it will return true, else it will return false. + */ +bool contain_rownum_walker(Node *node, void *context) +{ + if (node == NULL) { + return false; + } + + if (IsA(node, Rownum)) { + return true; + } + + return expression_tree_walker(node, (bool (*)())contain_rownum_walker, context); +} + + +/* + * get the jtnode's qualifiers list, make query tree's table jion tree's + * qualifiers to be a list. Then return the list. (parse->jointree->quals: + * 'where clause' and 'and clause') + */ +List *get_quals_lists(Node *jtnode) +{ + if (jtnode == NULL || !IsA(jtnode, FromExpr)) { + return NULL; + } + + FromExpr *expr = (FromExpr *)jtnode; + List *quallist = make_ands_implicit((Expr *)expr->quals); + + if (expr->quals != NULL && and_clause((Node *)expr->quals)) { + quallist = list_copy(quallist); + } + + return quallist; +} diff --git a/src/gausskernel/runtime/executor/execAmi.cpp b/src/gausskernel/runtime/executor/execAmi.cpp index 7d70d0b3b..e30bb139e 100755 --- a/src/gausskernel/runtime/executor/execAmi.cpp +++ b/src/gausskernel/runtime/executor/execAmi.cpp @@ -269,6 +269,9 @@ void ExecReScan(PlanState* node) InstrEndLoop(node->instrument); } + /* reset the rownum */ + node->ps_rownum = 0; + /* * If we have changed parameters, propagate that info. * diff --git a/src/gausskernel/runtime/executor/execProcnode.cpp b/src/gausskernel/runtime/executor/execProcnode.cpp index 8cdfa0aea..a448f0d15 100755 --- a/src/gausskernel/runtime/executor/execProcnode.cpp +++ b/src/gausskernel/runtime/executor/execProcnode.cpp @@ -560,6 +560,8 @@ PlanState* ExecInitNode(Plan* node, EState* e_state, int e_flags) /* restore the per query context */ e_state->es_query_cxt = query_context; + result->ps_rownum = 0; + gstrace_exit(GS_TRC_ID_ExecInitNode); return result; } @@ -743,6 +745,8 @@ TupleTableSlot* ExecProcNode(PlanState* node) MemoryContextSwitchTo(old_context); + node->ps_rownum++; + return result; } diff --git a/src/gausskernel/runtime/executor/execQual.cpp b/src/gausskernel/runtime/executor/execQual.cpp index 8af1f6812..40df8c80f 100755 --- a/src/gausskernel/runtime/executor/execQual.cpp +++ b/src/gausskernel/runtime/executor/execQual.cpp @@ -969,6 +969,19 @@ static Datum ExecEvalConst(ExprState* exprstate, ExprContext* econtext, bool* is return con->constvalue; } +/* ---------------------------------------------------------------- + * ExecEvalRownum: Returns the rownum + * ---------------------------------------------------------------- + */ +static Datum ExecEvalRownum(RownumState* exprstate, ExprContext* econtext, bool* isNull, ExprDoneCond* isDone) +{ + if (isDone != NULL) + *isDone = ExprSingleResult; + *isNull = false; + + return Int8GetDatum(exprstate->ps->ps_rownum + 1); +} + /* ---------------------------------------------------------------- * ExecEvalParamExec * @@ -5232,6 +5245,12 @@ ExprState* ExecInitExpr(Expr* node, PlanState* parent) gstrace_exit(GS_TRC_ID_ExecInitExpr); return (ExprState*)outlist; } + case T_Rownum: { + RownumState* rnstate = (RownumState*)makeNode(RownumState); + rnstate->ps = parent; + state = (ExprState*)rnstate; + state->evalfunc = (ExprStateEvalFunc)ExecEvalRownum; + } break; default: ereport(ERROR, (errcode(ERRCODE_UNRECOGNIZED_NODE_TYPE), diff --git a/src/include/nodes/execnodes.h b/src/include/nodes/execnodes.h index da82944dd..4ccfc4d28 100644 --- a/src/include/nodes/execnodes.h +++ b/src/include/nodes/execnodes.h @@ -1221,6 +1221,8 @@ typedef struct PlanState { List* plan_issues; bool recursive_reset; /* node already reset? */ bool qual_is_inited; + + int64 ps_rownum; /* store current rownum */ } PlanState; static inline bool planstate_need_stub(PlanState* ps) @@ -1455,7 +1457,6 @@ typedef struct RunTimeParamPredicateInfo { Oid datumType; /* the parameter data type. */ Oid varTypeOid; /* var type oid. */ int32 paramPosition; /* the parameter predicate position in *hdfsScanPredicateArr. */ - } RunTimeParamPredicateInfo; /* ---------------- @@ -2361,6 +2362,17 @@ struct VecLimitState : public LimitState { VectorBatch* subBatch; }; + +/* + * RownumState node: used for computing the pseudo-column ROWNUM + */ +typedef struct RownumState { + ExprState xprstate; + PlanState* ps; /* the value of ROWNUM depends on its parent PlanState */ +} RownumState; + + + /* ---------------- * GroupingFuncExprState node * diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h index 1be588831..a94b7bcdb 100644 --- a/src/include/nodes/nodes.h +++ b/src/include/nodes/nodes.h @@ -218,6 +218,7 @@ typedef enum NodeTag { #endif T_HashFilter, T_EstSPNode, + T_Rownum, /* * TAGS FOR EXPRESSION STATE NODES (execnodes.h) @@ -261,6 +262,7 @@ typedef enum NodeTag { T_SplitPartitionState, T_AddPartitionState, T_RangePartitionStartEndDefState, + T_RownumState, /* * TAGS FOR PLANNER NODES (relation.h) diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h index ef00849fc..31b2f0057 100755 --- a/src/include/nodes/primnodes.h +++ b/src/include/nodes/primnodes.h @@ -319,6 +319,17 @@ typedef struct WindowFunc { int location; /* token location, or -1 if unknown */ } WindowFunc; + +/* + * pseudo-column "ROWNUM" + */ +typedef struct Rownum { + Expr xpr; + Oid rownumcollid; /* OID of collation of result */ + int location; /* token location, or -1 if unknown */ +} Rownum; + + /* ---------------- * ArrayRef: describes an array subscripting operation * diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h index c8d618d13..3e20514b5 100755 --- a/src/include/nodes/relation.h +++ b/src/include/nodes/relation.h @@ -377,6 +377,8 @@ typedef struct PlannerInfo { */ bool is_under_recursive_tree; bool has_recursive_correlated_rte; /* true if any RTE correlated with recursive cte */ + + bool hasRownumQual; } PlannerInfo; /* diff --git a/src/include/optimizer/clauses.h b/src/include/optimizer/clauses.h index 575628b80..47c69cc0b 100755 --- a/src/include/optimizer/clauses.h +++ b/src/include/optimizer/clauses.h @@ -105,4 +105,7 @@ extern bool treat_as_join_clause(Node* clause, RestrictInfo* rinfo, int varRelid extern List* extract_function_outarguments(Oid funcid, List* parameters, List* funcname); extern bool need_adjust_agg_inner_func_type(Aggref* aggref); +extern bool contain_rownum_walker(Node *node, void *context); +extern List* get_quals_lists(Node *jtnode); + #endif /* CLAUSES_H */ diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h index d1cea3cf5..44fb5e388 100755 --- a/src/include/parser/kwlist.h +++ b/src/include/parser/kwlist.h @@ -432,6 +432,7 @@ PG_KEYWORD("role", ROLE, UNRESERVED_KEYWORD) PG_KEYWORD("rollback", ROLLBACK, UNRESERVED_KEYWORD) PG_KEYWORD("rollup", ROLLUP, UNRESERVED_KEYWORD) PG_KEYWORD("row", ROW, COL_NAME_KEYWORD) +PG_KEYWORD("rownum", ROWNUM, RESERVED_KEYWORD) PG_KEYWORD("rows", ROWS, UNRESERVED_KEYWORD) PG_KEYWORD("rule", RULE, UNRESERVED_KEYWORD) PG_KEYWORD("savepoint", SAVEPOINT, UNRESERVED_KEYWORD) diff --git a/src/test/regress/expected/xc_rownum.out b/src/test/regress/expected/xc_rownum.out new file mode 100644 index 000000000..72f0d177c --- /dev/null +++ b/src/test/regress/expected/xc_rownum.out @@ -0,0 +1,367 @@ +-------------------------------------------------------------------- +-------------------test rownum pseudocolumn ------------------------ +-------------------------------------------------------------------- + +------------------------------------ +--test the basic function of rownum +------------------------------------ + +--create test table +create table rownum_table (name varchar(20), age int, address varchar(20)); + +--insert data to test table +insert into rownum_table values ('leon', 23, 'xian'); +insert into rownum_table values ('james', 24, 'bejing'); +insert into rownum_table values ('jack', 35, 'xian'); +insert into rownum_table values ('mary', 42, 'chengdu'); +insert into rownum_table values ('perl', 35, 'shengzhen'); +insert into rownum_table values ('rose', 64, 'xian'); +insert into rownum_table values ('under', 57, 'xianyang'); +insert into rownum_table values ('taker', 81, 'shanghai'); +insert into rownum_table values ('frank', 19, 'luoyang'); +insert into rownum_table values ('angel', 100, 'xian'); + +--the query to test rownum +select * from rownum_table where rownum < 5; + name | age | address +-------+-----+--------- + leon | 23 | xian + james | 24 | bejing + jack | 35 | xian + mary | 42 | chengdu +(4 rows) + +select rownum, * from rownum_table where rownum < 1; + rownum | name | age | address +--------+------+-----+--------- +(0 rows) + +select rownum, * from rownum_table where rownum <= 1; + rownum | name | age | address +--------+------+-----+--------- + 1 | leon | 23 | xian +(1 row) + +select rownum, * from rownum_table where rownum <= 10; + rownum | name | age | address +--------+-------+-----+----------- + 1 | leon | 23 | xian + 2 | james | 24 | bejing + 3 | jack | 35 | xian + 4 | mary | 42 | chengdu + 5 | perl | 35 | shengzhen + 6 | rose | 64 | xian + 7 | under | 57 | xianyang + 8 | taker | 81 | shanghai + 9 | frank | 19 | luoyang + 10 | angel | 100 | xian +(10 rows) + +select rownum, * from rownum_table where address = 'xian'; + rownum | name | age | address +--------+-------+-----+--------- + 1 | leon | 23 | xian + 2 | jack | 35 | xian + 3 | rose | 64 | xian + 4 | angel | 100 | xian +(4 rows) + +select rownum, * from rownum_table where address = 'xian' and rownum < 4; + rownum | name | age | address +--------+------+-----+--------- + 1 | leon | 23 | xian + 2 | jack | 35 | xian + 3 | rose | 64 | xian +(3 rows) + +select rownum, name, address, age from rownum_table where address = 'xian' or rownum < 8; + rownum | name | address | age +--------+-------+-----------+----- + 1 | leon | xian | 23 + 2 | james | bejing | 24 + 3 | jack | xian | 35 + 4 | mary | chengdu | 42 + 5 | perl | shengzhen | 35 + 6 | rose | xian | 64 + 7 | under | xianyang | 57 + 8 | angel | xian | 100 +(8 rows) + + +------------------ +--avoid optimize +------------------ + +--test order by +--create test table +create table test_table +( + id integer primary key , + name varchar2(20) , + age integer check(age > 0), + address varchar2(20) not null, + tele varchar2(20) default '101' +); +NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index "test_table_pkey" for table "test_table" +--insert data +insert into test_table values(1,'charlie', 40, 'shanghai'); +insert into test_table values(2,'lincon', 10, 'xianyang'); +insert into test_table values(3,'charlie', 40, 'chengdu'); +insert into test_table values(4,'lincon', 10, 'xian', ''); +insert into test_table values(5,'charlie', 40, 'chengdu'); +insert into test_table values(6,'lincon', 10, 'xian', '12345657'); +--test order by +select * from (select * from test_table order by id) as result where rownum < 4; + id | name | age | address | tele +----+---------+-----+----------+------ + 1 | charlie | 40 | shanghai | 101 + 2 | lincon | 10 | xianyang | 101 + 3 | charlie | 40 | chengdu | 101 +(3 rows) + +select * from (select * from test_table order by id desc) as result where rownum < 2; + id | name | age | address | tele +----+--------+-----+---------+---------- + 6 | lincon | 10 | xian | 12345657 +(1 row) + +select * from (select * from test_table order by id asc) as result where rownum <= 5; + id | name | age | address | tele +----+---------+-----+----------+------ + 1 | charlie | 40 | shanghai | 101 + 2 | lincon | 10 | xianyang | 101 + 3 | charlie | 40 | chengdu | 101 + 4 | lincon | 10 | xian | + 5 | charlie | 40 | chengdu | 101 +(5 rows) + + +--test union and intersect +--create test table +create table distributors (id int, name varchar(20)); +create table actors (id int, name varchar(20)); +--insert data +insert into distributors values (1, 'westward'); +insert into distributors values (1, 'walt disney'); +insert into distributors values (1, 'warner bros'); +insert into distributors values (1, 'warren beatty'); + +insert into actors values (1, 'woody allen'); +insert into actors values (1, 'warren beatty'); +insert into actors values (1, 'walter matthau'); +insert into actors values (1, 'westward'); +--test union +select rownum, name from (select name from distributors union all select name from actors order by 1) as result where rownum <= 1; + rownum | name +--------+------------- + 1 | walt disney +(1 row) + +select rownum, name from (select name from distributors union all select name from actors order by 1) as result where rownum < 3; + rownum | name +--------+---------------- + 1 | walt disney + 2 | walter matthau +(2 rows) + +select rownum, name from (select name from distributors union all select name from actors order by 1) as result where rownum < 6; + rownum | name +--------+---------------- + 1 | walt disney + 2 | walter matthau + 3 | warner bros + 4 | warren beatty + 5 | warren beatty +(5 rows) + +select rownum, name from (select name from distributors where rownum < 3 union all select name from actors where rownum < 3 order by 1) as result; + rownum | name +--------+--------------- + 1 | walt disney + 2 | warren beatty + 3 | westward + 4 | woody allen +(4 rows) + +--test intersect +select rownum, name from (select name from distributors intersect all select name from actors order by 1) as result where rownum <= 1; + rownum | name +--------+--------------- + 1 | warren beatty +(1 row) + +select rownum, name from (select name from distributors intersect all select name from actors order by 1) as result where rownum < 3; + rownum | name +--------+--------------- + 1 | warren beatty + 2 | westward +(2 rows) + +select rownum, name from (select name from distributors intersect all select name from actors order by 1) as result where rownum < 6; + rownum | name +--------+--------------- + 1 | warren beatty + 2 | westward +(2 rows) + +select rownum, name from (select name from distributors where rownum <= 4 intersect all select name from actors where rownum <= 4 order by 1) as result; + rownum | name +--------+--------------- + 1 | warren beatty + 2 | westward +(2 rows) + + +--test except and minus +--create test table +create table except_table (a int, b int); +create table except_table1 (a int, b int); +--insert data +insert into except_table values (3, 4); +insert into except_table values (5, 4); +insert into except_table values (3, 4); +insert into except_table values (4, 4); +insert into except_table values (6, 4); +insert into except_table values (3, 4); +insert into except_table values (3, 4); +insert into except_table1 values (3, 4); +--test except and minus +select rownum, * from (select * from except_table except select * from except_table1 order by 1) as result where rownum <= 2; + rownum | a | b +--------+---+--- + 1 | 4 | 4 + 2 | 5 | 4 +(2 rows) + +select rownum, * from (select * from except_table minus select * from except_table1 order by 1) as result where rownum <= 3; + rownum | a | b +--------+---+--- + 1 | 4 | 4 + 2 | 5 | 4 + 3 | 6 | 4 +(3 rows) + +select rownum, * from (select * from except_table where rownum <= 3 except select * from except_table1 where rownum <=2 order by 1) as result; + rownum | a | b +--------+---+--- + 1 | 5 | 4 +(1 row) + +select rownum, * from (select * from except_table where rownum <= 3 minus select * from except_table1 where rownum <=2 order by 1) as result; + rownum | a | b +--------+---+--- + 1 | 5 | 4 +(1 row) + + +--drop the test table +drop table rownum_table; +drop table test_table; +drop table distributors; +drop table actors; +drop table except_table; +drop table except_table1; + +create table tbl_a(v1 integer); +insert into tbl_a values(1001); +insert into tbl_a values(1002); +insert into tbl_a values(1003); +insert into tbl_a values(1004); +insert into tbl_a values(1005); +insert into tbl_a values(1002); +create table tbl_b(v1 integer, v2 integer); +insert into tbl_b values (1001,214); +insert into tbl_b values (1003,216); +insert into tbl_b values (1002,213); +insert into tbl_b values (1002,212); +insert into tbl_b values (1002,211); +insert into tbl_b values (1003,217); +insert into tbl_b values (1005,218); +update tbl_a a set a.v1 = (select v2 from tbl_b b where a.v1 = b.v1 and rownum <= 1); +select * from tbl_a order by 1; + v1 +----- + 213 + 213 + 214 + 216 + 218 + +(6 rows) + + +update tbl_b set v2 = rownum where v1 = 1002; +select * from tbl_b where v1 = 1002 and rownum < 4 order by 1, 2; + v1 | v2 +------+---- + 1002 | 1 + 1002 | 2 + 1002 | 3 +(3 rows) + + +delete tbl_b where rownum > 3 and v1 = 1002; +delete tbl_b where rownum < 100 and v1 = 1002; + +select * from tbl_b order by 1, 2; + v1 | v2 +------+----- + 1001 | 214 + 1003 | 216 + 1003 | 217 + 1005 | 218 +(4 rows) + + +drop table tbl_a; +drop table tbl_b; + +--adapt pseudocolumn "rowid" of oracle, using "ctid" of postgresql +create table test_tbl(myint integer); +insert into test_tbl values(1); +insert into test_tbl values(2); +insert into test_tbl values(3); +select rowid,* from test_tbl; +ERROR: column "rowid" does not exist +LINE 1: select rowid,* from test_tbl; + ^ +CONTEXT: referenced column: rowid +select max(rowid) from test_tbl; +ERROR: column "rowid" does not exist +LINE 1: select max(rowid) from test_tbl; + ^ +CONTEXT: referenced column: max +delete from test_tbl a where a.rowid != (select max(b.rowid) from test_tbl b); +ERROR: column a.rowid does not exist +LINE 1: delete from test_tbl a where a.rowid != (select max(b.rowid)... + ^ +select rowid,* from test_tbl; +ERROR: column "rowid" does not exist +LINE 1: select rowid,* from test_tbl; + ^ +CONTEXT: referenced column: rowid +drop table test_tbl; + +create table aaaa ( + smgwname character varying(255), + seid character varying(33), + igmgwidx integer, + imsflag smallint +); +insert into aaaa values ('mrp', 'mrp', 0, 1); + +create table bbbb ( + imgwindex integer, + imsflag smallint +); +insert into bbbb values (0, 1); +insert into bbbb values (0, 1); +select (select a1.smgwname from aaaa a1 where a1.seid = ( select a2.seid from aaaa a2 where a2.igmgwidx = b.imgwindex and a2.imsflag = b.imsflag and rownum <=1)) from bbbb b; + smgwname +---------- + mrp + mrp +(2 rows) + +drop table aaaa; +drop table bbbb; diff --git a/src/test/regress/input/copy_error_log.source b/src/test/regress/input/copy_error_log.source index a825266dc..2c8f6bac9 100644 --- a/src/test/regress/input/copy_error_log.source +++ b/src/test/regress/input/copy_error_log.source @@ -36,7 +36,7 @@ select * from copy_error_log_create(copy_error_log_create()); select * from reverse(copy_error_log_create()); drop table if exists pgxc_copy_error_log; select * from copy_error_log_create(); -alter table pgxc_copy_error_log alter column rownum type char(50); +alter table pgxc_copy_error_log alter column lineno type char(50); drop table if exists err_copy_create_err_tab_001_01; create table err_copy_create_err_tab_001_01 ( @@ -59,7 +59,7 @@ copy err_copy_create_err_tab_001_01 from '@abs_srcdir@/tmp_check/datanode1/pg_co log errors reject limit 'unlimited' with(delimiter ',',format 'text', encoding 'utf8'); -alter table pgxc_copy_error_log drop column rownum ; +alter table pgxc_copy_error_log drop column lineno ; copy err_copy_create_err_tab_001_01 from '@abs_srcdir@/tmp_check/datanode1/pg_copydir/data_err_par' log errors reject limit 'unlimited' with(delimiter ',',format 'text', @@ -106,7 +106,7 @@ select * from copy_error_log_create(copy_error_log_create()); select * from reverse(copy_error_log_create()); drop table if exists pgxc_copy_error_log; select * from copy_error_log_create(); -alter table pgxc_copy_error_log alter column rownum type char(50); +alter table pgxc_copy_error_log alter column lineno type char(50); drop table if exists err_copy_create_err_tab_001_01; create table err_copy_create_err_tab_001_01 ( @@ -129,7 +129,7 @@ copy err_copy_create_err_tab_001_01 from '@abs_srcdir@/tmp_check/datanode1/pg_co log errors data reject limit 'unlimited' with(delimiter ',',format 'text', encoding 'utf8'); -alter table pgxc_copy_error_log drop column rownum ; +alter table pgxc_copy_error_log drop column lineno ; copy err_copy_create_err_tab_001_01 from '@abs_srcdir@/tmp_check/datanode1/pg_copydir/data_err_par' log errors data reject limit 'unlimited' with(delimiter ',',format 'text', diff --git a/src/test/regress/output/copy_error_log.source b/src/test/regress/output/copy_error_log.source index 18ccda1ab..f95deb139 100644 --- a/src/test/regress/output/copy_error_log.source +++ b/src/test/regress/output/copy_error_log.source @@ -67,7 +67,7 @@ select * from copy_error_log_create(); select * from copy_error_log_create(); ERROR: relation "pgxc_copy_error_log" already exists CONTEXT: SQL statement "CREATE TABLE public.pgxc_copy_error_log - (relname varchar, begintime timestamptz, filename varchar, rownum int8, rawrecord text, detail text)" + (relname varchar, begintime timestamptz, filename varchar, lineno int8, rawrecord text, detail text)" PL/pgSQL function copy_error_log_create() line 9 at EXECUTE statement select * from copy_error_log_create(copy_error_log_create()); ERROR: function copy_error_log_create(boolean) does not exist @@ -86,7 +86,7 @@ select * from copy_error_log_create(); t (1 row) -alter table pgxc_copy_error_log alter column rownum type char(50); +alter table pgxc_copy_error_log alter column lineno type char(50); drop table if exists err_copy_create_err_tab_001_01; NOTICE: table "err_copy_create_err_tab_001_01" does not exist, skipping create table err_copy_create_err_tab_001_01 @@ -114,7 +114,7 @@ with(delimiter ',',format 'text', encoding 'utf8'); ERROR: The column definition of public.pgxc_copy_error_log table is not as intended. HINT: You may want to use copy_error_log_create() to create it instead in order to use COPY FROM error logging. -alter table pgxc_copy_error_log drop column rownum ; +alter table pgxc_copy_error_log drop column lineno ; copy err_copy_create_err_tab_001_01 from '@abs_srcdir@/tmp_check/datanode1/pg_copydir/data_err_par' log errors reject limit 'unlimited' with(delimiter ',',format 'text', @@ -193,7 +193,7 @@ select * from copy_error_log_create(); select * from copy_error_log_create(); ERROR: relation "pgxc_copy_error_log" already exists CONTEXT: SQL statement "CREATE TABLE public.pgxc_copy_error_log - (relname varchar, begintime timestamptz, filename varchar, rownum int8, rawrecord text, detail text)" + (relname varchar, begintime timestamptz, filename varchar, lineno int8, rawrecord text, detail text)" PL/pgSQL function copy_error_log_create() line 9 at EXECUTE statement select * from copy_error_log_create(copy_error_log_create()); ERROR: function copy_error_log_create(boolean) does not exist @@ -212,7 +212,7 @@ select * from copy_error_log_create(); t (1 row) -alter table pgxc_copy_error_log alter column rownum type char(50); +alter table pgxc_copy_error_log alter column lineno type char(50); drop table if exists err_copy_create_err_tab_001_01; NOTICE: table "err_copy_create_err_tab_001_01" does not exist, skipping create table err_copy_create_err_tab_001_01 @@ -240,7 +240,7 @@ with(delimiter ',',format 'text', encoding 'utf8'); ERROR: The column definition of public.pgxc_copy_error_log table is not as intended. HINT: You may want to use copy_error_log_create() to create it instead in order to use COPY FROM error logging. -alter table pgxc_copy_error_log drop column rownum ; +alter table pgxc_copy_error_log drop column lineno ; copy err_copy_create_err_tab_001_01 from '@abs_srcdir@/tmp_check/datanode1/pg_copydir/data_err_par' log errors data reject limit 'unlimited' with(delimiter ',',format 'text', diff --git a/src/test/regress/parallel_schedule0 b/src/test/regress/parallel_schedule0 index d1b7b3167..37ca35417 100644 --- a/src/test/regress/parallel_schedule0 +++ b/src/test/regress/parallel_schedule0 @@ -47,7 +47,7 @@ test: single_node_oidjoins single_node_type_sanity single_node_opr_sanity # ---------- # These four each depend on the previous one # ---------- -test: single_node_insert +test: single_node_insert xc_rownum test: single_node_temple test: single_node_create_function_1 test: single_node_create_table_1 diff --git a/src/test/regress/sql/xc_rownum.sql b/src/test/regress/sql/xc_rownum.sql new file mode 100644 index 000000000..becf4892e --- /dev/null +++ b/src/test/regress/sql/xc_rownum.sql @@ -0,0 +1,167 @@ +-------------------------------------------------------------------- +-------------------test rownum pseudocolumn ------------------------ +-------------------------------------------------------------------- + +------------------------------------ +--test the basic function of rownum +------------------------------------ + +--create test table +create table rownum_table (name varchar(20), age int, address varchar(20)); + +--insert data to test table +insert into rownum_table values ('leon', 23, 'xian'); +insert into rownum_table values ('james', 24, 'bejing'); +insert into rownum_table values ('jack', 35, 'xian'); +insert into rownum_table values ('mary', 42, 'chengdu'); +insert into rownum_table values ('perl', 35, 'shengzhen'); +insert into rownum_table values ('rose', 64, 'xian'); +insert into rownum_table values ('under', 57, 'xianyang'); +insert into rownum_table values ('taker', 81, 'shanghai'); +insert into rownum_table values ('frank', 19, 'luoyang'); +insert into rownum_table values ('angel', 100, 'xian'); + +--the query to test rownum +select * from rownum_table where rownum < 5; +select rownum, * from rownum_table where rownum < 1; +select rownum, * from rownum_table where rownum <= 1; +select rownum, * from rownum_table where rownum <= 10; +select rownum, * from rownum_table where address = 'xian'; +select rownum, * from rownum_table where address = 'xian' and rownum < 4; +select rownum, name, address, age from rownum_table where address = 'xian' or rownum < 8; + +------------------ +--avoid optimize +------------------ + +--test order by +--create test table +create table test_table +( + id integer primary key , + name varchar2(20) , + age integer check(age > 0), + address varchar2(20) not null, + tele varchar2(20) default '101' +); +--insert data +insert into test_table values(1,'charlie', 40, 'shanghai'); +insert into test_table values(2,'lincon', 10, 'xianyang'); +insert into test_table values(3,'charlie', 40, 'chengdu'); +insert into test_table values(4,'lincon', 10, 'xian', ''); +insert into test_table values(5,'charlie', 40, 'chengdu'); +insert into test_table values(6,'lincon', 10, 'xian', '12345657'); +--test order by +select * from (select * from test_table order by id) as result where rownum < 4; +select * from (select * from test_table order by id desc) as result where rownum < 2; +select * from (select * from test_table order by id asc) as result where rownum <= 5; + +--test union and intersect +--create test table +create table distributors (id int, name varchar(20)); +create table actors (id int, name varchar(20)); +--insert data +insert into distributors values (1, 'westward'); +insert into distributors values (1, 'walt disney'); +insert into distributors values (1, 'warner bros'); +insert into distributors values (1, 'warren beatty'); + +insert into actors values (1, 'woody allen'); +insert into actors values (1, 'warren beatty'); +insert into actors values (1, 'walter matthau'); +insert into actors values (1, 'westward'); +--test union +select rownum, name from (select name from distributors union all select name from actors order by 1) as result where rownum <= 1; +select rownum, name from (select name from distributors union all select name from actors order by 1) as result where rownum < 3; +select rownum, name from (select name from distributors union all select name from actors order by 1) as result where rownum < 6; +select rownum, name from (select name from distributors where rownum < 3 union all select name from actors where rownum < 3 order by 1) as result; +--test intersect +select rownum, name from (select name from distributors intersect all select name from actors order by 1) as result where rownum <= 1; +select rownum, name from (select name from distributors intersect all select name from actors order by 1) as result where rownum < 3; +select rownum, name from (select name from distributors intersect all select name from actors order by 1) as result where rownum < 6; +select rownum, name from (select name from distributors where rownum <= 4 intersect all select name from actors where rownum <= 4 order by 1) as result; + +--test except and minus +--create test table +create table except_table (a int, b int); +create table except_table1 (a int, b int); +--insert data +insert into except_table values (3, 4); +insert into except_table values (5, 4); +insert into except_table values (3, 4); +insert into except_table values (4, 4); +insert into except_table values (6, 4); +insert into except_table values (3, 4); +insert into except_table values (3, 4); +insert into except_table1 values (3, 4); +--test except and minus +select rownum, * from (select * from except_table except select * from except_table1 order by 1) as result where rownum <= 2; +select rownum, * from (select * from except_table minus select * from except_table1 order by 1) as result where rownum <= 3; +select rownum, * from (select * from except_table where rownum <= 3 except select * from except_table1 where rownum <=2 order by 1) as result; +select rownum, * from (select * from except_table where rownum <= 3 minus select * from except_table1 where rownum <=2 order by 1) as result; + +--drop the test table +drop table rownum_table; +drop table test_table; +drop table distributors; +drop table actors; +drop table except_table; +drop table except_table1; + +create table tbl_a(v1 integer); +insert into tbl_a values(1001); +insert into tbl_a values(1002); +insert into tbl_a values(1003); +insert into tbl_a values(1004); +insert into tbl_a values(1005); +insert into tbl_a values(1002); +create table tbl_b(v1 integer, v2 integer); +insert into tbl_b values (1001,214); +insert into tbl_b values (1003,216); +insert into tbl_b values (1002,213); +insert into tbl_b values (1002,212); +insert into tbl_b values (1002,211); +insert into tbl_b values (1003,217); +insert into tbl_b values (1005,218); +update tbl_a a set a.v1 = (select v2 from tbl_b b where a.v1 = b.v1 and rownum <= 1); +select * from tbl_a order by 1; + +update tbl_b set v2 = rownum where v1 = 1002; +select * from tbl_b where v1 = 1002 and rownum < 4 order by 1, 2; + +delete tbl_b where rownum > 3 and v1 = 1002; +delete tbl_b where rownum < 100 and v1 = 1002; + +select * from tbl_b order by 1, 2; + +drop table tbl_a; +drop table tbl_b; + +--adapt pseudocolumn "rowid" of oracle, using "ctid" of postgresql +create table test_tbl(myint integer); +insert into test_tbl values(1); +insert into test_tbl values(2); +insert into test_tbl values(3); +select rowid,* from test_tbl; +select max(rowid) from test_tbl; +delete from test_tbl a where a.rowid != (select max(b.rowid) from test_tbl b); +select rowid,* from test_tbl; +drop table test_tbl; + +create table aaaa ( + smgwname character varying(255), + seid character varying(33), + igmgwidx integer, + imsflag smallint +); +insert into aaaa values ('mrp', 'mrp', 0, 1); + +create table bbbb ( + imgwindex integer, + imsflag smallint +); +insert into bbbb values (0, 1); +insert into bbbb values (0, 1); +select (select a1.smgwname from aaaa a1 where a1.seid = ( select a2.seid from aaaa a2 where a2.igmgwidx = b.imgwindex and a2.imsflag = b.imsflag and rownum <=1)) from bbbb b; +drop table aaaa; +drop table bbbb;