From 7705e72377c3b5ea481ac56780f7a6015ac439c7 Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Sat, 29 Nov 2025 11:06:48 +0800 Subject: [PATCH 1/5] 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 2/5] 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 3/5] 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 4/5] 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 5/5] 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); } /*