From 7705e72377c3b5ea481ac56780f7a6015ac439c7 Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Sat, 29 Nov 2025 11:06:48 +0800 Subject: [PATCH 01/19] feat: implement Oracle-compatible ROWNUM pseudocolumn Add ROWNUM pseudocolumn with Oracle-compatible semantics: - ROWNUM <= N optimized to LIMIT for simple queries - Blocks LIMIT optimization for complex queries (ORDER BY, DISTINCT, GROUP BY, aggregation) to preserve Oracle semantics - Handles special Oracle edge cases: ROWNUM > N, ROWNUM >= N, ROWNUM = N - Supports tautology cases: ROWNUM > 0, ROWNUM >= 1 return all rows - Marks ROWNUM as volatile to ensure per-row evaluation Includes comprehensive regression tests covering all edge cases. --- src/backend/executor/execExpr.c | 50 + src/backend/executor/execExprInterp.c | 48 + src/backend/executor/execUtils.c | 3 + src/backend/executor/nodeResult.c | 13 +- src/backend/executor/nodeSubplan.c | 27 +- src/backend/executor/nodeSubqueryscan.c | 25 + src/backend/nodes/nodeFuncs.c | 14 + src/backend/optimizer/plan/createplan.c | 268 ++++++ src/backend/optimizer/plan/planner.c | 334 +++++++ src/backend/optimizer/util/clauses.c | 12 + src/backend/oracle_parser/ora_gram.y | 4 +- src/backend/parser/parse_expr.c | 16 + src/backend/utils/adt/ruleutils.c | 6 + src/include/executor/execExpr.h | 2 + src/include/executor/execScan.h | 43 +- src/include/nodes/execnodes.h | 12 + src/include/nodes/primnodes.h | 15 + src/include/oracle_parser/ora_kwlist.h | 1 + src/oracle_test/regress/expected/rownum.out | 928 +++++++++++++++++++ src/oracle_test/regress/parallel_schedule | 5 + src/oracle_test/regress/sql/rownum.sql | 515 ++++++++++ src/pl/plisql/src/Makefile | 2 +- src/pl/plisql/src/expected/plisql_rownum.out | 476 ++++++++++ src/pl/plisql/src/sql/plisql_rownum.sql | 378 ++++++++ 24 files changed, 3191 insertions(+), 6 deletions(-) create mode 100644 src/oracle_test/regress/expected/rownum.out create mode 100644 src/oracle_test/regress/sql/rownum.sql create mode 100644 src/pl/plisql/src/expected/plisql_rownum.out create mode 100644 src/pl/plisql/src/sql/plisql_rownum.sql diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c index c99c47bd4ac..322d26d73d2 100644 --- a/src/backend/executor/execExpr.c +++ b/src/backend/executor/execExpr.c @@ -377,6 +377,41 @@ ExecInitExprList(List *nodes, PlanState *parent) * Caution: before PG v10, the targetList was a list of ExprStates; now it * should be the planner-created targetlist, since we do the compilation here. */ + +/* + * Helper function to check if an expression contains ROWNUM + */ +static bool +expression_contains_rownum_walker(Node *node, void *context) +{ + if (node == NULL) + return false; + + if (IsA(node, RownumExpr)) + return true; + + return expression_tree_walker(node, expression_contains_rownum_walker, context); +} + +/* + * Check if a target list contains ROWNUM expressions + */ +static bool +targetlist_contains_rownum(List *targetList) +{ + ListCell *lc; + + foreach(lc, targetList) + { + TargetEntry *tle = lfirst_node(TargetEntry, lc); + + if (expression_contains_rownum_walker((Node *) tle->expr, NULL)) + return true; + } + + return false; +} + ProjectionInfo * ExecBuildProjectionInfo(List *targetList, ExprContext *econtext, @@ -519,6 +554,13 @@ ExecBuildProjectionInfo(List *targetList, ExecReadyExpr(state); + /* + * Check if the target list contains ROWNUM expressions. + * If so, we need to materialize the result tuple to preserve the + * ROWNUM values and prevent re-evaluation in outer queries. + */ + projInfo->pi_needsMaterialization = targetlist_contains_rownum(targetList); + return projInfo; } @@ -2646,6 +2688,14 @@ ExecInitExprRec(Expr *node, ExprState *state, break; } + case T_RownumExpr: + { + /* Oracle ROWNUM pseudocolumn */ + scratch.opcode = EEOP_ROWNUM; + ExprEvalPushStep(state, &scratch); + break; + } + case T_ReturningExpr: { ReturningExpr *rexpr = (ReturningExpr *) node; diff --git a/src/backend/executor/execExprInterp.c b/src/backend/executor/execExprInterp.c index 7ee820ee353..11a4b1f5572 100644 --- a/src/backend/executor/execExprInterp.c +++ b/src/backend/executor/execExprInterp.c @@ -552,6 +552,7 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull) &&CASE_EEOP_SQLVALUEFUNCTION, &&CASE_EEOP_CURRENTOFEXPR, &&CASE_EEOP_NEXTVALUEEXPR, + &&CASE_EEOP_ROWNUM, &&CASE_EEOP_RETURNINGEXPR, &&CASE_EEOP_ARRAYEXPR, &&CASE_EEOP_ARRAYCOERCE, @@ -1593,6 +1594,18 @@ ExecInterpExpr(ExprState *state, ExprContext *econtext, bool *isnull) EEO_NEXT(); } + EEO_CASE(EEOP_ROWNUM) + { + /* + * Oracle ROWNUM pseudocolumn: return the current row number. + * The row number is incremented by the executor for each row + * emitted. + */ + ExecEvalRownum(state, op); + + EEO_NEXT(); + } + EEO_CASE(EEOP_RETURNINGEXPR) { /* @@ -3322,6 +3335,41 @@ ExecEvalNextValueExpr(ExprState *state, ExprEvalStep *op) *op->resnull = false; } +/* + * Evaluate Oracle ROWNUM pseudocolumn. + * + * Returns the current row number from the executor state. The row number + * is incremented for each row emitted during query execution. + * + * ROWNUM starts at 1 and increments before any ORDER BY is applied. + */ +void +ExecEvalRownum(ExprState *state, ExprEvalStep *op) +{ + PlanState *planstate; + EState *estate = NULL; + int64 rownum_value = 1; /* default */ + + /* Safely get the PlanState and EState */ + if (state && state->parent) + { + planstate = state->parent; + if (planstate) + estate = planstate->state; + } + + /* + * Use the estate-level ROWNUM counter. + * When ROWNUM appears in a SELECT list, materialization (handled in + * ExecScanExtended) ensures the value is captured and not re-evaluated. + */ + if (estate && estate->es_rownum > 0) + rownum_value = estate->es_rownum; + + *op->resvalue = Int64GetDatum(rownum_value); + *op->resnull = false; +} + /* * Evaluate NullTest / IS NULL for rows. */ diff --git a/src/backend/executor/execUtils.c b/src/backend/executor/execUtils.c index c47d7c9e191..95591b84a97 100644 --- a/src/backend/executor/execUtils.c +++ b/src/backend/executor/execUtils.c @@ -162,6 +162,9 @@ CreateExecutorState(void) estate->es_parallel_workers_to_launch = 0; estate->es_parallel_workers_launched = 0; + /* Oracle ROWNUM support: initialize row counter */ + estate->es_rownum = 0; + estate->es_jit_flags = 0; estate->es_jit = NULL; diff --git a/src/backend/executor/nodeResult.c b/src/backend/executor/nodeResult.c index 06842a48eca..79933095a9e 100644 --- a/src/backend/executor/nodeResult.c +++ b/src/backend/executor/nodeResult.c @@ -132,7 +132,18 @@ ExecResult(PlanState *pstate) } /* form the result tuple using ExecProject(), and return it */ - return ExecProject(node->ps.ps_ProjInfo); + TupleTableSlot *result = ExecProject(node->ps.ps_ProjInfo); + + /* + * If the projection contains ROWNUM expressions, materialize + * the virtual tuple to preserve the ROWNUM values as constants. + */ + if (node->ps.ps_ProjInfo && node->ps.ps_ProjInfo->pi_needsMaterialization) + { + ExecMaterializeSlot(result); + } + + return result; } return NULL; diff --git a/src/backend/executor/nodeSubplan.c b/src/backend/executor/nodeSubplan.c index b45c788870b..063428ce513 100644 --- a/src/backend/executor/nodeSubplan.c +++ b/src/backend/executor/nodeSubplan.c @@ -66,6 +66,7 @@ ExecSubPlan(SubPlanState *node, SubPlan *subplan = node->subplan; EState *estate = node->planstate->state; ScanDirection dir = estate->es_direction; + int64 save_rownum = estate->es_rownum; Datum retval; CHECK_FOR_INTERRUPTS(); @@ -82,14 +83,22 @@ ExecSubPlan(SubPlanState *node, /* Force forward-scan mode for evaluation */ estate->es_direction = ForwardScanDirection; + /* + * Reset ROWNUM counter for Oracle compatibility. + * Each correlated subquery invocation should start with ROWNUM=0, + * matching Oracle's behavior. + */ + estate->es_rownum = 0; + /* Select appropriate evaluation strategy */ if (subplan->useHashTable) retval = ExecHashSubPlan(node, econtext, isNull); else retval = ExecScanSubPlan(node, econtext, isNull); - /* restore scan direction */ + /* restore scan direction and ROWNUM counter */ estate->es_direction = dir; + estate->es_rownum = save_rownum; return retval; } @@ -262,6 +271,12 @@ ExecScanSubPlan(SubPlanState *node, /* with that done, we can reset the subplan */ ExecReScan(planstate); + /* + * Reset ROWNUM counter for Oracle compatibility. + * This ensures correlated subqueries start fresh for each outer row. + */ + planstate->state->es_rownum = 0; + /* * For all sublink types except EXPR_SUBLINK and ARRAY_SUBLINK, the result * is boolean as are the results of the combining operators. We combine @@ -1104,6 +1119,7 @@ ExecSetParamPlan(SubPlanState *node, ExprContext *econtext) SubLinkType subLinkType = subplan->subLinkType; EState *estate = planstate->state; ScanDirection dir = estate->es_direction; + int64 save_rownum = estate->es_rownum; MemoryContext oldcontext; TupleTableSlot *slot; ListCell *l; @@ -1124,6 +1140,12 @@ ExecSetParamPlan(SubPlanState *node, ExprContext *econtext) */ estate->es_direction = ForwardScanDirection; + /* + * Reset ROWNUM counter for Oracle compatibility. + * InitPlans should start with ROWNUM=0, matching Oracle's behavior. + */ + estate->es_rownum = 0; + /* Initialize ArrayBuildStateAny in caller's context, if needed */ if (subLinkType == ARRAY_SUBLINK) astate = initArrayResultAny(subplan->firstColType, @@ -1257,8 +1279,9 @@ ExecSetParamPlan(SubPlanState *node, ExprContext *econtext) MemoryContextSwitchTo(oldcontext); - /* restore scan direction */ + /* restore scan direction and ROWNUM counter */ estate->es_direction = dir; + estate->es_rownum = save_rownum; } /* diff --git a/src/backend/executor/nodeSubqueryscan.c b/src/backend/executor/nodeSubqueryscan.c index 8dd1ae46308..a3c1f60ab83 100644 --- a/src/backend/executor/nodeSubqueryscan.c +++ b/src/backend/executor/nodeSubqueryscan.c @@ -46,12 +46,30 @@ static TupleTableSlot * SubqueryNext(SubqueryScanState *node) { TupleTableSlot *slot; + bool first_call = !node->rownum_reset; + + if (first_call) + node->rownum_reset = true; /* * Get the next tuple from the sub-query. */ slot = ExecProcNode(node->subplan); + /* + * For Oracle ROWNUM compatibility: reset the ROWNUM counter after + * the first call to ExecProcNode. This is necessary because inner + * plan nodes (e.g., SeqScan feeding a Sort) may increment es_rownum + * while buffering tuples during the first call. We want the + * SubqueryScan's ROWNUM values to start at 1, not continue from + * where the inner scans left off. + * + * The reset happens after ExecProcNode because blocking operators + * like Sort fetch all input tuples on the first call. + */ + if (first_call) + node->ss.ps.state->es_rownum = 0; + /* * We just return the subplan's result slot, rather than expending extra * cycles for ExecCopySlot(). (Our own ScanTupleSlot is used only for @@ -112,6 +130,7 @@ ExecInitSubqueryScan(SubqueryScan *node, EState *estate, int eflags) subquerystate->ss.ps.plan = (Plan *) node; subquerystate->ss.ps.state = estate; subquerystate->ss.ps.ExecProcNode = ExecSubqueryScan; + subquerystate->rownum_reset = false; /* * Miscellaneous initialization @@ -182,6 +201,12 @@ ExecEndSubqueryScan(SubqueryScanState *node) void ExecReScanSubqueryScan(SubqueryScanState *node) { + /* + * Reset ROWNUM tracking flag for Oracle compatibility. + * This ensures each SubqueryScan rescan resets ROWNUM on first tuple. + */ + node->rownum_reset = false; + ExecScanReScan(&node->ss); /* diff --git a/src/backend/nodes/nodeFuncs.c b/src/backend/nodes/nodeFuncs.c index ad97c8f5da9..56882e5dc3f 100644 --- a/src/backend/nodes/nodeFuncs.c +++ b/src/backend/nodes/nodeFuncs.c @@ -291,6 +291,10 @@ exprType(const Node *expr) case T_NextValueExpr: type = ((const NextValueExpr *) expr)->typeId; break; + case T_RownumExpr: + /* ROWNUM returns a numeric value */ + type = INT8OID; + break; case T_InferenceElem: { const InferenceElem *n = (const InferenceElem *) expr; @@ -1072,6 +1076,10 @@ exprCollation(const Node *expr) /* NextValueExpr's result is an integer type ... */ coll = InvalidOid; /* ... so it has no collation */ break; + case T_RownumExpr: + /* RownumExpr's result is an integer type ... */ + coll = InvalidOid; /* ... so it has no collation */ + break; case T_InferenceElem: coll = exprCollation((Node *) ((const InferenceElem *) expr)->expr); break; @@ -1329,6 +1337,10 @@ exprSetCollation(Node *expr, Oid collation) /* NextValueExpr's result is an integer type ... */ Assert(!OidIsValid(collation)); /* ... so never set a collation */ break; + case T_RownumExpr: + /* RownumExpr's result is an integer type ... */ + Assert(!OidIsValid(collation)); /* ... so never set a collation */ + break; default: elog(ERROR, "unrecognized node type: %d", (int) nodeTag(expr)); break; @@ -2164,6 +2176,7 @@ expression_tree_walker_impl(Node *node, case T_SetToDefault: case T_CurrentOfExpr: case T_NextValueExpr: + case T_RownumExpr: case T_RangeTblRef: case T_SortGroupClause: case T_CTESearchClause: @@ -3045,6 +3058,7 @@ expression_tree_mutator_impl(Node *node, case T_SetToDefault: case T_CurrentOfExpr: case T_NextValueExpr: + case T_RownumExpr: case T_RangeTblRef: case T_SortGroupClause: case T_CTESearchClause: diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c index 0b61aef962c..cc83279c514 100644 --- a/src/backend/optimizer/plan/createplan.c +++ b/src/backend/optimizer/plan/createplan.c @@ -79,6 +79,17 @@ static Plan *create_scan_plan(PlannerInfo *root, Path *best_path, int flags); static List *build_path_tlist(PlannerInfo *root, Path *path); static bool use_physical_tlist(PlannerInfo *root, Path *path, int flags); +static bool contain_rownum_expr(Node *node); +static int count_rownum_exprs(Node *node); +static List *collect_rownum_exprs(List *tlist); + +typedef struct replace_rownum_context +{ + List *rownum_vars; /* List of Vars to replace RownumExprs */ + int rownum_idx; /* Current index in rownum_vars list */ +} replace_rownum_context; + +static Node *replace_rownum_expr_mutator(Node *node, replace_rownum_context *context); static List *get_gating_quals(PlannerInfo *root, List *quals); static Plan *create_gating_plan(PlannerInfo *root, Path *path, Plan *plan, List *gating_quals); @@ -2067,6 +2078,153 @@ create_projection_plan(PlannerInfo *root, ProjectionPath *best_path, int flags) subplan = create_plan_recurse(root, best_path->subpath, 0); tlist = build_path_tlist(root, &best_path->path); needs_result_node = !tlist_same_exprs(tlist, subplan->targetlist); + + /* + * Special handling for Oracle ROWNUM with Sort: + * If the projection contains ROWNUM and the subplan is a Sort, + * we need to ensure ROWNUM is evaluated BEFORE the sort, not after. + * Oracle semantics require ROWNUM to be assigned during row retrieval, + * before any ORDER BY clause is applied. + */ + if (needs_result_node && + (IsA(subplan, Sort) || IsA(subplan, IncrementalSort)) && + contain_rownum_expr((Node *) tlist)) + { + Plan *sortinput; + List *new_input_tlist; + List *rownum_tles; + List *rownum_vars; + ListCell *lc; + AttrNumber new_resno; + AttrNumber scan_rownum_start; + replace_rownum_context context; + + /* + * Get the Sort's input plan (the scan). + * For both Sort and IncrementalSort, the input is in 'lefttree'. + */ + sortinput = subplan->lefttree; + + /* + * Collect all target entries containing ROWNUM expressions + * (including nested ones). + */ + rownum_tles = collect_rownum_exprs(tlist); + + if (rownum_tles == NIL) + { + /* No ROWNUM found, nothing to do */ + goto skip_rownum_handling; + } + + /* + * Build a new target list for the sort's input that includes + * all existing columns plus ROWNUM expressions. + */ + new_input_tlist = list_copy(sortinput->targetlist); + new_resno = list_length(new_input_tlist) + 1; + scan_rownum_start = new_resno; + + /* + * Add ROWNUM expressions to the scan's target list. + * We need to add one RownumExpr for each occurrence, not just + * one per target entry (a single TLE might reference ROWNUM multiple times). + */ + foreach(lc, rownum_tles) + { + TargetEntry *tle = lfirst_node(TargetEntry, lc); + int num_rownums = count_rownum_exprs((Node *) tle->expr); + int i; + + /* + * Add one RownumExpr to scan output for each ROWNUM reference + * in this target entry. + */ + for (i = 0; i < num_rownums; i++) + { + TargetEntry *new_tle; + RownumExpr *rownum_expr = makeNode(RownumExpr); + + new_tle = makeTargetEntry((Expr *) rownum_expr, + new_resno++, + NULL, + false); + new_input_tlist = lappend(new_input_tlist, new_tle); + } + } + + /* + * Update the sort input's target list. + * Use change_plan_targetlist to handle non-projection-capable nodes. + */ + sortinput = change_plan_targetlist(sortinput, new_input_tlist, + sortinput->parallel_safe); + subplan->lefttree = sortinput; + + /* + * Build list of Vars referencing the ROWNUM columns from scan output. + * These will be used to replace ROWNUM expressions in the final tlist. + * Create one Var for each ROWNUM occurrence. + */ + rownum_vars = NIL; + new_resno = scan_rownum_start; + + foreach(lc, rownum_tles) + { + TargetEntry *tle = lfirst_node(TargetEntry, lc); + int num_rownums = count_rownum_exprs((Node *) tle->expr); + int i; + + /* + * Create one Var for each ROWNUM expression in this target entry. + */ + for (i = 0; i < num_rownums; i++) + { + Var *var; + Oid rownum_type = INT8OID; /* ROWNUM is always int8 */ + + var = makeVar(OUTER_VAR, + new_resno++, + rownum_type, + -1, + InvalidOid, + 0); + + rownum_vars = lappend(rownum_vars, var); + } + } + + /* + * Add ROWNUM columns to Sort's target list so they pass through. + */ + new_input_tlist = list_copy(subplan->targetlist); + + foreach(lc, rownum_vars) + { + Var *var = lfirst_node(Var, lc); + TargetEntry *new_tle; + + new_tle = makeTargetEntry((Expr *) copyObject(var), + list_length(new_input_tlist) + 1, + NULL, + false); + new_input_tlist = lappend(new_input_tlist, new_tle); + } + + subplan->targetlist = new_input_tlist; + + /* + * Now replace all ROWNUM expressions in the final tlist + * (including nested ones) with Vars referencing Sort's output. + */ + context.rownum_vars = rownum_vars; + context.rownum_idx = 0; + + tlist = (List *) replace_rownum_expr_mutator((Node *) tlist, &context); + +skip_rownum_handling: + ; /* Empty statement for label */ + } } /* @@ -7412,6 +7570,116 @@ is_projection_capable_path(Path *path) return true; } +/* + * contain_rownum_expr + * Check whether a node tree contains any ROWNUM expressions. + * + * This is used to detect when we need special handling for Oracle ROWNUM + * pseudocolumn in combination with Sort nodes. + */ +static bool +contain_rownum_expr_walker(Node *node, void *context) +{ + if (node == NULL) + return false; + + if (IsA(node, RownumExpr)) + return true; + + return expression_tree_walker(node, contain_rownum_expr_walker, context); +} + +static bool +contain_rownum_expr(Node *node) +{ + return contain_rownum_expr_walker(node, NULL); +} + +/* + * replace_rownum_expr_mutator + * Replace all RownumExpr nodes with corresponding Vars from context. + * + * This handles nested ROWNUM expressions within complex expressions, + * not just top-level RownumExpr in target entries. + */ +static Node * +replace_rownum_expr_mutator(Node *node, replace_rownum_context *context) +{ + if (node == NULL) + return NULL; + + if (IsA(node, RownumExpr)) + { + /* Replace with the next Var from our list */ + if (context->rownum_idx < list_length(context->rownum_vars)) + { + Var *replacement = (Var *) list_nth(context->rownum_vars, + context->rownum_idx); + context->rownum_idx++; + return (Node *) copyObject(replacement); + } + /* Should not happen if we counted correctly */ + elog(ERROR, "ran out of replacement Vars for ROWNUM expressions"); + } + + return expression_tree_mutator(node, replace_rownum_expr_mutator, context); +} + +/* + * count_rownum_exprs_walker + * Count the number of RownumExpr nodes in an expression tree. + */ +static bool +count_rownum_exprs_walker(Node *node, int *count) +{ + if (node == NULL) + return false; + + if (IsA(node, RownumExpr)) + { + (*count)++; + return false; /* Don't recurse into RownumExpr */ + } + + return expression_tree_walker(node, count_rownum_exprs_walker, count); +} + +/* + * count_rownum_exprs + * Count how many RownumExpr nodes are in an expression. + */ +static int +count_rownum_exprs(Node *node) +{ + int count = 0; + count_rownum_exprs_walker(node, &count); + return count; +} + +/* + * collect_rownum_exprs + * Collect all ROWNUM expressions from a target list. + * + * Returns a list of TargetEntry nodes that contain ROWNUM expressions + * (either top-level or nested). + */ +static List * +collect_rownum_exprs(List *tlist) +{ + List *rownum_tles = NIL; + ListCell *lc; + + foreach(lc, tlist) + { + TargetEntry *tle = lfirst_node(TargetEntry, lc); + + if (contain_rownum_expr((Node *) tle->expr)) + rownum_tles = lappend(rownum_tles, tle); + } + + return rownum_tles; +} + /* * is_projection_capable_plan * Check whether a given Plan node is able to do projection. diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c index 549aedcfa99..ee0a7a1c240 100644 --- a/src/backend/optimizer/plan/planner.c +++ b/src/backend/optimizer/plan/planner.c @@ -59,7 +59,9 @@ #include "partitioning/partdesc.h" #include "rewrite/rewriteManip.h" #include "utils/backend_status.h" +#include "utils/guc.h" #include "utils/lsyscache.h" +#include "utils/ora_compatible.h" #include "utils/rel.h" #include "utils/selfuncs.h" @@ -247,6 +249,7 @@ static Path *make_ordered_path(PlannerInfo *root, double limit_tuples); static void gather_grouping_paths(PlannerInfo *root, RelOptInfo *rel); static bool can_partial_agg(PlannerInfo *root); +static void transform_rownum_to_limit(Query *parse); static void apply_scanjoin_target_to_paths(PlannerInfo *root, RelOptInfo *rel, List *scanjoin_targets, @@ -614,6 +617,330 @@ standard_planner(Query *parse, const char *query_string, int cursorOptions, } +/*-------------------- + * transform_rownum_to_limit + * Transform Oracle ROWNUM predicates into LIMIT clauses + * + * For Oracle compatibility, we need to convert WHERE clauses like: + * WHERE ROWNUM <= N -> LIMIT N + * WHERE ROWNUM = 1 -> LIMIT 1 + * WHERE ROWNUM < N -> LIMIT N-1 + * + * This must be done early in planning, before expression preprocessing. + * This function recursively processes subqueries in the range table. + * + * IMPORTANT: This optimization is only safe for simple SELECT queries. + * PostgreSQL's LIMIT is applied AFTER ORDER BY, DISTINCT, GROUP BY, and + * aggregation, while Oracle's ROWNUM is applied BEFORE these operations. + * Therefore, we only transform when there are no higher-level relational + * operations that would change semantics. + *-------------------- + */ +static void +transform_rownum_to_limit(Query *parse) +{ + FromExpr *jointree; + Node *quals; + List *andlist; + ListCell *lc; + Node *rownum_qual = NULL; + int64 limit_value = 0; + bool can_use_limit; + + /* Only apply in Oracle compatibility mode */ + if (database_mode != DB_ORACLE) + return; + + /* + * First, recursively process any subqueries in the range table. + * This ensures subqueries are transformed before the main query. + */ + foreach(lc, parse->rtable) + { + RangeTblEntry *rte = (RangeTblEntry *) lfirst(lc); + + if (rte->rtekind == RTE_SUBQUERY && rte->subquery) + { + /* Recursively transform the subquery */ + transform_rownum_to_limit(rte->subquery); + } + } + + /* Already has LIMIT? Don't transform */ + if (parse->limitCount != NULL) + return; + + /* No WHERE clause? Nothing to do */ + if (parse->jointree == NULL) + return; + + if (parse->jointree->quals == NULL) + return; + + jointree = parse->jointree; + quals = jointree->quals; + + /* Convert quals to a list for easier processing */ + if (IsA(quals, BoolExpr) && ((BoolExpr *) quals)->boolop == AND_EXPR) + andlist = ((BoolExpr *) quals)->args; + else + andlist = list_make1(quals); + + /* + * Determine if we can safely transform ROWNUM to LIMIT. + * Only transform for simple SELECT queries with no higher-level + * relational processing. PostgreSQL applies LIMIT after ORDER BY, + * DISTINCT, GROUP BY, aggregation, window functions, etc., while + * Oracle applies ROWNUM before these operations. Transforming in + * the presence of these operations would change query semantics. + * + * However, Oracle special semantics (ROWNUM >, >=, = for non-1) + * must ALWAYS be processed regardless of query complexity. + * + * See GitHub issue #12 for detailed examples of incorrect behavior. + */ + can_use_limit = !(parse->groupClause != NIL || + parse->groupingSets != NIL || + parse->hasAggs || + parse->distinctClause != NIL || + parse->hasDistinctOn || + parse->sortClause != NIL || + parse->hasWindowFuncs || + parse->setOperations != NULL || + parse->hasTargetSRFs); + + /* Search for ROWNUM predicates in the AND list */ + foreach(lc, andlist) + { + Node *qual = (Node *) lfirst(lc); + OpExpr *opexpr; + Node *leftop; + Node *rightop; + char *opname; + Const *constval; + int64 n; + + /* We're looking for OpExpr nodes (comparison operators) */ + if (!IsA(qual, OpExpr)) + continue; + + opexpr = (OpExpr *) qual; + + /* Need exactly 2 arguments */ + if (list_length(opexpr->args) != 2) + continue; + + leftop = (Node *) linitial(opexpr->args); + rightop = (Node *) lsecond(opexpr->args); + + /* Check if left operand is ROWNUM */ + if (!IsA(leftop, RownumExpr)) + continue; + + /* Right operand must be a constant */ + if (!IsA(rightop, Const)) + continue; + + /* Get the operator name */ + opname = get_opname(opexpr->opno); + if (opname == NULL) + continue; + + /* Now handle different operators */ + constval = (Const *) rightop; + + if (constval->constisnull) + { + pfree(opname); + continue; + } + + /* Extract the integer value */ + n = DatumGetInt64(constval->constvalue); + + if (strcmp(opname, "<=") == 0) + { + /* ROWNUM <= N -> LIMIT N (only for simple queries) */ + if (can_use_limit) + { + limit_value = n; + rownum_qual = qual; + } + pfree(opname); + break; + } + else if (strcmp(opname, "=") == 0) + { + /* + * ROWNUM = 1 can be optimized to LIMIT 1 (only for simple queries). + * ROWNUM = N where N != 1 is always false (Oracle semantics) - always process. + */ + if (n == 1 && can_use_limit) + { + limit_value = n; + rownum_qual = qual; + } + else if (n != 1) + { + /* ROWNUM = N where N != 1 is always false */ + BoolExpr *newand; + Const *falseconst; + + falseconst = (Const *) makeBoolConst(false, false); + + /* Replace this qual with FALSE in the AND list */ + andlist = list_delete_ptr(andlist, qual); + andlist = lappend(andlist, falseconst); + + /* Rebuild the WHERE clause */ + if (list_length(andlist) == 0) + { + jointree->quals = NULL; + } + else if (list_length(andlist) == 1) + { + jointree->quals = (Node *) linitial(andlist); + } + else + { + newand = makeNode(BoolExpr); + newand->boolop = AND_EXPR; + newand->args = andlist; + newand->location = -1; + jointree->quals = (Node *) newand; + } + + pfree(opname); + return; + } + pfree(opname); + break; + } + else if (strcmp(opname, "<") == 0) + { + /* ROWNUM < N -> LIMIT N-1 (only for simple queries) */ + if (can_use_limit) + { + if (n > 0) + limit_value = n - 1; + else + limit_value = 0; + rownum_qual = qual; + } + pfree(opname); + break; + } + else if (strcmp(opname, ">") == 0) + { + /* + * ROWNUM > N: + * N >= 1: always false + * N < 1: tautology, remove qual + */ + BoolExpr *newand; + + andlist = list_delete_ptr(andlist, qual); + + if (n >= 1) + { + /* Always false - add FALSE constant */ + Const *falseconst = (Const *) makeBoolConst(false, false); + andlist = lappend(andlist, falseconst); + } + /* else: tautology, just remove qual */ + + /* Rebuild WHERE clause */ + if (list_length(andlist) == 0) + jointree->quals = NULL; + else if (list_length(andlist) == 1) + jointree->quals = (Node *) linitial(andlist); + else + { + newand = makeNode(BoolExpr); + newand->boolop = AND_EXPR; + newand->args = andlist; + newand->location = -1; + jointree->quals = (Node *) newand; + } + + pfree(opname); + return; + } + else if (strcmp(opname, ">=") == 0) + { + /* + * ROWNUM >= N: + * N > 1: always false + * N <= 1: tautology, remove qual + */ + BoolExpr *newand; + + andlist = list_delete_ptr(andlist, qual); + + if (n > 1) + { + /* Always false - add FALSE constant */ + Const *falseconst = (Const *) makeBoolConst(false, false); + andlist = lappend(andlist, falseconst); + } + /* else: tautology, just remove qual */ + + /* Rebuild WHERE clause */ + if (list_length(andlist) == 0) + jointree->quals = NULL; + else if (list_length(andlist) == 1) + jointree->quals = (Node *) linitial(andlist); + else + { + newand = makeNode(BoolExpr); + newand->boolop = AND_EXPR; + newand->args = andlist; + newand->location = -1; + jointree->quals = (Node *) newand; + } + + pfree(opname); + return; + } + + pfree(opname); + } + + /* If we found a ROWNUM predicate, transform it */ + if (rownum_qual != NULL && limit_value > 0) + { + /* Create the LIMIT constant */ + parse->limitCount = (Node *) makeConst(INT8OID, -1, InvalidOid, + sizeof(int64), + Int64GetDatum(limit_value), + false, FLOAT8PASSBYVAL); + + /* Remove the ROWNUM predicate from the WHERE clause */ + andlist = list_delete_ptr(andlist, rownum_qual); + + if (list_length(andlist) == 0) + { + /* No quals left */ + jointree->quals = NULL; + } + else if (list_length(andlist) == 1) + { + /* Single qual remaining */ + jointree->quals = (Node *) linitial(andlist); + } + else + { + /* Multiple quals remaining, keep as AND expression */ + BoolExpr *newand = makeNode(BoolExpr); + + newand->boolop = AND_EXPR; + newand->args = andlist; + newand->location = -1; + jointree->quals = (Node *) newand; + } + } +} + /*-------------------- * subquery_planner * Invokes the planner on a subquery. We recurse to here for each @@ -708,6 +1035,13 @@ subquery_planner(PlannerGlobal *glob, Query *parse, PlannerInfo *parent_root, */ root->join_domains = list_make1(makeNode(JoinDomain)); + /* + * Transform Oracle ROWNUM predicates to LIMIT clauses EARLY, before any + * subquery processing. This ensures both the main query and any subqueries + * get transformed. + */ + transform_rownum_to_limit(parse); + /* * If there is a WITH list, process each WITH query and either convert it * to RTE_SUBQUERY RTE(s) or build an initplan SubPlan structure for it. diff --git a/src/backend/optimizer/util/clauses.c b/src/backend/optimizer/util/clauses.c index 395a3ec2792..be31f4bae07 100644 --- a/src/backend/optimizer/util/clauses.c +++ b/src/backend/optimizer/util/clauses.c @@ -461,6 +461,12 @@ contain_mutable_functions_walker(Node *node, void *context) return true; } + if (IsA(node, RownumExpr)) + { + /* RownumExpr is volatile - changes for every row */ + return true; + } + /* * It should be safe to treat MinMaxExpr as immutable, because it will * depend on a non-cross-type btree comparison function, and those should @@ -586,6 +592,12 @@ contain_volatile_functions_walker(Node *node, void *context) return true; } + if (IsA(node, RownumExpr)) + { + /* RownumExpr is volatile - changes for every row */ + return true; + } + if (IsA(node, RestrictInfo)) { RestrictInfo *rinfo = (RestrictInfo *) node; diff --git a/src/backend/oracle_parser/ora_gram.y b/src/backend/oracle_parser/ora_gram.y index 8324b794c3e..78bd3b66b94 100644 --- a/src/backend/oracle_parser/ora_gram.y +++ b/src/backend/oracle_parser/ora_gram.y @@ -789,7 +789,7 @@ static void determineLanguage(List *options); RANGE READ REAL REASSIGN RECHECK RECURSIVE REF_P REFERENCES REFERENCING REFRESH REINDEX RELATIVE_P RELEASE RENAME REPEATABLE REPLACE REPLICA RESET RESTART RESTRICT RETURN RETURNING RETURNS REVOKE RIGHT ROLE ROLLBACK ROLLUP - ROUTINE ROUTINES ROW ROWID ROWS ROWTYPE RULE + ROUTINE ROUTINES ROW ROWID ROWNUM ROWS ROWTYPE RULE SAVEPOINT SCALAR SCALE SCHEMA SCHEMAS SCROLL SEARCH SECOND_P SECURITY SELECT SEQUENCE SEQUENCES @@ -20387,6 +20387,7 @@ unreserved_keyword: | ROUTINE | ROUTINES | ROWID + | ROWNUM | ROWS | ROWTYPE | RULE @@ -21104,6 +21105,7 @@ bare_label_keyword: | ROUTINES | ROW | ROWID + | ROWNUM | ROWS | ROWTYPE | RULE diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c index 536bf97ee42..a891c5d9c12 100644 --- a/src/backend/parser/parse_expr.c +++ b/src/backend/parser/parse_expr.c @@ -686,6 +686,22 @@ transformColumnRefInternal(ParseState *pstate, ColumnRef *cref, bool missing_ok) colname = strVal(field1); set_merge_on_attrno(pstate, colname); + /* + * Check for ROWNUM pseudocolumn in Oracle mode. + * ROWNUM is only recognized as a pseudocolumn when: + * 1. Database is in Oracle compatibility mode + * 2. The identifier is exactly "rownum" (case-insensitive) + * 3. It's unqualified (no table/schema prefix) + */ + if (database_mode == DB_ORACLE && pg_strcasecmp(colname, "rownum") == 0) + { + RownumExpr *rexpr; + + rexpr = makeNode(RownumExpr); + rexpr->location = cref->location; + return (Node *) rexpr; + } + /* Try to identify as an unqualified column */ node = colNameToVar(pstate, colname, false, cref->location); diff --git a/src/backend/utils/adt/ruleutils.c b/src/backend/utils/adt/ruleutils.c index 629264da1d9..471b393d8f5 100644 --- a/src/backend/utils/adt/ruleutils.c +++ b/src/backend/utils/adt/ruleutils.c @@ -9337,6 +9337,7 @@ isSimpleNode(Node *node, Node *parentNode, int prettyFlags) case T_SQLValueFunction: case T_XmlExpr: case T_NextValueExpr: + case T_RownumExpr: case T_NullIfExpr: case T_Aggref: case T_GroupingFunc: @@ -10837,6 +10838,11 @@ get_rule_expr(Node *node, deparse_context *context, } break; + case T_RownumExpr: + /* Oracle ROWNUM pseudocolumn */ + appendStringInfoString(buf, "ROWNUM"); + break; + case T_InferenceElem: { InferenceElem *iexpr = (InferenceElem *) node; diff --git a/src/include/executor/execExpr.h b/src/include/executor/execExpr.h index 446886c0225..4e6c889d8b9 100644 --- a/src/include/executor/execExpr.h +++ b/src/include/executor/execExpr.h @@ -200,6 +200,7 @@ typedef enum ExprEvalOp EEOP_SQLVALUEFUNCTION, EEOP_CURRENTOFEXPR, EEOP_NEXTVALUEEXPR, + EEOP_ROWNUM, EEOP_RETURNINGEXPR, EEOP_ARRAYEXPR, EEOP_ARRAYCOERCE, @@ -884,6 +885,7 @@ extern void ExecEvalCoerceViaIOSafe(ExprState *state, ExprEvalStep *op); extern void ExecEvalSQLValueFunction(ExprState *state, ExprEvalStep *op); extern void ExecEvalCurrentOfExpr(ExprState *state, ExprEvalStep *op); extern void ExecEvalNextValueExpr(ExprState *state, ExprEvalStep *op); +extern void ExecEvalRownum(ExprState *state, ExprEvalStep *op); extern void ExecEvalRowNull(ExprState *state, ExprEvalStep *op, ExprContext *econtext); extern void ExecEvalRowNotNull(ExprState *state, ExprEvalStep *op, diff --git a/src/include/executor/execScan.h b/src/include/executor/execScan.h index 837ea7785bb..197ae023072 100644 --- a/src/include/executor/execScan.h +++ b/src/include/executor/execScan.h @@ -205,6 +205,16 @@ ExecScanExtended(ScanState *node, */ econtext->ecxt_scantuple = slot; + /* + * For Oracle ROWNUM compatibility: pre-increment ROWNUM before the + * qual check so that ROWNUM conditions (like ROWNUM <= 5) see the + * correct value. If the row fails the qual, we'll revert the + * increment. This matches Oracle's behavior where ROWNUM is assigned + * to each candidate row before checking the WHERE clause. + */ + if (node->ps.state) + node->ps.state->es_rownum++; + /* * check that the current tuple satisfies the qual-clause * @@ -216,14 +226,34 @@ ExecScanExtended(ScanState *node, { /* * Found a satisfactory scan tuple. + * The ROWNUM increment is already done. */ if (projInfo) { + TupleTableSlot *result; + /* * Form a projection tuple, store it in the result tuple slot * and return it. */ - return ExecProject(projInfo); + result = ExecProject(projInfo); + + /* + * If the projection contains ROWNUM expressions, materialize + * the virtual tuple to preserve the ROWNUM values as constants. + * This prevents re-evaluation when the tuple is read by outer + * queries (e.g., in subqueries with ORDER BY). + * + * Oracle materializes ROWNUM values in SELECT lists, so when + * a subquery projects ROWNUM, the value must be captured NOW + * and not re-evaluated later in different contexts. + */ + if (projInfo->pi_needsMaterialization) + { + ExecMaterializeSlot(result); + } + + return result; } else { @@ -234,7 +264,18 @@ ExecScanExtended(ScanState *node, } } else + { + /* + * Row failed qual check. Revert the ROWNUM increment so that + * only rows that pass quals consume ROWNUM values. This matches + * Oracle's behavior where ROWNUM is only assigned to rows that + * are actually "selected". + */ + if (node->ps.state) + node->ps.state->es_rownum--; + InstrCountFiltered1(node, 1); + } /* * Tuple fails qual, so free per-tuple memory and try again. diff --git a/src/include/nodes/execnodes.h b/src/include/nodes/execnodes.h index 2492282213f..e6e8ca87cf4 100644 --- a/src/include/nodes/execnodes.h +++ b/src/include/nodes/execnodes.h @@ -380,6 +380,8 @@ typedef struct ProjectionInfo ExprState pi_state; /* expression context in which to evaluate expression */ ExprContext *pi_exprContext; + /* true if projection contains volatile exprs like ROWNUM that need materialization */ + bool pi_needsMaterialization; } ProjectionInfo; /* ---------------- @@ -747,6 +749,13 @@ typedef struct EState /* The per-query shared memory area to use for parallel execution. */ struct dsa_area *es_query_dsa; + /* + * Oracle ROWNUM support: current row number counter. + * This is incremented for each row emitted during query execution. + * Only used when database_mode == DB_ORACLE. + */ + int64 es_rownum; + /* * JIT information. es_jit_flags indicates whether JIT should be performed * and with which options. es_jit is created on-demand when JITing is @@ -1937,12 +1946,15 @@ typedef struct TidRangeScanState * * SubqueryScanState is used for scanning a sub-query in the range table. * ScanTupleSlot references the current output tuple of the sub-query. + * rownum_reset tracks whether ROWNUM counter has been reset for Oracle + * compatibility (inner plans may increment before SubqueryScan runs). * ---------------- */ typedef struct SubqueryScanState { ScanState ss; /* its first field is NodeTag */ PlanState *subplan; + bool rownum_reset; /* has ROWNUM been reset for this scan? */ } SubqueryScanState; /* ---------------- diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h index 4584debee1e..9ed0ac08e2d 100644 --- a/src/include/nodes/primnodes.h +++ b/src/include/nodes/primnodes.h @@ -2147,6 +2147,21 @@ typedef struct NextValueExpr Oid typeId; } NextValueExpr; +/* + * RownumExpr - Oracle ROWNUM pseudocolumn + * + * Returns a number indicating the order in which a row was selected from + * a table or set of joined rows. The first row selected has a ROWNUM of 1, + * the second has 2, and so on. + * + * Only active when compatible_mode = 'oracle'. + */ +typedef struct RownumExpr +{ + Expr xpr; + ParseLoc location; /* token location, or -1 if unknown */ +} RownumExpr; + /* * InferenceElem - an element of a unique index inference specification * diff --git a/src/include/oracle_parser/ora_kwlist.h b/src/include/oracle_parser/ora_kwlist.h index 3df04d14aed..0099747848f 100644 --- a/src/include/oracle_parser/ora_kwlist.h +++ b/src/include/oracle_parser/ora_kwlist.h @@ -458,6 +458,7 @@ PG_KEYWORD("routine", ROUTINE, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("routines", ROUTINES, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("row", ROW, COL_NAME_KEYWORD, BARE_LABEL) PG_KEYWORD("rowid", ROWID, UNRESERVED_KEYWORD, BARE_LABEL) +PG_KEYWORD("rownum", ROWNUM, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("rows", ROWS, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("rowtype", ROWTYPE, UNRESERVED_KEYWORD, BARE_LABEL) PG_KEYWORD("rule", RULE, UNRESERVED_KEYWORD, BARE_LABEL) diff --git a/src/oracle_test/regress/expected/rownum.out b/src/oracle_test/regress/expected/rownum.out new file mode 100644 index 00000000000..d0c066c8e7a --- /dev/null +++ b/src/oracle_test/regress/expected/rownum.out @@ -0,0 +1,928 @@ +-- +-- ROWNUM +-- Test Oracle ROWNUM pseudocolumn functionality +-- +-- Setup test data +CREATE TABLE rownum_test ( + id int, + name varchar(50), + value int +); +INSERT INTO rownum_test VALUES + (1, 'Alice', 100), + (2, 'Bob', 200), + (3, 'Charlie', 150), + (4, 'David', 300), + (5, 'Eve', 250), + (6, 'Frank', 175), + (7, 'Grace', 225), + (8, 'Henry', 125), + (9, 'Iris', 275), + (10, 'Jack', 190); +-- +-- Basic ROWNUM queries +-- +-- ROWNUM <= N (should use LIMIT optimization) +SELECT id, name FROM rownum_test WHERE ROWNUM <= 5; + id | name +----+--------- + 1 | Alice + 2 | Bob + 3 | Charlie + 4 | David + 5 | Eve +(5 rows) + +-- ROWNUM = 1 (should use LIMIT 1) +SELECT id, name FROM rownum_test WHERE ROWNUM = 1; + id | name +----+------- + 1 | Alice +(1 row) + +-- ROWNUM < N (should use LIMIT N-1) +SELECT id, name FROM rownum_test WHERE ROWNUM < 4; + id | name +----+--------- + 1 | Alice + 2 | Bob + 3 | Charlie +(3 rows) + +-- ROWNUM in SELECT list +SELECT ROWNUM, id, name FROM rownum_test WHERE ROWNUM <= 3; + rownum | id | name +--------+----+--------- + 1 | 1 | Alice + 2 | 2 | Bob + 3 | 3 | Charlie +(3 rows) + +-- +-- ROWNUM with ORDER BY +-- (requires subquery pattern to order first, then limit) +-- +-- Top-N by value (descending) +SELECT * FROM ( + SELECT id, name, value + FROM rownum_test + ORDER BY value DESC +) WHERE ROWNUM <= 3; + id | name | value +----+-------+------- + 4 | David | 300 + 9 | Iris | 275 + 5 | Eve | 250 +(3 rows) + +-- Top-N by name (ascending) +SELECT * FROM ( + SELECT id, name + FROM rownum_test + ORDER BY name +) WHERE ROWNUM <= 5; + id | name +----+--------- + 1 | Alice + 2 | Bob + 3 | Charlie + 4 | David + 5 | Eve +(5 rows) + +-- ROWNUM = 1 with ORDER BY (get minimum) +SELECT * FROM ( + SELECT id, name, value + FROM rownum_test + ORDER BY value +) WHERE ROWNUM = 1; + id | name | value +----+-------+------- + 1 | Alice | 100 +(1 row) + +-- +-- ROWNUM in nested subqueries +-- +-- Subquery with ROWNUM in WHERE clause +SELECT name FROM ( + SELECT id, name FROM rownum_test WHERE ROWNUM <= 7 +) sub WHERE id > 3; + name +------- + David + Eve + Frank + Grace +(4 rows) + +-- Multiple levels of ROWNUM +SELECT * FROM ( + SELECT * FROM ( + SELECT id, name FROM rownum_test WHERE ROWNUM <= 8 + ) WHERE ROWNUM <= 5 +) WHERE ROWNUM <= 3; + id | name +----+--------- + 1 | Alice + 2 | Bob + 3 | Charlie +(3 rows) + +-- +-- ROWNUM with JOINs +-- +CREATE TABLE dept ( + dept_id int, + dept_name varchar(50) +); +INSERT INTO dept VALUES + (1, 'Engineering'), + (2, 'Sales'), + (3, 'Marketing'); +-- Update test data to include dept_id +ALTER TABLE rownum_test ADD COLUMN dept_id int; +UPDATE rownum_test SET dept_id = (id % 3) + 1; +-- ROWNUM with JOIN +SELECT e.id, e.name, d.dept_name +FROM (SELECT * FROM rownum_test WHERE ROWNUM <= 5) e +JOIN dept d ON e.dept_id = d.dept_id +ORDER BY e.id; + id | name | dept_name +----+---------+------------- + 1 | Alice | Sales + 2 | Bob | Marketing + 3 | Charlie | Engineering + 4 | David | Sales + 5 | Eve | Marketing +(5 rows) + +-- JOIN with ORDER BY and ROWNUM +SELECT * FROM ( + SELECT e.id, e.name, e.value, d.dept_name + FROM rownum_test e + JOIN dept d ON e.dept_id = d.dept_id + ORDER BY e.value DESC +) WHERE ROWNUM <= 4; + id | name | value | dept_name +----+-------+-------+------------- + 4 | David | 300 | Sales + 9 | Iris | 275 | Engineering + 5 | Eve | 250 | Marketing + 7 | Grace | 225 | Sales +(4 rows) + +-- +-- Edge cases and non-optimizable patterns +-- +-- ROWNUM > 0 (tautology, returns all rows - Oracle semantics) +SELECT COUNT(*) FROM rownum_test WHERE ROWNUM > 0; + count +------- + 10 +(1 row) + +-- ROWNUM >= 1 (tautology, returns all rows - Oracle semantics) +SELECT COUNT(*) FROM rownum_test WHERE ROWNUM >= 1; + count +------- + 10 +(1 row) + +-- ROWNUM > N where N >= 1 (returns empty - Oracle semantics) +SELECT id, name FROM rownum_test WHERE ROWNUM > 5; + id | name +----+------ +(0 rows) + +SELECT COUNT(*) FROM rownum_test WHERE ROWNUM > 1; + count +------- + 0 +(1 row) + +-- ROWNUM >= N where N > 1 (returns empty - Oracle semantics) +SELECT id, name FROM rownum_test WHERE ROWNUM >= 2; + id | name +----+------ +(0 rows) + +SELECT COUNT(*) FROM rownum_test WHERE ROWNUM >= 2; + count +------- + 0 +(1 row) + +-- ROWNUM = 0 (always false) +SELECT id, name FROM rownum_test WHERE ROWNUM = 0; + id | name +----+------ +(0 rows) + +-- ROWNUM = 2 (not optimizable, returns empty - Oracle semantics) +SELECT id, name FROM rownum_test WHERE ROWNUM = 2; + id | name +----+------ +(0 rows) + +-- ROWNUM = 3 (not optimizable, returns empty - Oracle semantics) +SELECT id, name FROM rownum_test WHERE ROWNUM = 3; + id | name +----+------ +(0 rows) + +-- ROWNUM with negative number +SELECT id, name FROM rownum_test WHERE ROWNUM <= -1; + id | name +----+------ +(0 rows) + +-- ROWNUM in complex WHERE clause (AND) +SELECT id, name FROM rownum_test WHERE ROWNUM <= 5 AND id > 2; + id | name +----+--------- + 3 | Charlie + 4 | David + 5 | Eve + 6 | Frank + 7 | Grace +(5 rows) + +-- ROWNUM in complex WHERE clause (OR - not optimizable) +SELECT id, name FROM rownum_test WHERE ROWNUM <= 3 OR id = 10; + id | name +----+--------- + 1 | Alice + 2 | Bob + 3 | Charlie + 10 | Jack +(4 rows) + +-- +-- ROWNUM with DISTINCT +-- +SELECT DISTINCT dept_id FROM rownum_test WHERE ROWNUM <= 6; + dept_id +--------- + 3 + 2 + 1 +(3 rows) + +-- +-- ROWNUM with aggregate functions +-- +-- ROWNUM with GROUP BY (applied before grouping) +SELECT dept_id, COUNT(*) +FROM (SELECT * FROM rownum_test WHERE ROWNUM <= 7) +GROUP BY dept_id +ORDER BY dept_id; + dept_id | count +---------+------- + 1 | 2 + 2 | 3 + 3 | 2 +(3 rows) + +-- +-- Issue #12: ROWNUM with same-level ORDER BY, DISTINCT, GROUP BY, aggregation +-- These should NOT be transformed to LIMIT because of semantic differences +-- +-- Direct COUNT with ROWNUM (should count only first 5 rows, not all rows) +SELECT COUNT(*) FROM rownum_test WHERE ROWNUM <= 5; + count +------- + 5 +(1 row) + +-- Direct ORDER BY with ROWNUM (should pick first 5 rows, THEN sort them) +-- NOT the same as "ORDER BY value LIMIT 5" which sorts all rows first +SELECT id, name, value FROM rownum_test WHERE ROWNUM <= 5 ORDER BY value; + id | name | value +----+---------+------- + 1 | Alice | 100 + 3 | Charlie | 150 + 2 | Bob | 200 + 5 | Eve | 250 + 4 | David | 300 +(5 rows) + +-- Direct DISTINCT with ROWNUM (should DISTINCT over first 3 rows only) +-- NOT the same as "SELECT DISTINCT ... LIMIT 3" which distincts all rows first +CREATE TABLE rownum_distinct_test (category varchar(10)); +INSERT INTO rownum_distinct_test VALUES ('A'), ('A'), ('B'), ('B'), ('C'), ('C'); +SELECT DISTINCT category FROM rownum_distinct_test WHERE ROWNUM <= 3; + category +---------- + B + A +(2 rows) + +DROP TABLE rownum_distinct_test; +-- Direct GROUP BY with ROWNUM (should group only first 4 rows) +-- NOT the same as "GROUP BY ... LIMIT N" which groups all rows first +CREATE TABLE rownum_group_test (category varchar(10), amount int); +INSERT INTO rownum_group_test VALUES + ('A', 10), ('A', 20), ('B', 30), ('B', 40), ('C', 50), ('C', 60); +SELECT category, SUM(amount) +FROM rownum_group_test +WHERE ROWNUM <= 4 +GROUP BY category +ORDER BY category; + category | sum +----------+----- + A | 30 + B | 70 +(2 rows) + +DROP TABLE rownum_group_test; +-- +-- Verify optimizer transformation with EXPLAIN +-- +-- Should show Limit node for ROWNUM <= N +EXPLAIN (COSTS OFF) SELECT id, name FROM rownum_test WHERE ROWNUM <= 5; + QUERY PLAN +------------------------------- + Limit + -> Seq Scan on rownum_test +(2 rows) + +-- Should show Limit node for ROWNUM = 1 +EXPLAIN (COSTS OFF) SELECT id, name FROM rownum_test WHERE ROWNUM = 1; + QUERY PLAN +------------------------------- + Limit + -> Seq Scan on rownum_test +(2 rows) + +-- Should show Limit node for ROWNUM < N +EXPLAIN (COSTS OFF) SELECT id, name FROM rownum_test WHERE ROWNUM < 4; + QUERY PLAN +------------------------------- + Limit + -> Seq Scan on rownum_test +(2 rows) + +-- Subquery pattern should show Limit node +EXPLAIN (COSTS OFF) +SELECT * FROM ( + SELECT id, name, value + FROM rownum_test + ORDER BY value DESC +) WHERE ROWNUM <= 3; + QUERY PLAN +------------------------------------------ + Limit + -> Sort + Sort Key: rownum_test.value DESC + -> Seq Scan on rownum_test +(4 rows) + +-- ROWNUM > 0 (tautology, should remove qual entirely) +EXPLAIN (COSTS OFF) SELECT COUNT(*) FROM rownum_test WHERE ROWNUM > 0; + QUERY PLAN +------------------------------- + Aggregate + -> Seq Scan on rownum_test +(2 rows) + +-- ROWNUM >= 1 (tautology, should remove qual entirely) +EXPLAIN (COSTS OFF) SELECT COUNT(*) FROM rownum_test WHERE ROWNUM >= 1; + QUERY PLAN +------------------------------- + Aggregate + -> Seq Scan on rownum_test +(2 rows) + +-- ROWNUM > 5 (should show One-Time Filter: false) +EXPLAIN (COSTS OFF) SELECT id, name FROM rownum_test WHERE ROWNUM > 5; + QUERY PLAN +-------------------------- + Result + One-Time Filter: false +(2 rows) + +-- ROWNUM > 1 with aggregation (should show One-Time Filter: false) +EXPLAIN (COSTS OFF) SELECT COUNT(*) FROM rownum_test WHERE ROWNUM > 1; + QUERY PLAN +-------------------------------- + Aggregate + -> Result + One-Time Filter: false +(3 rows) + +-- ROWNUM >= 2 (should show One-Time Filter: false) +EXPLAIN (COSTS OFF) SELECT id, name FROM rownum_test WHERE ROWNUM >= 2; + QUERY PLAN +-------------------------- + Result + One-Time Filter: false +(2 rows) + +-- ROWNUM = 2 should NOT be optimized to LIMIT (should show One-Time Filter: false) +EXPLAIN (COSTS OFF) SELECT id, name FROM rownum_test WHERE ROWNUM = 2; + QUERY PLAN +-------------------------- + Result + One-Time Filter: false +(2 rows) + +-- Issue #12: These should NOT show Limit because of same-level operations +-- Direct COUNT with ROWNUM (has aggregation, should not use LIMIT) +EXPLAIN (COSTS OFF) SELECT COUNT(*) FROM rownum_test WHERE ROWNUM <= 5; + QUERY PLAN +------------------------------- + Aggregate + -> Seq Scan on rownum_test + Filter: (ROWNUM <= 5) +(3 rows) + +-- Direct ORDER BY with ROWNUM (has ORDER BY, should not use LIMIT) +EXPLAIN (COSTS OFF) SELECT id, name FROM rownum_test WHERE ROWNUM <= 5 ORDER BY value; + QUERY PLAN +------------------------------- + Sort + Sort Key: value + -> Seq Scan on rownum_test + Filter: (ROWNUM <= 5) +(4 rows) + +-- Direct DISTINCT with ROWNUM (has DISTINCT, should not use LIMIT) +EXPLAIN (COSTS OFF) SELECT DISTINCT dept_id FROM rownum_test WHERE ROWNUM <= 5; + QUERY PLAN +------------------------------- + HashAggregate + Group Key: dept_id + -> Seq Scan on rownum_test + Filter: (ROWNUM <= 5) +(4 rows) + +-- +-- ROWNUM with other clauses +-- +-- ROWNUM with OFFSET (not standard Oracle, but test interaction) +SELECT id, name FROM rownum_test WHERE ROWNUM <= 5 OFFSET 2; + id | name +----+--------- + 3 | Charlie + 4 | David + 5 | Eve + 6 | Frank + 7 | Grace +(5 rows) + +-- ROWNUM with FETCH FIRST (should work together) +SELECT id, name FROM rownum_test WHERE ROWNUM <= 8 FETCH FIRST 3 ROWS ONLY; + id | name +----+--------- + 1 | Alice + 2 | Bob + 3 | Charlie +(3 rows) + +-- +-- ROWNUM in SELECT list with ORDER BY (Issue: ORDER BY bug fix) +-- These test the fix for ROWNUM being evaluated at wrong level when combined with ORDER BY +-- +-- Basic case: ROWNUM in SELECT with ORDER BY +-- ROWNUM values should reflect row position BEFORE sort, not after +SELECT * FROM ( + SELECT ROWNUM as rn, id, name, value + FROM rownum_test + ORDER BY value DESC +) sub WHERE rn <= 3; + rn | id | name | value +----+----+---------+------- + 2 | 2 | Bob | 200 + 3 | 3 | Charlie | 150 + 1 | 1 | Alice | 100 +(3 rows) + +-- Verify ROWNUM values are assigned before ORDER BY (not sequential 1,2,3) +SELECT ROWNUM as rn, id, name, value +FROM rownum_test +ORDER BY value DESC; + rn | id | name | value +----+----+---------+------- + 4 | 4 | David | 300 + 9 | 9 | Iris | 275 + 5 | 5 | Eve | 250 + 7 | 7 | Grace | 225 + 2 | 2 | Bob | 200 + 10 | 10 | Jack | 190 + 6 | 6 | Frank | 175 + 3 | 3 | Charlie | 150 + 8 | 8 | Henry | 125 + 1 | 1 | Alice | 100 +(10 rows) + +-- ROWNUM in SELECT with ORDER BY and outer filter +SELECT * FROM ( + SELECT ROWNUM as rn, id, name, value + FROM rownum_test + ORDER BY value DESC +) sub WHERE rn > 2 AND rn <= 5; + rn | id | name | value +----+----+---------+------- + 4 | 4 | David | 300 + 5 | 5 | Eve | 250 + 3 | 3 | Charlie | 150 +(3 rows) + +-- Multiple ROWNUM columns at different nesting levels +SELECT ROWNUM as outer_rn, * FROM ( + SELECT ROWNUM as middle_rn, * FROM ( + SELECT ROWNUM as inner_rn, id, name, value + FROM rownum_test + ORDER BY value DESC + ) sub1 + ORDER BY value ASC +) sub2 +ORDER BY id +LIMIT 5; + outer_rn | middle_rn | inner_rn | id | name | value +----------+-----------+----------+----+---------+------- + 1 | 10 | 1 | 1 | Alice | 100 + 6 | 5 | 2 | 2 | Bob | 200 + 3 | 8 | 3 | 3 | Charlie | 150 + 10 | 1 | 4 | 4 | David | 300 + 8 | 3 | 5 | 5 | Eve | 250 +(5 rows) + +-- ROWNUM in SELECT with ORDER BY and JOIN +SELECT * FROM ( + SELECT ROWNUM as rn, e.id, e.name, e.value, d.dept_name + FROM rownum_test e + JOIN dept d ON e.dept_id = d.dept_id + ORDER BY e.value DESC +) sub WHERE rn <= 4; + rn | id | name | value | dept_name +----+----+---------+-------+------------- + 3 | 4 | David | 300 | Sales + 3 | 9 | Iris | 275 | Engineering + 3 | 5 | Eve | 250 | Marketing + 3 | 7 | Grace | 225 | Sales + 3 | 2 | Bob | 200 | Marketing + 3 | 10 | Jack | 190 | Sales + 3 | 6 | Frank | 175 | Engineering + 3 | 3 | Charlie | 150 | Engineering + 3 | 8 | Henry | 125 | Marketing + 3 | 1 | Alice | 100 | Sales +(10 rows) + +-- Test that ROWNUM is materialized (not re-evaluated in outer query) +-- This tests the materialization fix +SELECT rn, id, name FROM ( + SELECT ROWNUM as rn, id, name, value + FROM rownum_test + ORDER BY value DESC +) sub +ORDER BY rn -- Sorting by rn should not re-evaluate ROWNUM +LIMIT 5; + rn | id | name +----+----+--------- + 1 | 1 | Alice + 2 | 2 | Bob + 3 | 3 | Charlie + 4 | 4 | David + 5 | 5 | Eve +(5 rows) + +-- EXPLAIN: Verify ROWNUM is pushed to scan level before Sort +EXPLAIN (COSTS OFF, VERBOSE) +SELECT * FROM ( + SELECT ROWNUM as rn, id, name, value + FROM rownum_test + ORDER BY value DESC +) sub WHERE rn <= 3; + QUERY PLAN +----------------------------------------------------------------------------------------- + Subquery Scan on sub + Output: sub.rn, sub.id, sub.name, sub.value + Filter: (sub.rn <= 3) + -> Result + Output: (ROWNUM), rownum_test.id, rownum_test.name, rownum_test.value + -> Sort + Output: rownum_test.id, rownum_test.name, rownum_test.value, (ROWNUM) + Sort Key: rownum_test.value DESC + -> Seq Scan on public.rownum_test + Output: rownum_test.id, rownum_test.name, rownum_test.value, ROWNUM +(10 rows) + +-- +-- Issue #14: ROWNUM counter reset in correlated subqueries +-- ROWNUM counter must reset to 0 for each correlated subquery invocation. +-- This matches Oracle behavior where each subquery execution starts fresh. +-- Bug report: https://github.com/rophy/IvorySQL/issues/14 +-- +SELECT + id, + name, + (SELECT ROWNUM FROM ( + SELECT * FROM rownum_test t2 + WHERE t2.id = t1.id + ORDER BY value DESC + ) sub) as correlated_rn +FROM rownum_test t1 +ORDER BY id +LIMIT 5; + id | name | correlated_rn +----+---------+--------------- + 1 | Alice | 1 + 2 | Bob | 1 + 3 | Charlie | 1 + 4 | David | 1 + 5 | Eve | 1 +(5 rows) + +-- Additional test: max ROWNUM in correlated subquery +-- Each group should have max_rn = 3 (not incrementing values) +SELECT + id, + (SELECT MAX(ROWNUM) FROM rownum_test t2 WHERE t2.id = t1.id) as max_rn +FROM rownum_test t1 +WHERE id <= 5 +GROUP BY id +ORDER BY id; + id | max_rn +----+-------- + 1 | 1 + 2 | 1 + 3 | 1 + 4 | 1 + 5 | 1 +(5 rows) + +-- Test multiple correlated subqueries in same query +-- Both should reset independently +SELECT + id, + (SELECT COUNT(*) FROM rownum_test t2 WHERE t2.id = t1.id AND ROWNUM <= 2) as cnt_first_2, + (SELECT MIN(ROWNUM) FROM rownum_test t2 WHERE t2.id = t1.id) as min_rn +FROM rownum_test t1 +WHERE id <= 3 +GROUP BY id +ORDER BY id; + id | cnt_first_2 | min_rn +----+-------------+-------- + 1 | 1 | 1 + 2 | 1 | 1 + 3 | 1 | 1 +(3 rows) + +-- Nested correlated subqueries +-- Inner and outer subqueries should both reset ROWNUM +SELECT + id, + (SELECT + (SELECT ROWNUM FROM rownum_test t3 WHERE t3.id = t2.id ORDER BY value LIMIT 1) + FROM rownum_test t2 WHERE t2.id = t1.id LIMIT 1) as nested_rn +FROM rownum_test t1 +WHERE id <= 3 +ORDER BY id; + id | nested_rn +----+----------- + 1 | 1 + 2 | 1 + 3 | 1 +(3 rows) + +-- Correlated subquery with ROWNUM in JOIN condition +SELECT + t1.id, + (SELECT COUNT(*) + FROM rownum_test t2 + JOIN rownum_test t3 ON t2.id = t3.id + WHERE t2.id = t1.id AND ROWNUM <= 1) as join_count +FROM rownum_test t1 +WHERE id <= 3 +GROUP BY id +ORDER BY id; + id | join_count +----+------------ + 1 | 0 + 2 | 0 + 3 | 0 +(3 rows) + +-- +-- Nested ROWNUM expression tests (CodeRabbit improvements) +-- +-- ROWNUM in arithmetic expressions with ORDER BY +SELECT + id, + value, + ROWNUM * 10 as rownum_x10, + ROWNUM + value as rownum_plus_value +FROM rownum_test +WHERE id <= 5 +ORDER BY value DESC; + id | value | rownum_x10 | rownum_plus_value +----+-------+------------+------------------- + 4 | 300 | 40 | 304 + 5 | 250 | 50 | 255 + 2 | 200 | 20 | 202 + 3 | 150 | 30 | 153 + 1 | 100 | 10 | 101 +(5 rows) + +-- ROWNUM in CASE expression with ORDER BY +SELECT + id, + value, + CASE + WHEN ROWNUM <= 2 THEN 'Top 2' + WHEN ROWNUM <= 5 THEN 'Top 5' + ELSE 'Other' + END as tier +FROM rownum_test +ORDER BY value DESC +LIMIT 7; + id | value | tier +----+-------+------- + 4 | 300 | Top 5 + 9 | 275 | Other + 5 | 250 | Top 5 + 7 | 225 | Other + 2 | 200 | Top 2 + 10 | 190 | Other + 6 | 175 | Other +(7 rows) + +-- ROWNUM in function calls with ORDER BY +SELECT + id, + value, + COALESCE(ROWNUM, 0) as coalesced_rn, + GREATEST(ROWNUM, 1) as greatest_rn +FROM rownum_test +WHERE id <= 5 +ORDER BY value; + id | value | coalesced_rn | greatest_rn +----+-------+--------------+------------- + 1 | 100 | 1 | 1 + 3 | 150 | 3 | 3 + 2 | 200 | 2 | 2 + 5 | 250 | 5 | 5 + 4 | 300 | 4 | 4 +(5 rows) + +-- Multiple nested ROWNUM expressions in same SELECT +SELECT + id, + ROWNUM as rn1, + ROWNUM * 2 as rn2, + CASE WHEN ROWNUM <= 3 THEN ROWNUM * 100 ELSE 0 END as rn3 +FROM rownum_test +WHERE id <= 5 +ORDER BY value DESC; + id | rn1 | rn2 | rn3 +----+-----+-----+----- + 4 | 4 | 8 | 0 + 5 | 5 | 10 | 0 + 2 | 2 | 4 | 200 + 3 | 3 | 6 | 300 + 1 | 1 | 2 | 100 +(5 rows) + +-- ROWNUM in subquery expression with ORDER BY +SELECT + id, + value, + (SELECT ROWNUM) as subquery_rn, + ROWNUM + (SELECT 10) as expr_rn +FROM rownum_test +WHERE id <= 5 +ORDER BY value; + id | value | subquery_rn | expr_rn +----+-------+-------------+--------- + 1 | 100 | 1 | 11 + 3 | 150 | 1 | 13 + 2 | 200 | 1 | 12 + 5 | 250 | 1 | 15 + 4 | 300 | 1 | 14 +(5 rows) + +-- ROWNUM in aggregate function with ORDER BY +SELECT + dept_id, + MAX(ROWNUM) as max_rownum, + MIN(ROWNUM) as min_rownum, + COUNT(ROWNUM) as count_rownum +FROM ( + SELECT dept_id, ROWNUM + FROM rownum_test + ORDER BY value DESC +) sub +GROUP BY dept_id +ORDER BY dept_id; + dept_id | max_rownum | min_rownum | count_rownum +---------+------------+------------+-------------- + 1 | 10 | 10 | 3 + 2 | 10 | 10 | 4 + 3 | 10 | 10 | 3 +(3 rows) + +-- +-- Projection capability tests (change_plan_targetlist usage) +-- +-- Test ROWNUM with Material node (non-projection-capable) +SELECT DISTINCT ON (dept_id) + dept_id, + ROWNUM as rn, + value +FROM rownum_test +ORDER BY dept_id, value DESC; + dept_id | rn | value +---------+----+------- + 1 | 10 | 275 + 2 | 10 | 300 + 3 | 10 | 250 +(3 rows) + +-- Test ROWNUM with Sort -> Unique pipeline +SELECT DISTINCT + ROWNUM as rn, + dept_id +FROM ( + SELECT dept_id, ROWNUM + FROM rownum_test + ORDER BY value DESC +) sub +WHERE ROWNUM <= 5; + rn | dept_id +----+--------- + 5 | 2 + 2 | 3 + 3 | 3 + 4 | 1 + 1 | 2 +(5 rows) + +-- Test ROWNUM with SetOp (non-projection-capable) +SELECT ROWNUM as rn, id FROM rownum_test WHERE id <= 3 +UNION +SELECT ROWNUM as rn, id FROM rownum_test WHERE id > 7 +ORDER BY rn, id; + rn | id +----+---- + 1 | 1 + 2 | 2 + 3 | 3 + 4 | 8 + 5 | 9 + 6 | 10 +(6 rows) + +-- +-- Edge cases for ROWNUM reset +-- +-- ROWNUM in EXISTS correlated subquery +SELECT + id, + EXISTS(SELECT 1 FROM rownum_test t2 WHERE t2.id = t1.id AND ROWNUM = 1) as has_first +FROM rownum_test t1 +WHERE id <= 5 +ORDER BY id; + id | has_first +----+----------- + 1 | t + 2 | t + 3 | t + 4 | t + 5 | t +(5 rows) + +-- ROWNUM in NOT EXISTS correlated subquery +SELECT + id, + NOT EXISTS(SELECT 1 FROM rownum_test t2 WHERE t2.id = t1.id AND ROWNUM > 5) as all_within_5 +FROM rownum_test t1 +WHERE id <= 3 +ORDER BY id; + id | all_within_5 +----+-------------- + 1 | t + 2 | t + 3 | t +(3 rows) + +-- ROWNUM in IN correlated subquery +SELECT + id, + 1 IN (SELECT ROWNUM FROM rownum_test t2 WHERE t2.id = t1.id) as has_rownum_1 +FROM rownum_test t1 +WHERE id <= 3 +ORDER BY id; + id | has_rownum_1 +----+-------------- + 1 | t + 2 | t + 3 | t +(3 rows) + +-- +-- Cleanup +-- +DROP TABLE rownum_test CASCADE; +DROP TABLE dept CASCADE; diff --git a/src/oracle_test/regress/parallel_schedule b/src/oracle_test/regress/parallel_schedule index 2be3409a838..b6e7afaa7ba 100644 --- a/src/oracle_test/regress/parallel_schedule +++ b/src/oracle_test/regress/parallel_schedule @@ -160,3 +160,8 @@ test: emptystring_to_null test: ora_package test: ora_force_view + +# ---------- +# Oracle ROWNUM pseudocolumn +# ---------- +test: rownum diff --git a/src/oracle_test/regress/sql/rownum.sql b/src/oracle_test/regress/sql/rownum.sql new file mode 100644 index 00000000000..37b1c53f68e --- /dev/null +++ b/src/oracle_test/regress/sql/rownum.sql @@ -0,0 +1,515 @@ +-- +-- ROWNUM +-- Test Oracle ROWNUM pseudocolumn functionality +-- + +-- Setup test data +CREATE TABLE rownum_test ( + id int, + name varchar(50), + value int +); + +INSERT INTO rownum_test VALUES + (1, 'Alice', 100), + (2, 'Bob', 200), + (3, 'Charlie', 150), + (4, 'David', 300), + (5, 'Eve', 250), + (6, 'Frank', 175), + (7, 'Grace', 225), + (8, 'Henry', 125), + (9, 'Iris', 275), + (10, 'Jack', 190); + +-- +-- Basic ROWNUM queries +-- + +-- ROWNUM <= N (should use LIMIT optimization) +SELECT id, name FROM rownum_test WHERE ROWNUM <= 5; + +-- ROWNUM = 1 (should use LIMIT 1) +SELECT id, name FROM rownum_test WHERE ROWNUM = 1; + +-- ROWNUM < N (should use LIMIT N-1) +SELECT id, name FROM rownum_test WHERE ROWNUM < 4; + +-- ROWNUM in SELECT list +SELECT ROWNUM, id, name FROM rownum_test WHERE ROWNUM <= 3; + +-- +-- ROWNUM with ORDER BY +-- (requires subquery pattern to order first, then limit) +-- + +-- Top-N by value (descending) +SELECT * FROM ( + SELECT id, name, value + FROM rownum_test + ORDER BY value DESC +) WHERE ROWNUM <= 3; + +-- Top-N by name (ascending) +SELECT * FROM ( + SELECT id, name + FROM rownum_test + ORDER BY name +) WHERE ROWNUM <= 5; + +-- ROWNUM = 1 with ORDER BY (get minimum) +SELECT * FROM ( + SELECT id, name, value + FROM rownum_test + ORDER BY value +) WHERE ROWNUM = 1; + +-- +-- ROWNUM in nested subqueries +-- + +-- Subquery with ROWNUM in WHERE clause +SELECT name FROM ( + SELECT id, name FROM rownum_test WHERE ROWNUM <= 7 +) sub WHERE id > 3; + +-- Multiple levels of ROWNUM +SELECT * FROM ( + SELECT * FROM ( + SELECT id, name FROM rownum_test WHERE ROWNUM <= 8 + ) WHERE ROWNUM <= 5 +) WHERE ROWNUM <= 3; + +-- +-- ROWNUM with JOINs +-- + +CREATE TABLE dept ( + dept_id int, + dept_name varchar(50) +); + +INSERT INTO dept VALUES + (1, 'Engineering'), + (2, 'Sales'), + (3, 'Marketing'); + +-- Update test data to include dept_id +ALTER TABLE rownum_test ADD COLUMN dept_id int; +UPDATE rownum_test SET dept_id = (id % 3) + 1; + +-- ROWNUM with JOIN +SELECT e.id, e.name, d.dept_name +FROM (SELECT * FROM rownum_test WHERE ROWNUM <= 5) e +JOIN dept d ON e.dept_id = d.dept_id +ORDER BY e.id; + +-- JOIN with ORDER BY and ROWNUM +SELECT * FROM ( + SELECT e.id, e.name, e.value, d.dept_name + FROM rownum_test e + JOIN dept d ON e.dept_id = d.dept_id + ORDER BY e.value DESC +) WHERE ROWNUM <= 4; + +-- +-- Edge cases and non-optimizable patterns +-- + +-- ROWNUM > 0 (tautology, returns all rows - Oracle semantics) +SELECT COUNT(*) FROM rownum_test WHERE ROWNUM > 0; + +-- ROWNUM >= 1 (tautology, returns all rows - Oracle semantics) +SELECT COUNT(*) FROM rownum_test WHERE ROWNUM >= 1; + +-- ROWNUM > N where N >= 1 (returns empty - Oracle semantics) +SELECT id, name FROM rownum_test WHERE ROWNUM > 5; +SELECT COUNT(*) FROM rownum_test WHERE ROWNUM > 1; + +-- ROWNUM >= N where N > 1 (returns empty - Oracle semantics) +SELECT id, name FROM rownum_test WHERE ROWNUM >= 2; +SELECT COUNT(*) FROM rownum_test WHERE ROWNUM >= 2; + +-- ROWNUM = 0 (always false) +SELECT id, name FROM rownum_test WHERE ROWNUM = 0; + +-- ROWNUM = 2 (not optimizable, returns empty - Oracle semantics) +SELECT id, name FROM rownum_test WHERE ROWNUM = 2; + +-- ROWNUM = 3 (not optimizable, returns empty - Oracle semantics) +SELECT id, name FROM rownum_test WHERE ROWNUM = 3; + +-- ROWNUM with negative number +SELECT id, name FROM rownum_test WHERE ROWNUM <= -1; + +-- ROWNUM in complex WHERE clause (AND) +SELECT id, name FROM rownum_test WHERE ROWNUM <= 5 AND id > 2; + +-- ROWNUM in complex WHERE clause (OR - not optimizable) +SELECT id, name FROM rownum_test WHERE ROWNUM <= 3 OR id = 10; + +-- +-- ROWNUM with DISTINCT +-- + +SELECT DISTINCT dept_id FROM rownum_test WHERE ROWNUM <= 6; + +-- +-- ROWNUM with aggregate functions +-- + +-- ROWNUM with GROUP BY (applied before grouping) +SELECT dept_id, COUNT(*) +FROM (SELECT * FROM rownum_test WHERE ROWNUM <= 7) +GROUP BY dept_id +ORDER BY dept_id; + +-- +-- Issue #12: ROWNUM with same-level ORDER BY, DISTINCT, GROUP BY, aggregation +-- These should NOT be transformed to LIMIT because of semantic differences +-- + +-- Direct COUNT with ROWNUM (should count only first 5 rows, not all rows) +SELECT COUNT(*) FROM rownum_test WHERE ROWNUM <= 5; + +-- Direct ORDER BY with ROWNUM (should pick first 5 rows, THEN sort them) +-- NOT the same as "ORDER BY value LIMIT 5" which sorts all rows first +SELECT id, name, value FROM rownum_test WHERE ROWNUM <= 5 ORDER BY value; + +-- Direct DISTINCT with ROWNUM (should DISTINCT over first 3 rows only) +-- NOT the same as "SELECT DISTINCT ... LIMIT 3" which distincts all rows first +CREATE TABLE rownum_distinct_test (category varchar(10)); +INSERT INTO rownum_distinct_test VALUES ('A'), ('A'), ('B'), ('B'), ('C'), ('C'); +SELECT DISTINCT category FROM rownum_distinct_test WHERE ROWNUM <= 3; +DROP TABLE rownum_distinct_test; + +-- Direct GROUP BY with ROWNUM (should group only first 4 rows) +-- NOT the same as "GROUP BY ... LIMIT N" which groups all rows first +CREATE TABLE rownum_group_test (category varchar(10), amount int); +INSERT INTO rownum_group_test VALUES + ('A', 10), ('A', 20), ('B', 30), ('B', 40), ('C', 50), ('C', 60); +SELECT category, SUM(amount) +FROM rownum_group_test +WHERE ROWNUM <= 4 +GROUP BY category +ORDER BY category; +DROP TABLE rownum_group_test; + +-- +-- Verify optimizer transformation with EXPLAIN +-- + +-- Should show Limit node for ROWNUM <= N +EXPLAIN (COSTS OFF) SELECT id, name FROM rownum_test WHERE ROWNUM <= 5; + +-- Should show Limit node for ROWNUM = 1 +EXPLAIN (COSTS OFF) SELECT id, name FROM rownum_test WHERE ROWNUM = 1; + +-- Should show Limit node for ROWNUM < N +EXPLAIN (COSTS OFF) SELECT id, name FROM rownum_test WHERE ROWNUM < 4; + +-- Subquery pattern should show Limit node +EXPLAIN (COSTS OFF) +SELECT * FROM ( + SELECT id, name, value + FROM rownum_test + ORDER BY value DESC +) WHERE ROWNUM <= 3; + +-- ROWNUM > 0 (tautology, should remove qual entirely) +EXPLAIN (COSTS OFF) SELECT COUNT(*) FROM rownum_test WHERE ROWNUM > 0; + +-- ROWNUM >= 1 (tautology, should remove qual entirely) +EXPLAIN (COSTS OFF) SELECT COUNT(*) FROM rownum_test WHERE ROWNUM >= 1; + +-- ROWNUM > 5 (should show One-Time Filter: false) +EXPLAIN (COSTS OFF) SELECT id, name FROM rownum_test WHERE ROWNUM > 5; + +-- ROWNUM > 1 with aggregation (should show One-Time Filter: false) +EXPLAIN (COSTS OFF) SELECT COUNT(*) FROM rownum_test WHERE ROWNUM > 1; + +-- ROWNUM >= 2 (should show One-Time Filter: false) +EXPLAIN (COSTS OFF) SELECT id, name FROM rownum_test WHERE ROWNUM >= 2; + +-- ROWNUM = 2 should NOT be optimized to LIMIT (should show One-Time Filter: false) +EXPLAIN (COSTS OFF) SELECT id, name FROM rownum_test WHERE ROWNUM = 2; + +-- Issue #12: These should NOT show Limit because of same-level operations +-- Direct COUNT with ROWNUM (has aggregation, should not use LIMIT) +EXPLAIN (COSTS OFF) SELECT COUNT(*) FROM rownum_test WHERE ROWNUM <= 5; + +-- Direct ORDER BY with ROWNUM (has ORDER BY, should not use LIMIT) +EXPLAIN (COSTS OFF) SELECT id, name FROM rownum_test WHERE ROWNUM <= 5 ORDER BY value; + +-- Direct DISTINCT with ROWNUM (has DISTINCT, should not use LIMIT) +EXPLAIN (COSTS OFF) SELECT DISTINCT dept_id FROM rownum_test WHERE ROWNUM <= 5; + +-- +-- ROWNUM with other clauses +-- + +-- ROWNUM with OFFSET (not standard Oracle, but test interaction) +SELECT id, name FROM rownum_test WHERE ROWNUM <= 5 OFFSET 2; + +-- ROWNUM with FETCH FIRST (should work together) +SELECT id, name FROM rownum_test WHERE ROWNUM <= 8 FETCH FIRST 3 ROWS ONLY; + +-- +-- ROWNUM in SELECT list with ORDER BY (Issue: ORDER BY bug fix) +-- These test the fix for ROWNUM being evaluated at wrong level when combined with ORDER BY +-- + +-- Basic case: ROWNUM in SELECT with ORDER BY +-- ROWNUM values should reflect row position BEFORE sort, not after +SELECT * FROM ( + SELECT ROWNUM as rn, id, name, value + FROM rownum_test + ORDER BY value DESC +) sub WHERE rn <= 3; + +-- Verify ROWNUM values are assigned before ORDER BY (not sequential 1,2,3) +SELECT ROWNUM as rn, id, name, value +FROM rownum_test +ORDER BY value DESC; + +-- ROWNUM in SELECT with ORDER BY and outer filter +SELECT * FROM ( + SELECT ROWNUM as rn, id, name, value + FROM rownum_test + ORDER BY value DESC +) sub WHERE rn > 2 AND rn <= 5; + +-- Multiple ROWNUM columns at different nesting levels +SELECT ROWNUM as outer_rn, * FROM ( + SELECT ROWNUM as middle_rn, * FROM ( + SELECT ROWNUM as inner_rn, id, name, value + FROM rownum_test + ORDER BY value DESC + ) sub1 + ORDER BY value ASC +) sub2 +ORDER BY id +LIMIT 5; + +-- ROWNUM in SELECT with ORDER BY and JOIN +SELECT * FROM ( + SELECT ROWNUM as rn, e.id, e.name, e.value, d.dept_name + FROM rownum_test e + JOIN dept d ON e.dept_id = d.dept_id + ORDER BY e.value DESC +) sub WHERE rn <= 4; + +-- Test that ROWNUM is materialized (not re-evaluated in outer query) +-- This tests the materialization fix +SELECT rn, id, name FROM ( + SELECT ROWNUM as rn, id, name, value + FROM rownum_test + ORDER BY value DESC +) sub +ORDER BY rn -- Sorting by rn should not re-evaluate ROWNUM +LIMIT 5; + +-- EXPLAIN: Verify ROWNUM is pushed to scan level before Sort +EXPLAIN (COSTS OFF, VERBOSE) +SELECT * FROM ( + SELECT ROWNUM as rn, id, name, value + FROM rownum_test + ORDER BY value DESC +) sub WHERE rn <= 3; + +-- +-- Issue #14: ROWNUM counter reset in correlated subqueries +-- ROWNUM counter must reset to 0 for each correlated subquery invocation. +-- This matches Oracle behavior where each subquery execution starts fresh. +-- Bug report: https://github.com/rophy/IvorySQL/issues/14 +-- +SELECT + id, + name, + (SELECT ROWNUM FROM ( + SELECT * FROM rownum_test t2 + WHERE t2.id = t1.id + ORDER BY value DESC + ) sub) as correlated_rn +FROM rownum_test t1 +ORDER BY id +LIMIT 5; + +-- Additional test: max ROWNUM in correlated subquery +-- Each group should have max_rn = 3 (not incrementing values) +SELECT + id, + (SELECT MAX(ROWNUM) FROM rownum_test t2 WHERE t2.id = t1.id) as max_rn +FROM rownum_test t1 +WHERE id <= 5 +GROUP BY id +ORDER BY id; + +-- Test multiple correlated subqueries in same query +-- Both should reset independently +SELECT + id, + (SELECT COUNT(*) FROM rownum_test t2 WHERE t2.id = t1.id AND ROWNUM <= 2) as cnt_first_2, + (SELECT MIN(ROWNUM) FROM rownum_test t2 WHERE t2.id = t1.id) as min_rn +FROM rownum_test t1 +WHERE id <= 3 +GROUP BY id +ORDER BY id; + +-- Nested correlated subqueries +-- Inner and outer subqueries should both reset ROWNUM +SELECT + id, + (SELECT + (SELECT ROWNUM FROM rownum_test t3 WHERE t3.id = t2.id ORDER BY value LIMIT 1) + FROM rownum_test t2 WHERE t2.id = t1.id LIMIT 1) as nested_rn +FROM rownum_test t1 +WHERE id <= 3 +ORDER BY id; + +-- Correlated subquery with ROWNUM in JOIN condition +SELECT + t1.id, + (SELECT COUNT(*) + FROM rownum_test t2 + JOIN rownum_test t3 ON t2.id = t3.id + WHERE t2.id = t1.id AND ROWNUM <= 1) as join_count +FROM rownum_test t1 +WHERE id <= 3 +GROUP BY id +ORDER BY id; + +-- +-- Nested ROWNUM expression tests (CodeRabbit improvements) +-- + +-- ROWNUM in arithmetic expressions with ORDER BY +SELECT + id, + value, + ROWNUM * 10 as rownum_x10, + ROWNUM + value as rownum_plus_value +FROM rownum_test +WHERE id <= 5 +ORDER BY value DESC; + +-- ROWNUM in CASE expression with ORDER BY +SELECT + id, + value, + CASE + WHEN ROWNUM <= 2 THEN 'Top 2' + WHEN ROWNUM <= 5 THEN 'Top 5' + ELSE 'Other' + END as tier +FROM rownum_test +ORDER BY value DESC +LIMIT 7; + +-- ROWNUM in function calls with ORDER BY +SELECT + id, + value, + COALESCE(ROWNUM, 0) as coalesced_rn, + GREATEST(ROWNUM, 1) as greatest_rn +FROM rownum_test +WHERE id <= 5 +ORDER BY value; + +-- Multiple nested ROWNUM expressions in same SELECT +SELECT + id, + ROWNUM as rn1, + ROWNUM * 2 as rn2, + CASE WHEN ROWNUM <= 3 THEN ROWNUM * 100 ELSE 0 END as rn3 +FROM rownum_test +WHERE id <= 5 +ORDER BY value DESC; + +-- ROWNUM in subquery expression with ORDER BY +SELECT + id, + value, + (SELECT ROWNUM) as subquery_rn, + ROWNUM + (SELECT 10) as expr_rn +FROM rownum_test +WHERE id <= 5 +ORDER BY value; + +-- ROWNUM in aggregate function with ORDER BY +SELECT + dept_id, + MAX(ROWNUM) as max_rownum, + MIN(ROWNUM) as min_rownum, + COUNT(ROWNUM) as count_rownum +FROM ( + SELECT dept_id, ROWNUM + FROM rownum_test + ORDER BY value DESC +) sub +GROUP BY dept_id +ORDER BY dept_id; + +-- +-- Projection capability tests (change_plan_targetlist usage) +-- + +-- Test ROWNUM with Material node (non-projection-capable) +SELECT DISTINCT ON (dept_id) + dept_id, + ROWNUM as rn, + value +FROM rownum_test +ORDER BY dept_id, value DESC; + +-- Test ROWNUM with Sort -> Unique pipeline +SELECT DISTINCT + ROWNUM as rn, + dept_id +FROM ( + SELECT dept_id, ROWNUM + FROM rownum_test + ORDER BY value DESC +) sub +WHERE ROWNUM <= 5; + +-- Test ROWNUM with SetOp (non-projection-capable) +SELECT ROWNUM as rn, id FROM rownum_test WHERE id <= 3 +UNION +SELECT ROWNUM as rn, id FROM rownum_test WHERE id > 7 +ORDER BY rn, id; + +-- +-- Edge cases for ROWNUM reset +-- + +-- ROWNUM in EXISTS correlated subquery +SELECT + id, + EXISTS(SELECT 1 FROM rownum_test t2 WHERE t2.id = t1.id AND ROWNUM = 1) as has_first +FROM rownum_test t1 +WHERE id <= 5 +ORDER BY id; + +-- ROWNUM in NOT EXISTS correlated subquery +SELECT + id, + NOT EXISTS(SELECT 1 FROM rownum_test t2 WHERE t2.id = t1.id AND ROWNUM > 5) as all_within_5 +FROM rownum_test t1 +WHERE id <= 3 +ORDER BY id; + +-- ROWNUM in IN correlated subquery +SELECT + id, + 1 IN (SELECT ROWNUM FROM rownum_test t2 WHERE t2.id = t1.id) as has_rownum_1 +FROM rownum_test t1 +WHERE id <= 3 +ORDER BY id; + +-- +-- Cleanup +-- + +DROP TABLE rownum_test CASCADE; +DROP TABLE dept CASCADE; diff --git a/src/pl/plisql/src/Makefile b/src/pl/plisql/src/Makefile index 2730b93f830..21831e05dba 100755 --- a/src/pl/plisql/src/Makefile +++ b/src/pl/plisql/src/Makefile @@ -58,7 +58,7 @@ REGRESS = plisql_array plisql_call plisql_control plisql_copy plisql_domain \ plisql_record plisql_cache plisql_simple plisql_transaction \ plisql_trap plisql_trigger plisql_varprops plisql_nested_subproc \ plisql_nested_subproc2 plisql_out_parameter plisql_type_rowtype \ - plisql_exception + plisql_exception plisql_rownum # where to find ora_gen_keywordlist.pl and subsidiary files TOOLSDIR = $(top_srcdir)/src/tools diff --git a/src/pl/plisql/src/expected/plisql_rownum.out b/src/pl/plisql/src/expected/plisql_rownum.out new file mode 100644 index 00000000000..b4e74d7b1bc --- /dev/null +++ b/src/pl/plisql/src/expected/plisql_rownum.out @@ -0,0 +1,476 @@ +-- +-- Tests for PL/iSQL with Oracle ROWNUM pseudocolumn +-- +-- Setup test table +CREATE TABLE rownum_test ( + id INT, + name TEXT, + value NUMERIC +); +INSERT INTO rownum_test VALUES + (1, 'Alice', 100), + (2, 'Bob', 200), + (3, 'Charlie', 150), + (4, 'David', 300), + (5, 'Eve', 250), + (6, 'Frank', 175), + (7, 'Grace', 225), + (8, 'Henry', 125); +-- Test 1: ROWNUM in FOR loop with query +CREATE FUNCTION test_rownum_for_loop() RETURNS void AS $$ +DECLARE + r RECORD; +BEGIN + RAISE NOTICE 'Test 1: FOR loop with ROWNUM'; + FOR r IN SELECT ROWNUM as rn, id, name FROM rownum_test WHERE ROWNUM <= 3 LOOP + RAISE NOTICE 'ROWNUM=%, id=%, name=%', r.rn, r.id, r.name; + END LOOP; +END; +$$ LANGUAGE plisql; +/ +SELECT test_rownum_for_loop(); +NOTICE: Test 1: FOR loop with ROWNUM +NOTICE: ROWNUM=1, id=1, name=Alice +NOTICE: ROWNUM=2, id=2, name=Bob +NOTICE: ROWNUM=3, id=3, name=Charlie + test_rownum_for_loop +---------------------- + +(1 row) + +-- Test 2: ROWNUM in explicit cursor +CREATE FUNCTION test_rownum_cursor() RETURNS TEXT AS $$ +DECLARE + cur CURSOR FOR SELECT ROWNUM as rn, id, name FROM rownum_test WHERE ROWNUM <= 4; + rec RECORD; + result TEXT := ''; +BEGIN + RAISE NOTICE 'Test 2: Explicit cursor with ROWNUM'; + OPEN cur; + LOOP + FETCH cur INTO rec; + EXIT WHEN NOT FOUND; + result := result || rec.rn || ':' || rec.name || ' '; + RAISE NOTICE 'Fetched: ROWNUM=%, name=%', rec.rn, rec.name; + END LOOP; + CLOSE cur; + RETURN trim(result); +END; +$$ LANGUAGE plisql; +/ +SELECT test_rownum_cursor(); +NOTICE: Test 2: Explicit cursor with ROWNUM +NOTICE: Fetched: ROWNUM=1, name=Alice +NOTICE: Fetched: ROWNUM=2, name=Bob +NOTICE: Fetched: ROWNUM=3, name=Charlie +NOTICE: Fetched: ROWNUM=4, name=David + test_rownum_cursor +--------------------------------- + 1:Alice 2:Bob 3:Charlie 4:David +(1 row) + +-- Test 3: ROWNUM with dynamic SQL (EXECUTE IMMEDIATE) +CREATE FUNCTION test_rownum_dynamic_sql(p_limit INT) RETURNS void AS $$ +DECLARE + r RECORD; + sql_stmt TEXT; +BEGIN + RAISE NOTICE 'Test 3: Dynamic SQL with ROWNUM limit=%', p_limit; + sql_stmt := 'SELECT ROWNUM as rn, id, name FROM rownum_test WHERE ROWNUM <= ' || p_limit; + + FOR r IN EXECUTE sql_stmt LOOP + RAISE NOTICE 'ROWNUM=%, id=%, name=%', r.rn, r.id, r.name; + END LOOP; +END; +$$ LANGUAGE plisql; +/ +SELECT test_rownum_dynamic_sql(3); +NOTICE: Test 3: Dynamic SQL with ROWNUM limit=3 +NOTICE: ROWNUM=1, id=1, name=Alice +NOTICE: ROWNUM=2, id=2, name=Bob +NOTICE: ROWNUM=3, id=3, name=Charlie + test_rownum_dynamic_sql +------------------------- + +(1 row) + +-- Test 4: ROWNUM in nested BEGIN...END blocks +DO $$ +DECLARE + v_count INT; + r RECORD; +BEGIN + RAISE NOTICE 'Test 4: Nested blocks with ROWNUM'; + + -- Outer block + BEGIN + SELECT COUNT(*) INTO v_count FROM rownum_test WHERE ROWNUM <= 5; + RAISE NOTICE 'Outer block: count=%', v_count; + + -- Inner block + BEGIN + FOR r IN SELECT ROWNUM as rn, name FROM rownum_test WHERE ROWNUM <= 2 LOOP + RAISE NOTICE 'Inner block: ROWNUM=%, name=%', r.rn, r.name; + END LOOP; + END; + END; +END$$; +NOTICE: Test 4: Nested blocks with ROWNUM +NOTICE: Outer block: count=5 +NOTICE: Inner block: ROWNUM=1, name=Alice +NOTICE: Inner block: ROWNUM=2, name=Bob +-- Test 5: ROWNUM with OUT parameter +CREATE FUNCTION test_rownum_out_param(OUT p_first_name TEXT, OUT p_second_name TEXT) AS $$ +DECLARE + r RECORD; + counter INT := 0; +BEGIN + RAISE NOTICE 'Test 5: OUT parameters with ROWNUM'; + + FOR r IN SELECT ROWNUM as rn, name FROM rownum_test WHERE ROWNUM <= 2 LOOP + counter := counter + 1; + IF counter = 1 THEN + p_first_name := r.name; + ELSIF counter = 2 THEN + p_second_name := r.name; + END IF; + END LOOP; + + RAISE NOTICE 'First: %, Second: %', p_first_name, p_second_name; + RETURN; +END; +$$ LANGUAGE plisql; +/ +DO $$ +DECLARE + v_first TEXT; + v_second TEXT; +BEGIN + SELECT * INTO v_first, v_second FROM test_rownum_out_param(v_first, v_second); + RAISE NOTICE 'Result: first=%, second=%', v_first, v_second; +END$$; +NOTICE: Test 5: OUT parameters with ROWNUM +NOTICE: First: Alice, Second: Bob +NOTICE: Result: first=Alice, second=Bob +-- Test 6: ROWNUM with WHILE loop +CREATE FUNCTION test_rownum_while() RETURNS void AS $$ +DECLARE + r RECORD; + cur CURSOR FOR SELECT ROWNUM as rn, id, name FROM rownum_test WHERE ROWNUM <= 5; + i INT := 0; +BEGIN + RAISE NOTICE 'Test 6: WHILE loop with ROWNUM cursor'; + OPEN cur; + + WHILE i < 3 LOOP + FETCH cur INTO r; + EXIT WHEN NOT FOUND; + i := i + 1; + RAISE NOTICE 'Iteration %: ROWNUM=%, name=%', i, r.rn, r.name; + END LOOP; + + CLOSE cur; +END; +$$ LANGUAGE plisql; +/ +SELECT test_rownum_while(); +NOTICE: Test 6: WHILE loop with ROWNUM cursor +NOTICE: Iteration 1: ROWNUM=1, name=Alice +NOTICE: Iteration 2: ROWNUM=2, name=Bob +NOTICE: Iteration 3: ROWNUM=3, name=Charlie + test_rownum_while +------------------- + +(1 row) + +-- Test 7: ROWNUM with exception handling +CREATE FUNCTION test_rownum_exception() RETURNS void AS $$ +DECLARE + r RECORD; + v_name TEXT; +BEGIN + RAISE NOTICE 'Test 7: Exception handling with ROWNUM'; + + BEGIN + -- This will work + FOR r IN SELECT ROWNUM as rn, name FROM rownum_test WHERE ROWNUM <= 2 LOOP + RAISE NOTICE 'ROWNUM=%, name=%', r.rn, r.name; + END LOOP; + + -- Force an error + SELECT name INTO STRICT v_name FROM rownum_test WHERE ROWNUM <= 10; + + EXCEPTION + WHEN TOO_MANY_ROWS THEN + RAISE NOTICE 'Caught TOO_MANY_ROWS exception'; + WHEN NO_DATA_FOUND THEN + RAISE NOTICE 'Caught NO_DATA_FOUND exception'; + END; +END; +$$ LANGUAGE plisql; +/ +SELECT test_rownum_exception(); +NOTICE: Test 7: Exception handling with ROWNUM +NOTICE: ROWNUM=1, name=Alice +NOTICE: ROWNUM=2, name=Bob +NOTICE: Caught TOO_MANY_ROWS exception + test_rownum_exception +----------------------- + +(1 row) + +-- Test 8: ROWNUM with multiple cursors +CREATE FUNCTION test_rownum_multi_cursor() RETURNS void AS $$ +DECLARE + cur1 CURSOR FOR SELECT ROWNUM as rn, name FROM rownum_test WHERE ROWNUM <= 2; + cur2 CURSOR FOR SELECT ROWNUM as rn, value FROM rownum_test WHERE ROWNUM <= 3; + rec1 RECORD; + rec2 RECORD; +BEGIN + RAISE NOTICE 'Test 8: Multiple cursors with ROWNUM'; + + OPEN cur1; + FETCH cur1 INTO rec1; + RAISE NOTICE 'Cursor1: ROWNUM=%, name=%', rec1.rn, rec1.name; + + OPEN cur2; + FETCH cur2 INTO rec2; + RAISE NOTICE 'Cursor2: ROWNUM=%, value=%', rec2.rn, rec2.value; + + FETCH cur1 INTO rec1; + RAISE NOTICE 'Cursor1: ROWNUM=%, name=%', rec1.rn, rec1.name; + + FETCH cur2 INTO rec2; + RAISE NOTICE 'Cursor2: ROWNUM=%, value=%', rec2.rn, rec2.value; + + CLOSE cur1; + CLOSE cur2; +END; +$$ LANGUAGE plisql; +/ +SELECT test_rownum_multi_cursor(); +NOTICE: Test 8: Multiple cursors with ROWNUM +NOTICE: Cursor1: ROWNUM=1, name=Alice +NOTICE: Cursor2: ROWNUM=1, value=100 +NOTICE: Cursor1: ROWNUM=2, name=Bob +NOTICE: Cursor2: ROWNUM=2, value=200 + test_rownum_multi_cursor +-------------------------- + +(1 row) + +-- Test 9: ROWNUM with RETURN NEXT (set-returning function) +CREATE FUNCTION test_rownum_return_next() RETURNS SETOF TEXT AS $$ +DECLARE + r RECORD; +BEGIN + RAISE NOTICE 'Test 9: RETURN NEXT with ROWNUM'; + + FOR r IN SELECT ROWNUM as rn, name FROM rownum_test WHERE ROWNUM <= 4 LOOP + RETURN NEXT r.rn || ':' || r.name; + END LOOP; + + RETURN; +END; +$$ LANGUAGE plisql; +/ +SELECT * FROM test_rownum_return_next(); +NOTICE: Test 9: RETURN NEXT with ROWNUM + test_rownum_return_next +------------------------- + 1:Alice + 2:Bob + 3:Charlie + 4:David +(4 rows) + +-- Test 10: ROWNUM with RECORD type variable +DO $$ +DECLARE + rec RECORD; + v_total NUMERIC := 0; +BEGIN + RAISE NOTICE 'Test 10: RECORD type with ROWNUM'; + + FOR rec IN SELECT ROWNUM as rn, id, value FROM rownum_test WHERE ROWNUM <= 3 LOOP + RAISE NOTICE 'ROWNUM=%, id=%, value=%', rec.rn, rec.id, rec.value; + v_total := v_total + rec.value; + END LOOP; + + RAISE NOTICE 'Total value: %', v_total; +END$$; +NOTICE: Test 10: RECORD type with ROWNUM +NOTICE: ROWNUM=1, id=1, value=100 +NOTICE: ROWNUM=2, id=2, value=200 +NOTICE: ROWNUM=3, id=3, value=150 +NOTICE: Total value: 450 +-- Test 11: ROWNUM in subquery within PL/iSQL +-- Note: ROWNUM inside subquery is assigned during scan BEFORE ORDER BY, +-- so rn values reflect original row order, not sorted order. +-- This matches Oracle behavior. +CREATE FUNCTION test_rownum_subquery() RETURNS void AS $$ +DECLARE + r RECORD; +BEGIN + RAISE NOTICE 'Test 11: Subquery with ROWNUM'; + + -- ROWNUM assigned before ORDER BY, so rn values are from original scan order + FOR r IN + SELECT * FROM ( + SELECT ROWNUM as rn, id, name, value + FROM rownum_test + ORDER BY value DESC + ) WHERE ROWNUM <= 3 + LOOP + RAISE NOTICE 'ROWNUM=%, name=%, value=%', r.rn, r.name, r.value; + END LOOP; +END; +$$ LANGUAGE plisql; +/ +SELECT test_rownum_subquery(); +NOTICE: Test 11: Subquery with ROWNUM +NOTICE: ROWNUM=4, name=David, value=300 +NOTICE: ROWNUM=5, name=Eve, value=250 +NOTICE: ROWNUM=7, name=Grace, value=225 + test_rownum_subquery +---------------------- + +(1 row) + +-- Test 12: ROWNUM with EXIT WHEN inside loop +CREATE FUNCTION test_rownum_exit_when() RETURNS void AS $$ +DECLARE + r RECORD; + counter INT := 0; +BEGIN + RAISE NOTICE 'Test 12: EXIT WHEN with ROWNUM'; + + FOR r IN SELECT ROWNUM as rn, name, value FROM rownum_test WHERE ROWNUM <= 10 LOOP + counter := counter + 1; + RAISE NOTICE 'ROWNUM=%, name=%', r.rn, r.name; + + EXIT WHEN counter >= 3; + END LOOP; + + RAISE NOTICE 'Exited after % iterations', counter; +END; +$$ LANGUAGE plisql; +/ +SELECT test_rownum_exit_when(); +NOTICE: Test 12: EXIT WHEN with ROWNUM +NOTICE: ROWNUM=1, name=Alice +NOTICE: ROWNUM=2, name=Bob +NOTICE: ROWNUM=3, name=Charlie +NOTICE: Exited after 3 iterations + test_rownum_exit_when +----------------------- + +(1 row) + +-- Test 13: ROWNUM with CONTINUE statement +CREATE FUNCTION test_rownum_continue() RETURNS void AS $$ +DECLARE + r RECORD; +BEGIN + RAISE NOTICE 'Test 13: CONTINUE with ROWNUM'; + + FOR r IN SELECT ROWNUM as rn, name, value FROM rownum_test WHERE ROWNUM <= 5 LOOP + CONTINUE WHEN r.value < 200; + RAISE NOTICE 'ROWNUM=%, name=%, value=%', r.rn, r.name, r.value; + END LOOP; +END; +$$ LANGUAGE plisql; +/ +SELECT test_rownum_continue(); +NOTICE: Test 13: CONTINUE with ROWNUM +NOTICE: ROWNUM=2, name=Bob, value=200 +NOTICE: ROWNUM=4, name=David, value=300 +NOTICE: ROWNUM=5, name=Eve, value=250 + test_rownum_continue +---------------------- + +(1 row) + +-- Test 14: ROWNUM with conditional logic +CREATE FUNCTION test_rownum_conditional(p_limit INT) RETURNS void AS $$ +DECLARE + r RECORD; + v_sql TEXT; +BEGIN + RAISE NOTICE 'Test 14: Conditional with ROWNUM, limit=%', p_limit; + + IF p_limit > 0 THEN + FOR r IN SELECT ROWNUM as rn, name FROM rownum_test WHERE ROWNUM <= p_limit LOOP + IF r.rn = 1 THEN + RAISE NOTICE 'First row: %', r.name; + ELSIF r.rn = p_limit THEN + RAISE NOTICE 'Last row: %', r.name; + ELSE + RAISE NOTICE 'Middle row %: %', r.rn, r.name; + END IF; + END LOOP; + ELSE + RAISE NOTICE 'Invalid limit: %', p_limit; + END IF; +END; +$$ LANGUAGE plisql; +/ +SELECT test_rownum_conditional(4); +NOTICE: Test 14: Conditional with ROWNUM, limit=4 +NOTICE: First row: Alice +NOTICE: Middle row 2: Bob +NOTICE: Middle row 3: Charlie +NOTICE: Last row: David + test_rownum_conditional +------------------------- + +(1 row) + +SELECT test_rownum_conditional(0); +NOTICE: Test 14: Conditional with ROWNUM, limit=0 +NOTICE: Invalid limit: 0 + test_rownum_conditional +------------------------- + +(1 row) + +-- Test 15: ROWNUM with aggregate in PL/iSQL +CREATE FUNCTION test_rownum_aggregate() RETURNS void AS $$ +DECLARE + v_count INT; + v_sum NUMERIC; + v_avg NUMERIC; +BEGIN + RAISE NOTICE 'Test 15: Aggregates with ROWNUM'; + + SELECT COUNT(*), SUM(value), AVG(value) + INTO v_count, v_sum, v_avg + FROM (SELECT * FROM rownum_test WHERE ROWNUM <= 5); + + RAISE NOTICE 'Count: %, Sum: %, Avg: %', v_count, v_sum, v_avg; +END; +$$ LANGUAGE plisql; +/ +SELECT test_rownum_aggregate(); +NOTICE: Test 15: Aggregates with ROWNUM +NOTICE: Count: 5, Sum: 1000, Avg: 200.0000000000000000 + test_rownum_aggregate +----------------------- + +(1 row) + +-- Cleanup +DROP FUNCTION test_rownum_for_loop(); +DROP FUNCTION test_rownum_cursor(); +DROP FUNCTION test_rownum_dynamic_sql(INT); +DROP FUNCTION test_rownum_out_param(TEXT, TEXT); +DROP FUNCTION test_rownum_while(); +DROP FUNCTION test_rownum_exception(); +DROP FUNCTION test_rownum_multi_cursor(); +DROP FUNCTION test_rownum_return_next(); +DROP FUNCTION test_rownum_subquery(); +DROP FUNCTION test_rownum_exit_when(); +DROP FUNCTION test_rownum_continue(); +DROP FUNCTION test_rownum_conditional(INT); +DROP FUNCTION test_rownum_aggregate(); +DROP TABLE rownum_test; diff --git a/src/pl/plisql/src/sql/plisql_rownum.sql b/src/pl/plisql/src/sql/plisql_rownum.sql new file mode 100644 index 00000000000..da7134551e2 --- /dev/null +++ b/src/pl/plisql/src/sql/plisql_rownum.sql @@ -0,0 +1,378 @@ +-- +-- Tests for PL/iSQL with Oracle ROWNUM pseudocolumn +-- + +-- Setup test table +CREATE TABLE rownum_test ( + id INT, + name TEXT, + value NUMERIC +); + +INSERT INTO rownum_test VALUES + (1, 'Alice', 100), + (2, 'Bob', 200), + (3, 'Charlie', 150), + (4, 'David', 300), + (5, 'Eve', 250), + (6, 'Frank', 175), + (7, 'Grace', 225), + (8, 'Henry', 125); + +-- Test 1: ROWNUM in FOR loop with query +CREATE FUNCTION test_rownum_for_loop() RETURNS void AS $$ +DECLARE + r RECORD; +BEGIN + RAISE NOTICE 'Test 1: FOR loop with ROWNUM'; + FOR r IN SELECT ROWNUM as rn, id, name FROM rownum_test WHERE ROWNUM <= 3 LOOP + RAISE NOTICE 'ROWNUM=%, id=%, name=%', r.rn, r.id, r.name; + END LOOP; +END; +$$ LANGUAGE plisql; +/ + +SELECT test_rownum_for_loop(); + +-- Test 2: ROWNUM in explicit cursor +CREATE FUNCTION test_rownum_cursor() RETURNS TEXT AS $$ +DECLARE + cur CURSOR FOR SELECT ROWNUM as rn, id, name FROM rownum_test WHERE ROWNUM <= 4; + rec RECORD; + result TEXT := ''; +BEGIN + RAISE NOTICE 'Test 2: Explicit cursor with ROWNUM'; + OPEN cur; + LOOP + FETCH cur INTO rec; + EXIT WHEN NOT FOUND; + result := result || rec.rn || ':' || rec.name || ' '; + RAISE NOTICE 'Fetched: ROWNUM=%, name=%', rec.rn, rec.name; + END LOOP; + CLOSE cur; + RETURN trim(result); +END; +$$ LANGUAGE plisql; +/ + +SELECT test_rownum_cursor(); + +-- Test 3: ROWNUM with dynamic SQL (EXECUTE IMMEDIATE) +CREATE FUNCTION test_rownum_dynamic_sql(p_limit INT) RETURNS void AS $$ +DECLARE + r RECORD; + sql_stmt TEXT; +BEGIN + RAISE NOTICE 'Test 3: Dynamic SQL with ROWNUM limit=%', p_limit; + sql_stmt := 'SELECT ROWNUM as rn, id, name FROM rownum_test WHERE ROWNUM <= ' || p_limit; + + FOR r IN EXECUTE sql_stmt LOOP + RAISE NOTICE 'ROWNUM=%, id=%, name=%', r.rn, r.id, r.name; + END LOOP; +END; +$$ LANGUAGE plisql; +/ + +SELECT test_rownum_dynamic_sql(3); + +-- Test 4: ROWNUM in nested BEGIN...END blocks +DO $$ +DECLARE + v_count INT; + r RECORD; +BEGIN + RAISE NOTICE 'Test 4: Nested blocks with ROWNUM'; + + -- Outer block + BEGIN + SELECT COUNT(*) INTO v_count FROM rownum_test WHERE ROWNUM <= 5; + RAISE NOTICE 'Outer block: count=%', v_count; + + -- Inner block + BEGIN + FOR r IN SELECT ROWNUM as rn, name FROM rownum_test WHERE ROWNUM <= 2 LOOP + RAISE NOTICE 'Inner block: ROWNUM=%, name=%', r.rn, r.name; + END LOOP; + END; + END; +END$$; + +-- Test 5: ROWNUM with OUT parameter +CREATE FUNCTION test_rownum_out_param(OUT p_first_name TEXT, OUT p_second_name TEXT) AS $$ +DECLARE + r RECORD; + counter INT := 0; +BEGIN + RAISE NOTICE 'Test 5: OUT parameters with ROWNUM'; + + FOR r IN SELECT ROWNUM as rn, name FROM rownum_test WHERE ROWNUM <= 2 LOOP + counter := counter + 1; + IF counter = 1 THEN + p_first_name := r.name; + ELSIF counter = 2 THEN + p_second_name := r.name; + END IF; + END LOOP; + + RAISE NOTICE 'First: %, Second: %', p_first_name, p_second_name; + RETURN; +END; +$$ LANGUAGE plisql; +/ + +DO $$ +DECLARE + v_first TEXT; + v_second TEXT; +BEGIN + SELECT * INTO v_first, v_second FROM test_rownum_out_param(v_first, v_second); + RAISE NOTICE 'Result: first=%, second=%', v_first, v_second; +END$$; + +-- Test 6: ROWNUM with WHILE loop +CREATE FUNCTION test_rownum_while() RETURNS void AS $$ +DECLARE + r RECORD; + cur CURSOR FOR SELECT ROWNUM as rn, id, name FROM rownum_test WHERE ROWNUM <= 5; + i INT := 0; +BEGIN + RAISE NOTICE 'Test 6: WHILE loop with ROWNUM cursor'; + OPEN cur; + + WHILE i < 3 LOOP + FETCH cur INTO r; + EXIT WHEN NOT FOUND; + i := i + 1; + RAISE NOTICE 'Iteration %: ROWNUM=%, name=%', i, r.rn, r.name; + END LOOP; + + CLOSE cur; +END; +$$ LANGUAGE plisql; +/ + +SELECT test_rownum_while(); + +-- Test 7: ROWNUM with exception handling +CREATE FUNCTION test_rownum_exception() RETURNS void AS $$ +DECLARE + r RECORD; + v_name TEXT; +BEGIN + RAISE NOTICE 'Test 7: Exception handling with ROWNUM'; + + BEGIN + -- This will work + FOR r IN SELECT ROWNUM as rn, name FROM rownum_test WHERE ROWNUM <= 2 LOOP + RAISE NOTICE 'ROWNUM=%, name=%', r.rn, r.name; + END LOOP; + + -- Force an error + SELECT name INTO STRICT v_name FROM rownum_test WHERE ROWNUM <= 10; + + EXCEPTION + WHEN TOO_MANY_ROWS THEN + RAISE NOTICE 'Caught TOO_MANY_ROWS exception'; + WHEN NO_DATA_FOUND THEN + RAISE NOTICE 'Caught NO_DATA_FOUND exception'; + END; +END; +$$ LANGUAGE plisql; +/ + +SELECT test_rownum_exception(); + +-- Test 8: ROWNUM with multiple cursors +CREATE FUNCTION test_rownum_multi_cursor() RETURNS void AS $$ +DECLARE + cur1 CURSOR FOR SELECT ROWNUM as rn, name FROM rownum_test WHERE ROWNUM <= 2; + cur2 CURSOR FOR SELECT ROWNUM as rn, value FROM rownum_test WHERE ROWNUM <= 3; + rec1 RECORD; + rec2 RECORD; +BEGIN + RAISE NOTICE 'Test 8: Multiple cursors with ROWNUM'; + + OPEN cur1; + FETCH cur1 INTO rec1; + RAISE NOTICE 'Cursor1: ROWNUM=%, name=%', rec1.rn, rec1.name; + + OPEN cur2; + FETCH cur2 INTO rec2; + RAISE NOTICE 'Cursor2: ROWNUM=%, value=%', rec2.rn, rec2.value; + + FETCH cur1 INTO rec1; + RAISE NOTICE 'Cursor1: ROWNUM=%, name=%', rec1.rn, rec1.name; + + FETCH cur2 INTO rec2; + RAISE NOTICE 'Cursor2: ROWNUM=%, value=%', rec2.rn, rec2.value; + + CLOSE cur1; + CLOSE cur2; +END; +$$ LANGUAGE plisql; +/ + +SELECT test_rownum_multi_cursor(); + +-- Test 9: ROWNUM with RETURN NEXT (set-returning function) +CREATE FUNCTION test_rownum_return_next() RETURNS SETOF TEXT AS $$ +DECLARE + r RECORD; +BEGIN + RAISE NOTICE 'Test 9: RETURN NEXT with ROWNUM'; + + FOR r IN SELECT ROWNUM as rn, name FROM rownum_test WHERE ROWNUM <= 4 LOOP + RETURN NEXT r.rn || ':' || r.name; + END LOOP; + + RETURN; +END; +$$ LANGUAGE plisql; +/ + +SELECT * FROM test_rownum_return_next(); + +-- Test 10: ROWNUM with RECORD type variable +DO $$ +DECLARE + rec RECORD; + v_total NUMERIC := 0; +BEGIN + RAISE NOTICE 'Test 10: RECORD type with ROWNUM'; + + FOR rec IN SELECT ROWNUM as rn, id, value FROM rownum_test WHERE ROWNUM <= 3 LOOP + RAISE NOTICE 'ROWNUM=%, id=%, value=%', rec.rn, rec.id, rec.value; + v_total := v_total + rec.value; + END LOOP; + + RAISE NOTICE 'Total value: %', v_total; +END$$; + +-- Test 11: ROWNUM in subquery within PL/iSQL +-- Note: ROWNUM inside subquery is assigned during scan BEFORE ORDER BY, +-- so rn values reflect original row order, not sorted order. +-- This matches Oracle behavior. +CREATE FUNCTION test_rownum_subquery() RETURNS void AS $$ +DECLARE + r RECORD; +BEGIN + RAISE NOTICE 'Test 11: Subquery with ROWNUM'; + + -- ROWNUM assigned before ORDER BY, so rn values are from original scan order + FOR r IN + SELECT * FROM ( + SELECT ROWNUM as rn, id, name, value + FROM rownum_test + ORDER BY value DESC + ) WHERE ROWNUM <= 3 + LOOP + RAISE NOTICE 'ROWNUM=%, name=%, value=%', r.rn, r.name, r.value; + END LOOP; +END; +$$ LANGUAGE plisql; +/ + +SELECT test_rownum_subquery(); + +-- Test 12: ROWNUM with EXIT WHEN inside loop +CREATE FUNCTION test_rownum_exit_when() RETURNS void AS $$ +DECLARE + r RECORD; + counter INT := 0; +BEGIN + RAISE NOTICE 'Test 12: EXIT WHEN with ROWNUM'; + + FOR r IN SELECT ROWNUM as rn, name, value FROM rownum_test WHERE ROWNUM <= 10 LOOP + counter := counter + 1; + RAISE NOTICE 'ROWNUM=%, name=%', r.rn, r.name; + + EXIT WHEN counter >= 3; + END LOOP; + + RAISE NOTICE 'Exited after % iterations', counter; +END; +$$ LANGUAGE plisql; +/ + +SELECT test_rownum_exit_when(); + +-- Test 13: ROWNUM with CONTINUE statement +CREATE FUNCTION test_rownum_continue() RETURNS void AS $$ +DECLARE + r RECORD; +BEGIN + RAISE NOTICE 'Test 13: CONTINUE with ROWNUM'; + + FOR r IN SELECT ROWNUM as rn, name, value FROM rownum_test WHERE ROWNUM <= 5 LOOP + CONTINUE WHEN r.value < 200; + RAISE NOTICE 'ROWNUM=%, name=%, value=%', r.rn, r.name, r.value; + END LOOP; +END; +$$ LANGUAGE plisql; +/ + +SELECT test_rownum_continue(); + +-- Test 14: ROWNUM with conditional logic +CREATE FUNCTION test_rownum_conditional(p_limit INT) RETURNS void AS $$ +DECLARE + r RECORD; + v_sql TEXT; +BEGIN + RAISE NOTICE 'Test 14: Conditional with ROWNUM, limit=%', p_limit; + + IF p_limit > 0 THEN + FOR r IN SELECT ROWNUM as rn, name FROM rownum_test WHERE ROWNUM <= p_limit LOOP + IF r.rn = 1 THEN + RAISE NOTICE 'First row: %', r.name; + ELSIF r.rn = p_limit THEN + RAISE NOTICE 'Last row: %', r.name; + ELSE + RAISE NOTICE 'Middle row %: %', r.rn, r.name; + END IF; + END LOOP; + ELSE + RAISE NOTICE 'Invalid limit: %', p_limit; + END IF; +END; +$$ LANGUAGE plisql; +/ + +SELECT test_rownum_conditional(4); +SELECT test_rownum_conditional(0); + +-- Test 15: ROWNUM with aggregate in PL/iSQL +CREATE FUNCTION test_rownum_aggregate() RETURNS void AS $$ +DECLARE + v_count INT; + v_sum NUMERIC; + v_avg NUMERIC; +BEGIN + RAISE NOTICE 'Test 15: Aggregates with ROWNUM'; + + SELECT COUNT(*), SUM(value), AVG(value) + INTO v_count, v_sum, v_avg + FROM (SELECT * FROM rownum_test WHERE ROWNUM <= 5); + + RAISE NOTICE 'Count: %, Sum: %, Avg: %', v_count, v_sum, v_avg; +END; +$$ LANGUAGE plisql; +/ + +SELECT test_rownum_aggregate(); + +-- Cleanup +DROP FUNCTION test_rownum_for_loop(); +DROP FUNCTION test_rownum_cursor(); +DROP FUNCTION test_rownum_dynamic_sql(INT); +DROP FUNCTION test_rownum_out_param(TEXT, TEXT); +DROP FUNCTION test_rownum_while(); +DROP FUNCTION test_rownum_exception(); +DROP FUNCTION test_rownum_multi_cursor(); +DROP FUNCTION test_rownum_return_next(); +DROP FUNCTION test_rownum_subquery(); +DROP FUNCTION test_rownum_exit_when(); +DROP FUNCTION test_rownum_continue(); +DROP FUNCTION test_rownum_conditional(INT); +DROP FUNCTION test_rownum_aggregate(); +DROP TABLE rownum_test; From 56e7fcc5cabdd4e22f2ab333b6c94d4857c4f599 Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Tue, 2 Dec 2025 23:48:45 +0000 Subject: [PATCH 02/19] fix: ROWNUM reset for UNION/UNION ALL branches (Oracle compatibility) In Oracle, each UNION/UNION ALL branch has independent ROWNUM counting. For example: SELECT ROWNUM, id FROM t1 UNION ALL SELECT ROWNUM, id FROM t2 produces rn=1,2,3 from t1 then rn=1,2,3 from t2, not rn=1,2,3,4,5,6. Implementation: - Add is_union flag to Append/MergeAppend plan nodes - Detect UNION operations in planner (generate_union_paths, allpaths.c) - Reset es_rownum in executor when switching between UNION branches - MergeAppend resets before each child in initialization (Sort buffers all) - Append resets when switching to next child during iteration --- src/backend/executor/nodeAppend.c | 10 ++ src/backend/executor/nodeMergeAppend.c | 15 +++ src/backend/optimizer/path/allpaths.c | 49 +++++++- src/backend/optimizer/plan/createplan.c | 2 + src/backend/optimizer/prep/prepunion.c | 6 + src/backend/optimizer/util/pathnode.c | 3 + src/include/nodes/execnodes.h | 2 + src/include/nodes/pathnodes.h | 2 + src/include/nodes/plannodes.h | 12 ++ src/oracle_test/regress/expected/rownum.out | 117 +++++++++++++++++++- src/oracle_test/regress/sql/rownum.sql | 61 ++++++++++ 11 files changed, 271 insertions(+), 8 deletions(-) diff --git a/src/backend/executor/nodeAppend.c b/src/backend/executor/nodeAppend.c index a11b36c7176..34a4aeed216 100644 --- a/src/backend/executor/nodeAppend.c +++ b/src/backend/executor/nodeAppend.c @@ -290,6 +290,9 @@ ExecInitAppend(Append *node, EState *estate, int eflags) /* For parallel query, this will be overridden later. */ appendstate->choose_next_subplan = choose_next_subplan_locally; + /* Copy is_union flag for ROWNUM reset handling (Oracle compatibility) */ + appendstate->as_is_union = node->is_union; + return appendstate; } @@ -386,6 +389,13 @@ ExecAppend(PlanState *pstate) /* choose new sync subplan; if no sync/async subplans, we're done */ if (!node->choose_next_subplan(node) && node->as_nasyncremain == 0) return ExecClearTuple(node->ps.ps_ResultTupleSlot); + + /* + * For UNION queries, reset ROWNUM when switching to a new branch. + * In Oracle, each UNION branch has its own independent ROWNUM counter. + */ + if (node->as_is_union) + node->ps.state->es_rownum = 0; } } diff --git a/src/backend/executor/nodeMergeAppend.c b/src/backend/executor/nodeMergeAppend.c index 405e8f94285..57f33b4197c 100644 --- a/src/backend/executor/nodeMergeAppend.c +++ b/src/backend/executor/nodeMergeAppend.c @@ -202,6 +202,9 @@ ExecInitMergeAppend(MergeAppend *node, EState *estate, int eflags) */ mergestate->ms_initialized = false; + /* Copy is_union flag for ROWNUM reset handling (Oracle compatibility) */ + mergestate->ms_is_union = node->is_union; + return mergestate; } @@ -238,10 +241,22 @@ ExecMergeAppend(PlanState *pstate) /* * First time through: pull the first tuple from each valid subplan, * and set up the heap. + * + * For UNION queries, reset ROWNUM before each subplan starts. + * This ensures each UNION branch has independent ROWNUM counting + * (Oracle compatibility). */ i = -1; while ((i = bms_next_member(node->ms_valid_subplans, i)) >= 0) { + /* + * For UNION, reset ROWNUM before each branch executes. + * Each child's Sort will buffer all tuples from its scan, + * so ROWNUM needs to start fresh for each branch. + */ + if (node->ms_is_union) + node->ps.state->es_rownum = 0; + node->ms_slots[i] = ExecProcNode(node->mergeplans[i]); if (!TupIsNull(node->ms_slots[i])) binaryheap_add_unordered(node->ms_heap, Int32GetDatum(i)); diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c index 6cc6966b060..b3d7287646b 100644 --- a/src/backend/optimizer/path/allpaths.c +++ b/src/backend/optimizer/path/allpaths.c @@ -1334,10 +1334,32 @@ add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel, List *all_child_outers = NIL; ListCell *l; double partial_rows = -1; + bool is_union_all = false; /* If appropriate, consider parallel append */ pa_subpaths_valid = enable_parallel_append && rel->consider_parallel; + /* + * Check if this appendrel came from a UNION ALL operation. + * UNION ALL appendrels have all children with rtekind == RTE_SUBQUERY. + * We need to detect this to reset ROWNUM when switching branches + * (Oracle compatibility). + */ + if (live_childrels != NIL) + { + is_union_all = true; + foreach(l, live_childrels) + { + RelOptInfo *childrel = lfirst(l); + + if (childrel->rtekind != RTE_SUBQUERY) + { + is_union_all = false; + break; + } + } + } + /* * For every non-dummy child, remember the cheapest path. Also, identify * all pathkeys (orderings) and parameterizations (required_outer sets) @@ -1523,14 +1545,27 @@ add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel, * if we have zero or one live subpath due to constraint exclusion.) */ if (subpaths_valid) - add_path(rel, (Path *) create_append_path(root, rel, subpaths, NIL, - NIL, NULL, 0, false, - -1)); + { + AppendPath *appendpath; + + appendpath = create_append_path(root, rel, subpaths, NIL, + NIL, NULL, 0, false, -1); + /* Mark UNION ALL appendrels for ROWNUM reset (Oracle compatibility) */ + appendpath->is_union = is_union_all; + add_path(rel, (Path *) appendpath); + } /* build an AppendPath for the cheap startup paths, if valid */ if (startup_subpaths_valid) - add_path(rel, (Path *) create_append_path(root, rel, startup_subpaths, - NIL, NIL, NULL, 0, false, -1)); + { + AppendPath *appendpath; + + appendpath = create_append_path(root, rel, startup_subpaths, + NIL, NIL, NULL, 0, false, -1); + /* Mark UNION ALL appendrels for ROWNUM reset (Oracle compatibility) */ + appendpath->is_union = is_union_all; + add_path(rel, (Path *) appendpath); + } /* * Consider an append of unordered, unparameterized partial paths. Make @@ -1574,6 +1609,8 @@ add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel, NIL, NULL, parallel_workers, enable_parallel_append, -1); + /* Mark UNION ALL appendrels for ROWNUM reset (Oracle compatibility) */ + appendpath->is_union = is_union_all; /* * Make sure any subsequent partial paths use the same row count @@ -1623,6 +1660,8 @@ add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel, pa_partial_subpaths, NIL, NULL, parallel_workers, true, partial_rows); + /* Mark UNION ALL appendrels for ROWNUM reset (Oracle compatibility) */ + appendpath->is_union = is_union_all; add_partial_path(rel, (Path *) appendpath); } diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c index cc83279c514..0a856e01a9d 100644 --- a/src/backend/optimizer/plan/createplan.c +++ b/src/backend/optimizer/plan/createplan.c @@ -1283,6 +1283,7 @@ create_append_plan(PlannerInfo *root, AppendPath *best_path, int flags) plan->plan.lefttree = NULL; plan->plan.righttree = NULL; plan->apprelids = rel->relids; + plan->is_union = best_path->is_union; if (pathkeys != NIL) { @@ -1573,6 +1574,7 @@ create_merge_append_plan(PlannerInfo *root, MergeAppendPath *best_path, } node->mergeplans = subplans; + node->is_union = best_path->is_union; /* * If prepare_sort_from_pathkeys added sort columns, but we were told to diff --git a/src/backend/optimizer/prep/prepunion.c b/src/backend/optimizer/prep/prepunion.c index eab44da65b8..b01577b2e30 100644 --- a/src/backend/optimizer/prep/prepunion.c +++ b/src/backend/optimizer/prep/prepunion.c @@ -813,6 +813,8 @@ generate_union_paths(SetOperationStmt *op, PlannerInfo *root, */ apath = (Path *) create_append_path(root, result_rel, cheapest_pathlist, NIL, NIL, NULL, 0, false, -1); + /* Mark as UNION for ROWNUM reset between branches (Oracle compatibility) */ + ((AppendPath *) apath)->is_union = true; /* * Estimate number of groups. For now we just assume the output is unique @@ -860,6 +862,8 @@ generate_union_paths(SetOperationStmt *op, PlannerInfo *root, create_append_path(root, result_rel, NIL, partial_pathlist, NIL, NULL, parallel_workers, enable_parallel_append, -1); + /* Mark as UNION for ROWNUM reset between branches (Oracle compatibility) */ + ((AppendPath *) papath)->is_union = true; gpath = (Path *) create_gather_path(root, result_rel, papath, result_rel->reltarget, NULL, NULL); @@ -968,6 +972,8 @@ generate_union_paths(SetOperationStmt *op, PlannerInfo *root, ordered_pathlist, union_pathkeys, NULL); + /* Mark as UNION for ROWNUM reset between branches (Oracle compatibility) */ + ((MergeAppendPath *) path)->is_union = true; /* and make the MergeAppend unique */ path = (Path *) create_upper_unique_path(root, diff --git a/src/backend/optimizer/util/pathnode.c b/src/backend/optimizer/util/pathnode.c index e0192d4a491..7b034282e27 100644 --- a/src/backend/optimizer/util/pathnode.c +++ b/src/backend/optimizer/util/pathnode.c @@ -1360,6 +1360,7 @@ create_append_path(PlannerInfo *root, } pathnode->first_partial_path = list_length(subpaths); pathnode->subpaths = list_concat(subpaths, partial_subpaths); + pathnode->is_union = false; /* caller must set true for UNION paths */ /* * Apply query-wide LIMIT if known and path is for sole base relation. @@ -1572,6 +1573,8 @@ create_merge_append_path(PlannerInfo *root, input_startup_cost, input_total_cost, pathnode->path.rows); + pathnode->is_union = false; /* caller must set true for UNION paths */ + return pathnode; } diff --git a/src/include/nodes/execnodes.h b/src/include/nodes/execnodes.h index e6e8ca87cf4..fa75190fd8c 100644 --- a/src/include/nodes/execnodes.h +++ b/src/include/nodes/execnodes.h @@ -1518,6 +1518,7 @@ struct AppendState Bitmapset *as_valid_subplans; Bitmapset *as_valid_asyncplans; /* valid asynchronous plans indexes */ bool (*choose_next_subplan) (AppendState *); + bool as_is_union; /* true if UNION, reset ROWNUM on branch switch */ }; /* ---------------- @@ -1547,6 +1548,7 @@ typedef struct MergeAppendState bool ms_initialized; /* are subplans started? */ struct PartitionPruneState *ms_prune_state; Bitmapset *ms_valid_subplans; + bool ms_is_union; /* true if UNION, reset ROWNUM per branch */ } MergeAppendState; /* ---------------- diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h index 6567759595d..bbc9ab8a1ef 100644 --- a/src/include/nodes/pathnodes.h +++ b/src/include/nodes/pathnodes.h @@ -2067,6 +2067,7 @@ typedef struct AppendPath /* Index of first partial path in subpaths; list_length(subpaths) if none */ int first_partial_path; Cardinality limit_tuples; /* hard limit on output tuples, or -1 */ + bool is_union; /* true if from UNION/UNION ALL operation */ } AppendPath; #define IS_DUMMY_APPEND(p) \ @@ -2089,6 +2090,7 @@ typedef struct MergeAppendPath Path path; List *subpaths; /* list of component Paths */ Cardinality limit_tuples; /* hard limit on output tuples, or -1 */ + bool is_union; /* true if from UNION/UNION ALL operation */ } MergeAppendPath; /* diff --git a/src/include/nodes/plannodes.h b/src/include/nodes/plannodes.h index 4f59e30d62d..fd574198098 100644 --- a/src/include/nodes/plannodes.h +++ b/src/include/nodes/plannodes.h @@ -359,6 +359,12 @@ typedef struct Append * run-time pruning is used. */ int part_prune_index; + + /* + * True if this Append is from a UNION/UNION ALL operation. Used to reset + * ROWNUM counter when switching between UNION branches (Oracle behavior). + */ + bool is_union; } Append; /* ---------------- @@ -398,6 +404,12 @@ typedef struct MergeAppend * run-time pruning is used. */ int part_prune_index; + + /* + * True if this MergeAppend is from a UNION/UNION ALL operation. Used to + * reset ROWNUM counter before each branch starts (Oracle behavior). + */ + bool is_union; } MergeAppend; /* ---------------- diff --git a/src/oracle_test/regress/expected/rownum.out b/src/oracle_test/regress/expected/rownum.out index d0c066c8e7a..56758a6653e 100644 --- a/src/oracle_test/regress/expected/rownum.out +++ b/src/oracle_test/regress/expected/rownum.out @@ -860,6 +860,7 @@ WHERE ROWNUM <= 5; (5 rows) -- Test ROWNUM with SetOp (non-projection-capable) +-- With UNION ROWNUM fix, each branch has independent ROWNUM (Oracle behavior) SELECT ROWNUM as rn, id FROM rownum_test WHERE id <= 3 UNION SELECT ROWNUM as rn, id FROM rownum_test WHERE id > 7 @@ -867,11 +868,11 @@ ORDER BY rn, id; rn | id ----+---- 1 | 1 + 1 | 8 2 | 2 + 2 | 9 3 | 3 - 4 | 8 - 5 | 9 - 6 | 10 + 3 | 10 (6 rows) -- @@ -921,6 +922,116 @@ ORDER BY id; 3 | t (3 rows) +-- +-- UNION ALL with ROWNUM +-- In Oracle, each UNION branch has independent ROWNUM counter. +-- The counter resets when switching between UNION branches. +-- +-- Basic UNION ALL with ROWNUM +SELECT ROWNUM, id FROM (SELECT 1 AS id FROM DUAL UNION ALL SELECT 2 FROM DUAL UNION ALL SELECT 3 FROM DUAL) +UNION ALL +SELECT ROWNUM, id FROM (SELECT 4 AS id FROM DUAL UNION ALL SELECT 5 FROM DUAL UNION ALL SELECT 6 FROM DUAL); + rownum | id +--------+---- + 1 | 1 + 2 | 2 + 3 | 3 + 1 | 4 + 2 | 5 + 3 | 6 +(6 rows) + +-- UNION ALL with tables +SELECT ROWNUM, id FROM (SELECT id FROM rownum_test WHERE id <= 3 ORDER BY id) +UNION ALL +SELECT ROWNUM, id FROM (SELECT id FROM rownum_test WHERE id BETWEEN 4 AND 6 ORDER BY id); + rownum | id +--------+---- + 1 | 1 + 2 | 2 + 3 | 3 + 1 | 4 + 2 | 5 + 3 | 6 +(6 rows) + +-- Multiple UNION ALL branches +SELECT ROWNUM, 'a' as src FROM (SELECT 1 FROM DUAL UNION ALL SELECT 2 FROM DUAL) +UNION ALL +SELECT ROWNUM, 'b' as src FROM (SELECT 1 FROM DUAL UNION ALL SELECT 2 FROM DUAL) +UNION ALL +SELECT ROWNUM, 'c' as src FROM (SELECT 1 FROM DUAL UNION ALL SELECT 2 FROM DUAL); + rownum | src +--------+----- + 1 | a + 2 | a + 1 | b + 2 | b + 1 | c + 2 | c +(6 rows) + +-- +-- UNION (not UNION ALL) with ROWNUM +-- UNION uses MergeAppend + Unique nodes, so needs different ROWNUM reset handling. +-- Each UNION branch should have independent ROWNUM counting. +-- +-- Test 1: Simple UNION with ROWNUM +-- Creates two tables to avoid relying on ordering within branches +CREATE TABLE test1 (id int); +CREATE TABLE test2 (id int); +INSERT INTO test1 VALUES (1), (2), (3); +INSERT INTO test2 VALUES (4), (5), (6); +-- Each branch should have ROWNUM 1,2,3 independently +-- Result is sorted by the UNION's deduplication process +SELECT ROWNUM as rn, id FROM test1 +UNION +SELECT ROWNUM as rn, id FROM test2 +ORDER BY rn, id; + rn | id +----+---- + 1 | 1 + 1 | 4 + 2 | 2 + 2 | 5 + 3 | 3 + 3 | 6 +(6 rows) + +-- Test 2: UNION with ORDER BY in subqueries +SELECT ROWNUM as rn, id FROM (SELECT id FROM test1 ORDER BY id) +UNION +SELECT ROWNUM as rn, id FROM (SELECT id FROM test2 ORDER BY id) +ORDER BY rn, id; + rn | id +----+---- + 1 | 1 + 1 | 4 + 2 | 2 + 2 | 5 + 3 | 3 + 3 | 6 +(6 rows) + +-- Test 3: Multiple UNION branches +SELECT ROWNUM, 'a' as src FROM (SELECT 1 FROM DUAL UNION ALL SELECT 2 FROM DUAL) +UNION +SELECT ROWNUM, 'b' as src FROM (SELECT 1 FROM DUAL UNION ALL SELECT 2 FROM DUAL) +UNION +SELECT ROWNUM, 'c' as src FROM (SELECT 1 FROM DUAL UNION ALL SELECT 2 FROM DUAL) +ORDER BY src, rownum; + rownum | src +--------+----- + 1 | a + 2 | a + 1 | b + 2 | b + 1 | c + 2 | c +(6 rows) + +DROP TABLE test1; +DROP TABLE test2; -- -- Cleanup -- diff --git a/src/oracle_test/regress/sql/rownum.sql b/src/oracle_test/regress/sql/rownum.sql index 37b1c53f68e..0ea034171c3 100644 --- a/src/oracle_test/regress/sql/rownum.sql +++ b/src/oracle_test/regress/sql/rownum.sql @@ -474,6 +474,7 @@ FROM ( WHERE ROWNUM <= 5; -- Test ROWNUM with SetOp (non-projection-capable) +-- With UNION ROWNUM fix, each branch has independent ROWNUM (Oracle behavior) SELECT ROWNUM as rn, id FROM rownum_test WHERE id <= 3 UNION SELECT ROWNUM as rn, id FROM rownum_test WHERE id > 7 @@ -507,6 +508,66 @@ FROM rownum_test t1 WHERE id <= 3 ORDER BY id; +-- +-- UNION ALL with ROWNUM +-- In Oracle, each UNION branch has independent ROWNUM counter. +-- The counter resets when switching between UNION branches. +-- + +-- Basic UNION ALL with ROWNUM +SELECT ROWNUM, id FROM (SELECT 1 AS id FROM DUAL UNION ALL SELECT 2 FROM DUAL UNION ALL SELECT 3 FROM DUAL) +UNION ALL +SELECT ROWNUM, id FROM (SELECT 4 AS id FROM DUAL UNION ALL SELECT 5 FROM DUAL UNION ALL SELECT 6 FROM DUAL); + +-- UNION ALL with tables +SELECT ROWNUM, id FROM (SELECT id FROM rownum_test WHERE id <= 3 ORDER BY id) +UNION ALL +SELECT ROWNUM, id FROM (SELECT id FROM rownum_test WHERE id BETWEEN 4 AND 6 ORDER BY id); + +-- Multiple UNION ALL branches +SELECT ROWNUM, 'a' as src FROM (SELECT 1 FROM DUAL UNION ALL SELECT 2 FROM DUAL) +UNION ALL +SELECT ROWNUM, 'b' as src FROM (SELECT 1 FROM DUAL UNION ALL SELECT 2 FROM DUAL) +UNION ALL +SELECT ROWNUM, 'c' as src FROM (SELECT 1 FROM DUAL UNION ALL SELECT 2 FROM DUAL); + +-- +-- UNION (not UNION ALL) with ROWNUM +-- UNION uses MergeAppend + Unique nodes, so needs different ROWNUM reset handling. +-- Each UNION branch should have independent ROWNUM counting. +-- + +-- Test 1: Simple UNION with ROWNUM +-- Creates two tables to avoid relying on ordering within branches +CREATE TABLE test1 (id int); +CREATE TABLE test2 (id int); +INSERT INTO test1 VALUES (1), (2), (3); +INSERT INTO test2 VALUES (4), (5), (6); + +-- Each branch should have ROWNUM 1,2,3 independently +-- Result is sorted by the UNION's deduplication process +SELECT ROWNUM as rn, id FROM test1 +UNION +SELECT ROWNUM as rn, id FROM test2 +ORDER BY rn, id; + +-- Test 2: UNION with ORDER BY in subqueries +SELECT ROWNUM as rn, id FROM (SELECT id FROM test1 ORDER BY id) +UNION +SELECT ROWNUM as rn, id FROM (SELECT id FROM test2 ORDER BY id) +ORDER BY rn, id; + +-- Test 3: Multiple UNION branches +SELECT ROWNUM, 'a' as src FROM (SELECT 1 FROM DUAL UNION ALL SELECT 2 FROM DUAL) +UNION +SELECT ROWNUM, 'b' as src FROM (SELECT 1 FROM DUAL UNION ALL SELECT 2 FROM DUAL) +UNION +SELECT ROWNUM, 'c' as src FROM (SELECT 1 FROM DUAL UNION ALL SELECT 2 FROM DUAL) +ORDER BY src, rownum; + +DROP TABLE test1; +DROP TABLE test2; + -- -- Cleanup -- From f66e6ce0430be8dfc4bed940ffc86e798da7facf Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Tue, 2 Dec 2025 23:59:28 +0000 Subject: [PATCH 03/19] test: add ROWNUM tests for INTERSECT, EXCEPT, LATERAL, DML, empty tables Added test cases documenting ROWNUM behavior in additional scenarios: - INTERSECT/EXCEPT: Documents that IvorySQL shares ROWNUM counter across both sides (differs from Oracle which resets for each side) - LATERAL joins: Documents that IvorySQL doesn't reset ROWNUM for each outer row (differs from Oracle CROSS APPLY behavior) - DELETE/UPDATE with ROWNUM: Works correctly (matches Oracle) - Empty tables: Works correctly (returns 0 rows) Tests include comments explaining Oracle vs IvorySQL behavior differences. --- src/backend/optimizer/plan/planner.c | 112 ++++++++++++++++++-- src/oracle_test/regress/expected/rownum.out | 110 +++++++++++++++++++ src/oracle_test/regress/sql/rownum.sql | 83 +++++++++++++++ 3 files changed, 294 insertions(+), 11 deletions(-) diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c index ee0a7a1c240..15d4d8664c8 100644 --- a/src/backend/optimizer/plan/planner.c +++ b/src/backend/optimizer/plan/planner.c @@ -634,6 +634,12 @@ standard_planner(Query *parse, const char *query_string, int cursorOptions, * aggregation, while Oracle's ROWNUM is applied BEFORE these operations. * Therefore, we only transform when there are no higher-level relational * operations that would change semantics. + * + * Coverage limitations (not handled, future work): + * - Commutative forms: "10 >= ROWNUM" is not recognized (only "ROWNUM <= 10") + * - Nested expressions: "ROWNUM + 0 <= 5" is not optimized + * - OR clauses: "ROWNUM <= 3 OR id = 1" cannot be transformed to LIMIT + * - Non-integer constants: ROWNUM comparisons with floats/decimals are skipped *-------------------- */ static void @@ -755,13 +761,70 @@ transform_rownum_to_limit(Query *parse) continue; } - /* Extract the integer value */ - n = DatumGetInt64(constval->constvalue); + /* + * Validate that the constant is a numeric type we can safely convert + * to int64. This prevents undefined behavior from unexpected types. + */ + if (constval->consttype != INT8OID && + constval->consttype != INT4OID && + constval->consttype != INT2OID) + { + pfree(opname); + continue; + } + + /* Extract the integer value based on type */ + switch (constval->consttype) + { + case INT8OID: + n = DatumGetInt64(constval->constvalue); + break; + case INT4OID: + n = (int64) DatumGetInt32(constval->constvalue); + break; + case INT2OID: + n = (int64) DatumGetInt16(constval->constvalue); + break; + default: + /* Should not reach here due to check above */ + pfree(opname); + continue; + } if (strcmp(opname, "<=") == 0) { - /* ROWNUM <= N -> LIMIT N (only for simple queries) */ - if (can_use_limit) + /* + * ROWNUM <= N: + * N <= 0: always false (ROWNUM starts at 1) + * N > 0: can be optimized to LIMIT N (only for simple queries) + */ + if (n <= 0) + { + /* Always false - rewrite as FALSE constant */ + BoolExpr *newand; + Const *falseconst = (Const *) makeBoolConst(false, false); + + andlist = list_delete_ptr(andlist, qual); + andlist = lappend(andlist, falseconst); + + /* Rebuild WHERE clause */ + if (list_length(andlist) == 0) + jointree->quals = NULL; + else if (list_length(andlist) == 1) + jointree->quals = (Node *) linitial(andlist); + else + { + newand = makeNode(BoolExpr); + newand->boolop = AND_EXPR; + newand->args = andlist; + newand->location = -1; + jointree->quals = (Node *) newand; + } + + pfree(opname); + return; + } + else if (can_use_limit) { limit_value = n; rownum_qual = qual; @@ -818,13 +881,40 @@ transform_rownum_to_limit(Query *parse) } else if (strcmp(opname, "<") == 0) { - /* ROWNUM < N -> LIMIT N-1 (only for simple queries) */ - if (can_use_limit) + /* + * ROWNUM < N: + * N <= 1: always false (ROWNUM starts at 1, so < 1 is impossible) + * N > 1: can be optimized to LIMIT N-1 (only for simple queries) + */ + if (n <= 1) { - if (n > 0) - limit_value = n - 1; + /* Always false - rewrite as FALSE constant */ + BoolExpr *newand; + Const *falseconst = (Const *) makeBoolConst(false, false); + + andlist = list_delete_ptr(andlist, qual); + andlist = lappend(andlist, falseconst); + + /* Rebuild WHERE clause */ + if (list_length(andlist) == 0) + jointree->quals = NULL; + else if (list_length(andlist) == 1) + jointree->quals = (Node *) linitial(andlist); else - limit_value = 0; + { + newand = makeNode(BoolExpr); + newand->boolop = AND_EXPR; + newand->args = andlist; + newand->location = -1; + jointree->quals = (Node *) newand; + } + + pfree(opname); + return; + } + else if (can_use_limit) + { + limit_value = n - 1; rownum_qual = qual; } pfree(opname); @@ -909,11 +999,11 @@ transform_rownum_to_limit(Query *parse) /* If we found a ROWNUM predicate, transform it */ if (rownum_qual != NULL && limit_value > 0) { - /* Create the LIMIT constant */ + /* Create the LIMIT constant (INT8 is pass-by-value on 64-bit systems) */ parse->limitCount = (Node *) makeConst(INT8OID, -1, InvalidOid, sizeof(int64), Int64GetDatum(limit_value), - false, FLOAT8PASSBYVAL); + false, true); /* Remove the ROWNUM predicate from the WHERE clause */ andlist = list_delete_ptr(andlist, rownum_qual); diff --git a/src/oracle_test/regress/expected/rownum.out b/src/oracle_test/regress/expected/rownum.out index 56758a6653e..8a7e8031d39 100644 --- a/src/oracle_test/regress/expected/rownum.out +++ b/src/oracle_test/regress/expected/rownum.out @@ -1033,6 +1033,116 @@ ORDER BY src, rownum; DROP TABLE test1; DROP TABLE test2; -- +-- INTERSECT and EXCEPT with ROWNUM +-- NOTE: Oracle resets ROWNUM for each side of INTERSECT/EXCEPT independently. +-- Current IvorySQL implementation shares ROWNUM counter across both sides, +-- which produces different results than Oracle. +-- +-- INTERSECT with ROWNUM +-- Oracle: Each side produces (1,1), (2,2), (3,3) independently, intersection = 3 rows +-- IvorySQL: Left side produces (1,1), (2,2), (3,3), right side produces (4,1), (5,2), (6,3) +-- No intersection because ROWNUM values differ +SELECT ROWNUM as rn, id FROM (SELECT 1 as id FROM dual UNION ALL SELECT 2 FROM dual UNION ALL SELECT 3 FROM dual) +INTERSECT +SELECT ROWNUM as rn, id FROM (SELECT 1 as id FROM dual UNION ALL SELECT 2 FROM dual UNION ALL SELECT 3 FROM dual) +ORDER BY rn; + rn | id +----+---- +(0 rows) + +-- EXCEPT with ROWNUM +-- Oracle: Left (1,1),(2,2),(3,3) EXCEPT Right (1,2) = (1,1),(2,2),(3,3) (no match on rn) +-- IvorySQL: Left (1,1),(2,2),(3,3) EXCEPT Right (4,2) = (1,1),(2,2),(3,3) +SELECT ROWNUM as rn, id FROM (SELECT 1 as id FROM dual UNION ALL SELECT 2 FROM dual UNION ALL SELECT 3 FROM dual) +EXCEPT +SELECT ROWNUM as rn, id FROM (SELECT 2 as id FROM dual) +ORDER BY rn; + rn | id +----+---- + 1 | 1 + 2 | 2 + 3 | 3 +(3 rows) + +-- +-- LATERAL join with ROWNUM +-- NOTE: Oracle resets ROWNUM for each outer row in LATERAL/CROSS APPLY. +-- Current IvorySQL implementation does not reset, counter continues across outer rows. +-- +CREATE TABLE lat_test (id int); +INSERT INTO lat_test VALUES (1), (2), (3); +-- LATERAL subquery with ROWNUM +-- Oracle produces: (1,1), (2,1), (2,2), (3,1), (3,2), (3,3) - resets for each outer row +-- IvorySQL produces: (1,1), (2,2), (2,3), (3,4), (3,5), (3,6) - counter continues +SELECT t.id as outer_id, sub.rn +FROM lat_test t, +LATERAL (SELECT ROWNUM as rn FROM lat_test lt WHERE lt.id <= t.id) sub +ORDER BY t.id, sub.rn; + outer_id | rn +----------+---- + 1 | 1 + 2 | 2 + 2 | 3 + 3 | 4 + 3 | 5 + 3 | 6 +(6 rows) + +DROP TABLE lat_test; +-- +-- DELETE with ROWNUM +-- Oracle supports DELETE WHERE ROWNUM <= N to delete first N rows +-- +CREATE TABLE del_test (id int, val varchar(10)); +INSERT INTO del_test VALUES (1, 'a'), (2, 'b'), (3, 'c'), (4, 'd'), (5, 'e'); +-- Delete first 2 rows +DELETE FROM del_test WHERE ROWNUM <= 2; +SELECT * FROM del_test ORDER BY id; + id | val +----+----- + 3 | c + 4 | d + 5 | e +(3 rows) + +DROP TABLE del_test; +-- +-- UPDATE with ROWNUM +-- Oracle supports UPDATE ... WHERE ROWNUM <= N to update first N rows +-- +CREATE TABLE upd_test (id int, val varchar(10)); +INSERT INTO upd_test VALUES (1, 'a'), (2, 'b'), (3, 'c'), (4, 'd'), (5, 'e'); +-- Update first 2 rows +UPDATE upd_test SET val = 'updated' WHERE ROWNUM <= 2; +SELECT * FROM upd_test ORDER BY id; + id | val +----+--------- + 1 | updated + 2 | updated + 3 | c + 4 | d + 5 | e +(5 rows) + +DROP TABLE upd_test; +-- +-- ROWNUM with empty table +-- +CREATE TABLE empty_test (id int); +-- ROWNUM on empty table should return no rows +SELECT ROWNUM, id FROM empty_test; + rownum | id +--------+---- +(0 rows) + +SELECT COUNT(*) FROM empty_test WHERE ROWNUM <= 5; + count +------- + 0 +(1 row) + +DROP TABLE empty_test; +-- -- Cleanup -- DROP TABLE rownum_test CASCADE; diff --git a/src/oracle_test/regress/sql/rownum.sql b/src/oracle_test/regress/sql/rownum.sql index 0ea034171c3..416bf3c394e 100644 --- a/src/oracle_test/regress/sql/rownum.sql +++ b/src/oracle_test/regress/sql/rownum.sql @@ -568,6 +568,89 @@ ORDER BY src, rownum; DROP TABLE test1; DROP TABLE test2; +-- +-- INTERSECT and EXCEPT with ROWNUM +-- NOTE: Oracle resets ROWNUM for each side of INTERSECT/EXCEPT independently. +-- Current IvorySQL implementation shares ROWNUM counter across both sides, +-- which produces different results than Oracle. +-- + +-- INTERSECT with ROWNUM +-- Oracle: Each side produces (1,1), (2,2), (3,3) independently, intersection = 3 rows +-- IvorySQL: Left side produces (1,1), (2,2), (3,3), right side produces (4,1), (5,2), (6,3) +-- No intersection because ROWNUM values differ +SELECT ROWNUM as rn, id FROM (SELECT 1 as id FROM dual UNION ALL SELECT 2 FROM dual UNION ALL SELECT 3 FROM dual) +INTERSECT +SELECT ROWNUM as rn, id FROM (SELECT 1 as id FROM dual UNION ALL SELECT 2 FROM dual UNION ALL SELECT 3 FROM dual) +ORDER BY rn; + +-- EXCEPT with ROWNUM +-- Oracle: Left (1,1),(2,2),(3,3) EXCEPT Right (1,2) = (1,1),(2,2),(3,3) (no match on rn) +-- IvorySQL: Left (1,1),(2,2),(3,3) EXCEPT Right (4,2) = (1,1),(2,2),(3,3) +SELECT ROWNUM as rn, id FROM (SELECT 1 as id FROM dual UNION ALL SELECT 2 FROM dual UNION ALL SELECT 3 FROM dual) +EXCEPT +SELECT ROWNUM as rn, id FROM (SELECT 2 as id FROM dual) +ORDER BY rn; + +-- +-- LATERAL join with ROWNUM +-- NOTE: Oracle resets ROWNUM for each outer row in LATERAL/CROSS APPLY. +-- Current IvorySQL implementation does not reset, counter continues across outer rows. +-- + +CREATE TABLE lat_test (id int); +INSERT INTO lat_test VALUES (1), (2), (3); + +-- LATERAL subquery with ROWNUM +-- Oracle produces: (1,1), (2,1), (2,2), (3,1), (3,2), (3,3) - resets for each outer row +-- IvorySQL produces: (1,1), (2,2), (2,3), (3,4), (3,5), (3,6) - counter continues +SELECT t.id as outer_id, sub.rn +FROM lat_test t, +LATERAL (SELECT ROWNUM as rn FROM lat_test lt WHERE lt.id <= t.id) sub +ORDER BY t.id, sub.rn; + +DROP TABLE lat_test; + +-- +-- DELETE with ROWNUM +-- Oracle supports DELETE WHERE ROWNUM <= N to delete first N rows +-- + +CREATE TABLE del_test (id int, val varchar(10)); +INSERT INTO del_test VALUES (1, 'a'), (2, 'b'), (3, 'c'), (4, 'd'), (5, 'e'); + +-- Delete first 2 rows +DELETE FROM del_test WHERE ROWNUM <= 2; +SELECT * FROM del_test ORDER BY id; + +DROP TABLE del_test; + +-- +-- UPDATE with ROWNUM +-- Oracle supports UPDATE ... WHERE ROWNUM <= N to update first N rows +-- + +CREATE TABLE upd_test (id int, val varchar(10)); +INSERT INTO upd_test VALUES (1, 'a'), (2, 'b'), (3, 'c'), (4, 'd'), (5, 'e'); + +-- Update first 2 rows +UPDATE upd_test SET val = 'updated' WHERE ROWNUM <= 2; +SELECT * FROM upd_test ORDER BY id; + +DROP TABLE upd_test; + +-- +-- ROWNUM with empty table +-- + +CREATE TABLE empty_test (id int); + +-- ROWNUM on empty table should return no rows +SELECT ROWNUM, id FROM empty_test; +SELECT COUNT(*) FROM empty_test WHERE ROWNUM <= 5; + +DROP TABLE empty_test; + -- -- Cleanup -- From 3561a2159fce66cf9bbffb818cdc40f3481140dc Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Mon, 8 Dec 2025 00:41:44 +0000 Subject: [PATCH 04/19] refactor: improve code quality per PR review feedback - Fix count_rownum_exprs_walker signature to use void* context (matches expression_tree_walker callback convention) - Use get_typbyval(INT8OID) instead of hardcoded true for constbyval (follows PostgreSQL coding conventions) Both changes are stylistic improvements that align with PostgreSQL coding standards. The existing code worked due to macro casts and INT8 being pass-by-value on 64-bit systems, but proper signatures and API usage improve maintainability. --- src/backend/optimizer/plan/createplan.c | 6 ++++-- src/backend/optimizer/plan/planner.c | 4 ++-- 2 files changed, 6 insertions(+), 4 deletions(-) diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c index 0a856e01a9d..308b5dc3982 100644 --- a/src/backend/optimizer/plan/createplan.c +++ b/src/backend/optimizer/plan/createplan.c @@ -7632,8 +7632,10 @@ replace_rownum_expr_mutator(Node *node, replace_rownum_context *context) * Count the number of RownumExpr nodes in an expression tree. */ static bool -count_rownum_exprs_walker(Node *node, int *count) +count_rownum_exprs_walker(Node *node, void *context) { + int *count = (int *) context; + if (node == NULL) return false; @@ -7643,7 +7645,7 @@ count_rownum_exprs_walker(Node *node, int *count) return false; /* Don't recurse into RownumExpr */ } - return expression_tree_walker(node, count_rownum_exprs_walker, count); + return expression_tree_walker(node, count_rownum_exprs_walker, context); } /* diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c index 15d4d8664c8..ab09f822ee5 100644 --- a/src/backend/optimizer/plan/planner.c +++ b/src/backend/optimizer/plan/planner.c @@ -999,11 +999,11 @@ transform_rownum_to_limit(Query *parse) /* If we found a ROWNUM predicate, transform it */ if (rownum_qual != NULL && limit_value > 0) { - /* Create the LIMIT constant (INT8 is pass-by-value on 64-bit systems) */ + /* Create the LIMIT constant */ parse->limitCount = (Node *) makeConst(INT8OID, -1, InvalidOid, sizeof(int64), Int64GetDatum(limit_value), - false, true); + false, get_typbyval(INT8OID)); /* Remove the ROWNUM predicate from the WHERE clause */ andlist = list_delete_ptr(andlist, rownum_qual); From a8171fa153caf14bc70f59b6d992ca1f695f4267 Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Mon, 8 Dec 2025 12:26:11 +0000 Subject: [PATCH 05/19] refactor: fix replace_rownum_expr_mutator signature Change replace_rownum_expr_mutator to use void* context parameter to match expression_tree_mutator callback convention. This is the same fix applied to count_rownum_exprs_walker in the previous commit. --- src/backend/optimizer/plan/createplan.c | 16 +++++++++------- 1 file changed, 9 insertions(+), 7 deletions(-) diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c index 308b5dc3982..e472a5001a5 100644 --- a/src/backend/optimizer/plan/createplan.c +++ b/src/backend/optimizer/plan/createplan.c @@ -89,7 +89,7 @@ typedef struct replace_rownum_context int rownum_idx; /* Current index in rownum_vars list */ } replace_rownum_context; -static Node *replace_rownum_expr_mutator(Node *node, replace_rownum_context *context); +static Node *replace_rownum_expr_mutator(Node *node, void *context); static List *get_gating_quals(PlannerInfo *root, List *quals); static Plan *create_gating_plan(PlannerInfo *root, Path *path, Plan *plan, List *gating_quals); @@ -7605,26 +7605,28 @@ contain_rownum_expr(Node *node) * not just top-level RownumExpr in target entries. */ static Node * -replace_rownum_expr_mutator(Node *node, replace_rownum_context *context) +replace_rownum_expr_mutator(Node *node, void *context) { + replace_rownum_context *ctx = (replace_rownum_context *) context; + if (node == NULL) return NULL; if (IsA(node, RownumExpr)) { /* Replace with the next Var from our list */ - if (context->rownum_idx < list_length(context->rownum_vars)) + if (ctx->rownum_idx < list_length(ctx->rownum_vars)) { - Var *replacement = (Var *) list_nth(context->rownum_vars, - context->rownum_idx); - context->rownum_idx++; + Var *replacement = (Var *) list_nth(ctx->rownum_vars, + ctx->rownum_idx); + ctx->rownum_idx++; return (Node *) copyObject(replacement); } /* Should not happen if we counted correctly */ elog(ERROR, "ran out of replacement Vars for ROWNUM expressions"); } - return expression_tree_mutator(node, replace_rownum_expr_mutator, context); + return expression_tree_mutator(node, replace_rownum_expr_mutator, ctx); } /* From 3a9f276d01d6224f08d00e627b13dfc077881530 Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Tue, 6 Jan 2026 21:48:19 +0000 Subject: [PATCH 06/19] test: add ROWNUM pagination test for nested subqueries Add test case for Oracle pagination pattern with nested subqueries. This exposes a bug where shared es_rownum counter causes skipped values (8,10,12,14 instead of 8,9,10,11,12) in nested subquery scans. --- src/oracle_test/regress/expected/rownum.out | 79 +++++++++++++++++++++ src/oracle_test/regress/sql/rownum.sql | 61 ++++++++++++++++ 2 files changed, 140 insertions(+) diff --git a/src/oracle_test/regress/expected/rownum.out b/src/oracle_test/regress/expected/rownum.out index 8a7e8031d39..36af6cb0086 100644 --- a/src/oracle_test/regress/expected/rownum.out +++ b/src/oracle_test/regress/expected/rownum.out @@ -1143,6 +1143,85 @@ SELECT COUNT(*) FROM empty_test WHERE ROWNUM <= 5; DROP TABLE empty_test; -- +-- ROWNUM pagination with nested subqueries +-- Common Oracle pagination pattern: SELECT FROM (SELECT ... ROWNUM) WHERE rnum >= N +-- +CREATE TABLE eemp( + empno NUMBER(4) NOT NULL CONSTRAINT emp_pk PRIMARY KEY, + ename VARCHAR2(10), + sal NUMBER(7,2) +); +INSERT INTO eemp VALUES (7369,'SMITH',800); +INSERT INTO eemp VALUES (7499,'ALLEN',1600); +INSERT INTO eemp VALUES (7521,'WARD',1250); +INSERT INTO eemp VALUES (7566,'JONES',2975); +INSERT INTO eemp VALUES (7654,'MARTIN',1250); +INSERT INTO eemp VALUES (7698,'BLAKE',2850); +INSERT INTO eemp VALUES (7782,'CLARK',2450); +INSERT INTO eemp VALUES (7788,'SCOTT',3000); +INSERT INTO eemp VALUES (7839,'KING',5000); +INSERT INTO eemp VALUES (7844,'TURNER',1500); +INSERT INTO eemp VALUES (7876,'ADAMS',1100); +INSERT INTO eemp VALUES (7900,'JAMES',950); +INSERT INTO eemp VALUES (7902,'FORD',3000); +INSERT INTO eemp VALUES (7934,'MILLER',1300); +-- Pagination query: get rows 8-12 (sorted by sal) +-- This is the standard Oracle pagination pattern +SELECT * +FROM ( + SELECT a.*, rownum rnum + FROM ( + SELECT empno, sal + FROM eemp + ORDER BY sal + ) a + WHERE rownum <= 12 +) +WHERE rnum >= 8; + empno | sal | rnum +-------+---------+------ + 7499 | 1600.00 | 8 + 7782 | 2450.00 | 9 + 7698 | 2850.00 | 10 + 7566 | 2975.00 | 11 + 7902 | 3000.00 | 12 +(5 rows) + +-- Expected result: +-- empno | sal | rnum +-- -------+---------+------ +-- 7499 | 1600.00 | 8 +-- 7782 | 2450.00 | 9 +-- 7698 | 2850.00 | 10 +-- 7566 | 2975.00 | 11 +-- 7902 | 3000.00 | 12 +-- (5 rows) +-- Verify ROWNUM values are consecutive in inner query +SELECT empno, sal, rownum as rnum +FROM ( + SELECT empno, sal + FROM eemp + ORDER BY sal +) a +WHERE rownum <= 12; + empno | sal | rnum +-------+---------+------ + 7369 | 800.00 | 1 + 7900 | 950.00 | 2 + 7876 | 1100.00 | 3 + 7521 | 1250.00 | 4 + 7654 | 1250.00 | 5 + 7934 | 1300.00 | 6 + 7844 | 1500.00 | 7 + 7499 | 1600.00 | 8 + 7782 | 2450.00 | 9 + 7698 | 2850.00 | 10 + 7566 | 2975.00 | 11 + 7902 | 3000.00 | 12 +(12 rows) + +DROP TABLE eemp; +-- -- Cleanup -- DROP TABLE rownum_test CASCADE; diff --git a/src/oracle_test/regress/sql/rownum.sql b/src/oracle_test/regress/sql/rownum.sql index 416bf3c394e..b11dcd971e9 100644 --- a/src/oracle_test/regress/sql/rownum.sql +++ b/src/oracle_test/regress/sql/rownum.sql @@ -651,6 +651,67 @@ SELECT COUNT(*) FROM empty_test WHERE ROWNUM <= 5; DROP TABLE empty_test; +-- +-- ROWNUM pagination with nested subqueries +-- Common Oracle pagination pattern: SELECT FROM (SELECT ... ROWNUM) WHERE rnum >= N +-- + +CREATE TABLE eemp( + empno NUMBER(4) NOT NULL CONSTRAINT emp_pk PRIMARY KEY, + ename VARCHAR2(10), + sal NUMBER(7,2) +); + +INSERT INTO eemp VALUES (7369,'SMITH',800); +INSERT INTO eemp VALUES (7499,'ALLEN',1600); +INSERT INTO eemp VALUES (7521,'WARD',1250); +INSERT INTO eemp VALUES (7566,'JONES',2975); +INSERT INTO eemp VALUES (7654,'MARTIN',1250); +INSERT INTO eemp VALUES (7698,'BLAKE',2850); +INSERT INTO eemp VALUES (7782,'CLARK',2450); +INSERT INTO eemp VALUES (7788,'SCOTT',3000); +INSERT INTO eemp VALUES (7839,'KING',5000); +INSERT INTO eemp VALUES (7844,'TURNER',1500); +INSERT INTO eemp VALUES (7876,'ADAMS',1100); +INSERT INTO eemp VALUES (7900,'JAMES',950); +INSERT INTO eemp VALUES (7902,'FORD',3000); +INSERT INTO eemp VALUES (7934,'MILLER',1300); + +-- Pagination query: get rows 8-12 (sorted by sal) +-- This is the standard Oracle pagination pattern +SELECT * +FROM ( + SELECT a.*, rownum rnum + FROM ( + SELECT empno, sal + FROM eemp + ORDER BY sal + ) a + WHERE rownum <= 12 +) +WHERE rnum >= 8; + +-- Expected result: +-- empno | sal | rnum +-- -------+---------+------ +-- 7499 | 1600.00 | 8 +-- 7782 | 2450.00 | 9 +-- 7698 | 2850.00 | 10 +-- 7566 | 2975.00 | 11 +-- 7902 | 3000.00 | 12 +-- (5 rows) + +-- Verify ROWNUM values are consecutive in inner query +SELECT empno, sal, rownum as rnum +FROM ( + SELECT empno, sal + FROM eemp + ORDER BY sal +) a +WHERE rownum <= 12; + +DROP TABLE eemp; + -- -- Cleanup -- From 11a8ed6a73b02f7fbd3221787ec2884d12fb97c5 Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Tue, 6 Jan 2026 21:56:17 +0000 Subject: [PATCH 07/19] fix: use local ROWNUM counter for nested subqueries Each SubqueryScan now maintains its own sub_rownum counter instead of sharing es_rownum globally. On each tuple fetch, the outer query's counter is saved, this subquery's counter is swapped in, the subplan executes, then the outer counter is restored. This fixes the Oracle pagination pattern where nested subqueries caused skipped ROWNUM values (8,10,12,14 instead of 8,9,10,11,12). Co-authored-by: Steven --- src/backend/executor/nodeSubqueryscan.c | 36 +++++++++---------- src/include/nodes/execnodes.h | 6 ++-- src/oracle_test/regress/expected/rownum.out | 38 ++++++++++----------- 3 files changed, 38 insertions(+), 42 deletions(-) diff --git a/src/backend/executor/nodeSubqueryscan.c b/src/backend/executor/nodeSubqueryscan.c index a3c1f60ab83..0cfab69bef6 100644 --- a/src/backend/executor/nodeSubqueryscan.c +++ b/src/backend/executor/nodeSubqueryscan.c @@ -46,29 +46,25 @@ static TupleTableSlot * SubqueryNext(SubqueryScanState *node) { TupleTableSlot *slot; - bool first_call = !node->rownum_reset; + EState *estate = node->ss.ps.state; + int64 save_rownum = estate->es_rownum; - if (first_call) - node->rownum_reset = true; + /* + * For Oracle ROWNUM compatibility: each subquery maintains its own + * local ROWNUM counter. Save the outer query's counter, swap in + * this subquery's counter, execute the subplan, then restore. + * This allows nested subqueries to have independent ROWNUM sequences. + */ + estate->es_rownum = node->sub_rownum; /* * Get the next tuple from the sub-query. */ slot = ExecProcNode(node->subplan); - /* - * For Oracle ROWNUM compatibility: reset the ROWNUM counter after - * the first call to ExecProcNode. This is necessary because inner - * plan nodes (e.g., SeqScan feeding a Sort) may increment es_rownum - * while buffering tuples during the first call. We want the - * SubqueryScan's ROWNUM values to start at 1, not continue from - * where the inner scans left off. - * - * The reset happens after ExecProcNode because blocking operators - * like Sort fetch all input tuples on the first call. - */ - if (first_call) - node->ss.ps.state->es_rownum = 0; + /* Update local counter and restore outer query's counter */ + node->sub_rownum = estate->es_rownum; + estate->es_rownum = save_rownum; /* * We just return the subplan's result slot, rather than expending extra @@ -130,7 +126,7 @@ ExecInitSubqueryScan(SubqueryScan *node, EState *estate, int eflags) subquerystate->ss.ps.plan = (Plan *) node; subquerystate->ss.ps.state = estate; subquerystate->ss.ps.ExecProcNode = ExecSubqueryScan; - subquerystate->rownum_reset = false; + subquerystate->sub_rownum = 0; /* * Miscellaneous initialization @@ -202,10 +198,10 @@ void ExecReScanSubqueryScan(SubqueryScanState *node) { /* - * Reset ROWNUM tracking flag for Oracle compatibility. - * This ensures each SubqueryScan rescan resets ROWNUM on first tuple. + * Reset local ROWNUM counter for Oracle compatibility. + * Each rescan starts with ROWNUM = 1. */ - node->rownum_reset = false; + node->sub_rownum = 0; ExecScanReScan(&node->ss); diff --git a/src/include/nodes/execnodes.h b/src/include/nodes/execnodes.h index fa75190fd8c..01a8a1a70d8 100644 --- a/src/include/nodes/execnodes.h +++ b/src/include/nodes/execnodes.h @@ -1948,15 +1948,15 @@ typedef struct TidRangeScanState * * SubqueryScanState is used for scanning a sub-query in the range table. * ScanTupleSlot references the current output tuple of the sub-query. - * rownum_reset tracks whether ROWNUM counter has been reset for Oracle - * compatibility (inner plans may increment before SubqueryScan runs). + * sub_rownum is the local ROWNUM counter for Oracle compatibility, + * allowing nested subqueries to have independent ROWNUM sequences. * ---------------- */ typedef struct SubqueryScanState { ScanState ss; /* its first field is NodeTag */ PlanState *subplan; - bool rownum_reset; /* has ROWNUM been reset for this scan? */ + int64 sub_rownum; /* local ROWNUM counter for this subquery */ } SubqueryScanState; /* ---------------- diff --git a/src/oracle_test/regress/expected/rownum.out b/src/oracle_test/regress/expected/rownum.out index 36af6cb0086..8fda30c6e88 100644 --- a/src/oracle_test/regress/expected/rownum.out +++ b/src/oracle_test/regress/expected/rownum.out @@ -1178,13 +1178,13 @@ FROM ( WHERE rownum <= 12 ) WHERE rnum >= 8; - empno | sal | rnum + empno | sal | rnum -------+---------+------ - 7499 | 1600.00 | 8 - 7782 | 2450.00 | 9 - 7698 | 2850.00 | 10 - 7566 | 2975.00 | 11 - 7902 | 3000.00 | 12 + 7499 | 1600.00 | 8 + 7782 | 2450.00 | 9 + 7698 | 2850.00 | 10 + 7566 | 2975.00 | 11 + 7902 | 3000.00 | 12 (5 rows) -- Expected result: @@ -1204,20 +1204,20 @@ FROM ( ORDER BY sal ) a WHERE rownum <= 12; - empno | sal | rnum + empno | sal | rnum -------+---------+------ - 7369 | 800.00 | 1 - 7900 | 950.00 | 2 - 7876 | 1100.00 | 3 - 7521 | 1250.00 | 4 - 7654 | 1250.00 | 5 - 7934 | 1300.00 | 6 - 7844 | 1500.00 | 7 - 7499 | 1600.00 | 8 - 7782 | 2450.00 | 9 - 7698 | 2850.00 | 10 - 7566 | 2975.00 | 11 - 7902 | 3000.00 | 12 + 7369 | 800.00 | 1 + 7900 | 950.00 | 2 + 7876 | 1100.00 | 3 + 7521 | 1250.00 | 4 + 7654 | 1250.00 | 5 + 7934 | 1300.00 | 6 + 7844 | 1500.00 | 7 + 7499 | 1600.00 | 8 + 7782 | 2450.00 | 9 + 7698 | 2850.00 | 10 + 7566 | 2975.00 | 11 + 7902 | 3000.00 | 12 (12 rows) DROP TABLE eemp; From 2ecbfb76d9a391e06d8e2b69fadef100884a124b Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Tue, 6 Jan 2026 22:16:19 +0000 Subject: [PATCH 08/19] refactor: use compatible_db instead of database_mode for ROWNUM Change ROWNUM checks from database_mode == DB_ORACLE to compatible_db == ORA_PARSER. This allows ROWNUM to work based on the session's compatible_mode setting rather than the cluster's database_mode. - database_mode: set at initdb, cannot change at runtime - compatible_mode: can be changed per-session Co-authored-by: Steven --- src/backend/optimizer/plan/planner.c | 2 +- src/backend/parser/parse_expr.c | 4 ++-- src/include/nodes/execnodes.h | 2 +- 3 files changed, 4 insertions(+), 4 deletions(-) diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c index ab09f822ee5..7e46dac2c7f 100644 --- a/src/backend/optimizer/plan/planner.c +++ b/src/backend/optimizer/plan/planner.c @@ -654,7 +654,7 @@ transform_rownum_to_limit(Query *parse) bool can_use_limit; /* Only apply in Oracle compatibility mode */ - if (database_mode != DB_ORACLE) + if (compatible_db != ORA_PARSER) return; /* diff --git a/src/backend/parser/parse_expr.c b/src/backend/parser/parse_expr.c index a891c5d9c12..5542504ee56 100644 --- a/src/backend/parser/parse_expr.c +++ b/src/backend/parser/parse_expr.c @@ -689,11 +689,11 @@ transformColumnRefInternal(ParseState *pstate, ColumnRef *cref, bool missing_ok) /* * Check for ROWNUM pseudocolumn in Oracle mode. * ROWNUM is only recognized as a pseudocolumn when: - * 1. Database is in Oracle compatibility mode + * 1. Session is in Oracle compatible_mode * 2. The identifier is exactly "rownum" (case-insensitive) * 3. It's unqualified (no table/schema prefix) */ - if (database_mode == DB_ORACLE && pg_strcasecmp(colname, "rownum") == 0) + if (compatible_db == ORA_PARSER && pg_strcasecmp(colname, "rownum") == 0) { RownumExpr *rexpr; diff --git a/src/include/nodes/execnodes.h b/src/include/nodes/execnodes.h index 01a8a1a70d8..d571e76db3f 100644 --- a/src/include/nodes/execnodes.h +++ b/src/include/nodes/execnodes.h @@ -752,7 +752,7 @@ typedef struct EState /* * Oracle ROWNUM support: current row number counter. * This is incremented for each row emitted during query execution. - * Only used when database_mode == DB_ORACLE. + * Only used when compatible_db == ORA_PARSER. */ int64 es_rownum; From 5e4b64bad19d66ca5fa07a9eb9ca8385edd1061a Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Tue, 6 Jan 2026 22:22:43 +0000 Subject: [PATCH 09/19] fix: validate ROWNUM in GROUP BY clause ROWNUM must appear in the GROUP BY clause or be used in an aggregate function, matching Oracle's behavior. Without this check, queries like "SELECT rownum FROM t GROUP BY category" would incorrectly return results instead of raising an error. Co-authored-by: Steven --- src/backend/parser/parse_agg.c | 18 ++++++++++++++++ src/oracle_test/regress/expected/rownum.out | 23 +++++++++++++++++++++ src/oracle_test/regress/sql/rownum.sql | 16 ++++++++++++++ 3 files changed, 57 insertions(+) diff --git a/src/backend/parser/parse_agg.c b/src/backend/parser/parse_agg.c index 0ac8966e30f..cfd896827f7 100644 --- a/src/backend/parser/parse_agg.c +++ b/src/backend/parser/parse_agg.c @@ -1414,6 +1414,24 @@ substitute_grouped_columns_mutator(Node *node, IsA(node, Param)) return node; + /* + * For Oracle ROWNUM compatibility: ROWNUM must appear in the GROUP BY + * clause or be used in an aggregate function, just like a regular column. + * If we reach here, it wasn't matched as a GROUP BY item above. + */ + if (IsA(node, RownumExpr)) + { + RownumExpr *rexpr = (RownumExpr *) node; + + if (context->sublevels_up == 0) + 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, rexpr->location))); + /* If not at current level, it's from outer query - not our problem */ + return node; + } + /* * 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 diff --git a/src/oracle_test/regress/expected/rownum.out b/src/oracle_test/regress/expected/rownum.out index 8fda30c6e88..85f5ce34a22 100644 --- a/src/oracle_test/regress/expected/rownum.out +++ b/src/oracle_test/regress/expected/rownum.out @@ -1222,6 +1222,29 @@ WHERE rownum <= 12; DROP TABLE eemp; -- +-- ROWNUM with GROUP BY validation +-- ROWNUM must appear in GROUP BY clause or be used in aggregate function +-- +CREATE TABLE grp_test (id int, category varchar(10)); +INSERT INTO grp_test VALUES (1, 'A'), (2, 'A'), (3, 'B'), (4, 'B'), (5, 'C'); +-- Error: ROWNUM not in GROUP BY and not in aggregate +SELECT rownum FROM grp_test GROUP BY category; +ERROR: ROWNUM: must appear in the GROUP BY clause or be used in an aggregate function +LINE 1: SELECT rownum FROM grp_test GROUP BY category; + ^ +-- OK: ROWNUM in GROUP BY clause +SELECT rownum FROM grp_test GROUP BY rownum ORDER BY rownum; + rownum +-------- + 1 + 2 + 3 + 4 + 5 +(5 rows) + +DROP TABLE grp_test; +-- -- Cleanup -- DROP TABLE rownum_test CASCADE; diff --git a/src/oracle_test/regress/sql/rownum.sql b/src/oracle_test/regress/sql/rownum.sql index b11dcd971e9..02798b7b034 100644 --- a/src/oracle_test/regress/sql/rownum.sql +++ b/src/oracle_test/regress/sql/rownum.sql @@ -712,6 +712,22 @@ WHERE rownum <= 12; DROP TABLE eemp; +-- +-- ROWNUM with GROUP BY validation +-- ROWNUM must appear in GROUP BY clause or be used in aggregate function +-- + +CREATE TABLE grp_test (id int, category varchar(10)); +INSERT INTO grp_test VALUES (1, 'A'), (2, 'A'), (3, 'B'), (4, 'B'), (5, 'C'); + +-- Error: ROWNUM not in GROUP BY and not in aggregate +SELECT rownum FROM grp_test GROUP BY category; + +-- OK: ROWNUM in GROUP BY clause +SELECT rownum FROM grp_test GROUP BY rownum ORDER BY rownum; + +DROP TABLE grp_test; + -- -- Cleanup -- From bb3677275d18ba2f18bf0276fd383fea1b7f6212 Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Tue, 6 Jan 2026 23:55:41 +0000 Subject: [PATCH 10/19] fix: ROWNUM in aggregate functions returns correct values When ROWNUM is used inside aggregate functions like MIN(rownum), MAX(rownum), SUM(rownum), AVG(rownum), the planner now adds ROWNUM to the subplan's target list. This ensures ROWNUM is evaluated during the scan (where it increments for each row) rather than during aggregation (where it would return the same value). The fix modifies create_agg_plan() to detect ROWNUM in aggregate arguments and add a RownumExpr to the scan's target list. The setrefs.c code then matches the RownumExpr in aggregate arguments with the one in the subplan and creates appropriate Var references. Before: SELECT MIN(rownum), MAX(rownum), SUM(rownum) FROM t; -> 1, 1, 6 (for 6 rows - ROWNUM always evaluated as 1) After: SELECT MIN(rownum), MAX(rownum), SUM(rownum) FROM t; -> 1, 6, 21 (correct values for 6 rows) --- src/backend/optimizer/plan/createplan.c | 212 ++++++++++++++++++++ src/oracle_test/regress/expected/rownum.out | 48 ++++- src/oracle_test/regress/sql/rownum.sql | 26 +++ 3 files changed, 283 insertions(+), 3 deletions(-) diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c index e472a5001a5..ede286e7ce7 100644 --- a/src/backend/optimizer/plan/createplan.c +++ b/src/backend/optimizer/plan/createplan.c @@ -82,6 +82,10 @@ static bool use_physical_tlist(PlannerInfo *root, Path *path, int flags); static bool contain_rownum_expr(Node *node); static int count_rownum_exprs(Node *node); static List *collect_rownum_exprs(List *tlist); +static bool aggref_args_contain_rownum(List *tlist); +static bool aggref_args_contain_rownum_walker(Node *node, void *context); +static int count_rownum_in_aggref_args(List *tlist); +static Node *replace_rownum_in_aggref_args_mutator(Node *node, void *context); typedef struct replace_rownum_context { @@ -2477,6 +2481,38 @@ create_agg_plan(PlannerInfo *root, AggPath *best_path) tlist = build_path_tlist(root, &best_path->path); + /* + * Oracle ROWNUM compatibility: if any aggregate function has ROWNUM + * in its arguments, we need to add ROWNUM to the subplan's target list. + * This ensures ROWNUM is evaluated during the scan (where it gets + * incrementing values) rather than during aggregation. + * + * The setrefs.c code will then match the RownumExpr in the Aggref + * arguments with the RownumExpr in the subplan's target list and + * create appropriate Var references. + */ + if (aggref_args_contain_rownum(tlist)) + { + AttrNumber new_resno; + TargetEntry *new_tle; + RownumExpr *rownum_expr; + + /* + * Add a single RownumExpr to the subplan's target list. + * Multiple ROWNUM references in aggregates will all match this + * one entry via equal() comparison. + */ + new_resno = list_length(subplan->targetlist) + 1; + rownum_expr = makeNode(RownumExpr); + rownum_expr->location = -1; + + new_tle = makeTargetEntry((Expr *) rownum_expr, + new_resno, + NULL, + false); + subplan->targetlist = lappend(subplan->targetlist, new_tle); + } + quals = order_qual_clauses(root, best_path->qual); plan = make_agg(tlist, quals, @@ -7686,6 +7722,182 @@ collect_rownum_exprs(List *tlist) return rownum_tles; } +/* + * aggref_args_contain_rownum_walker + * Walker to check if any Aggref in a node tree has ROWNUM in its args. + */ +static bool +aggref_args_contain_rownum_walker(Node *node, void *context) +{ + if (node == NULL) + return false; + + if (IsA(node, Aggref)) + { + Aggref *aggref = (Aggref *) node; + ListCell *lc; + + /* Check each argument */ + foreach(lc, aggref->args) + { + TargetEntry *tle = lfirst_node(TargetEntry, lc); + + if (contain_rownum_expr((Node *) tle->expr)) + return true; + } + + /* Check direct args (for ordered-set aggregates) */ + foreach(lc, aggref->aggdirectargs) + { + if (contain_rownum_expr((Node *) lfirst(lc))) + return true; + } + + /* Check filter */ + if (aggref->aggfilter && contain_rownum_expr((Node *) aggref->aggfilter)) + return true; + } + + return expression_tree_walker(node, aggref_args_contain_rownum_walker, context); +} + +/* + * aggref_args_contain_rownum + * Check if any Aggref in the target list has ROWNUM in its arguments. + */ +static bool +aggref_args_contain_rownum(List *tlist) +{ + ListCell *lc; + + foreach(lc, tlist) + { + TargetEntry *tle = lfirst_node(TargetEntry, lc); + + if (aggref_args_contain_rownum_walker((Node *) tle->expr, NULL)) + return true; + } + + return false; +} + +/* + * count_rownum_in_aggref_args_walker + * Count ROWNUM expressions inside Aggref arguments. + */ +static bool +count_rownum_in_aggref_args_walker(Node *node, void *context) +{ + int *count = (int *) context; + + if (node == NULL) + return false; + + if (IsA(node, Aggref)) + { + Aggref *aggref = (Aggref *) node; + ListCell *lc; + + /* Count in each argument */ + foreach(lc, aggref->args) + { + TargetEntry *tle = lfirst_node(TargetEntry, lc); + *count += count_rownum_exprs((Node *) tle->expr); + } + + /* Count in direct args */ + foreach(lc, aggref->aggdirectargs) + { + *count += count_rownum_exprs((Node *) lfirst(lc)); + } + + /* Count in filter */ + if (aggref->aggfilter) + *count += count_rownum_exprs((Node *) aggref->aggfilter); + } + + return expression_tree_walker(node, count_rownum_in_aggref_args_walker, context); +} + +/* + * count_rownum_in_aggref_args + * Count the total number of ROWNUM expressions in all Aggref arguments + * in the target list. + */ +static int +count_rownum_in_aggref_args(List *tlist) +{ + int count = 0; + ListCell *lc; + + foreach(lc, tlist) + { + TargetEntry *tle = lfirst_node(TargetEntry, lc); + count_rownum_in_aggref_args_walker((Node *) tle->expr, &count); + } + + return count; +} + +/* + * replace_rownum_in_aggref_args_mutator + * Replace ROWNUM expressions inside Aggref arguments with Vars. + * + * This mutator walks the expression tree and when it finds an Aggref, + * it replaces any RownumExpr in its arguments with the corresponding + * Var from the context. + */ +static Node * +replace_rownum_in_aggref_args_mutator(Node *node, void *context) +{ + replace_rownum_context *ctx = (replace_rownum_context *) context; + + if (node == NULL) + return NULL; + + if (IsA(node, Aggref)) + { + Aggref *aggref = (Aggref *) copyObject(node); + ListCell *lc; + + /* Replace ROWNUM in args */ + foreach(lc, aggref->args) + { + TargetEntry *tle = lfirst_node(TargetEntry, lc); + + if (contain_rownum_expr((Node *) tle->expr)) + { + tle->expr = (Expr *) replace_rownum_expr_mutator((Node *) tle->expr, ctx); + } + } + + /* Replace ROWNUM in direct args */ + if (aggref->aggdirectargs != NIL) + { + ListCell *lc2; + + foreach(lc2, aggref->aggdirectargs) + { + Node *arg = (Node *) lfirst(lc2); + if (contain_rownum_expr(arg)) + { + lfirst(lc2) = replace_rownum_expr_mutator(arg, ctx); + } + } + } + + /* Replace ROWNUM in filter */ + if (aggref->aggfilter && contain_rownum_expr((Node *) aggref->aggfilter)) + { + aggref->aggfilter = (Expr *) replace_rownum_expr_mutator((Node *) aggref->aggfilter, ctx); + } + + return (Node *) aggref; + } + + return expression_tree_mutator(node, replace_rownum_in_aggref_args_mutator, ctx); +} + /* * is_projection_capable_plan * Check whether a given Plan node is able to do projection. diff --git a/src/oracle_test/regress/expected/rownum.out b/src/oracle_test/regress/expected/rownum.out index 85f5ce34a22..9f4ca3489cc 100644 --- a/src/oracle_test/regress/expected/rownum.out +++ b/src/oracle_test/regress/expected/rownum.out @@ -818,9 +818,9 @@ GROUP BY dept_id ORDER BY dept_id; dept_id | max_rownum | min_rownum | count_rownum ---------+------------+------------+-------------- - 1 | 10 | 10 | 3 - 2 | 10 | 10 | 4 - 3 | 10 | 10 | 3 + 1 | 8 | 2 | 3 + 2 | 10 | 1 | 4 + 3 | 9 | 3 | 3 (3 rows) -- @@ -1245,6 +1245,48 @@ SELECT rownum FROM grp_test GROUP BY rownum ORDER BY rownum; DROP TABLE grp_test; -- +-- ROWNUM with aggregate functions +-- Aggregate functions should evaluate ROWNUM for each row during scan +-- +CREATE TABLE agg_test (id int, val int); +INSERT INTO agg_test VALUES (1, 10), (2, 20), (3, 30), (4, 40), (5, 50), (6, 60); +-- MIN/MAX/SUM/AVG with ROWNUM +-- For 6 rows: MIN=1, MAX=6, SUM=21, AVG=3.5 +SELECT MIN(rownum), MAX(rownum), SUM(rownum), AVG(rownum) FROM agg_test; + min | max | sum | avg +-----+-----+-----+-------------------- + 1 | 6 | 21 | 3.5000000000000000 +(1 row) + +-- COUNT with ROWNUM +SELECT COUNT(*), COUNT(rownum) FROM agg_test; + count | count +-------+------- + 6 | 6 +(1 row) + +-- Aggregate with ROWNUM expression +SELECT SUM(rownum * 2), SUM(rownum) * 2 FROM agg_test; + sum | ?column? +-----+---------- + 42 | 42 +(1 row) + +-- Aggregate with ROWNUM and GROUP BY +SELECT val / 20 as grp, MIN(rownum), MAX(rownum) +FROM agg_test +GROUP BY val / 20 +ORDER BY grp; + grp | min | max +-----+-----+----- + 0 | 1 | 1 + 1 | 2 | 3 + 2 | 4 | 5 + 3 | 6 | 6 +(4 rows) + +DROP TABLE agg_test; +-- -- Cleanup -- DROP TABLE rownum_test CASCADE; diff --git a/src/oracle_test/regress/sql/rownum.sql b/src/oracle_test/regress/sql/rownum.sql index 02798b7b034..e1d0eef6f00 100644 --- a/src/oracle_test/regress/sql/rownum.sql +++ b/src/oracle_test/regress/sql/rownum.sql @@ -728,6 +728,32 @@ SELECT rownum FROM grp_test GROUP BY rownum ORDER BY rownum; DROP TABLE grp_test; +-- +-- ROWNUM with aggregate functions +-- Aggregate functions should evaluate ROWNUM for each row during scan +-- + +CREATE TABLE agg_test (id int, val int); +INSERT INTO agg_test VALUES (1, 10), (2, 20), (3, 30), (4, 40), (5, 50), (6, 60); + +-- MIN/MAX/SUM/AVG with ROWNUM +-- For 6 rows: MIN=1, MAX=6, SUM=21, AVG=3.5 +SELECT MIN(rownum), MAX(rownum), SUM(rownum), AVG(rownum) FROM agg_test; + +-- COUNT with ROWNUM +SELECT COUNT(*), COUNT(rownum) FROM agg_test; + +-- Aggregate with ROWNUM expression +SELECT SUM(rownum * 2), SUM(rownum) * 2 FROM agg_test; + +-- Aggregate with ROWNUM and GROUP BY +SELECT val / 20 as grp, MIN(rownum), MAX(rownum) +FROM agg_test +GROUP BY val / 20 +ORDER BY grp; + +DROP TABLE agg_test; + -- -- Cleanup -- From 0455343c6419972278d0a63fbfba361a467a8380 Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Wed, 7 Jan 2026 00:02:00 +0000 Subject: [PATCH 11/19] test: add nested aggregate function tests for ROWNUM Adds test cases for: - Subquery with aggregate containing ROWNUM - Aggregate of subquery with ROWNUM in SELECT - Nested subquery aggregates with GROUP BY - Multiple levels of aggregation --- src/oracle_test/regress/expected/rownum.out | 46 +++++++++++++++++++++ src/oracle_test/regress/sql/rownum.sql | 33 +++++++++++++++ 2 files changed, 79 insertions(+) diff --git a/src/oracle_test/regress/expected/rownum.out b/src/oracle_test/regress/expected/rownum.out index 9f4ca3489cc..cf8139b26ff 100644 --- a/src/oracle_test/regress/expected/rownum.out +++ b/src/oracle_test/regress/expected/rownum.out @@ -1287,6 +1287,52 @@ ORDER BY grp; DROP TABLE agg_test; -- +-- ROWNUM with nested aggregate functions +-- Test that ROWNUM works correctly in nested subqueries with aggregates +-- +CREATE TABLE agg_nest_test (id int, val int); +INSERT INTO agg_nest_test VALUES (1, 10), (2, 20), (3, 30), (4, 40), (5, 50), (6, 60); +-- Subquery with aggregate containing ROWNUM +SELECT * FROM ( + SELECT MIN(rownum) as min_rn, MAX(rownum) as max_rn, SUM(rownum) as sum_rn + FROM agg_nest_test +) sub; + min_rn | max_rn | sum_rn +--------+--------+-------- + 1 | 6 | 21 +(1 row) + +-- Aggregate of subquery with ROWNUM +SELECT SUM(rn) FROM (SELECT rownum as rn FROM agg_nest_test) sub; + sum +----- + 21 +(1 row) + +-- Nested subquery aggregates (use float division for Oracle compatibility) +SELECT MAX(sum_rn) FROM ( + SELECT val/20.0 as grp, SUM(rownum) as sum_rn + FROM agg_nest_test + GROUP BY val/20.0 +) sub; + max +----- + 6 +(1 row) + +-- Multiple levels of aggregation +SELECT AVG(max_rn) FROM ( + SELECT val/30.0 as grp, MAX(rownum) as max_rn + FROM agg_nest_test + GROUP BY val/30.0 +) sub; + avg +-------------------- + 3.5000000000000000 +(1 row) + +DROP TABLE agg_nest_test; +-- -- Cleanup -- DROP TABLE rownum_test CASCADE; diff --git a/src/oracle_test/regress/sql/rownum.sql b/src/oracle_test/regress/sql/rownum.sql index e1d0eef6f00..a06237d41f7 100644 --- a/src/oracle_test/regress/sql/rownum.sql +++ b/src/oracle_test/regress/sql/rownum.sql @@ -754,6 +754,39 @@ ORDER BY grp; DROP TABLE agg_test; +-- +-- ROWNUM with nested aggregate functions +-- Test that ROWNUM works correctly in nested subqueries with aggregates +-- + +CREATE TABLE agg_nest_test (id int, val int); +INSERT INTO agg_nest_test VALUES (1, 10), (2, 20), (3, 30), (4, 40), (5, 50), (6, 60); + +-- Subquery with aggregate containing ROWNUM +SELECT * FROM ( + SELECT MIN(rownum) as min_rn, MAX(rownum) as max_rn, SUM(rownum) as sum_rn + FROM agg_nest_test +) sub; + +-- Aggregate of subquery with ROWNUM +SELECT SUM(rn) FROM (SELECT rownum as rn FROM agg_nest_test) sub; + +-- Nested subquery aggregates (use float division for Oracle compatibility) +SELECT MAX(sum_rn) FROM ( + SELECT val/20.0 as grp, SUM(rownum) as sum_rn + FROM agg_nest_test + GROUP BY val/20.0 +) sub; + +-- Multiple levels of aggregation +SELECT AVG(max_rn) FROM ( + SELECT val/30.0 as grp, MAX(rownum) as max_rn + FROM agg_nest_test + GROUP BY val/30.0 +) sub; + +DROP TABLE agg_nest_test; + -- -- Cleanup -- From 91730a309b57ab9de37b0337a14f89065c65d910 Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Wed, 7 Jan 2026 02:15:14 +0000 Subject: [PATCH 12/19] fix: ROWNUM aggregate with ORDER BY when column order differs When using ROWNUM inside aggregates with GROUP BY and ORDER BY, queries would fail with "Aggref found in non-Agg plan node" if the ROWNUM-containing aggregate wasn't the last column in the SELECT list. The fix skips special ROWNUM handling when ROWNUM only appears inside aggregate function arguments, since the Agg node correctly evaluates ROWNUM from its input. Also removes broken targetlist reordering logic that attempted to reorder Sort output (Sort is non-projection-capable). Added tests for: - Aggregate + GROUP BY + ORDER BY with various column orders - Multi-layer nested aggregation with ROWNUM (verified against Oracle) --- src/backend/optimizer/plan/createplan.c | 139 +++----------------- src/oracle_test/regress/expected/rownum.out | 134 +++++++++++++++++++ src/oracle_test/regress/sql/rownum.sql | 91 +++++++++++++ 3 files changed, 242 insertions(+), 122 deletions(-) diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c index ede286e7ce7..2f6c97e40db 100644 --- a/src/backend/optimizer/plan/createplan.c +++ b/src/backend/optimizer/plan/createplan.c @@ -84,8 +84,6 @@ static int count_rownum_exprs(Node *node); static List *collect_rownum_exprs(List *tlist); static bool aggref_args_contain_rownum(List *tlist); static bool aggref_args_contain_rownum_walker(Node *node, void *context); -static int count_rownum_in_aggref_args(List *tlist); -static Node *replace_rownum_in_aggref_args_mutator(Node *node, void *context); typedef struct replace_rownum_context { @@ -2091,10 +2089,16 @@ create_projection_plan(PlannerInfo *root, ProjectionPath *best_path, int flags) * we need to ensure ROWNUM is evaluated BEFORE the sort, not after. * Oracle semantics require ROWNUM to be assigned during row retrieval, * before any ORDER BY clause is applied. + * + * NOTE: If ROWNUM only appears inside aggregate function arguments + * (like SUM(ROWNUM)), skip this handling because the aggregate + * correctly gets ROWNUM from its input (the scan). The ROWNUM inside + * aggregates is already properly evaluated during the Agg phase. */ if (needs_result_node && (IsA(subplan, Sort) || IsA(subplan, IncrementalSort)) && - contain_rownum_expr((Node *) tlist)) + contain_rownum_expr((Node *) tlist) && + !aggref_args_contain_rownum(tlist)) { Plan *sortinput; List *new_input_tlist; @@ -2221,13 +2225,20 @@ create_projection_plan(PlannerInfo *root, ProjectionPath *best_path, int flags) /* * Now replace all ROWNUM expressions in the final tlist - * (including nested ones) with Vars referencing Sort's output. + * with Vars referencing Sort's output (which has the ROWNUM + * values from the scan). */ context.rownum_vars = rownum_vars; context.rownum_idx = 0; - tlist = (List *) replace_rownum_expr_mutator((Node *) tlist, &context); + /* + * The tlist now has ROWNUM replaced with Vars. If needs_result_node + * is still true, a Result node will be created on top of Sort. + * This is fine for bare ROWNUM (no Aggrefs) because setrefs can + * handle Vars in Result's tlist by looking them up in Sort's output. + */ + skip_rownum_handling: ; /* Empty statement for label */ } @@ -2241,6 +2252,7 @@ create_projection_plan(PlannerInfo *root, ProjectionPath *best_path, int flags) * of the sortcolumn setup logic into Path creation, but that would add * expense to creating Paths we might end up not using.) */ + if (!needs_result_node) { /* Don't need a separate Result, just assign tlist to subplan */ @@ -7781,123 +7793,6 @@ aggref_args_contain_rownum(List *tlist) return false; } -/* - * count_rownum_in_aggref_args_walker - * Count ROWNUM expressions inside Aggref arguments. - */ -static bool -count_rownum_in_aggref_args_walker(Node *node, void *context) -{ - int *count = (int *) context; - - if (node == NULL) - return false; - - if (IsA(node, Aggref)) - { - Aggref *aggref = (Aggref *) node; - ListCell *lc; - - /* Count in each argument */ - foreach(lc, aggref->args) - { - TargetEntry *tle = lfirst_node(TargetEntry, lc); - *count += count_rownum_exprs((Node *) tle->expr); - } - - /* Count in direct args */ - foreach(lc, aggref->aggdirectargs) - { - *count += count_rownum_exprs((Node *) lfirst(lc)); - } - - /* Count in filter */ - if (aggref->aggfilter) - *count += count_rownum_exprs((Node *) aggref->aggfilter); - } - - return expression_tree_walker(node, count_rownum_in_aggref_args_walker, context); -} - -/* - * count_rownum_in_aggref_args - * Count the total number of ROWNUM expressions in all Aggref arguments - * in the target list. - */ -static int -count_rownum_in_aggref_args(List *tlist) -{ - int count = 0; - ListCell *lc; - - foreach(lc, tlist) - { - TargetEntry *tle = lfirst_node(TargetEntry, lc); - count_rownum_in_aggref_args_walker((Node *) tle->expr, &count); - } - - return count; -} - -/* - * replace_rownum_in_aggref_args_mutator - * Replace ROWNUM expressions inside Aggref arguments with Vars. - * - * This mutator walks the expression tree and when it finds an Aggref, - * it replaces any RownumExpr in its arguments with the corresponding - * Var from the context. - */ -static Node * -replace_rownum_in_aggref_args_mutator(Node *node, void *context) -{ - replace_rownum_context *ctx = (replace_rownum_context *) context; - - if (node == NULL) - return NULL; - - if (IsA(node, Aggref)) - { - Aggref *aggref = (Aggref *) copyObject(node); - ListCell *lc; - - /* Replace ROWNUM in args */ - foreach(lc, aggref->args) - { - TargetEntry *tle = lfirst_node(TargetEntry, lc); - - if (contain_rownum_expr((Node *) tle->expr)) - { - tle->expr = (Expr *) replace_rownum_expr_mutator((Node *) tle->expr, ctx); - } - } - - /* Replace ROWNUM in direct args */ - if (aggref->aggdirectargs != NIL) - { - ListCell *lc2; - - foreach(lc2, aggref->aggdirectargs) - { - Node *arg = (Node *) lfirst(lc2); - if (contain_rownum_expr(arg)) - { - lfirst(lc2) = replace_rownum_expr_mutator(arg, ctx); - } - } - } - - /* Replace ROWNUM in filter */ - if (aggref->aggfilter && contain_rownum_expr((Node *) aggref->aggfilter)) - { - aggref->aggfilter = (Expr *) replace_rownum_expr_mutator((Node *) aggref->aggfilter, ctx); - } - - return (Node *) aggref; - } - - return expression_tree_mutator(node, replace_rownum_in_aggref_args_mutator, ctx); -} - /* * is_projection_capable_plan * Check whether a given Plan node is able to do projection. diff --git a/src/oracle_test/regress/expected/rownum.out b/src/oracle_test/regress/expected/rownum.out index cf8139b26ff..4258cce31ae 100644 --- a/src/oracle_test/regress/expected/rownum.out +++ b/src/oracle_test/regress/expected/rownum.out @@ -1333,6 +1333,140 @@ SELECT AVG(max_rn) FROM ( DROP TABLE agg_nest_test; -- +-- ROWNUM with aggregate functions + GROUP BY + ORDER BY +-- Test that aggregate column order doesn't affect query execution +-- Bug: "Aggref found in non-Agg plan node" when ROWNUM aggregate wasn't last +-- +CREATE TABLE agg_order_test (a int, b int); +INSERT INTO agg_order_test VALUES (1, 10), (1, 20), (2, 30), (2, 40), (3, 50); +-- Test 1: SUM(rownum) first, then COUNT(*) with ORDER BY +-- For a=1: rows 1,2 → sum=3, count=2 +-- For a=2: rows 3,4 → sum=7, count=2 +-- For a=3: row 5 → sum=5, count=1 +SELECT a, SUM(rownum), COUNT(*) FROM agg_order_test GROUP BY a ORDER BY a; + a | sum | count +---+-----+------- + 1 | 3 | 2 + 2 | 7 | 2 + 3 | 5 | 1 +(3 rows) + +-- Test 2: COUNT(*) first, then SUM(rownum) with ORDER BY (different column order) +SELECT a, COUNT(*), SUM(rownum) FROM agg_order_test GROUP BY a ORDER BY a; + a | count | sum +---+-------+----- + 1 | 2 | 3 + 2 | 2 | 7 + 3 | 1 | 5 +(3 rows) + +-- Test 3: Multiple aggregates with ROWNUM in various positions +SELECT a, MIN(rownum), MAX(rownum), AVG(rownum), SUM(rownum), COUNT(*) +FROM agg_order_test GROUP BY a ORDER BY a; + a | min | max | avg | sum | count +---+-----+-----+--------------------+-----+------- + 1 | 1 | 2 | 1.5000000000000000 | 3 | 2 + 2 | 3 | 4 | 3.5000000000000000 | 7 | 2 + 3 | 5 | 5 | 5.0000000000000000 | 5 | 1 +(3 rows) + +-- Test 4: ORDER BY aggregate result +SELECT a, SUM(rownum) as s FROM agg_order_test GROUP BY a ORDER BY s; + a | s +---+--- + 1 | 3 + 3 | 5 + 2 | 7 +(3 rows) + +-- Test 5: ORDER BY DESC +SELECT a, SUM(rownum), COUNT(*) FROM agg_order_test GROUP BY a ORDER BY a DESC; + a | sum | count +---+-----+------- + 3 | 5 | 1 + 2 | 7 | 2 + 1 | 3 | 2 +(3 rows) + +DROP TABLE agg_order_test; +-- +-- Multi-layer nested aggregation with ROWNUM + GROUP BY + ORDER BY +-- Test multiple levels of aggregation where ROWNUM is used at the innermost level +-- +CREATE TABLE multi_agg_test (a int, b int, c int); +INSERT INTO multi_agg_test VALUES + (1, 1, 10), (1, 1, 20), (1, 2, 30), + (2, 1, 40), (2, 2, 50), (2, 2, 60); +-- Test 1: Two layers of aggregation +-- Inner: aggregate ROWNUM by (a, b) +-- Outer: aggregate by (a) with ORDER BY +SELECT a, SUM(inner_sum) as total_sum, COUNT(*) as group_count +FROM ( + SELECT a, b, SUM(rownum) as inner_sum, COUNT(*) as inner_count + FROM multi_agg_test + GROUP BY a, b + ORDER BY a, b +) sub +GROUP BY a +ORDER BY a; + a | total_sum | group_count +---+-----------+------------- + 1 | 6 | 2 + 2 | 15 | 2 +(2 rows) + +-- Test 2: Three layers of aggregation +SELECT MAX(mid_sum) as max_mid_sum +FROM ( + SELECT a, SUM(inner_sum) as mid_sum + FROM ( + SELECT a, b, SUM(rownum) as inner_sum + FROM multi_agg_test + GROUP BY a, b + ORDER BY a, b + ) layer1 + GROUP BY a + ORDER BY a +) layer2; + max_mid_sum +------------- + 15 +(1 row) + +-- Test 3: Different aggregate functions at each layer with ORDER BY +SELECT a, AVG(inner_max), SUM(inner_min), COUNT(*) +FROM ( + SELECT a, b, MAX(rownum) as inner_max, MIN(rownum) as inner_min + FROM multi_agg_test + GROUP BY a, b + ORDER BY a, b +) sub +GROUP BY a +ORDER BY a; + a | avg | sum | count +---+--------------------+-----+------- + 1 | 2.5000000000000000 | 4 | 2 + 2 | 5.0000000000000000 | 9 | 2 +(2 rows) + +-- Test 4: Nested aggregation with ROWNUM in arithmetic expression +SELECT a, SUM(rownum_doubled) as total_doubled +FROM ( + SELECT a, b, SUM(rownum * 2) as rownum_doubled + FROM multi_agg_test + GROUP BY a, b + ORDER BY a +) sub +GROUP BY a +ORDER BY a DESC; + a | total_doubled +---+--------------- + 2 | 30 + 1 | 12 +(2 rows) + +DROP TABLE multi_agg_test; +-- -- Cleanup -- DROP TABLE rownum_test CASCADE; diff --git a/src/oracle_test/regress/sql/rownum.sql b/src/oracle_test/regress/sql/rownum.sql index a06237d41f7..6edd98eff8e 100644 --- a/src/oracle_test/regress/sql/rownum.sql +++ b/src/oracle_test/regress/sql/rownum.sql @@ -787,6 +787,97 @@ SELECT AVG(max_rn) FROM ( DROP TABLE agg_nest_test; +-- +-- ROWNUM with aggregate functions + GROUP BY + ORDER BY +-- Test that aggregate column order doesn't affect query execution +-- Bug: "Aggref found in non-Agg plan node" when ROWNUM aggregate wasn't last +-- + +CREATE TABLE agg_order_test (a int, b int); +INSERT INTO agg_order_test VALUES (1, 10), (1, 20), (2, 30), (2, 40), (3, 50); + +-- Test 1: SUM(rownum) first, then COUNT(*) with ORDER BY +-- For a=1: rows 1,2 → sum=3, count=2 +-- For a=2: rows 3,4 → sum=7, count=2 +-- For a=3: row 5 → sum=5, count=1 +SELECT a, SUM(rownum), COUNT(*) FROM agg_order_test GROUP BY a ORDER BY a; + +-- Test 2: COUNT(*) first, then SUM(rownum) with ORDER BY (different column order) +SELECT a, COUNT(*), SUM(rownum) FROM agg_order_test GROUP BY a ORDER BY a; + +-- Test 3: Multiple aggregates with ROWNUM in various positions +SELECT a, MIN(rownum), MAX(rownum), AVG(rownum), SUM(rownum), COUNT(*) +FROM agg_order_test GROUP BY a ORDER BY a; + +-- Test 4: ORDER BY aggregate result +SELECT a, SUM(rownum) as s FROM agg_order_test GROUP BY a ORDER BY s; + +-- Test 5: ORDER BY DESC +SELECT a, SUM(rownum), COUNT(*) FROM agg_order_test GROUP BY a ORDER BY a DESC; + +DROP TABLE agg_order_test; + +-- +-- Multi-layer nested aggregation with ROWNUM + GROUP BY + ORDER BY +-- Test multiple levels of aggregation where ROWNUM is used at the innermost level +-- + +CREATE TABLE multi_agg_test (a int, b int, c int); +INSERT INTO multi_agg_test VALUES + (1, 1, 10), (1, 1, 20), (1, 2, 30), + (2, 1, 40), (2, 2, 50), (2, 2, 60); + +-- Test 1: Two layers of aggregation +-- Inner: aggregate ROWNUM by (a, b) +-- Outer: aggregate by (a) with ORDER BY +SELECT a, SUM(inner_sum) as total_sum, COUNT(*) as group_count +FROM ( + SELECT a, b, SUM(rownum) as inner_sum, COUNT(*) as inner_count + FROM multi_agg_test + GROUP BY a, b + ORDER BY a, b +) sub +GROUP BY a +ORDER BY a; + +-- Test 2: Three layers of aggregation +SELECT MAX(mid_sum) as max_mid_sum +FROM ( + SELECT a, SUM(inner_sum) as mid_sum + FROM ( + SELECT a, b, SUM(rownum) as inner_sum + FROM multi_agg_test + GROUP BY a, b + ORDER BY a, b + ) layer1 + GROUP BY a + ORDER BY a +) layer2; + +-- Test 3: Different aggregate functions at each layer with ORDER BY +SELECT a, AVG(inner_max), SUM(inner_min), COUNT(*) +FROM ( + SELECT a, b, MAX(rownum) as inner_max, MIN(rownum) as inner_min + FROM multi_agg_test + GROUP BY a, b + ORDER BY a, b +) sub +GROUP BY a +ORDER BY a; + +-- Test 4: Nested aggregation with ROWNUM in arithmetic expression +SELECT a, SUM(rownum_doubled) as total_doubled +FROM ( + SELECT a, b, SUM(rownum * 2) as rownum_doubled + FROM multi_agg_test + GROUP BY a, b + ORDER BY a +) sub +GROUP BY a +ORDER BY a DESC; + +DROP TABLE multi_agg_test; + -- -- Cleanup -- From d6d8e08b831b338e65359c9be683272bd872a042 Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Thu, 8 Jan 2026 12:40:16 +0000 Subject: [PATCH 13/19] test: add scroll cursor ROWNUM bug regression test Documents bug where FETCH PRIOR/NEXT re-evaluates ROWNUM instead of using materialized values from original query. Ref: https://github.com/IvorySQL/IvorySQL/pull/1000#issuecomment-3717658753 --- src/oracle_test/regress/expected/rownum.out | 70 +++++++++++++++++++++ src/oracle_test/regress/sql/rownum.sql | 44 +++++++++++++ 2 files changed, 114 insertions(+) diff --git a/src/oracle_test/regress/expected/rownum.out b/src/oracle_test/regress/expected/rownum.out index 4258cce31ae..2aa6d8247a3 100644 --- a/src/oracle_test/regress/expected/rownum.out +++ b/src/oracle_test/regress/expected/rownum.out @@ -1467,6 +1467,76 @@ ORDER BY a DESC; DROP TABLE multi_agg_test; -- +-- SCROLL CURSOR with ROWNUM +-- Bug: FETCH PRIOR/NEXT re-evaluates ROWNUM instead of using materialized values +-- https://github.com/IvorySQL/IvorySQL/pull/1000#issuecomment-3717658753 +-- +CREATE TABLE cursor_rownum_test (c1 serial, c2 int); +INSERT INTO cursor_rownum_test (c2) SELECT generate_series(1, 20); +-- Test scroll cursor with ROWNUM in subquery +BEGIN; +-- Declare a scroll cursor with ROWNUM in subquery +DECLARE cursor_rn SCROLL CURSOR FOR +SELECT * +FROM (SELECT *, rownum rn FROM cursor_rownum_test WHERE rownum <= 10) AS foo +WHERE rn > 3 LIMIT 5; +-- Fetch all rows - should get rows with rn 4,5,6,7,8 +FETCH ALL IN cursor_rn; + c1 | c2 | rn +----+----+---- + 4 | 4 | 4 + 5 | 5 | 5 + 6 | 6 | 6 + 7 | 7 | 7 + 8 | 8 | 8 +(5 rows) + +-- FETCH FIRST should return row with rn=4 +FETCH FIRST IN cursor_rn; + c1 | c2 | rn +----+----+---- + 4 | 4 | 4 +(1 row) + +-- FETCH LAST should return row with rn=8 +FETCH LAST IN cursor_rn; + c1 | c2 | rn +----+----+---- + 8 | 8 | 8 +(1 row) + +-- FETCH PRIOR from LAST should return row with rn=7 (not a new incremented value) +FETCH PRIOR IN cursor_rn; + c1 | c2 | rn +----+----+---- + 7 | 7 | 9 +(1 row) + +-- FETCH NEXT should return row with rn=8 again (not a new incremented value) +FETCH NEXT IN cursor_rn; + c1 | c2 | rn +----+----+---- + 8 | 8 | 10 +(1 row) + +-- FETCH ABSOLUTE 2 should return row with rn=5 +FETCH ABSOLUTE 2 IN cursor_rn; + c1 | c2 | rn +----+----+---- + 5 | 5 | 5 +(1 row) + +-- FETCH RELATIVE -1 should return row with rn=4 +FETCH RELATIVE -1 IN cursor_rn; + c1 | c2 | rn +----+----+---- + 4 | 4 | 6 +(1 row) + +CLOSE cursor_rn; +COMMIT; +DROP TABLE cursor_rownum_test; +-- -- Cleanup -- DROP TABLE rownum_test CASCADE; diff --git a/src/oracle_test/regress/sql/rownum.sql b/src/oracle_test/regress/sql/rownum.sql index 6edd98eff8e..74ef17a991e 100644 --- a/src/oracle_test/regress/sql/rownum.sql +++ b/src/oracle_test/regress/sql/rownum.sql @@ -878,6 +878,50 @@ ORDER BY a DESC; DROP TABLE multi_agg_test; +-- +-- SCROLL CURSOR with ROWNUM +-- Bug: FETCH PRIOR/NEXT re-evaluates ROWNUM instead of using materialized values +-- https://github.com/IvorySQL/IvorySQL/pull/1000#issuecomment-3717658753 +-- + +CREATE TABLE cursor_rownum_test (c1 serial, c2 int); +INSERT INTO cursor_rownum_test (c2) SELECT generate_series(1, 20); + +-- Test scroll cursor with ROWNUM in subquery +BEGIN; + +-- Declare a scroll cursor with ROWNUM in subquery +DECLARE cursor_rn SCROLL CURSOR FOR +SELECT * +FROM (SELECT *, rownum rn FROM cursor_rownum_test WHERE rownum <= 10) AS foo +WHERE rn > 3 LIMIT 5; + +-- Fetch all rows - should get rows with rn 4,5,6,7,8 +FETCH ALL IN cursor_rn; + +-- FETCH FIRST should return row with rn=4 +FETCH FIRST IN cursor_rn; + +-- FETCH LAST should return row with rn=8 +FETCH LAST IN cursor_rn; + +-- FETCH PRIOR from LAST should return row with rn=7 (not a new incremented value) +FETCH PRIOR IN cursor_rn; + +-- FETCH NEXT should return row with rn=8 again (not a new incremented value) +FETCH NEXT IN cursor_rn; + +-- FETCH ABSOLUTE 2 should return row with rn=5 +FETCH ABSOLUTE 2 IN cursor_rn; + +-- FETCH RELATIVE -1 should return row with rn=4 +FETCH RELATIVE -1 IN cursor_rn; + +CLOSE cursor_rn; +COMMIT; + +DROP TABLE cursor_rownum_test; + -- -- Cleanup -- From 5c54046cb6dcf05680e3d4e5c10e4a1a0d2f8fdc Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Thu, 8 Jan 2026 13:24:23 +0000 Subject: [PATCH 14/19] fix: materialize scroll cursor results when ROWNUM present For scroll cursors containing ROWNUM expressions, materialize all results into a tuplestore on first execution. This ensures FETCH PRIOR/NEXT/RELATIVE return the same ROWNUM values computed during initial scan, rather than re-evaluating (which caused incorrect incrementing values). Added plan_contains_rownum() to detect ROWNUM in plan trees, handling SubqueryScan, Append, and MergeAppend nodes. Fixes: https://github.com/IvorySQL/IvorySQL/pull/1000#issuecomment-3717658753 --- src/backend/tcop/pquery.c | 141 ++++++++++++++++++++ src/oracle_test/regress/expected/rownum.out | 6 +- 2 files changed, 144 insertions(+), 3 deletions(-) diff --git a/src/backend/tcop/pquery.c b/src/backend/tcop/pquery.c index 24aadea11be..08df204841d 100644 --- a/src/backend/tcop/pquery.c +++ b/src/backend/tcop/pquery.c @@ -22,6 +22,8 @@ #include "executor/executor.h" #include "executor/tstoreReceiver.h" #include "miscadmin.h" +#include "nodes/nodeFuncs.h" +#include "nodes/plannodes.h" #include "pg_trace.h" #include "tcop/pquery.h" #include "tcop/utility.h" @@ -60,6 +62,130 @@ static uint64 DoPortalRunFetch(Portal portal, DestReceiver *dest); static void DoPortalRewind(Portal portal); static TupleDesc CreateTupleDescFromParams(ParamListInfo params); +static bool plan_contains_rownum_walker(Node *node, void *context); +static bool plan_contains_rownum(Plan *plan); +static void FillPortalStoreForSelect(Portal portal); + +/* + * Helper function to check if an expression contains ROWNUM + */ +static bool +plan_contains_rownum_walker(Node *node, void *context) +{ + if (node == NULL) + return false; + + if (IsA(node, RownumExpr)) + return true; + + return expression_tree_walker(node, plan_contains_rownum_walker, context); +} + +/* + * Check if a plan tree contains ROWNUM expressions in targetlists. + * This is used to determine if scroll cursor results need materialization. + */ +static bool +plan_contains_rownum(Plan *plan) +{ + ListCell *lc; + + if (plan == NULL) + return false; + + /* Check the plan's targetlist */ + foreach(lc, plan->targetlist) + { + TargetEntry *tle = lfirst_node(TargetEntry, lc); + + if (plan_contains_rownum_walker((Node *) tle->expr, NULL)) + return true; + } + + /* Recursively check standard child plans */ + if (plan->lefttree && plan_contains_rownum(plan->lefttree)) + return true; + if (plan->righttree && plan_contains_rownum(plan->righttree)) + return true; + + /* Handle special plan node types with additional child plans */ + switch (nodeTag(plan)) + { + case T_SubqueryScan: + { + SubqueryScan *splan = (SubqueryScan *) plan; + if (plan_contains_rownum(splan->subplan)) + return true; + } + break; + + case T_Append: + { + Append *aplan = (Append *) plan; + foreach(lc, aplan->appendplans) + { + if (plan_contains_rownum((Plan *) lfirst(lc))) + return true; + } + } + break; + + case T_MergeAppend: + { + MergeAppend *mplan = (MergeAppend *) plan; + foreach(lc, mplan->mergeplans) + { + if (plan_contains_rownum((Plan *) lfirst(lc))) + return true; + } + } + break; + + default: + /* Most plan nodes only have lefttree/righttree children */ + break; + } + + return false; +} + +/* + * FillPortalStoreForSelect + * Run a PORTAL_ONE_SELECT query and store results in portal's holdStore. + * + * This is used for scroll cursors that contain ROWNUM expressions. + * We need to materialize results so that FETCH PRIOR/NEXT don't re-evaluate + * ROWNUM values. + */ +static void +FillPortalStoreForSelect(Portal portal) +{ + QueryDesc *queryDesc = portal->queryDesc; + DestReceiver *treceiver; + + Assert(queryDesc != NULL); + Assert(portal->holdStore == NULL); + + PortalCreateHoldStore(portal); + treceiver = CreateDestReceiver(DestTuplestore); + SetTuplestoreDestReceiverParams(treceiver, + portal->holdStore, + portal->holdContext, + false, + NULL, + NULL); + + /* Run the query to completion, storing results in tuplestore */ + PushActiveSnapshot(queryDesc->snapshot); + queryDesc->dest = treceiver; + ExecutorRun(queryDesc, ForwardScanDirection, 0); + PopActiveSnapshot(); + + treceiver->rDestroy(treceiver); + + /* Reset the tuplestore to start */ + tuplestore_rescan(portal->holdStore); +} /* * CreateQueryDesc @@ -892,6 +1018,21 @@ PortalRunSelect(Portal portal, /* Caller messed up if we have neither a ready query nor held data. */ Assert(queryDesc || portal->holdStore); + /* + * For scroll cursors with ROWNUM in the plan, we need to materialize + * all results on first execution. This ensures that FETCH PRIOR/NEXT + * return the same ROWNUM values that were computed during the initial + * forward scan, rather than re-evaluating ROWNUM (which would give + * incorrect incrementing values). + */ + if (queryDesc != NULL && + portal->holdStore == NULL && + (portal->cursorOptions & CURSOR_OPT_SCROLL) && + plan_contains_rownum(queryDesc->plannedstmt->planTree)) + { + FillPortalStoreForSelect(portal); + } + /* * Force the queryDesc destination to the right thing. This supports * MOVE, for example, which will pass in dest = DestNone. This is okay to diff --git a/src/oracle_test/regress/expected/rownum.out b/src/oracle_test/regress/expected/rownum.out index 2aa6d8247a3..71afe0d21e0 100644 --- a/src/oracle_test/regress/expected/rownum.out +++ b/src/oracle_test/regress/expected/rownum.out @@ -1509,14 +1509,14 @@ FETCH LAST IN cursor_rn; FETCH PRIOR IN cursor_rn; c1 | c2 | rn ----+----+---- - 7 | 7 | 9 + 7 | 7 | 7 (1 row) -- FETCH NEXT should return row with rn=8 again (not a new incremented value) FETCH NEXT IN cursor_rn; c1 | c2 | rn ----+----+---- - 8 | 8 | 10 + 8 | 8 | 8 (1 row) -- FETCH ABSOLUTE 2 should return row with rn=5 @@ -1530,7 +1530,7 @@ FETCH ABSOLUTE 2 IN cursor_rn; FETCH RELATIVE -1 IN cursor_rn; c1 | c2 | rn ----+----+---- - 4 | 4 | 6 + 4 | 4 | 4 (1 row) CLOSE cursor_rn; From fc279e07a19eb2cc80c8eaac78b8ccb898956f76 Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Thu, 8 Jan 2026 13:49:44 +0000 Subject: [PATCH 15/19] test: add deeply nested ROWNUM scroll cursor test Tests that FETCH PRIOR/NEXT preserve both outer_rn and inner_rn values when using scroll cursors with multiple ROWNUM nesting levels. --- src/oracle_test/regress/expected/rownum.out | 52 +++++++++++++++++++++ src/oracle_test/regress/sql/rownum.sql | 32 +++++++++++++ 2 files changed, 84 insertions(+) diff --git a/src/oracle_test/regress/expected/rownum.out b/src/oracle_test/regress/expected/rownum.out index 71afe0d21e0..d7d885ab6d9 100644 --- a/src/oracle_test/regress/expected/rownum.out +++ b/src/oracle_test/regress/expected/rownum.out @@ -1535,6 +1535,58 @@ FETCH RELATIVE -1 IN cursor_rn; CLOSE cursor_rn; COMMIT; +-- Test scroll cursor with deeply nested ROWNUM (multiple levels) +BEGIN; +DECLARE cursor_nested SCROLL CURSOR FOR +SELECT * FROM ( + SELECT rownum as outer_rn, * FROM ( + SELECT rownum as inner_rn, c1, c2 + FROM cursor_rownum_test + WHERE rownum <= 8 + ) sub1 + WHERE rownum <= 6 +) sub2 +WHERE outer_rn <= 4; +-- Fetch all rows +FETCH ALL IN cursor_nested; + outer_rn | inner_rn | c1 | c2 +----------+----------+----+---- + 1 | 1 | 1 | 1 + 2 | 2 | 2 | 2 + 3 | 3 | 3 | 3 + 4 | 4 | 4 | 4 +(4 rows) + +-- FETCH LAST +FETCH LAST IN cursor_nested; + outer_rn | inner_rn | c1 | c2 +----------+----------+----+---- + 4 | 4 | 4 | 4 +(1 row) + +-- FETCH PRIOR - should preserve both outer_rn and inner_rn values +FETCH PRIOR IN cursor_nested; + outer_rn | inner_rn | c1 | c2 +----------+----------+----+---- + 3 | 3 | 3 | 3 +(1 row) + +-- FETCH FIRST +FETCH FIRST IN cursor_nested; + outer_rn | inner_rn | c1 | c2 +----------+----------+----+---- + 1 | 1 | 1 | 1 +(1 row) + +-- FETCH NEXT - should preserve both outer_rn and inner_rn values +FETCH NEXT IN cursor_nested; + outer_rn | inner_rn | c1 | c2 +----------+----------+----+---- + 2 | 2 | 2 | 2 +(1 row) + +CLOSE cursor_nested; +COMMIT; DROP TABLE cursor_rownum_test; -- -- Cleanup diff --git a/src/oracle_test/regress/sql/rownum.sql b/src/oracle_test/regress/sql/rownum.sql index 74ef17a991e..a8bea43cf35 100644 --- a/src/oracle_test/regress/sql/rownum.sql +++ b/src/oracle_test/regress/sql/rownum.sql @@ -920,6 +920,38 @@ FETCH RELATIVE -1 IN cursor_rn; CLOSE cursor_rn; COMMIT; +-- Test scroll cursor with deeply nested ROWNUM (multiple levels) +BEGIN; + +DECLARE cursor_nested SCROLL CURSOR FOR +SELECT * FROM ( + SELECT rownum as outer_rn, * FROM ( + SELECT rownum as inner_rn, c1, c2 + FROM cursor_rownum_test + WHERE rownum <= 8 + ) sub1 + WHERE rownum <= 6 +) sub2 +WHERE outer_rn <= 4; + +-- Fetch all rows +FETCH ALL IN cursor_nested; + +-- FETCH LAST +FETCH LAST IN cursor_nested; + +-- FETCH PRIOR - should preserve both outer_rn and inner_rn values +FETCH PRIOR IN cursor_nested; + +-- FETCH FIRST +FETCH FIRST IN cursor_nested; + +-- FETCH NEXT - should preserve both outer_rn and inner_rn values +FETCH NEXT IN cursor_nested; + +CLOSE cursor_nested; +COMMIT; + DROP TABLE cursor_rownum_test; -- From ede79067b8c243a4c5fd9cfc3676992eced4b40a Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Thu, 8 Jan 2026 14:23:13 +0000 Subject: [PATCH 16/19] test: add ROWNUM keyword behavior regression tests Documents current IvorySQL behavior vs Oracle for ROWNUM: 1. ROWNUM as column/table alias (rownum.sql): - Oracle: Does NOT allow ROWNUM as alias (ERROR) - IvorySQL: Allows it (differs from Oracle) 2. ROWNUM as PL/iSQL parameter/variable (ora_plisql.sql): - Oracle: Allows, treats as regular identifier - IvorySQL: Creates function but treats 'rownum' as pseudocolumn Ref: https://github.com/IvorySQL/IvorySQL/pull/1000#issuecomment-3717690863 --- .../regress/expected/ora_plisql.out | 44 ++++++++++++++++++ src/oracle_test/regress/expected/rownum.out | 41 +++++++++++++++++ src/oracle_test/regress/sql/ora_plisql.sql | 45 +++++++++++++++++++ src/oracle_test/regress/sql/rownum.sql | 29 ++++++++++++ 4 files changed, 159 insertions(+) diff --git a/src/oracle_test/regress/expected/ora_plisql.out b/src/oracle_test/regress/expected/ora_plisql.out index 5fe0dd7d614..56c6b12ed51 100755 --- a/src/oracle_test/regress/expected/ora_plisql.out +++ b/src/oracle_test/regress/expected/ora_plisql.out @@ -1825,3 +1825,47 @@ drop procedure ff_proc; drop procedure f_proc; drop function f_test; drop function ff_test; +-- +-- ROWNUM as function parameter and variable name +-- Oracle allows ROWNUM as parameter/variable name in PL/SQL. +-- https://github.com/IvorySQL/IvorySQL/pull/1000#issuecomment-3717690863 +-- +-- Current IvorySQL behavior: Fails because ROWNUM is treated as keyword +-- TODO: These should work to match Oracle behavior +-- +-- Test 1: Function with 'rownum' as parameter name +-- Oracle: Creates successfully +-- IvorySQL: Currently fails with syntax error +CREATE OR REPLACE FUNCTION test_rownum_param(rownum IN VARCHAR2) RETURN INTEGER IS +BEGIN + RAISE NOTICE 'Parameter value: %', rownum; + RETURN 23; +END; +/ +-- Test 2: Call the function with variable named 'rownum' +-- Oracle: Runs successfully +-- IvorySQL: Currently fails +DECLARE + rownum VARCHAR2(256) := 'hello'; + ret INTEGER; +BEGIN + ret := test_rownum_param(rownum); + RAISE NOTICE 'Return value: %', ret; +END; +/ +NOTICE: Parameter value: 1 +NOTICE: Return value: 23 +-- Test 3: Named parameter call using 'rownum =>' +-- Oracle: Runs successfully +-- IvorySQL: Currently fails +DECLARE + ret INTEGER; +BEGIN + ret := test_rownum_param(rownum => 'world'); + RAISE NOTICE 'Named param return: %', ret; +END; +/ +NOTICE: Parameter value: 1 +NOTICE: Named param return: 23 +-- Cleanup (may fail if function wasn't created) +DROP FUNCTION IF EXISTS test_rownum_param; diff --git a/src/oracle_test/regress/expected/rownum.out b/src/oracle_test/regress/expected/rownum.out index d7d885ab6d9..9fc4fdd16f4 100644 --- a/src/oracle_test/regress/expected/rownum.out +++ b/src/oracle_test/regress/expected/rownum.out @@ -1589,6 +1589,47 @@ CLOSE cursor_nested; COMMIT; DROP TABLE cursor_rownum_test; -- +-- ROWNUM as column/table alias +-- Oracle does NOT allow ROWNUM as column alias (with or without AS) or table alias. +-- https://github.com/IvorySQL/IvorySQL/pull/1000#issuecomment-3717690863 +-- +-- Current IvorySQL behavior: Allows ROWNUM as alias (differs from Oracle) +-- TODO: These should produce errors to match Oracle behavior +-- +CREATE TABLE alias_test (id int, name varchar(10), job varchar(10)); +INSERT INTO alias_test VALUES (1, 'SMITH', 'CLERK'), (2, 'ALLEN', 'SALESMAN'); +-- Test 1: ROWNUM as column alias without AS +-- Oracle: ERROR ORA-00923: FROM keyword not found where expected +-- IvorySQL: Currently allows this (incorrectly treats 'rownum' as alias for 'job') +SELECT id, name, job rownum FROM alias_test; + id | name | rownum +----+-------+---------- + 1 | SMITH | CLERK + 2 | ALLEN | SALESMAN +(2 rows) + +-- Test 2: ROWNUM as column alias with AS +-- Oracle: ERROR ORA-00923: FROM keyword not found where expected +-- IvorySQL: Currently allows this +SELECT id, name, job AS rownum FROM alias_test; + id | name | rownum +----+-------+---------- + 1 | SMITH | CLERK + 2 | ALLEN | SALESMAN +(2 rows) + +-- Test 3: ROWNUM as table alias +-- Oracle: ERROR ORA-00923: FROM keyword not found where expected +-- IvorySQL: Currently allows this +SELECT rownum.id FROM alias_test rownum; + id +---- + 1 + 2 +(2 rows) + +DROP TABLE alias_test; +-- -- Cleanup -- DROP TABLE rownum_test CASCADE; diff --git a/src/oracle_test/regress/sql/ora_plisql.sql b/src/oracle_test/regress/sql/ora_plisql.sql index 6dbbe7b2a08..b39f021171a 100755 --- a/src/oracle_test/regress/sql/ora_plisql.sql +++ b/src/oracle_test/regress/sql/ora_plisql.sql @@ -1457,3 +1457,48 @@ drop procedure f_proc; drop function f_test; drop function ff_test; +-- +-- ROWNUM as function parameter and variable name +-- Oracle allows ROWNUM as parameter/variable name in PL/SQL. +-- https://github.com/IvorySQL/IvorySQL/pull/1000#issuecomment-3717690863 +-- +-- Current IvorySQL behavior: Fails because ROWNUM is treated as keyword +-- TODO: These should work to match Oracle behavior +-- + +-- Test 1: Function with 'rownum' as parameter name +-- Oracle: Creates successfully +-- IvorySQL: Currently fails with syntax error +CREATE OR REPLACE FUNCTION test_rownum_param(rownum IN VARCHAR2) RETURN INTEGER IS +BEGIN + RAISE NOTICE 'Parameter value: %', rownum; + RETURN 23; +END; +/ + +-- Test 2: Call the function with variable named 'rownum' +-- Oracle: Runs successfully +-- IvorySQL: Currently fails +DECLARE + rownum VARCHAR2(256) := 'hello'; + ret INTEGER; +BEGIN + ret := test_rownum_param(rownum); + RAISE NOTICE 'Return value: %', ret; +END; +/ + +-- Test 3: Named parameter call using 'rownum =>' +-- Oracle: Runs successfully +-- IvorySQL: Currently fails +DECLARE + ret INTEGER; +BEGIN + ret := test_rownum_param(rownum => 'world'); + RAISE NOTICE 'Named param return: %', ret; +END; +/ + +-- Cleanup (may fail if function wasn't created) +DROP FUNCTION IF EXISTS test_rownum_param; + diff --git a/src/oracle_test/regress/sql/rownum.sql b/src/oracle_test/regress/sql/rownum.sql index a8bea43cf35..12f7fbd7363 100644 --- a/src/oracle_test/regress/sql/rownum.sql +++ b/src/oracle_test/regress/sql/rownum.sql @@ -954,6 +954,35 @@ COMMIT; DROP TABLE cursor_rownum_test; +-- +-- ROWNUM as column/table alias +-- Oracle does NOT allow ROWNUM as column alias (with or without AS) or table alias. +-- https://github.com/IvorySQL/IvorySQL/pull/1000#issuecomment-3717690863 +-- +-- Current IvorySQL behavior: Allows ROWNUM as alias (differs from Oracle) +-- TODO: These should produce errors to match Oracle behavior +-- + +CREATE TABLE alias_test (id int, name varchar(10), job varchar(10)); +INSERT INTO alias_test VALUES (1, 'SMITH', 'CLERK'), (2, 'ALLEN', 'SALESMAN'); + +-- Test 1: ROWNUM as column alias without AS +-- Oracle: ERROR ORA-00923: FROM keyword not found where expected +-- IvorySQL: Currently allows this (incorrectly treats 'rownum' as alias for 'job') +SELECT id, name, job rownum FROM alias_test; + +-- Test 2: ROWNUM as column alias with AS +-- Oracle: ERROR ORA-00923: FROM keyword not found where expected +-- IvorySQL: Currently allows this +SELECT id, name, job AS rownum FROM alias_test; + +-- Test 3: ROWNUM as table alias +-- Oracle: ERROR ORA-00923: FROM keyword not found where expected +-- IvorySQL: Currently allows this +SELECT rownum.id FROM alias_test rownum; + +DROP TABLE alias_test; + -- -- Cleanup -- From 42cb0d39c84514d469526568210fd9cf1316745f Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Thu, 8 Jan 2026 14:55:45 +0000 Subject: [PATCH 17/19] fix: reject ROWNUM/ROWID as column and table aliases MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit Add semantic validation to reject ROWNUM and ROWID as aliases in Oracle compatibility mode, matching Oracle's behavior: - Column alias: SELECT 1 rownum → ERROR - Column alias with AS: SELECT 1 AS rownum → ERROR - Table alias: SELECT * FROM t rownum → ERROR - Subquery alias: SELECT * FROM (SELECT 1) rownum → ERROR Validation added in: - parse_target.c:transformTargetEntry() for column aliases - parse_relation.c:addRangeTableEntry() for table aliases - parse_relation.c:addRangeTableEntryForSubquery() for subquery aliases --- src/backend/parser/parse_relation.c | 36 +++++++++++++++++++++ src/backend/parser/parse_target.c | 21 ++++++++++++ src/oracle_test/regress/expected/rownum.out | 33 ++++++------------- src/oracle_test/regress/sql/rownum.sql | 6 ---- 4 files changed, 66 insertions(+), 30 deletions(-) diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c index ea60e2a7ae1..28578a21a29 100644 --- a/src/backend/parser/parse_relation.c +++ b/src/backend/parser/parse_relation.c @@ -1513,6 +1513,25 @@ addRangeTableEntry(ParseState *pstate, Assert(pstate != NULL); + /* + * In Oracle compatibility mode, reject ROWNUM and ROWID as explicit + * table aliases. Oracle treats these as reserved pseudocolumns that + * cannot be used as table aliases. + */ + if (compatible_db == ORA_PARSER && alias != NULL) + { + if (pg_strcasecmp(alias->aliasname, "rownum") == 0) + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("ROWNUM cannot be used as a table alias"), + parser_errposition(pstate, relation->location))); + if (pg_strcasecmp(alias->aliasname, "rowid") == 0) + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("ROWID cannot be used as a table alias"), + parser_errposition(pstate, relation->location))); + } + rte->rtekind = RTE_RELATION; rte->alias = alias; @@ -1719,6 +1738,23 @@ addRangeTableEntryForSubquery(ParseState *pstate, Assert(pstate != NULL); + /* + * In Oracle compatibility mode, reject ROWNUM and ROWID as explicit + * subquery aliases. Oracle treats these as reserved pseudocolumns that + * cannot be used as table aliases. + */ + if (compatible_db == ORA_PARSER && alias != NULL) + { + if (pg_strcasecmp(alias->aliasname, "rownum") == 0) + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("ROWNUM cannot be used as a table alias"))); + if (pg_strcasecmp(alias->aliasname, "rowid") == 0) + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("ROWID cannot be used as a table alias"))); + } + rte->rtekind = RTE_SUBQUERY; rte->subquery = subquery; rte->alias = alias; diff --git a/src/backend/parser/parse_target.c b/src/backend/parser/parse_target.c index 26c10270fdb..05988f3dfbe 100644 --- a/src/backend/parser/parse_target.c +++ b/src/backend/parser/parse_target.c @@ -29,7 +29,9 @@ #include "parser/parse_type.h" #include "parser/parsetree.h" #include "utils/builtins.h" +#include "utils/guc.h" #include "utils/lsyscache.h" +#include "utils/ora_compatible.h" #include "utils/rel.h" static void markTargetListOrigin(ParseState *pstate, TargetEntry *tle, @@ -94,6 +96,25 @@ transformTargetEntry(ParseState *pstate, expr = transformExpr(pstate, node, exprKind); } + /* + * In Oracle compatibility mode, reject ROWNUM and ROWID as explicit + * column aliases. Oracle treats these as reserved pseudocolumns that + * cannot be used as aliases. + */ + if (compatible_db == ORA_PARSER && colname != NULL) + { + if (pg_strcasecmp(colname, "rownum") == 0) + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("ROWNUM cannot be used as a column alias"), + parser_errposition(pstate, exprLocation(node)))); + if (pg_strcasecmp(colname, "rowid") == 0) + ereport(ERROR, + (errcode(ERRCODE_SYNTAX_ERROR), + errmsg("ROWID cannot be used as a column alias"), + parser_errposition(pstate, exprLocation(node)))); + } + if (colname == NULL && !resjunk) { /* diff --git a/src/oracle_test/regress/expected/rownum.out b/src/oracle_test/regress/expected/rownum.out index 9fc4fdd16f4..bc635e62067 100644 --- a/src/oracle_test/regress/expected/rownum.out +++ b/src/oracle_test/regress/expected/rownum.out @@ -1593,41 +1593,26 @@ DROP TABLE cursor_rownum_test; -- Oracle does NOT allow ROWNUM as column alias (with or without AS) or table alias. -- https://github.com/IvorySQL/IvorySQL/pull/1000#issuecomment-3717690863 -- --- Current IvorySQL behavior: Allows ROWNUM as alias (differs from Oracle) --- TODO: These should produce errors to match Oracle behavior --- CREATE TABLE alias_test (id int, name varchar(10), job varchar(10)); INSERT INTO alias_test VALUES (1, 'SMITH', 'CLERK'), (2, 'ALLEN', 'SALESMAN'); -- Test 1: ROWNUM as column alias without AS -- Oracle: ERROR ORA-00923: FROM keyword not found where expected --- IvorySQL: Currently allows this (incorrectly treats 'rownum' as alias for 'job') SELECT id, name, job rownum FROM alias_test; - id | name | rownum -----+-------+---------- - 1 | SMITH | CLERK - 2 | ALLEN | SALESMAN -(2 rows) - +ERROR: ROWNUM cannot be used as a column alias +LINE 1: SELECT id, name, job rownum FROM alias_test; + ^ -- Test 2: ROWNUM as column alias with AS -- Oracle: ERROR ORA-00923: FROM keyword not found where expected --- IvorySQL: Currently allows this SELECT id, name, job AS rownum FROM alias_test; - id | name | rownum -----+-------+---------- - 1 | SMITH | CLERK - 2 | ALLEN | SALESMAN -(2 rows) - +ERROR: ROWNUM cannot be used as a column alias +LINE 1: SELECT id, name, job AS rownum FROM alias_test; + ^ -- Test 3: ROWNUM as table alias -- Oracle: ERROR ORA-00923: FROM keyword not found where expected --- IvorySQL: Currently allows this SELECT rownum.id FROM alias_test rownum; - id ----- - 1 - 2 -(2 rows) - +ERROR: ROWNUM cannot be used as a table alias +LINE 1: SELECT rownum.id FROM alias_test rownum; + ^ DROP TABLE alias_test; -- -- Cleanup diff --git a/src/oracle_test/regress/sql/rownum.sql b/src/oracle_test/regress/sql/rownum.sql index 12f7fbd7363..37371d38695 100644 --- a/src/oracle_test/regress/sql/rownum.sql +++ b/src/oracle_test/regress/sql/rownum.sql @@ -959,26 +959,20 @@ DROP TABLE cursor_rownum_test; -- Oracle does NOT allow ROWNUM as column alias (with or without AS) or table alias. -- https://github.com/IvorySQL/IvorySQL/pull/1000#issuecomment-3717690863 -- --- Current IvorySQL behavior: Allows ROWNUM as alias (differs from Oracle) --- TODO: These should produce errors to match Oracle behavior --- CREATE TABLE alias_test (id int, name varchar(10), job varchar(10)); INSERT INTO alias_test VALUES (1, 'SMITH', 'CLERK'), (2, 'ALLEN', 'SALESMAN'); -- Test 1: ROWNUM as column alias without AS -- Oracle: ERROR ORA-00923: FROM keyword not found where expected --- IvorySQL: Currently allows this (incorrectly treats 'rownum' as alias for 'job') SELECT id, name, job rownum FROM alias_test; -- Test 2: ROWNUM as column alias with AS -- Oracle: ERROR ORA-00923: FROM keyword not found where expected --- IvorySQL: Currently allows this SELECT id, name, job AS rownum FROM alias_test; -- Test 3: ROWNUM as table alias -- Oracle: ERROR ORA-00923: FROM keyword not found where expected --- IvorySQL: Currently allows this SELECT rownum.id FROM alias_test rownum; DROP TABLE alias_test; From 61d2053e0fe6f87c186910cc2a96776b77e7bea8 Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Thu, 8 Jan 2026 15:04:28 +0000 Subject: [PATCH 18/19] fix: allow ROWNUM/ROWID as PL/iSQL variable names In PL/iSQL's pre-columnref hook, check if ROWNUM or ROWID identifiers resolve to declared variables. This prevents the SQL parser from converting them to pseudocolumn references, matching Oracle behavior where these can be used as variable/parameter names in PL/SQL. The fix adds special handling in plisql_pre_column_ref() to check ROWNUM/ROWID names even when resolve_option is not PLISQL_RESOLVE_VARIABLE, since the SQL parser would otherwise intercept them first. --- .../regress/expected/ora_plisql.out | 10 ++---- src/oracle_test/regress/sql/ora_plisql.sql | 6 ---- src/pl/plisql/src/pl_comp.c | 31 +++++++++++++++++-- 3 files changed, 31 insertions(+), 16 deletions(-) diff --git a/src/oracle_test/regress/expected/ora_plisql.out b/src/oracle_test/regress/expected/ora_plisql.out index 56c6b12ed51..33b01d1c6dc 100755 --- a/src/oracle_test/regress/expected/ora_plisql.out +++ b/src/oracle_test/regress/expected/ora_plisql.out @@ -1830,12 +1830,8 @@ drop function ff_test; -- Oracle allows ROWNUM as parameter/variable name in PL/SQL. -- https://github.com/IvorySQL/IvorySQL/pull/1000#issuecomment-3717690863 -- --- Current IvorySQL behavior: Fails because ROWNUM is treated as keyword --- TODO: These should work to match Oracle behavior --- -- Test 1: Function with 'rownum' as parameter name -- Oracle: Creates successfully --- IvorySQL: Currently fails with syntax error CREATE OR REPLACE FUNCTION test_rownum_param(rownum IN VARCHAR2) RETURN INTEGER IS BEGIN RAISE NOTICE 'Parameter value: %', rownum; @@ -1844,7 +1840,6 @@ END; / -- Test 2: Call the function with variable named 'rownum' -- Oracle: Runs successfully --- IvorySQL: Currently fails DECLARE rownum VARCHAR2(256) := 'hello'; ret INTEGER; @@ -1853,11 +1848,10 @@ BEGIN RAISE NOTICE 'Return value: %', ret; END; / -NOTICE: Parameter value: 1 +NOTICE: Parameter value: hello NOTICE: Return value: 23 -- Test 3: Named parameter call using 'rownum =>' -- Oracle: Runs successfully --- IvorySQL: Currently fails DECLARE ret INTEGER; BEGIN @@ -1865,7 +1859,7 @@ BEGIN RAISE NOTICE 'Named param return: %', ret; END; / -NOTICE: Parameter value: 1 +NOTICE: Parameter value: world NOTICE: Named param return: 23 -- Cleanup (may fail if function wasn't created) DROP FUNCTION IF EXISTS test_rownum_param; diff --git a/src/oracle_test/regress/sql/ora_plisql.sql b/src/oracle_test/regress/sql/ora_plisql.sql index b39f021171a..ced4cccf0c8 100755 --- a/src/oracle_test/regress/sql/ora_plisql.sql +++ b/src/oracle_test/regress/sql/ora_plisql.sql @@ -1462,13 +1462,9 @@ drop function ff_test; -- Oracle allows ROWNUM as parameter/variable name in PL/SQL. -- https://github.com/IvorySQL/IvorySQL/pull/1000#issuecomment-3717690863 -- --- Current IvorySQL behavior: Fails because ROWNUM is treated as keyword --- TODO: These should work to match Oracle behavior --- -- Test 1: Function with 'rownum' as parameter name -- Oracle: Creates successfully --- IvorySQL: Currently fails with syntax error CREATE OR REPLACE FUNCTION test_rownum_param(rownum IN VARCHAR2) RETURN INTEGER IS BEGIN RAISE NOTICE 'Parameter value: %', rownum; @@ -1478,7 +1474,6 @@ END; -- Test 2: Call the function with variable named 'rownum' -- Oracle: Runs successfully --- IvorySQL: Currently fails DECLARE rownum VARCHAR2(256) := 'hello'; ret INTEGER; @@ -1490,7 +1485,6 @@ END; -- Test 3: Named parameter call using 'rownum =>' -- Oracle: Runs successfully --- IvorySQL: Currently fails DECLARE ret INTEGER; BEGIN diff --git a/src/pl/plisql/src/pl_comp.c b/src/pl/plisql/src/pl_comp.c index 7c4347294ac..5c3ba3941c2 100644 --- a/src/pl/plisql/src/pl_comp.c +++ b/src/pl/plisql/src/pl_comp.c @@ -34,6 +34,7 @@ #include "utils/fmgroids.h" #include "utils/guc.h" #include "utils/lsyscache.h" +#include "utils/ora_compatible.h" #include "utils/memutils.h" #include "utils/regproc.h" #include "utils/syscache.h" @@ -1610,8 +1611,34 @@ plisql_pre_column_ref(ParseState *pstate, ColumnRef *cref) if (expr->func->resolve_option == PLISQL_RESOLVE_VARIABLE) return resolve_column_ref(pstate, expr, cref, false); - else - return NULL; + + /* + * Even when resolve_option is not PLISQL_RESOLVE_VARIABLE, we need to + * check if the identifier is ROWNUM or ROWID and exists as a PL/iSQL + * variable. This is necessary because the SQL parser would otherwise + * convert these to pseudocolumn references before the post-columnref + * hook has a chance to resolve them as variables. + * + * This matches Oracle behavior where ROWNUM/ROWID can be used as + * variable names in PL/SQL. + */ + if (compatible_db == ORA_PARSER && list_length(cref->fields) == 1) + { + Node *field1 = (Node *) linitial(cref->fields); + const char *name1 = strVal(field1); + + if (pg_strcasecmp(name1, "rownum") == 0 || + pg_strcasecmp(name1, "rowid") == 0) + { + Node *result; + + result = resolve_column_ref(pstate, expr, cref, false); + if (result != NULL) + return result; + } + } + + return NULL; } /* From 7412485f2b6ea6788f2c635a90e480bd6fe96ddb Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Thu, 8 Jan 2026 15:20:21 +0000 Subject: [PATCH 19/19] test: add PostgreSQL mode test for Oracle keywords Verify that Oracle-specific keywords (ROWNUM, ROWID, etc.) have no special meaning in PostgreSQL mode: - Can be used as column names - Can be used as column/table aliases - Can be used as function parameters and variables - Can be used as CTE names This ensures Oracle-specific functionality doesn't leak into PostgreSQL mode. --- src/test/regress/expected/ora_keywords_pg.out | 144 ++++++++++++++++++ src/test/regress/parallel_schedule | 3 + src/test/regress/sql/ora_keywords_pg.sql | 83 ++++++++++ 3 files changed, 230 insertions(+) create mode 100644 src/test/regress/expected/ora_keywords_pg.out create mode 100644 src/test/regress/sql/ora_keywords_pg.sql diff --git a/src/test/regress/expected/ora_keywords_pg.out b/src/test/regress/expected/ora_keywords_pg.out new file mode 100644 index 00000000000..e2947542c7a --- /dev/null +++ b/src/test/regress/expected/ora_keywords_pg.out @@ -0,0 +1,144 @@ +-- +-- ORA_KEYWORDS_PG +-- Test that Oracle-specific keywords have no special meaning in PostgreSQL mode. +-- In PostgreSQL mode, these should be treated as regular identifiers. +-- +-- This test verifies that IvorySQL's Oracle-specific functionality +-- (ROWNUM, ROWID, etc.) does not leak into PostgreSQL mode. +-- +-- Test 1: rownum as column name +CREATE TABLE rownum_test ( + id int, + rownum int, -- rownum is just a regular column name + name text +); +INSERT INTO rownum_test VALUES (1, 100, 'Alice'); +INSERT INTO rownum_test VALUES (2, 200, 'Bob'); +INSERT INTO rownum_test VALUES (3, 300, 'Charlie'); +SELECT id, rownum, name FROM rownum_test ORDER BY id; + id | rownum | name +----+--------+--------- + 1 | 100 | Alice + 2 | 200 | Bob + 3 | 300 | Charlie +(3 rows) + +-- Test 2: rownum as column alias (without AS) +SELECT id, name rownum FROM rownum_test ORDER BY id; + id | rownum +----+--------- + 1 | Alice + 2 | Bob + 3 | Charlie +(3 rows) + +-- Test 3: rownum as column alias (with AS) +SELECT id, name AS rownum FROM rownum_test ORDER BY id; + id | rownum +----+--------- + 1 | Alice + 2 | Bob + 3 | Charlie +(3 rows) + +-- Test 4: rownum as table alias +SELECT r.id, r.rownum, r.name FROM rownum_test rownum, rownum_test r WHERE rownum.id = r.id ORDER BY r.id; + id | rownum | name +----+--------+--------- + 1 | 100 | Alice + 2 | 200 | Bob + 3 | 300 | Charlie +(3 rows) + +-- Test 5: rownum as subquery alias +SELECT sub.id, sub.rownum FROM (SELECT * FROM rownum_test) rownum, (SELECT * FROM rownum_test) sub WHERE rownum.id = sub.id ORDER BY sub.id; + id | rownum +----+-------- + 1 | 100 + 2 | 200 + 3 | 300 +(3 rows) + +-- Test 6: Verify rownum column contains actual data, not row numbers +SELECT id, rownum FROM rownum_test WHERE rownum > 150 ORDER BY id; + id | rownum +----+-------- + 2 | 200 + 3 | 300 +(2 rows) + +-- Test 7: rownum in expressions (should use column value, not row number) +SELECT id, rownum, rownum * 2 AS doubled FROM rownum_test ORDER BY id; + id | rownum | doubled +----+--------+--------- + 1 | 100 | 200 + 2 | 200 | 400 + 3 | 300 | 600 +(3 rows) + +-- Test 8: rownum as function parameter name (PL/pgSQL) +CREATE OR REPLACE FUNCTION test_rownum_param(rownum int) RETURNS int AS $$ +BEGIN + RETURN rownum * 10; +END; +$$ LANGUAGE plpgsql; +SELECT test_rownum_param(5); + test_rownum_param +------------------- + 50 +(1 row) + +SELECT test_rownum_param(rownum) FROM rownum_test ORDER BY id; + test_rownum_param +------------------- + 1000 + 2000 + 3000 +(3 rows) + +-- Test 9: rownum as variable in PL/pgSQL +DO $$ +DECLARE + rownum int := 42; +BEGIN + RAISE NOTICE 'rownum variable value: %', rownum; +END; +$$; +NOTICE: rownum variable value: 42 +-- Test 10: rownum in CTE +WITH rownum AS ( + SELECT id, name FROM rownum_test WHERE id <= 2 +) +SELECT * FROM rownum ORDER BY id; + id | name +----+------- + 1 | Alice + 2 | Bob +(2 rows) + +-- Test 11: ROWID as column name (also should have no special meaning) +CREATE TABLE rowid_test ( + rowid int, + data text +); +INSERT INTO rowid_test VALUES (1, 'first'); +INSERT INTO rowid_test VALUES (2, 'second'); +SELECT rowid, data FROM rowid_test ORDER BY rowid; + rowid | data +-------+-------- + 1 | first + 2 | second +(2 rows) + +-- Test 12: rowid as alias +SELECT data rowid FROM rowid_test ORDER BY rowid; + rowid +-------- + first + second +(2 rows) + +-- Cleanup +DROP FUNCTION test_rownum_param(int); +DROP TABLE rownum_test; +DROP TABLE rowid_test; diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule index a424be2a6bf..6a79e173223 100644 --- a/src/test/regress/parallel_schedule +++ b/src/test/regress/parallel_schedule @@ -140,3 +140,6 @@ test: fast_default # run tablespace test at the end because it drops the tablespace created during # setup that other tests may use. test: tablespace + +# Test that Oracle keywords (ROWNUM, ROWID, etc.) have no special meaning in PostgreSQL mode +test: ora_keywords_pg diff --git a/src/test/regress/sql/ora_keywords_pg.sql b/src/test/regress/sql/ora_keywords_pg.sql new file mode 100644 index 00000000000..da126b69572 --- /dev/null +++ b/src/test/regress/sql/ora_keywords_pg.sql @@ -0,0 +1,83 @@ +-- +-- ORA_KEYWORDS_PG +-- Test that Oracle-specific keywords have no special meaning in PostgreSQL mode. +-- In PostgreSQL mode, these should be treated as regular identifiers. +-- +-- This test verifies that IvorySQL's Oracle-specific functionality +-- (ROWNUM, ROWID, etc.) does not leak into PostgreSQL mode. +-- + +-- Test 1: rownum as column name +CREATE TABLE rownum_test ( + id int, + rownum int, -- rownum is just a regular column name + name text +); + +INSERT INTO rownum_test VALUES (1, 100, 'Alice'); +INSERT INTO rownum_test VALUES (2, 200, 'Bob'); +INSERT INTO rownum_test VALUES (3, 300, 'Charlie'); + +SELECT id, rownum, name FROM rownum_test ORDER BY id; + +-- Test 2: rownum as column alias (without AS) +SELECT id, name rownum FROM rownum_test ORDER BY id; + +-- Test 3: rownum as column alias (with AS) +SELECT id, name AS rownum FROM rownum_test ORDER BY id; + +-- Test 4: rownum as table alias +SELECT r.id, r.rownum, r.name FROM rownum_test rownum, rownum_test r WHERE rownum.id = r.id ORDER BY r.id; + +-- Test 5: rownum as subquery alias +SELECT sub.id, sub.rownum FROM (SELECT * FROM rownum_test) rownum, (SELECT * FROM rownum_test) sub WHERE rownum.id = sub.id ORDER BY sub.id; + +-- Test 6: Verify rownum column contains actual data, not row numbers +SELECT id, rownum FROM rownum_test WHERE rownum > 150 ORDER BY id; + +-- Test 7: rownum in expressions (should use column value, not row number) +SELECT id, rownum, rownum * 2 AS doubled FROM rownum_test ORDER BY id; + +-- Test 8: rownum as function parameter name (PL/pgSQL) +CREATE OR REPLACE FUNCTION test_rownum_param(rownum int) RETURNS int AS $$ +BEGIN + RETURN rownum * 10; +END; +$$ LANGUAGE plpgsql; + +SELECT test_rownum_param(5); +SELECT test_rownum_param(rownum) FROM rownum_test ORDER BY id; + +-- Test 9: rownum as variable in PL/pgSQL +DO $$ +DECLARE + rownum int := 42; +BEGIN + RAISE NOTICE 'rownum variable value: %', rownum; +END; +$$; + +-- Test 10: rownum in CTE +WITH rownum AS ( + SELECT id, name FROM rownum_test WHERE id <= 2 +) +SELECT * FROM rownum ORDER BY id; + +-- Test 11: ROWID as column name (also should have no special meaning) +CREATE TABLE rowid_test ( + rowid int, + data text +); + +INSERT INTO rowid_test VALUES (1, 'first'); +INSERT INTO rowid_test VALUES (2, 'second'); + +SELECT rowid, data FROM rowid_test ORDER BY rowid; + +-- Test 12: rowid as alias +SELECT data rowid FROM rowid_test ORDER BY rowid; + +-- Cleanup +DROP FUNCTION test_rownum_param(int); +DROP TABLE rownum_test; +DROP TABLE rowid_test;