diff --git a/src/backend/distributed/deparser/ruleutils_13.c b/src/backend/distributed/deparser/ruleutils_13.c index 8af283569..040878150 100644 --- a/src/backend/distributed/deparser/ruleutils_13.c +++ b/src/backend/distributed/deparser/ruleutils_13.c @@ -2082,7 +2082,10 @@ get_select_query_def(Query *query, deparse_context *context, force_colno, context); } - /* Add the LIMIT clause if given */ + /* + * Add the LIMIT/OFFSET clauses if given. If non-default options, use the + * standard spelling of LIMIT. + */ if (query->limitOffset != NULL) { appendContextKeyword(context, " OFFSET ", @@ -2091,13 +2094,24 @@ get_select_query_def(Query *query, deparse_context *context, } if (query->limitCount != NULL) { - appendContextKeyword(context, " LIMIT ", - -PRETTYINDENT_STD, PRETTYINDENT_STD, 0); - if (IsA(query->limitCount, Const) && - ((Const *) query->limitCount)->constisnull) - appendStringInfoString(buf, "ALL"); - else + if (query->limitOption == LIMIT_OPTION_WITH_TIES) + { + // had to add '(' and ')' here because it fails with casting + appendContextKeyword(context, " FETCH FIRST (", + -PRETTYINDENT_STD, PRETTYINDENT_STD, 0); get_rule_expr(query->limitCount, context, false); + appendStringInfo(buf, ") ROWS WITH TIES"); + } + else + { + appendContextKeyword(context, " LIMIT ", + -PRETTYINDENT_STD, PRETTYINDENT_STD, 0); + if (IsA(query->limitCount, Const) && + ((Const *) query->limitCount)->constisnull) + appendStringInfoString(buf, "ALL"); + else + get_rule_expr(query->limitCount, context, false); + } } /* Add FOR [KEY] UPDATE/SHARE clauses if present */ diff --git a/src/backend/distributed/planner/multi_logical_optimizer.c b/src/backend/distributed/planner/multi_logical_optimizer.c index 5ee7e51eb..0753bf0ee 100644 --- a/src/backend/distributed/planner/multi_logical_optimizer.c +++ b/src/backend/distributed/planner/multi_logical_optimizer.c @@ -1490,6 +1490,9 @@ MasterExtendedOpNode(MultiExtendedOp *originalOpNode, masterExtendedOpNode->hasDistinctOn = originalOpNode->hasDistinctOn; masterExtendedOpNode->limitCount = originalOpNode->limitCount; masterExtendedOpNode->limitOffset = originalOpNode->limitOffset; +#if PG_VERSION_NUM >= PG_VERSION_13 + masterExtendedOpNode->limitOption = originalOpNode->limitOption; +#endif masterExtendedOpNode->havingQual = newHavingQual; if (!extendedOpNodeProperties->onlyPushableWindowFunctions) @@ -2430,7 +2433,8 @@ WorkerExtendedOpNode(MultiExtendedOp *originalOpNode, originalTargetEntryList); ProcessLimitOrderByForWorkerQuery(limitOrderByReference, originalLimitCount, - originalLimitOffset, originalSortClauseList, + originalLimitOffset, + originalSortClauseList, originalGroupClauseList, originalTargetEntryList, &queryOrderByLimit, @@ -2450,6 +2454,14 @@ WorkerExtendedOpNode(MultiExtendedOp *originalOpNode, workerExtendedOpNode->windowClause = queryWindowClause.workerWindowClauseList; workerExtendedOpNode->sortClauseList = queryOrderByLimit.workerSortClauseList; workerExtendedOpNode->limitCount = queryOrderByLimit.workerLimitCount; +#if PG_VERSION_NUM >= PG_VERSION_13 + + /* + * If the limitCount cannot be pushed down it will be NULL, so the deparser will + * ignore the limitOption. + */ + workerExtendedOpNode->limitOption = originalOpNode->limitOption; +#endif return workerExtendedOpNode; } diff --git a/src/backend/distributed/planner/multi_logical_planner.c b/src/backend/distributed/planner/multi_logical_planner.c index 7dfd60324..fb208ef02 100644 --- a/src/backend/distributed/planner/multi_logical_planner.c +++ b/src/backend/distributed/planner/multi_logical_planner.c @@ -1777,6 +1777,9 @@ MultiExtendedOpNode(Query *queryTree, Query *originalQuery) extendedOpNode->sortClauseList = queryTree->sortClause; extendedOpNode->limitCount = queryTree->limitCount; extendedOpNode->limitOffset = queryTree->limitOffset; +#if PG_VERSION_NUM >= PG_VERSION_13 + extendedOpNode->limitOption = queryTree->limitOption; +#endif extendedOpNode->havingQual = queryTree->havingQual; extendedOpNode->distinctClause = queryTree->distinctClause; extendedOpNode->hasDistinctOn = queryTree->hasDistinctOn; diff --git a/src/backend/distributed/planner/multi_physical_planner.c b/src/backend/distributed/planner/multi_physical_planner.c index dd4c2ebfd..a258924af 100644 --- a/src/backend/distributed/planner/multi_physical_planner.c +++ b/src/backend/distributed/planner/multi_physical_planner.c @@ -515,6 +515,9 @@ BuildJobQuery(MultiNode *multiNode, List *dependentJobList) List *sortClauseList = NIL; Node *limitCount = NULL; Node *limitOffset = NULL; +#if PG_VERSION_NUM >= PG_VERSION_13 + LimitOption limitOption = LIMIT_OPTION_DEFAULT; +#endif Node *havingQual = NULL; bool hasDistinctOn = false; List *distinctClause = NIL; @@ -596,6 +599,9 @@ BuildJobQuery(MultiNode *multiNode, List *dependentJobList) limitCount = extendedOp->limitCount; limitOffset = extendedOp->limitOffset; +#if PG_VERSION_NUM >= PG_VERSION_13 + limitOption = extendedOp->limitOption; +#endif sortClauseList = extendedOp->sortClauseList; havingQual = extendedOp->havingQual; } @@ -651,6 +657,9 @@ BuildJobQuery(MultiNode *multiNode, List *dependentJobList) jobQuery->groupClause = groupClauseList; jobQuery->limitOffset = limitOffset; jobQuery->limitCount = limitCount; +#if PG_VERSION_NUM >= PG_VERSION_13 + jobQuery->limitOption = limitOption; +#endif jobQuery->havingQual = havingQual; jobQuery->hasAggs = contain_aggs_of_level((Node *) targetList, 0) || contain_aggs_of_level((Node *) havingQual, 0); diff --git a/src/backend/distributed/utils/citus_outfuncs.c b/src/backend/distributed/utils/citus_outfuncs.c index 97d4d47d6..1043c06a7 100644 --- a/src/backend/distributed/utils/citus_outfuncs.c +++ b/src/backend/distributed/utils/citus_outfuncs.c @@ -321,6 +321,9 @@ OutMultiExtendedOp(OUTFUNC_ARGS) WRITE_NODE_FIELD(sortClauseList); WRITE_NODE_FIELD(limitCount); WRITE_NODE_FIELD(limitOffset); +#if PG_VERSION_NUM >= PG_VERSION_13 + WRITE_ENUM_FIELD(limitOption, LimitOption); +#endif WRITE_NODE_FIELD(havingQual); WRITE_BOOL_FIELD(hasDistinctOn); WRITE_NODE_FIELD(distinctClause); diff --git a/src/include/distributed/multi_logical_planner.h b/src/include/distributed/multi_logical_planner.h index 9bb41a96d..55655a2f3 100644 --- a/src/include/distributed/multi_logical_planner.h +++ b/src/include/distributed/multi_logical_planner.h @@ -174,6 +174,9 @@ typedef struct MultiExtendedOp List *sortClauseList; Node *limitCount; Node *limitOffset; +#if PG_VERSION_NUM >= PG_VERSION_13 + LimitOption limitOption; +#endif Node *havingQual; List *distinctClause; List *windowClause; diff --git a/src/test/regress/expected/pg13_with_ties.out b/src/test/regress/expected/pg13_with_ties.out new file mode 100644 index 000000000..5219b093d --- /dev/null +++ b/src/test/regress/expected/pg13_with_ties.out @@ -0,0 +1,287 @@ +SHOW server_version \gset +SELECT substring(:'server_version', '\d+')::int > 12 AS server_version_above_twelve +\gset +\if :server_version_above_twelve +\else +\q +\endif +CREATE TABLE with_ties_table (a INT, b INT); +SELECT create_distributed_table('with_ties_table', 'a'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +INSERT INTO with_ties_table VALUES (10, 20), (11, 21), (12, 22), (12, 22), (12, 22), (12, 23), (14, 24); +-- test ordering by distribution column +SELECT a FROM with_ties_table ORDER BY a OFFSET 1 FETCH FIRST 2 ROWS WITH TIES; + a +--------------------------------------------------------------------- + 11 + 12 + 12 + 12 + 12 +(5 rows) + +-- test ordering by non-distribution column +SELECT b FROM with_ties_table ORDER BY b OFFSET 1 FETCH FIRST 2 ROWS WITH TIES; + b +--------------------------------------------------------------------- + 21 + 22 + 22 + 22 +(4 rows) + +-- test ordering by distribution column filtering one shard +SELECT a FROM with_ties_table WHERE a=12 ORDER BY a OFFSET 1 FETCH FIRST 1 ROWS WITH TIES; + a +--------------------------------------------------------------------- + 12 + 12 + 12 +(3 rows) + +-- test ordering by non-distribution column filtering one shard +SELECT b FROM with_ties_table WHERE a=12 ORDER BY b OFFSET 1 FETCH FIRST 1 ROWS WITH TIES; + b +--------------------------------------------------------------------- + 22 + 22 +(2 rows) + +-- test INSERT SELECTs into local table +CREATE TABLE with_ties_table_2 (a INT, b INT); +-- test ordering by distribution column +INSERT INTO with_ties_table_2 SELECT a, b FROM with_ties_table ORDER BY a OFFSET 1 FETCH FIRST 2 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; + a | b +--------------------------------------------------------------------- + 11 | 21 + 12 | 22 + 12 | 22 + 12 | 22 + 12 | 23 +(5 rows) + +TRUNCATE with_ties_table_2; +-- test ordering by non-distribution column +INSERT INTO with_ties_table_2 SELECT a, b FROM with_ties_table ORDER BY b OFFSET 1 FETCH FIRST 2 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; + a | b +--------------------------------------------------------------------- + 11 | 21 + 12 | 22 + 12 | 22 + 12 | 22 +(4 rows) + +TRUNCATE with_ties_table_2; +-- test ordering by distribution column filtering one shard +INSERT INTO with_ties_table_2 SELECT a FROM with_ties_table WHERE a=12 ORDER BY a OFFSET 1 FETCH FIRST 1 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; + a | b +--------------------------------------------------------------------- + 12 | + 12 | + 12 | +(3 rows) + +TRUNCATE with_ties_table_2; +-- test ordering by non-distribution column filtering one shard +INSERT INTO with_ties_table_2 SELECT a, b FROM with_ties_table WHERE a=12 ORDER BY b OFFSET 1 FETCH FIRST 1 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; + a | b +--------------------------------------------------------------------- + 12 | 22 + 12 | 22 +(2 rows) + +TRUNCATE with_ties_table_2; +-- test INSERT SELECTs into distributed table +SELECT create_distributed_table('with_ties_table_2', 'a'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +-- test ordering by distribution column +INSERT INTO with_ties_table_2 SELECT a, b FROM with_ties_table ORDER BY a OFFSET 1 FETCH FIRST 2 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; + a | b +--------------------------------------------------------------------- + 11 | 21 + 12 | 22 + 12 | 22 + 12 | 22 + 12 | 23 +(5 rows) + +TRUNCATE with_ties_table_2; +-- test ordering by non-distribution column +INSERT INTO with_ties_table_2 SELECT a, b FROM with_ties_table ORDER BY b OFFSET 1 FETCH FIRST 2 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; + a | b +--------------------------------------------------------------------- + 11 | 21 + 12 | 22 + 12 | 22 + 12 | 22 +(4 rows) + +TRUNCATE with_ties_table_2; +-- test ordering by distribution column filtering one shard +INSERT INTO with_ties_table_2 SELECT a FROM with_ties_table WHERE a=12 ORDER BY a OFFSET 1 FETCH FIRST 1 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; + a | b +--------------------------------------------------------------------- + 12 | + 12 | + 12 | +(3 rows) + +TRUNCATE with_ties_table_2; +-- test ordering by non-distribution column filtering one shard +INSERT INTO with_ties_table_2 SELECT a, b FROM with_ties_table WHERE a=12 ORDER BY b OFFSET 1 FETCH FIRST 1 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; + a | b +--------------------------------------------------------------------- + 12 | 22 + 12 | 22 +(2 rows) + +TRUNCATE with_ties_table_2; +-- test INSERT SELECTs into distributed table with a different distribution column +SELECT undistribute_table('with_ties_table_2'); +NOTICE: Creating a new local table for public.with_ties_table_2 +NOTICE: Moving the data of public.with_ties_table_2 +NOTICE: Dropping the old public.with_ties_table_2 +NOTICE: Renaming the new table to public.with_ties_table_2 + undistribute_table +--------------------------------------------------------------------- + +(1 row) + +SELECT create_distributed_table('with_ties_table_2', 'b'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +-- test ordering by distribution column +INSERT INTO with_ties_table_2 SELECT a, b FROM with_ties_table ORDER BY a OFFSET 1 FETCH FIRST 2 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; + a | b +--------------------------------------------------------------------- + 11 | 21 + 12 | 22 + 12 | 22 + 12 | 22 + 12 | 23 +(5 rows) + +TRUNCATE with_ties_table_2; +-- test ordering by non-distribution column +INSERT INTO with_ties_table_2 SELECT a, b FROM with_ties_table ORDER BY b OFFSET 1 FETCH FIRST 2 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; + a | b +--------------------------------------------------------------------- + 11 | 21 + 12 | 22 + 12 | 22 + 12 | 22 +(4 rows) + +TRUNCATE with_ties_table_2; +-- test ordering by distribution column filtering one shard +-- selecting actual b column makes this test flaky but we have tp select something for dist column +INSERT INTO with_ties_table_2 SELECT a, 1 FROM with_ties_table WHERE a=12 ORDER BY a OFFSET 1 FETCH FIRST 1 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; + a | b +--------------------------------------------------------------------- + 12 | 1 + 12 | 1 + 12 | 1 +(3 rows) + +TRUNCATE with_ties_table_2; +-- test ordering by non-distribution column filtering one shard +INSERT INTO with_ties_table_2 SELECT a, b FROM with_ties_table WHERE a=12 ORDER BY b OFFSET 1 FETCH FIRST 1 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; + a | b +--------------------------------------------------------------------- + 12 | 22 + 12 | 22 +(2 rows) + +TRUNCATE with_ties_table_2; +-- test ordering by multiple columns +SELECT a, b FROM with_ties_table ORDER BY a, b OFFSET 1 FETCH FIRST 2 ROWS WITH TIES; + a | b +--------------------------------------------------------------------- + 11 | 21 + 12 | 22 + 12 | 22 + 12 | 22 +(4 rows) + +-- test ordering by multiple columns filtering one shard +SELECT a, b FROM with_ties_table WHERE a=12 ORDER BY a, b OFFSET 1 FETCH FIRST 1 ROWS WITH TIES; + a | b +--------------------------------------------------------------------- + 12 | 22 + 12 | 22 +(2 rows) + +-- test without ties +-- test ordering by distribution column +SELECT a FROM with_ties_table ORDER BY a OFFSET 1 FETCH FIRST 2 ROWS ONLY; + a +--------------------------------------------------------------------- + 11 + 12 +(2 rows) + +-- test ordering by non-distribution column +SELECT b FROM with_ties_table ORDER BY b OFFSET 1 FETCH FIRST 2 ROWS ONLY; + b +--------------------------------------------------------------------- + 21 + 22 +(2 rows) + +-- test ordering by distribution column filtering one shard +SELECT a FROM with_ties_table WHERE a=12 ORDER BY a OFFSET 1 FETCH FIRST 1 ROWS ONLY; + a +--------------------------------------------------------------------- + 12 +(1 row) + +-- test ordering by non-distribution column filtering one shard +SELECT b FROM with_ties_table WHERE a=12 ORDER BY b OFFSET 1 FETCH FIRST 1 ROWS ONLY; + b +--------------------------------------------------------------------- + 22 +(1 row) + +--test other syntaxes +SELECT a FROM with_ties_table ORDER BY a OFFSET 1 FETCH NEXT 2 ROW WITH TIES; + a +--------------------------------------------------------------------- + 11 + 12 + 12 + 12 + 12 +(5 rows) + +SELECT a FROM with_ties_table ORDER BY a OFFSET 2 FETCH NEXT ROW WITH TIES; + a +--------------------------------------------------------------------- + 12 + 12 + 12 + 12 +(4 rows) + diff --git a/src/test/regress/expected/pg13_with_ties_0.out b/src/test/regress/expected/pg13_with_ties_0.out new file mode 100644 index 000000000..e25fbb82d --- /dev/null +++ b/src/test/regress/expected/pg13_with_ties_0.out @@ -0,0 +1,6 @@ +SHOW server_version \gset +SELECT substring(:'server_version', '\d+')::int > 12 AS server_version_above_twelve +\gset +\if :server_version_above_twelve +\else +\q diff --git a/src/test/regress/multi_schedule b/src/test/regress/multi_schedule index f2772abfb..4a772fe0a 100644 --- a/src/test/regress/multi_schedule +++ b/src/test/regress/multi_schedule @@ -94,7 +94,7 @@ test: sql_procedure multi_function_in_join row_types materialized_view undistrib test: multi_subquery_in_where_reference_clause full_join adaptive_executor propagate_set_commands test: multi_subquery_union multi_subquery_in_where_clause multi_subquery_misc statement_cancel_error_message test: multi_agg_distinct multi_agg_approximate_distinct multi_limit_clause_approximate multi_outer_join_reference multi_single_relation_subquery multi_prepare_plsql set_role_in_transaction -test: multi_reference_table multi_select_for_update relation_access_tracking +test: multi_reference_table multi_select_for_update relation_access_tracking pg13_with_ties test: custom_aggregate_support aggregate_support tdigest_aggregate_support test: multi_average_expression multi_working_columns multi_having_pushdown having_subquery test: multi_array_agg multi_limit_clause multi_orderby_limit_pushdown diff --git a/src/test/regress/multi_schedule_hyperscale b/src/test/regress/multi_schedule_hyperscale index b5a529119..9df744b8f 100644 --- a/src/test/regress/multi_schedule_hyperscale +++ b/src/test/regress/multi_schedule_hyperscale @@ -67,7 +67,7 @@ test: multi_subquery_in_where_reference_clause full_join adaptive_executor propa test: rollback_to_savepoint insert_select_into_local_table undistribute_table test: multi_subquery_union multi_subquery_in_where_clause multi_subquery_misc test: multi_limit_clause_approximate multi_single_relation_subquery set_role_in_transaction -test: multi_select_for_update +test: multi_select_for_update pg13_with_ties test: multi_average_expression multi_working_columns multi_having_pushdown test: multi_array_agg test: multi_jsonb_agg multi_jsonb_object_agg multi_json_agg multi_json_object_agg bool_agg ch_bench_having ch_bench_subquery_repartition chbenchmark_all_queries expression_reference_join diff --git a/src/test/regress/multi_schedule_hyperscale_superuser b/src/test/regress/multi_schedule_hyperscale_superuser index 1fe0f0fdc..9641e1191 100644 --- a/src/test/regress/multi_schedule_hyperscale_superuser +++ b/src/test/regress/multi_schedule_hyperscale_superuser @@ -72,7 +72,7 @@ test: multi_function_in_join row_types materialized_view test: multi_subquery_in_where_reference_clause full_join adaptive_executor propagate_set_commands test: multi_subquery_union multi_subquery_in_where_clause multi_subquery_misc test: multi_agg_distinct multi_limit_clause_approximate multi_outer_join_reference -test: multi_select_for_update relation_access_tracking +test: multi_select_for_update relation_access_tracking pg13_with_ties test: multi_working_columns multi_having_pushdown test: bool_agg ch_bench_having ch_bench_subquery_repartition chbenchmark_all_queries expression_reference_join test: multi_agg_type_conversion multi_count_type_conversion diff --git a/src/test/regress/sql/pg13_with_ties.sql b/src/test/regress/sql/pg13_with_ties.sql new file mode 100644 index 000000000..b8ba29bb7 --- /dev/null +++ b/src/test/regress/sql/pg13_with_ties.sql @@ -0,0 +1,124 @@ +SHOW server_version \gset +SELECT substring(:'server_version', '\d+')::int > 12 AS server_version_above_twelve +\gset +\if :server_version_above_twelve +\else +\q +\endif + + +CREATE TABLE with_ties_table (a INT, b INT); +SELECT create_distributed_table('with_ties_table', 'a'); +INSERT INTO with_ties_table VALUES (10, 20), (11, 21), (12, 22), (12, 22), (12, 22), (12, 23), (14, 24); + +-- test ordering by distribution column +SELECT a FROM with_ties_table ORDER BY a OFFSET 1 FETCH FIRST 2 ROWS WITH TIES; + +-- test ordering by non-distribution column +SELECT b FROM with_ties_table ORDER BY b OFFSET 1 FETCH FIRST 2 ROWS WITH TIES; + +-- test ordering by distribution column filtering one shard +SELECT a FROM with_ties_table WHERE a=12 ORDER BY a OFFSET 1 FETCH FIRST 1 ROWS WITH TIES; + +-- test ordering by non-distribution column filtering one shard +SELECT b FROM with_ties_table WHERE a=12 ORDER BY b OFFSET 1 FETCH FIRST 1 ROWS WITH TIES; + + +-- test INSERT SELECTs into local table +CREATE TABLE with_ties_table_2 (a INT, b INT); + +-- test ordering by distribution column +INSERT INTO with_ties_table_2 SELECT a, b FROM with_ties_table ORDER BY a OFFSET 1 FETCH FIRST 2 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; +TRUNCATE with_ties_table_2; + +-- test ordering by non-distribution column +INSERT INTO with_ties_table_2 SELECT a, b FROM with_ties_table ORDER BY b OFFSET 1 FETCH FIRST 2 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; +TRUNCATE with_ties_table_2; + +-- test ordering by distribution column filtering one shard +INSERT INTO with_ties_table_2 SELECT a FROM with_ties_table WHERE a=12 ORDER BY a OFFSET 1 FETCH FIRST 1 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; +TRUNCATE with_ties_table_2; + +-- test ordering by non-distribution column filtering one shard +INSERT INTO with_ties_table_2 SELECT a, b FROM with_ties_table WHERE a=12 ORDER BY b OFFSET 1 FETCH FIRST 1 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; +TRUNCATE with_ties_table_2; + + +-- test INSERT SELECTs into distributed table +SELECT create_distributed_table('with_ties_table_2', 'a'); + +-- test ordering by distribution column +INSERT INTO with_ties_table_2 SELECT a, b FROM with_ties_table ORDER BY a OFFSET 1 FETCH FIRST 2 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; +TRUNCATE with_ties_table_2; + +-- test ordering by non-distribution column +INSERT INTO with_ties_table_2 SELECT a, b FROM with_ties_table ORDER BY b OFFSET 1 FETCH FIRST 2 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; +TRUNCATE with_ties_table_2; + +-- test ordering by distribution column filtering one shard +INSERT INTO with_ties_table_2 SELECT a FROM with_ties_table WHERE a=12 ORDER BY a OFFSET 1 FETCH FIRST 1 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; +TRUNCATE with_ties_table_2; + +-- test ordering by non-distribution column filtering one shard +INSERT INTO with_ties_table_2 SELECT a, b FROM with_ties_table WHERE a=12 ORDER BY b OFFSET 1 FETCH FIRST 1 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; +TRUNCATE with_ties_table_2; + + +-- test INSERT SELECTs into distributed table with a different distribution column +SELECT undistribute_table('with_ties_table_2'); +SELECT create_distributed_table('with_ties_table_2', 'b'); + +-- test ordering by distribution column +INSERT INTO with_ties_table_2 SELECT a, b FROM with_ties_table ORDER BY a OFFSET 1 FETCH FIRST 2 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; +TRUNCATE with_ties_table_2; + +-- test ordering by non-distribution column +INSERT INTO with_ties_table_2 SELECT a, b FROM with_ties_table ORDER BY b OFFSET 1 FETCH FIRST 2 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; +TRUNCATE with_ties_table_2; + +-- test ordering by distribution column filtering one shard +-- selecting actual b column makes this test flaky but we have tp select something for dist column +INSERT INTO with_ties_table_2 SELECT a, 1 FROM with_ties_table WHERE a=12 ORDER BY a OFFSET 1 FETCH FIRST 1 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; +TRUNCATE with_ties_table_2; + +-- test ordering by non-distribution column filtering one shard +INSERT INTO with_ties_table_2 SELECT a, b FROM with_ties_table WHERE a=12 ORDER BY b OFFSET 1 FETCH FIRST 1 ROWS WITH TIES; +SELECT * FROM with_ties_table_2 ORDER BY a, b; +TRUNCATE with_ties_table_2; + + +-- test ordering by multiple columns +SELECT a, b FROM with_ties_table ORDER BY a, b OFFSET 1 FETCH FIRST 2 ROWS WITH TIES; + +-- test ordering by multiple columns filtering one shard +SELECT a, b FROM with_ties_table WHERE a=12 ORDER BY a, b OFFSET 1 FETCH FIRST 1 ROWS WITH TIES; + + +-- test without ties +-- test ordering by distribution column +SELECT a FROM with_ties_table ORDER BY a OFFSET 1 FETCH FIRST 2 ROWS ONLY; + +-- test ordering by non-distribution column +SELECT b FROM with_ties_table ORDER BY b OFFSET 1 FETCH FIRST 2 ROWS ONLY; + +-- test ordering by distribution column filtering one shard +SELECT a FROM with_ties_table WHERE a=12 ORDER BY a OFFSET 1 FETCH FIRST 1 ROWS ONLY; + +-- test ordering by non-distribution column filtering one shard +SELECT b FROM with_ties_table WHERE a=12 ORDER BY b OFFSET 1 FETCH FIRST 1 ROWS ONLY; + + +--test other syntaxes +SELECT a FROM with_ties_table ORDER BY a OFFSET 1 FETCH NEXT 2 ROW WITH TIES; +SELECT a FROM with_ties_table ORDER BY a OFFSET 2 FETCH NEXT ROW WITH TIES;