From 6fe721ff5b56a712ea331fe54ae3d0744a6fccfb Mon Sep 17 00:00:00 2001 From: zhoujingbnu Date: Thu, 14 Nov 2024 17:13:14 +0800 Subject: [PATCH] nth_value enhancement feature without changing buildin function --- src/common/backend/nodes/copyfuncs.cpp | 4 + src/common/backend/nodes/equalfuncs.cpp | 5 +- src/common/backend/nodes/makefuncs.cpp | 2 + src/common/backend/nodes/outfuncs.cpp | 8 + src/common/backend/nodes/readfuncs.cpp | 7 +- src/common/backend/parser/gram.y | 105 +++++- src/common/backend/parser/parse_func.cpp | 5 +- src/common/backend/utils/adt/ruleutils.cpp | 14 +- src/common/backend/utils/adt/windowfuncs.cpp | 33 +- src/common/backend/utils/init/globals.cpp | 4 +- .../interfaces/libpq/frontend_parser/gram.y | 6 +- src/gausskernel/optimizer/util/clauses.cpp | 2 + .../runtime/executor/nodeWindowAgg.cpp | 2 + .../vecexecutor/vecnode/vecwindowagg.cpp | 2 + src/include/miscadmin.h | 1 + src/include/nodes/parsenodes_common.h | 2 + src/include/nodes/primnodes.h | 2 + src/include/parser/kwlist.h | 2 + src/include/windowapi.h | 2 + src/test/regress/expected/analytic_funcs.out | 356 ++++++++++++++++++ src/test/regress/parallel_schedule0A | 1 + src/test/regress/sql/analytic_funcs.sql | 43 +++ 22 files changed, 590 insertions(+), 18 deletions(-) create mode 100644 src/test/regress/expected/analytic_funcs.out create mode 100644 src/test/regress/sql/analytic_funcs.sql diff --git a/src/common/backend/nodes/copyfuncs.cpp b/src/common/backend/nodes/copyfuncs.cpp index 4e5fd0eb7..6d98d550f 100644 --- a/src/common/backend/nodes/copyfuncs.cpp +++ b/src/common/backend/nodes/copyfuncs.cpp @@ -2777,6 +2777,8 @@ static WindowFunc* _copyWindowFunc(const WindowFunc* from) COPY_SCALAR_FIELD(winkpfirst); } COPY_LOCATION_FIELD(location); + COPY_SCALAR_FIELD(is_from_last); + COPY_SCALAR_FIELD(is_ignore_nulls); return newnode; } @@ -4168,6 +4170,8 @@ static FuncCall* _copyFuncCall(const FuncCall* from) COPY_NODE_FIELD(over); COPY_LOCATION_FIELD(location); COPY_SCALAR_FIELD(call_func); + COPY_SCALAR_FIELD(is_from_last); + COPY_SCALAR_FIELD(is_ignore_nulls); return newnode; } diff --git a/src/common/backend/nodes/equalfuncs.cpp b/src/common/backend/nodes/equalfuncs.cpp index a6ebe2a7c..53cdbed41 100644 --- a/src/common/backend/nodes/equalfuncs.cpp +++ b/src/common/backend/nodes/equalfuncs.cpp @@ -284,7 +284,8 @@ static bool _equalWindowFunc(const WindowFunc* a, const WindowFunc* b) COMPARE_SCALAR_FIELD(winkpfirst); } COMPARE_LOCATION_FIELD(location); - + COMPARE_SCALAR_FIELD(is_from_last); + COMPARE_SCALAR_FIELD(is_ignore_nulls); return true; } @@ -2690,6 +2691,8 @@ static bool _equalFuncCall(const FuncCall* a, const FuncCall* b) COMPARE_NODE_FIELD(over); COMPARE_LOCATION_FIELD(location); COMPARE_SCALAR_FIELD(call_func); + COMPARE_SCALAR_FIELD(is_from_last); + COMPARE_SCALAR_FIELD(is_ignore_nulls); return true; } diff --git a/src/common/backend/nodes/makefuncs.cpp b/src/common/backend/nodes/makefuncs.cpp index 30c786dca..612354de5 100644 --- a/src/common/backend/nodes/makefuncs.cpp +++ b/src/common/backend/nodes/makefuncs.cpp @@ -647,6 +647,8 @@ FuncCall* makeFuncCall(List* funcname, List* args, int location) funcCall->aggKeep = NULL; funcCall->over = NULL; funcCall->location = location; + funcCall->is_from_last = FALSE; + funcCall->is_ignore_nulls = FALSE; return funcCall; } diff --git a/src/common/backend/nodes/outfuncs.cpp b/src/common/backend/nodes/outfuncs.cpp index 71f1c39d9..85675482e 100755 --- a/src/common/backend/nodes/outfuncs.cpp +++ b/src/common/backend/nodes/outfuncs.cpp @@ -2643,6 +2643,10 @@ static void _outWindowFunc(StringInfo str, WindowFunc* node) WRITE_TYPEINFO_FIELD(wintype); WRITE_FUNCINFO_FIELD(winfnoid); + if (t_thrd.proc->workingVersionNum >= IGNORE_NULLS_VERSION_NUMBER) { + WRITE_BOOL_FIELD(is_from_last); + WRITE_BOOL_FIELD(is_ignore_nulls); + } } static void _outArrayRef(StringInfo str, ArrayRef* node) @@ -4346,6 +4350,10 @@ static void _outFuncCall(StringInfo str, FuncCall* node) WRITE_NODE_FIELD(over); WRITE_LOCATION_FIELD(location); WRITE_BOOL_FIELD(call_func); + if (t_thrd.proc->workingVersionNum >= IGNORE_NULLS_VERSION_NUMBER) { + WRITE_BOOL_FIELD(is_from_last); + WRITE_BOOL_FIELD(is_ignore_nulls); + } } static void _outTableLikeClause(StringInfo str, const TableLikeClause* node) diff --git a/src/common/backend/nodes/readfuncs.cpp b/src/common/backend/nodes/readfuncs.cpp index a9bf0871a..bc4299946 100755 --- a/src/common/backend/nodes/readfuncs.cpp +++ b/src/common/backend/nodes/readfuncs.cpp @@ -2394,7 +2394,12 @@ static WindowFunc* _readWindowFunc(void) READ_TYPEINFO_FIELD(wintype); READ_FUNCINFO_FIELD(winfnoid); - + IF_EXIST(is_from_last) { + READ_BOOL_FIELD(is_from_last); + } + IF_EXIST(is_ignore_nulls) { + READ_BOOL_FIELD(is_ignore_nulls); + } READ_DONE(); } diff --git a/src/common/backend/parser/gram.y b/src/common/backend/parser/gram.y index fb6ce49cb..27ffd78ce 100644 --- a/src/common/backend/parser/gram.y +++ b/src/common/backend/parser/gram.y @@ -646,6 +646,7 @@ static char* IdentResolveToChar(char *ident, core_yyscan_t yyscanner); %type opt_percent only_or_ties %type OptSeqOptList SeqOptList +%type ignNulls fromLast %type SeqOptElem /* INSERT */ @@ -761,7 +762,7 @@ static char* IdentResolveToChar(char *ident, core_yyscan_t yyscanner); %type xml_whitespace_option %type func_application func_with_separator func_expr_common_subexpr index_functional_expr_key func_application_special functime_app -%type func_expr func_expr_windowless +%type func_expr func_expr_windowless analytic_func_expr %type common_table_expr %type keep_clause %type with_clause opt_with_clause @@ -771,7 +772,7 @@ static char* IdentResolveToChar(char *ident, core_yyscan_t yyscanner); %type within_group_clause pkg_body_subprogram %type window_clause window_definition_list opt_partition_clause -%type window_definition over_clause window_specification +%type window_definition over_clause window_specification opt_over_clause opt_frame_clause frame_extent frame_bound %type opt_existing_window_name opt_unique_key %type opt_if_not_exists @@ -972,7 +973,7 @@ static char* IdentResolveToChar(char *ident, core_yyscan_t yyscanner); MODEL MODIFY_P MONTH_P MOVE MOVEMENT MYSQL_ERRNO // DB4AI NAME_P NAMES NAN_P NATIONAL NATURAL NCHAR NEXT NO NOCOMPRESS NOCYCLE NODE NOLOGGING NOMAXVALUE NOMINVALUE NONE - NOT NOTHING NOTIFY NOTNULL NOVALIDATE NOWAIT NULL_P NULLCOLS NULLIF NULLS_P NUMBER_P NUMERIC NUMSTR NVARCHAR NVARCHAR2 NVL + NOT NOTHING NOTIFY NOTNULL NOVALIDATE NOWAIT NTH_VALUE_P NULL_P NULLCOLS NULLIF NULLS_P NUMBER_P NUMERIC NUMSTR NVARCHAR NVARCHAR2 NVL OBJECT_P OF OFF OFFSET OIDS ON ONLY OPERATOR OPTIMIZATION OPTION OPTIONALLY OPTIONS OR ORDER OUT_P OUTER_P OVER OVERLAPS OVERLAY OWNED OWNER OUTFILE @@ -992,7 +993,7 @@ static char* IdentResolveToChar(char *ident, core_yyscan_t yyscanner); RANDOMIZED RANGE RATIO RAW READ REAL REASSIGN REBUILD RECHECK RECURSIVE RECYCLEBIN REDISANYVALUE REF REFERENCES REFRESH REINDEX REJECT_P RELATIVE_P RELEASE RELOPTIONS REMOTE_P REMOVE RENAME REPEAT REPEATABLE REPLACE REPLICA - RESET RESIZE RESOURCE RESTART RESTRICT RETURN RETURNED_SQLSTATE RETURNING RETURNS REUSE REVOKE RIGHT ROLE ROLES ROLLBACK ROLLUP ROTATE + RESET RESIZE RESOURCE RESPECT_P RESTART RESTRICT RETURN RETURNED_SQLSTATE RETURNING RETURNS REUSE REVOKE RIGHT ROLE ROLES ROLLBACK ROLLUP ROTATE ROTATION ROW ROW_COUNT ROWNUM ROWS ROWTYPE_P RULE SAMPLE SAVEPOINT SCHEDULE SCHEMA SCHEMA_NAME SCROLL SEARCH SECOND_P SECURITY SELECT SEPARATOR_P SEQUENCE SEQUENCES @@ -28899,7 +28900,7 @@ c_expr_noparen: columnref { $$ = $1; } * (Note that many of the special SQL functions wouldn't actually make any * sense as functional index entries, but we ignore that consideration here.) */ -func_expr: func_application within_group_clause filter_clause keep_clause over_clause +func_expr: func_application within_group_clause filter_clause keep_clause opt_over_clause { FuncCall *n = (FuncCall *) $1; @@ -29057,6 +29058,96 @@ func_expr: func_application within_group_clause filter_clause keep_clause over_c { $$ = MakeNoArgFunctionCall(SystemFuncName("current_schema"), @1); } + | analytic_func_expr + { $$ = $1; } + ; +opt_over_clause: + over_clause { $$ = $1; } + | /*EMPTY*/ { $$ = NULL; } + ; +analytic_func_expr: + NTH_VALUE_P '(' func_arg_list ')' fromLast ignNulls over_clause + { + FuncCall *n = makeNode(FuncCall); + n->funcname = SystemFuncName("nth_value"); + n->args = $3; + n->is_from_last = $5; + n->is_ignore_nulls = $6; + n->agg_order = NIL; + n->agg_star = FALSE; + n->agg_distinct = FALSE; + n->func_variadic = FALSE; + n->over = $7; + n->location = @1; + n->call_func = false; + $$ = (Node *)n; + } + | NTH_VALUE_P '(' func_arg_list ')' fromLast over_clause + { + FuncCall *n = makeNode(FuncCall); + n->funcname = SystemFuncName("nth_value"); + n->args = $3; + n->is_from_last = $5; + n->is_ignore_nulls = FALSE; + n->agg_order = NIL; + n->agg_star = FALSE; + n->agg_distinct = FALSE; + n->func_variadic = FALSE; + n->over = $6; + n->location = @1; + n->call_func = false; + $$ = (Node *)n; + } + | NTH_VALUE_P '(' func_arg_list ')' ignNulls over_clause + { + FuncCall *n = makeNode(FuncCall); + n->funcname = SystemFuncName("nth_value"); + n->args = $3; + n->is_from_last = FALSE; + n->is_ignore_nulls = $5; + n->agg_order = NIL; + n->agg_star = FALSE; + n->agg_distinct = FALSE; + n->func_variadic = FALSE; + n->over = $6; + n->location = @1; + n->call_func = false; + $$ = (Node *)n; + } + | NTH_VALUE_P '(' func_arg_list ')' over_clause + { + FuncCall *n = makeNode(FuncCall); + n->funcname = SystemFuncName("nth_value"); + n->args = $3; + n->is_from_last = FALSE; + n->is_ignore_nulls = FALSE; + n->agg_order = NIL; + n->agg_star = FALSE; + n->agg_distinct = FALSE; + n->func_variadic = FALSE; + n->over = $5; + n->location = @1; + n->call_func = false; + $$ = (Node *)n; + } + ; +fromLast: FROM FIRST_P + { + $$ = false; + } + | FROM LAST_P + { + $$ = true; + } + ; +ignNulls: IGNORE NULLS_P + { + $$ = true; + } + | RESPECT_P NULLS_P + { + $$ = false; + } ; func_application: func_name '(' func_arg_list opt_sort_clause ')' @@ -30125,8 +30216,6 @@ over_clause: OVER window_specification n->location = @2; $$ = n; } - | /*EMPTY*/ - { $$ = NULL; } ; window_specification: '(' opt_existing_window_name opt_partition_clause @@ -31821,6 +31910,7 @@ unreserved_keyword: | RESET | RESIZE | RESOURCE + | RESPECT_P | RESTART | RESTRICT | RESULT @@ -32015,6 +32105,7 @@ col_name_keyword: | NATIONAL | NCHAR | NONE + | NTH_VALUE_P | NULLIF | NUMBER_P | NUMERIC diff --git a/src/common/backend/parser/parse_func.cpp b/src/common/backend/parser/parse_func.cpp index 90afc66eb..0e6eef448 100644 --- a/src/common/backend/parser/parse_func.cpp +++ b/src/common/backend/parser/parse_func.cpp @@ -77,6 +77,8 @@ Node* ParseFuncOrColumn(ParseState* pstate, List* funcname, List* fargs, Node* l bool agg_star = (fn ? fn->agg_star : false); bool agg_distinct = (fn ? fn->agg_distinct : false); bool func_variadic = (fn ? fn->func_variadic : false); + bool is_from_last = (fn ? fn->is_from_last : false); + bool is_ignore_nulls = (fn ? fn->is_ignore_nulls : false); WindowDef* over = (fn ? fn->over : NULL); KeepClause *aggKeep = (fn ? fn->aggKeep : NULL); Oid rettype; @@ -635,7 +637,8 @@ Node* ParseFuncOrColumn(ParseState* pstate, List* funcname, List* fargs, Node* l wfunc->winstar = agg_star; wfunc->winagg = (fdresult == FUNCDETAIL_AGGREGATE); wfunc->location = location; - + wfunc->is_from_last = is_from_last; + wfunc->is_ignore_nulls = is_ignore_nulls; /* * agg_star is allowed for aggregate functions but distinct isn't */ diff --git a/src/common/backend/utils/adt/ruleutils.cpp b/src/common/backend/utils/adt/ruleutils.cpp index a7fbdb9db..2defb6b78 100644 --- a/src/common/backend/utils/adt/ruleutils.cpp +++ b/src/common/backend/utils/adt/ruleutils.cpp @@ -11382,6 +11382,10 @@ static void get_windowfunc_expr(WindowFunc* wfunc, deparse_context* context) } funcname = generate_function_name(wfunc->winfnoid, nargs, argnames, argtypes, false, NULL); + + if (pg_strcasecmp(funcname,"\"nth_value\"") == 0) { + funcname = "nth_value"; + } appendStringInfo(buf, "%s(", funcname); /* winstar can be set only in zero-argument aggregates */ @@ -11395,8 +11399,14 @@ static void get_windowfunc_expr(WindowFunc* wfunc, deparse_context* context) Assert(funcname); if (pg_strcasecmp(funcname, "listagg") == 0) appendStringInfoString(buf, ") WITHIN GROUP "); - else - appendStringInfoString(buf, ") OVER "); + else { + appendStringInfoString(buf, ")"); + if (wfunc->is_from_last) + appendStringInfoString(buf, " FROM LAST"); + if (wfunc->is_ignore_nulls) + appendStringInfoString(buf, " IGNORE NULLS"); + appendStringInfoString(buf, " OVER "); + } construct_windowClause(context); diff --git a/src/common/backend/utils/adt/windowfuncs.cpp b/src/common/backend/utils/adt/windowfuncs.cpp index 349bb3c69..65070e186 100644 --- a/src/common/backend/utils/adt/windowfuncs.cpp +++ b/src/common/backend/utils/adt/windowfuncs.cpp @@ -396,6 +396,9 @@ Datum window_nth_value(PG_FUNCTION_ARGS) Datum result; bool isnull = false; int32 nth; + bool isout = false; + bool isFromLast = winobj->is_from_last; + bool isIgnNulls = winobj->is_ignore_nulls; nth = DatumGetInt32(WinGetFuncArgCurrent(winobj, 1, &isnull)); if (isnull) @@ -406,8 +409,32 @@ Datum window_nth_value(PG_FUNCTION_ARGS) ereport(ERROR, (errcode(ERRCODE_INVALID_ARGUMENT_FOR_NTH_VALUE), errmsg("argument of nth_value must be greater than zero"))); - - result = WinGetFuncArgInFrame(winobj, 0, nth - 1, WINDOW_SEEK_HEAD, const_offset, &isnull, NULL); + int startingPos = 0; + if (isFromLast) { + if (isIgnNulls) { + do { + result = WinGetFuncArgInFrame(winobj, 0, startingPos--, WINDOW_SEEK_TAIL, false, &isnull, &isout); + } while (isnull && !isout); + if (nth > 1) { + /* the startingPos should be startingPos+1, the nth index should be staringPos+1-(nth-1) */ + result = WinGetFuncArgInFrame(winobj, 0, startingPos-nth+2, WINDOW_SEEK_TAIL, false, &isnull, &isout); + } + } else { + result = WinGetFuncArgInFrame(winobj, 0, 1-nth, WINDOW_SEEK_TAIL, const_offset, &isnull, NULL); + } + } else { + if (isIgnNulls) { + do { + result = WinGetFuncArgInFrame(winobj, 0, startingPos++, WINDOW_SEEK_HEAD, false, &isnull, &isout); + } while (isnull && !isout); + if (nth > 1) { + /* the startingPos should be startingPos-1,the nth index should be startingPos-1 + nth-1 */ + result = WinGetFuncArgInFrame(winobj, 0, startingPos+nth-2, WINDOW_SEEK_HEAD, false, &isnull, &isout); + } + } else { + result = WinGetFuncArgInFrame(winobj, 0, nth - 1, WINDOW_SEEK_HEAD, const_offset, &isnull, NULL); + } + } if (isnull) PG_RETURN_NULL(); @@ -448,4 +475,4 @@ Datum window_delta(PG_FUNCTION_ARGS) } PG_RETURN_DATUM(res); -} \ No newline at end of file +} diff --git a/src/common/backend/utils/init/globals.cpp b/src/common/backend/utils/init/globals.cpp index ebe6c7db2..a79666647 100644 --- a/src/common/backend/utils/init/globals.cpp +++ b/src/common/backend/utils/init/globals.cpp @@ -76,12 +76,14 @@ bool will_shutdown = false; * NEXT | 93000 | ? | ? * ********************************************/ -const uint32 GRAND_VERSION_NUM = 93024; + +const uint32 GRAND_VERSION_NUM = 93025; /******************************************** * 2.VERSION NUM FOR EACH FEATURE * Please write indescending order. ********************************************/ +const uint32 IGNORE_NULLS_VERSION_NUMBER = 93025; const uint32 DATAVEC_VERSION_NUMBER = 93019; const uint32 HTAP_VERSION_NUMBER = 93015; const uint32 KEEP_FUNC_VERSION_NUMBER = 93014; diff --git a/src/common/interfaces/libpq/frontend_parser/gram.y b/src/common/interfaces/libpq/frontend_parser/gram.y index 0108d541a..42b9569c6 100755 --- a/src/common/interfaces/libpq/frontend_parser/gram.y +++ b/src/common/interfaces/libpq/frontend_parser/gram.y @@ -577,7 +577,7 @@ extern THR_LOCAL bool stmt_contains_operator_plus; MAPPING MASKING MASTER MASTR MATCH MATERIALIZED MATCHED MAXEXTENTS MAXSIZE MAXTRANS MAXVALUE MERGE MESSAGE_TEXT METHOD MINUS_P MINUTE_P MINUTE_SECOND_P MINVALUE MINEXTENTS MODE MODIFY_P MONTH_P MOVE MOVEMENT MODEL MYSQL_ERRNO// DB4AI NAME_P NAMES NAN_P NATIONAL NATURAL NCHAR NEXT NLSSORT NO NOCOMPRESS NOCYCLE NODE NOLOGGING NOMAXVALUE NOMINVALUE NONE - NOT NOTHING NOTIFY NOTNULL NOVALIDATE NOWAIT NULL_P NULLCOLS NULLIF NULLS_P NUMBER_P NUMERIC NUMSTR NVARCHAR NVARCHAR2 NVL + NOT NOTHING NOTIFY NOTNULL NOVALIDATE NOWAIT NTH_VALUE_P NULL_P NULLCOLS NULLIF NULLS_P NUMBER_P NUMERIC NUMSTR NVARCHAR NVARCHAR2 NVL OBJECT_P OF OFF OFFSET OIDS ON ONLY OPERATOR OPTIMIZATION OPTION OPTIONALLY OPTIONS OR ORDER OUT_P OUTER_P OVER OVERLAPS OVERLAY OWNED OWNER OUTFILE @@ -597,7 +597,7 @@ extern THR_LOCAL bool stmt_contains_operator_plus; RANDOMIZED RANGE RATIO RAW READ REAL REASSIGN REBUILD RECHECK RECURSIVE RECYCLEBIN REDISANYVALUE REF REFERENCES REFRESH REINDEX REJECT_P RELATIVE_P RELEASE RELOPTIONS REMOTE_P REMOVE RENAME REPEAT REPEATABLE REPLACE REPLICA - RESET RESIZE RESOURCE RESTART RESTRICT RETURN RETURNED_SQLSTATE RETURNING RETURNS REUSE REVOKE RIGHT ROLE ROLES ROLLBACK ROLLUP ROTATE + RESET RESIZE RESOURCE RESPECT_P RESTART RESTRICT RETURN RETURNED_SQLSTATE RETURNING RETURNS REUSE REVOKE RIGHT ROLE ROLES ROLLBACK ROLLUP ROTATE ROTATION ROW ROW_COUNT ROWNUM ROWS ROWTYPE_P RULE SAMPLE SAVEPOINT SCHEDULE SCHEMA SCHEMA_NAME SCROLL SEARCH SECOND_P SECURITY SELECT SEPARATOR_P SEQUENCE SEQUENCES @@ -12003,6 +12003,7 @@ unreserved_keyword: | NOTHING | NOTIFY | NOWAIT + | NTH_VALUE_P | NULLCOLS | NULLS_P | NUMSTR @@ -12075,6 +12076,7 @@ unreserved_keyword: | RESET | RESIZE | RESOURCE + | RESPECT_P | RESTART | RESTRICT | RETURNS diff --git a/src/gausskernel/optimizer/util/clauses.cpp b/src/gausskernel/optimizer/util/clauses.cpp index 94897a76e..a8dffb6c4 100644 --- a/src/gausskernel/optimizer/util/clauses.cpp +++ b/src/gausskernel/optimizer/util/clauses.cpp @@ -2599,6 +2599,8 @@ Node* eval_const_expressions_mutator(Node* node, eval_const_expressions_context* newexpr->winkporder = (List*)expression_tree_mutator( (Node*)expr->winkporder, (Node* (*)(Node*, void*)) eval_const_expressions_mutator, (void*)context); newexpr->winkpfirst = expr->winkpfirst; + newexpr->is_from_last = expr->is_from_last; + newexpr->is_ignore_nulls = expr->is_ignore_nulls; newexpr->location = expr->location; return (Node*)newexpr; diff --git a/src/gausskernel/runtime/executor/nodeWindowAgg.cpp b/src/gausskernel/runtime/executor/nodeWindowAgg.cpp index d684fc95f..c5bd2dbe3 100644 --- a/src/gausskernel/runtime/executor/nodeWindowAgg.cpp +++ b/src/gausskernel/runtime/executor/nodeWindowAgg.cpp @@ -1488,6 +1488,8 @@ WindowAggState* ExecInitWindowAgg(WindowAgg* node, EState* estate, int eflags) winobj->winstate = winstate; winobj->argstates = wfuncstate->args; winobj->localmem = NULL; + winobj->is_from_last = wfunc->is_from_last; + winobj->is_ignore_nulls = wfunc->is_ignore_nulls; perfuncstate->winobj = winobj; } } diff --git a/src/gausskernel/runtime/vecexecutor/vecnode/vecwindowagg.cpp b/src/gausskernel/runtime/vecexecutor/vecnode/vecwindowagg.cpp index 697aa508a..c0af25c09 100644 --- a/src/gausskernel/runtime/vecexecutor/vecnode/vecwindowagg.cpp +++ b/src/gausskernel/runtime/vecexecutor/vecnode/vecwindowagg.cpp @@ -267,6 +267,8 @@ VecWindowAggState* ExecInitVecWindowAgg(VecWindowAgg* node, EState* estate, int winobj->winstate = winstate; winobj->argstates = wfuncstate->args; winobj->localmem = NULL; + winobj->is_from_last = wfunc->is_from_last; + winobj->is_ignore_nulls = wfunc->is_ignore_nulls; perfuncstate->winobj = winobj; } } diff --git a/src/include/miscadmin.h b/src/include/miscadmin.h index 9acb8e45f..a4fbc05a7 100644 --- a/src/include/miscadmin.h +++ b/src/include/miscadmin.h @@ -162,6 +162,7 @@ extern const uint32 CHARBYTE_SEMANTIC_VERSION_NUMBER; extern const uint32 APPLY_JOIN_VERSION_NUMBER; extern const uint32 PUBLIC_SYNONYM_VERSION_NUMBER; extern const uint32 KEEP_FUNC_VERSION_NUMBER; +extern const uint32 IGNORE_NULLS_VERSION_NUMBER; extern void register_backend_version(uint32 backend_version); extern bool contain_backend_version(uint32 version_number); diff --git a/src/include/nodes/parsenodes_common.h b/src/include/nodes/parsenodes_common.h index 17e3a09e9..e987766e7 100644 --- a/src/include/nodes/parsenodes_common.h +++ b/src/include/nodes/parsenodes_common.h @@ -1742,6 +1742,8 @@ typedef struct FuncCall { struct WindowDef *over; /* OVER clause, if any */ int location; /* token location, or -1 if unknown */ bool call_func; /* call function, false is select function */ + bool is_from_last; /* used for window function nth_value */ + bool is_ignore_nulls; /* used for window function nth_value */ } FuncCall; /* diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h index 0333e1c41..cf0a9db52 100644 --- a/src/include/nodes/primnodes.h +++ b/src/include/nodes/primnodes.h @@ -367,6 +367,8 @@ typedef struct WindowFunc { #ifdef USE_SPQ bool windistinct; /* TRUE if it's agg(DISTINCT ...) */ #endif + bool is_from_last; /* used for window function nth_value */ + bool is_ignore_nulls; /* used for window function nth_value */ } WindowFunc; /* diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h index ef67eb08a..ef4bfd7cb 100644 --- a/src/include/parser/kwlist.h +++ b/src/include/parser/kwlist.h @@ -442,6 +442,7 @@ PG_KEYWORD("notify", NOTIFY, UNRESERVED_KEYWORD) PG_KEYWORD("notnull", NOTNULL, TYPE_FUNC_NAME_KEYWORD) PG_KEYWORD("novalidate", NOVALIDATE, UNRESERVED_KEYWORD) PG_KEYWORD("nowait", NOWAIT, UNRESERVED_KEYWORD) +PG_KEYWORD("nth_value", NTH_VALUE_P, COL_NAME_KEYWORD) PG_KEYWORD("null", NULL_P, RESERVED_KEYWORD) PG_KEYWORD("nullcols", NULLCOLS, UNRESERVED_KEYWORD) PG_KEYWORD("nullif", NULLIF, COL_NAME_KEYWORD) @@ -550,6 +551,7 @@ PG_KEYWORD("replica", REPLICA, UNRESERVED_KEYWORD) PG_KEYWORD("reset", RESET, UNRESERVED_KEYWORD) PG_KEYWORD("resize", RESIZE, UNRESERVED_KEYWORD) PG_KEYWORD("resource", RESOURCE, UNRESERVED_KEYWORD) +PG_KEYWORD("respect", RESPECT_P, UNRESERVED_KEYWORD) PG_KEYWORD("restart", RESTART, UNRESERVED_KEYWORD) PG_KEYWORD("restrict", RESTRICT, UNRESERVED_KEYWORD) PG_KEYWORD("result", RESULT, UNRESERVED_KEYWORD) diff --git a/src/include/windowapi.h b/src/include/windowapi.h index 31c4d4f4b..58a81eac3 100644 --- a/src/include/windowapi.h +++ b/src/include/windowapi.h @@ -57,6 +57,8 @@ typedef struct WindowObjectData { int readptr; /* tuplestore read pointer for this fn */ int64 markpos; /* row that markptr is positioned on */ int64 seekpos; /* row that readptr is positioned on */ + bool is_from_last; /* used for nth_value */ + bool is_ignore_nulls; /* used for nth_value */ } WindowObjectData; /* this struct is private in nodeWindowAgg.c */ diff --git a/src/test/regress/expected/analytic_funcs.out b/src/test/regress/expected/analytic_funcs.out new file mode 100644 index 000000000..245901816 --- /dev/null +++ b/src/test/regress/expected/analytic_funcs.out @@ -0,0 +1,356 @@ +--nth_value support algorithm FROM LAST/FIRST and IGNORE/REPSECT NULLS +DROP TABLE IF EXISTS temp_table; +NOTICE: table "temp_table" does not exist, skipping +CREATE TABLE temp_table(ten int, four int); +insert into temp_table values(1,1),(1,1),(7,1),(9,1),(0,2),(1,3),(3,3),(null,1),(null,2),(8,1),(null,1),(null,1); +--check whole partition +SELECT NTH_VALUE(TEN, 1) OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; + nth_value | ten | four +-----------+-----+------ + 1 | 1 | 1 + 1 | 1 | 1 + 1 | 7 | 1 + 1 | 8 | 1 + 1 | 9 | 1 + 1 | | 1 + 1 | | 1 + 1 | | 1 + 0 | 0 | 2 + 0 | | 2 + 1 | 1 | 3 + 1 | 3 | 3 +(12 rows) + +SELECT NTH_VALUE(TEN, 1) FROM LAST OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; + nth_value | ten | four +-----------+-----+------ + | 1 | 1 + | 1 | 1 + | 7 | 1 + | 8 | 1 + | 9 | 1 + | | 1 + | | 1 + | | 1 + | 0 | 2 + | | 2 + 3 | 1 | 3 + 3 | 3 | 3 +(12 rows) + +SELECT NTH_VALUE(TEN, 1) FROM FIRST OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; + nth_value | ten | four +-----------+-----+------ + 1 | 1 | 1 + 1 | 1 | 1 + 1 | 7 | 1 + 1 | 8 | 1 + 1 | 9 | 1 + 1 | | 1 + 1 | | 1 + 1 | | 1 + 0 | 0 | 2 + 0 | | 2 + 1 | 1 | 3 + 1 | 3 | 3 +(12 rows) + +SELECT NTH_VALUE(TEN, 1) IGNORE NULLS OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; + nth_value | ten | four +-----------+-----+------ + 1 | 1 | 1 + 1 | 1 | 1 + 1 | 7 | 1 + 1 | 8 | 1 + 1 | 9 | 1 + 1 | | 1 + 1 | | 1 + 1 | | 1 + 0 | 0 | 2 + 0 | | 2 + 1 | 1 | 3 + 1 | 3 | 3 +(12 rows) + +SELECT NTH_VALUE(TEN, 1) RESPECT NULLS OVER (PARTITION BY FOUR order by ten desc ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; + nth_value | ten | four +-----------+-----+------ + | | 1 + | | 1 + | | 1 + | 9 | 1 + | 8 | 1 + | 7 | 1 + | 1 | 1 + | 1 | 1 + | | 2 + | 0 | 2 + 3 | 3 | 3 + 3 | 1 | 3 +(12 rows) + +SELECT NTH_VALUE(TEN, 1) FROM LAST IGNORE NULLS OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; + nth_value | ten | four +-----------+-----+------ + 9 | 1 | 1 + 9 | 1 | 1 + 9 | 7 | 1 + 9 | 8 | 1 + 9 | 9 | 1 + 9 | | 1 + 9 | | 1 + 9 | | 1 + 0 | 0 | 2 + 0 | | 2 + 3 | 1 | 3 + 3 | 3 | 3 +(12 rows) + +SELECT NTH_VALUE(TEN,2) FROM LAST IGNORE NULLS OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; + nth_value | ten | four +-----------+-----+------ + 8 | 1 | 1 + 8 | 1 | 1 + 8 | 7 | 1 + 8 | 8 | 1 + 8 | 9 | 1 + 8 | | 1 + 8 | | 1 + 8 | | 1 + | 0 | 2 + | | 2 + 1 | 1 | 3 + 1 | 3 | 3 +(12 rows) + +SELECT NTH_VALUE(TEN,3) FROM LAST IGNORE NULLS OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; + nth_value | ten | four +-----------+-----+------ + 7 | 1 | 1 + 7 | 1 | 1 + 7 | 7 | 1 + 7 | 8 | 1 + 7 | 9 | 1 + 7 | | 1 + 7 | | 1 + 7 | | 1 + | 0 | 2 + | | 2 + | 1 | 3 + | 3 | 3 +(12 rows) + +SELECT NTH_VALUE(TEN,2) FROM FIRST IGNORE NULLS OVER (PARTITION BY FOUR order by ten desc ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; + nth_value | ten | four +-----------+-----+------ + 8 | | 1 + 8 | | 1 + 8 | | 1 + 8 | 9 | 1 + 8 | 8 | 1 + 8 | 7 | 1 + 8 | 1 | 1 + 8 | 1 | 1 + | | 2 + | 0 | 2 + 1 | 3 | 3 + 1 | 1 | 3 +(12 rows) + +SELECT NTH_VALUE(TEN,3) FROM FIRST IGNORE NULLS OVER (PARTITION BY FOUR order by ten desc ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; + nth_value | ten | four +-----------+-----+------ + 7 | | 1 + 7 | | 1 + 7 | | 1 + 7 | 9 | 1 + 7 | 8 | 1 + 7 | 7 | 1 + 7 | 1 | 1 + 7 | 1 | 1 + | | 2 + | 0 | 2 + | 3 | 3 + | 1 | 3 +(12 rows) + +--check default frame head to current row +SELECT NTH_VALUE(TEN, 1) FROM FIRST IGNORE NULLS OVER (PARTITION BY FOUR order by ten desc) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; + nth_value | ten | four +-----------+-----+------ + | | 1 + | | 1 + | | 1 + 9 | 9 | 1 + 9 | 8 | 1 + 9 | 7 | 1 + 9 | 1 | 1 + 9 | 1 | 1 + | | 2 + 0 | 0 | 2 + 3 | 3 | 3 + 3 | 1 | 3 +(12 rows) + +SELECT NTH_VALUE(TEN, 2) FROM FIRST IGNORE NULLS OVER (PARTITION BY FOUR order by ten desc) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; + nth_value | ten | four +-----------+-----+------ + | | 1 + | | 1 + | | 1 + | 9 | 1 + 8 | 8 | 1 + 8 | 7 | 1 + 8 | 1 | 1 + 8 | 1 | 1 + | | 2 + | 0 | 2 + | 3 | 3 + 1 | 1 | 3 +(12 rows) + +SELECT NTH_VALUE(TEN, 3) FROM FIRST IGNORE NULLS OVER (PARTITION BY FOUR order by ten desc) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; + nth_value | ten | four +-----------+-----+------ + | | 1 + | | 1 + | | 1 + | 9 | 1 + | 8 | 1 + 7 | 7 | 1 + 7 | 1 | 1 + 7 | 1 | 1 + | | 2 + | 0 | 2 + | 3 | 3 + | 1 | 3 +(12 rows) + +SELECT NTH_VALUE(TEN, 1) FROM LAST IGNORE NULLS OVER (PARTITION BY FOUR order by ten desc) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; + nth_value | ten | four +-----------+-----+------ + | | 1 + | | 1 + | | 1 + 9 | 9 | 1 + 8 | 8 | 1 + 7 | 7 | 1 + 1 | 1 | 1 + 1 | 1 | 1 + | | 2 + 0 | 0 | 2 + 3 | 3 | 3 + 1 | 1 | 3 +(12 rows) + +SELECT NTH_VALUE(TEN, 2) FROM LAST IGNORE NULLS OVER (PARTITION BY FOUR order by ten desc) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; + nth_value | ten | four +-----------+-----+------ + | | 1 + | | 1 + | | 1 + | 9 | 1 + 9 | 8 | 1 + 8 | 7 | 1 + 1 | 1 | 1 + 1 | 1 | 1 + | | 2 + | 0 | 2 + | 3 | 3 + 3 | 1 | 3 +(12 rows) + +SELECT NTH_VALUE(TEN, 3) FROM LAST IGNORE NULLS OVER (PARTITION BY FOUR order by ten desc) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; + nth_value | ten | four +-----------+-----+------ + | | 1 + | | 1 + | | 1 + | 9 | 1 + | 8 | 1 + 9 | 7 | 1 + 7 | 1 | 1 + 7 | 1 | 1 + | | 2 + | 0 | 2 + | 3 | 3 + | 1 | 3 +(12 rows) + +--check error case +SELECT NTH_VALUE(TEN, 0) FROM LAST IGNORE NULLS OVER (PARTITION BY FOUR order by ten desc) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; +ERROR: argument of nth_value must be greater than zero +SELECT NTH_VALUE(TEN, 1) IGNORE NULLS FROM LAST OVER (PARTITION BY FOUR order by ten desc) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; +ERROR: syntax error at or near "FROM" +LINE 1: SELECT NTH_VALUE(TEN, 1) IGNORE NULLS FROM LAST OVER (PARTIT... + ^ +SELECT NTH_VALUE(TEN, 1) FROM LAST IGNORE NULLS OVER (PARTITION BY FOUR order by ten desc) AS NTH_VALUE, TEN, FOUR +FROM temp_table +GROUP BY 1 +ORDER BY FOUR, TEN desc; +ERROR: window functions not allowed in GROUP BY clause +LINE 1: SELECT NTH_VALUE(TEN, 1) FROM LAST IGNORE NULLS OVER (PARTIT... + ^ +--check for dump +CREATE VIEW nthview1 as SELECT NTH_VALUE(TEN, 1) OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; +create view nthview2 as SELECT NTH_VALUE(TEN, 1) FROM LAST OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; +create view nthview3 as SELECT NTH_VALUE(TEN, 2) IGNORE NULLS OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; +create view nthview4 as SELECT NTH_VALUE(TEN,3) FROM LAST IGNORE NULLS OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; +\d+ nthview1 + View "public.nthview1" + Column | Type | Modifiers | Storage | Description +-----------+---------+-----------+---------+------------- + nth_value | integer | | plain | + ten | integer | | plain | + four | integer | | plain | +View definition: + SELECT nth_value(temp_table.ten, 1) OVER (PARTITION BY temp_table.four ORDER BY temp_table.ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS "nth_value", + temp_table.ten, temp_table.four + FROM temp_table + ORDER BY temp_table.four, temp_table.ten; + +\d+ nthview2 + View "public.nthview2" + Column | Type | Modifiers | Storage | Description +-----------+---------+-----------+---------+------------- + nth_value | integer | | plain | + ten | integer | | plain | + four | integer | | plain | +View definition: + SELECT nth_value(temp_table.ten, 1) FROM LAST OVER (PARTITION BY temp_table.four ORDER BY temp_table.ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS "nth_value", + temp_table.ten, temp_table.four + FROM temp_table + ORDER BY temp_table.four, temp_table.ten; + +\d+ nthview3 + View "public.nthview3" + Column | Type | Modifiers | Storage | Description +-----------+---------+-----------+---------+------------- + nth_value | integer | | plain | + ten | integer | | plain | + four | integer | | plain | +View definition: + SELECT nth_value(temp_table.ten, 2) IGNORE NULLS OVER (PARTITION BY temp_table.four ORDER BY temp_table.ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS "nth_value", + temp_table.ten, temp_table.four + FROM temp_table + ORDER BY temp_table.four, temp_table.ten; + +\d+ nthview4 + View "public.nthview4" + Column | Type | Modifiers | Storage | Description +-----------+---------+-----------+---------+------------- + nth_value | integer | | plain | + ten | integer | | plain | + four | integer | | plain | +View definition: + SELECT nth_value(temp_table.ten, 3) FROM LAST IGNORE NULLS OVER (PARTITION BY temp_table.four ORDER BY temp_table.ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS "nth_value", + temp_table.ten, temp_table.four + FROM temp_table + ORDER BY temp_table.four, temp_table.ten; + +DROP TABLE IF EXISTS temp_table CASCADE; +NOTICE: drop cascades to 4 other objects +DETAIL: drop cascades to view nthview1 +drop cascades to view nthview2 +drop cascades to view nthview3 +drop cascades to view nthview4 diff --git a/src/test/regress/parallel_schedule0A b/src/test/regress/parallel_schedule0A index 21d790c0b..962ab37a7 100644 --- a/src/test/regress/parallel_schedule0A +++ b/src/test/regress/parallel_schedule0A @@ -14,6 +14,7 @@ # usecases for improving coverage # these use cases may affect other usecases, please keep these usecases unique in their parallel groups # -------------------------- +test: analytic_funcs test: timecapsule_partition_ustore_test_1 test: timecapsule_partition_ustore_test_2 test: ddl diff --git a/src/test/regress/sql/analytic_funcs.sql b/src/test/regress/sql/analytic_funcs.sql new file mode 100644 index 000000000..8a0af1a66 --- /dev/null +++ b/src/test/regress/sql/analytic_funcs.sql @@ -0,0 +1,43 @@ +--nth_value support algorithm FROM LAST/FIRST and IGNORE/REPSECT NULLS +DROP TABLE IF EXISTS temp_table; +CREATE TABLE temp_table(ten int, four int); +insert into temp_table values(1,1),(1,1),(7,1),(9,1),(0,2),(1,3),(3,3),(null,1),(null,2),(8,1),(null,1),(null,1); +--check whole partition +SELECT NTH_VALUE(TEN, 1) OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; +SELECT NTH_VALUE(TEN, 1) FROM LAST OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; +SELECT NTH_VALUE(TEN, 1) FROM FIRST OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; +SELECT NTH_VALUE(TEN, 1) IGNORE NULLS OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; +SELECT NTH_VALUE(TEN, 1) RESPECT NULLS OVER (PARTITION BY FOUR order by ten desc ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; +SELECT NTH_VALUE(TEN, 1) FROM LAST IGNORE NULLS OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; +SELECT NTH_VALUE(TEN,2) FROM LAST IGNORE NULLS OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; +SELECT NTH_VALUE(TEN,3) FROM LAST IGNORE NULLS OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; +SELECT NTH_VALUE(TEN,2) FROM FIRST IGNORE NULLS OVER (PARTITION BY FOUR order by ten desc ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; +SELECT NTH_VALUE(TEN,3) FROM FIRST IGNORE NULLS OVER (PARTITION BY FOUR order by ten desc ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; +--check default frame head to current row +SELECT NTH_VALUE(TEN, 1) FROM FIRST IGNORE NULLS OVER (PARTITION BY FOUR order by ten desc) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; +SELECT NTH_VALUE(TEN, 2) FROM FIRST IGNORE NULLS OVER (PARTITION BY FOUR order by ten desc) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; +SELECT NTH_VALUE(TEN, 3) FROM FIRST IGNORE NULLS OVER (PARTITION BY FOUR order by ten desc) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; +SELECT NTH_VALUE(TEN, 1) FROM LAST IGNORE NULLS OVER (PARTITION BY FOUR order by ten desc) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; +SELECT NTH_VALUE(TEN, 2) FROM LAST IGNORE NULLS OVER (PARTITION BY FOUR order by ten desc) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; +SELECT NTH_VALUE(TEN, 3) FROM LAST IGNORE NULLS OVER (PARTITION BY FOUR order by ten desc) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; +--check error case +SELECT NTH_VALUE(TEN, 0) FROM LAST IGNORE NULLS OVER (PARTITION BY FOUR order by ten desc) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; +SELECT NTH_VALUE(TEN, 1) IGNORE NULLS FROM LAST OVER (PARTITION BY FOUR order by ten desc) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN desc; +SELECT NTH_VALUE(TEN, 1) FROM LAST IGNORE NULLS OVER (PARTITION BY FOUR order by ten desc) AS NTH_VALUE, TEN, FOUR +FROM temp_table +GROUP BY 1 +ORDER BY FOUR, TEN desc; +--check for dump +CREATE VIEW nthview1 as SELECT NTH_VALUE(TEN, 1) OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; +create view nthview2 as SELECT NTH_VALUE(TEN, 1) FROM LAST OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; +create view nthview3 as SELECT NTH_VALUE(TEN, 2) IGNORE NULLS OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; +create view nthview4 as SELECT NTH_VALUE(TEN,3) FROM LAST IGNORE NULLS OVER (PARTITION BY FOUR order by ten ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS NTH_VALUE, TEN, FOUR FROM temp_table ORDER BY FOUR, TEN; + + +\d+ nthview1 +\d+ nthview2 +\d+ nthview3 +\d+ nthview4 + + +DROP TABLE IF EXISTS temp_table CASCADE;