diff --git a/src/backend/distributed/planner/recursive_planning.c b/src/backend/distributed/planner/recursive_planning.c index cd2871ec4..b9331e0f3 100644 --- a/src/backend/distributed/planner/recursive_planning.c +++ b/src/backend/distributed/planner/recursive_planning.c @@ -126,7 +126,8 @@ static bool CteReferenceListWalker(Node *node, CteReferenceWalkerContext *contex static bool ContainsReferencesToOuterQuery(Query *query); static bool ContainsReferencesToOuterQueryWalker(Node *node, VarLevelsUpWalkerContext *context); -static Query * BuildSubPlanResultQuery(Query *subquery, uint64 planId, uint32 subPlanId); +static Query * BuildSubPlanResultQuery(Query *subquery, List *columnAliasList, + uint64 planId, uint32 subPlanId); /* @@ -295,7 +296,8 @@ RecursivelyPlanCTEs(Query *query, RecursivePlanningContext *planningContext) planningContext->subPlanList = lappend(planningContext->subPlanList, subPlan); /* replace references to the CTE with a subquery that reads results */ - resultQuery = BuildSubPlanResultQuery(subquery, planId, subPlanId); + resultQuery = BuildSubPlanResultQuery(subquery, cte->aliascolnames, planId, + subPlanId); foreach(rteCell, context.cteReferenceList) { @@ -528,7 +530,11 @@ RecursivelyPlanSubquery(Query *subquery, RecursivePlanningContext *planningConte subPlan = CreateDistributedSubPlan(subPlanId, subquery); planningContext->subPlanList = lappend(planningContext->subPlanList, subPlan); - resultQuery = BuildSubPlanResultQuery(subquery, planId, subPlanId); + /* + * BuildSubPlanResultQuery() can optionally use provided column aliases. + * We do not need to send additional alias list for subqueries. + */ + resultQuery = BuildSubPlanResultQuery(subquery, NIL, planId, subPlanId); if (log_min_messages <= DEBUG1 || client_min_messages <= DEBUG1) { @@ -712,13 +718,15 @@ ContainsReferencesToOuterQueryWalker(Node *node, VarLevelsUpWalkerContext *conte * read_intermediate_result('_', ') * AS res (); * - * The target list and column definition list are derived from the given subquery. + * The target list and column definition list are derived from the given subquery + * and columm name alias list. * * If any of the types in the target list cannot be used in the binary copy format, * then the copy format 'text' is used, otherwise 'binary' is used. */ static Query * -BuildSubPlanResultQuery(Query *subquery, uint64 planId, uint32 subPlanId) +BuildSubPlanResultQuery(Query *subquery, List *columnAliasList, uint64 planId, + uint32 subPlanId) { Query *resultQuery = NULL; char *resultIdString = NULL; @@ -739,6 +747,7 @@ BuildSubPlanResultQuery(Query *subquery, uint64 planId, uint32 subPlanId) int columnNumber = 1; bool useBinaryCopyFormat = true; Oid copyFormatId = BinaryCopyFormatId(); + int columnAliasCount = list_length(columnAliasList); /* build the target list and column definition list */ foreach(targetEntryCell, subquery->targetList) @@ -776,7 +785,23 @@ BuildSubPlanResultQuery(Query *subquery, uint64 planId, uint32 subPlanId) newTargetEntry = makeNode(TargetEntry); newTargetEntry->expr = (Expr *) functionColumnVar; newTargetEntry->resno = columnNumber; - newTargetEntry->resname = columnName; + + /* + * Rename the column only if a column alias is defined. + * Notice that column alias count could be less than actual + * column count. We only use provided aliases and keep the + * original column names if no alias is defined. + */ + if (columnAliasCount >= columnNumber) + { + Value *columnAlias = (Value *) list_nth(columnAliasList, columnNumber - 1); + Assert(IsA(columnAlias, String)); + newTargetEntry->resname = strVal(columnAlias); + } + else + { + newTargetEntry->resname = columnName; + } newTargetEntry->resjunk = false; targetList = lappend(targetList, newTargetEntry); diff --git a/src/test/regress/expected/subquery_complex_target_list.out b/src/test/regress/expected/subquery_complex_target_list.out index 32cf90fcb..a3900088c 100644 --- a/src/test/regress/expected/subquery_complex_target_list.out +++ b/src/test/regress/expected/subquery_complex_target_list.out @@ -25,6 +25,23 @@ DEBUG: generating subplan 1_1 for subquery SELECT user_id FROM public.users_tab 4 | 6 (3 rows) +-- column renaming in a subquery +SELECT * +FROM + ( + SELECT user_id, value_1, value_2 FROM users_table OFFSET 0 + ) as foo(x, y) +ORDER BY 1 DESC, 2 DESC, 3 DESC LIMIT 5; +DEBUG: generating subplan 3_1 for subquery SELECT user_id, value_1, value_2 FROM public.users_table OFFSET 0 + x | y | value_2 +---+---+--------- + 6 | 5 | 2 + 6 | 5 | 0 + 6 | 3 | 2 + 6 | 2 | 4 + 6 | 2 | 4 +(5 rows) + -- aggregate distinct in the subqueries -- avg distinct on partition key -- count distinct on partition key @@ -49,12 +66,12 @@ FROM WHERE foo.avg != bar.cnt_1 AND baz.cnt_2 = events_table.event_type ORDER BY 1 DESC; DEBUG: push down of limit count: 3 -DEBUG: generating subplan 3_1 for subquery SELECT avg(DISTINCT user_id) AS avg FROM public.users_table ORDER BY (avg(DISTINCT user_id)) DESC LIMIT 3 +DEBUG: generating subplan 5_1 for subquery SELECT avg(DISTINCT user_id) AS avg FROM public.users_table ORDER BY (avg(DISTINCT user_id)) DESC LIMIT 3 DEBUG: push down of limit count: 3 -DEBUG: generating subplan 3_2 for subquery SELECT count(DISTINCT user_id) AS cnt_1 FROM public.users_table ORDER BY (count(DISTINCT user_id)) DESC LIMIT 3 -DEBUG: generating subplan 3_3 for subquery SELECT count(DISTINCT value_2) AS cnt_2 FROM public.users_table ORDER BY (count(DISTINCT value_2)) DESC LIMIT 4 +DEBUG: generating subplan 5_2 for subquery SELECT count(DISTINCT user_id) AS cnt_1 FROM public.users_table ORDER BY (count(DISTINCT user_id)) DESC LIMIT 3 +DEBUG: generating subplan 5_3 for subquery SELECT count(DISTINCT value_2) AS cnt_2 FROM public.users_table ORDER BY (count(DISTINCT value_2)) DESC LIMIT 4 DEBUG: push down of limit count: 4 -DEBUG: generating subplan 3_4 for subquery SELECT user_id, sum(DISTINCT value_2) AS sum FROM public.users_table GROUP BY user_id ORDER BY user_id DESC LIMIT 4 +DEBUG: generating subplan 5_4 for subquery SELECT user_id, sum(DISTINCT value_2) AS sum FROM public.users_table GROUP BY user_id ORDER BY user_id DESC LIMIT 4 avg | cnt_1 | cnt_2 | sum --------------------+-------+-------+----- 3.5000000000000000 | 6 | 6 | 10 @@ -92,11 +109,11 @@ FROM ) as baz ORDER BY 1 DESC; DEBUG: push down of limit count: 3 -DEBUG: generating subplan 8_1 for subquery SELECT (min(user_id) * 2), (max(user_id) / 2), sum(user_id) AS sum, (count(user_id))::double precision AS count, (avg(user_id))::bigint AS avg FROM public.users_table ORDER BY (min(user_id) * 2) DESC LIMIT 3 +DEBUG: generating subplan 10_1 for subquery SELECT (min(user_id) * 2), (max(user_id) / 2), sum(user_id) AS sum, (count(user_id))::double precision AS count, (avg(user_id))::bigint AS avg FROM public.users_table ORDER BY (min(user_id) * 2) DESC LIMIT 3 DEBUG: push down of limit count: 3 -DEBUG: generating subplan 8_2 for subquery SELECT (min(value_3) * (2)::double precision), (max(value_3) / (2)::double precision), sum(value_3) AS sum, count(value_3) AS count, avg(value_3) AS avg FROM public.users_table ORDER BY (min(value_3) * (2)::double precision) DESC LIMIT 3 +DEBUG: generating subplan 10_2 for subquery SELECT (min(value_3) * (2)::double precision), (max(value_3) / (2)::double precision), sum(value_3) AS sum, count(value_3) AS count, avg(value_3) AS avg FROM public.users_table ORDER BY (min(value_3) * (2)::double precision) DESC LIMIT 3 DEBUG: push down of limit count: 3 -DEBUG: generating subplan 8_3 for subquery SELECT min("time") AS min, max("time") AS max, count("time") AS count, count(*) FILTER (WHERE (user_id = 3)) AS cnt_with_filter, count(*) FILTER (WHERE ((user_id)::text ~~ '%3%'::text)) AS cnt_with_filter_2 FROM public.users_table ORDER BY (min("time")) DESC LIMIT 3 +DEBUG: generating subplan 10_3 for subquery SELECT min("time") AS min, max("time") AS max, count("time") AS count, count(*) FILTER (WHERE (user_id = 3)) AS cnt_with_filter, count(*) FILTER (WHERE ((user_id)::text ~~ '%3%'::text)) AS cnt_with_filter_2 FROM public.users_table ORDER BY (min("time")) DESC LIMIT 3 ?column? | ?column? | sum | count | avg | ?column? | ?column? | sum | count | avg | min | max | count | cnt_with_filter | cnt_with_filter_2 ----------+----------+-----+-------+-----+----------+----------+-----+-------+-----------------+---------------------------------+---------------------------------+-------+-----------------+------------------- 2 | 3 | 376 | 101 | 4 | 0 | 2.5 | 273 | 101 | 2.7029702970297 | Wed Nov 22 18:19:49.944985 2017 | Thu Nov 23 17:30:34.635085 2017 | 101 | 17 | 17 @@ -144,13 +161,13 @@ FROM WHERE foo.avg != bar.cnt_1 AND baz.cnt_2 != events_table.event_type ORDER BY 1 DESC; DEBUG: push down of limit count: 3 -DEBUG: generating subplan 12_1 for subquery SELECT avg(((user_id)::numeric * (5.0 / ((value_1)::numeric + 0.1)))) AS avg FROM public.users_table ORDER BY (avg(((user_id)::numeric * (5.0 / ((value_1)::numeric + 0.1))))) DESC LIMIT 3 +DEBUG: generating subplan 14_1 for subquery SELECT avg(((user_id)::numeric * (5.0 / ((value_1)::numeric + 0.1)))) AS avg FROM public.users_table ORDER BY (avg(((user_id)::numeric * (5.0 / ((value_1)::numeric + 0.1))))) DESC LIMIT 3 DEBUG: push down of limit count: 3 -DEBUG: generating subplan 12_2 for subquery SELECT sum(((((user_id)::numeric * (5.0 / (((value_1 + value_2))::numeric + 0.1))))::double precision * value_3)) AS cnt_1 FROM public.users_table ORDER BY (sum(((((user_id)::numeric * (5.0 / (((value_1 + value_2))::numeric + 0.1))))::double precision * value_3))) DESC LIMIT 3 +DEBUG: generating subplan 14_2 for subquery SELECT sum(((((user_id)::numeric * (5.0 / (((value_1 + value_2))::numeric + 0.1))))::double precision * value_3)) AS cnt_1 FROM public.users_table ORDER BY (sum(((((user_id)::numeric * (5.0 / (((value_1 + value_2))::numeric + 0.1))))::double precision * value_3))) DESC LIMIT 3 DEBUG: push down of limit count: 4 -DEBUG: generating subplan 12_3 for subquery SELECT avg(CASE WHEN (user_id > 4) THEN value_1 ELSE NULL::integer END) AS cnt_2, avg(CASE WHEN (user_id > 500) THEN value_1 ELSE NULL::integer END) AS cnt_3, sum(CASE WHEN ((value_1 = 1) OR (value_2 = 1)) THEN 1 ELSE 0 END) AS sum_1, date_part('year'::text, max("time")) AS l_year, strpos((max(user_id))::text, '1'::text) AS pos FROM public.users_table ORDER BY (avg(CASE WHEN (user_id > 4) THEN value_1 ELSE NULL::integer END)) DESC LIMIT 4 +DEBUG: generating subplan 14_3 for subquery SELECT avg(CASE WHEN (user_id > 4) THEN value_1 ELSE NULL::integer END) AS cnt_2, avg(CASE WHEN (user_id > 500) THEN value_1 ELSE NULL::integer END) AS cnt_3, sum(CASE WHEN ((value_1 = 1) OR (value_2 = 1)) THEN 1 ELSE 0 END) AS sum_1, date_part('year'::text, max("time")) AS l_year, strpos((max(user_id))::text, '1'::text) AS pos FROM public.users_table ORDER BY (avg(CASE WHEN (user_id > 4) THEN value_1 ELSE NULL::integer END)) DESC LIMIT 4 DEBUG: push down of limit count: 25 -DEBUG: generating subplan 12_4 for subquery SELECT COALESCE(value_3, (20)::double precision) AS count_pay FROM public.users_table ORDER BY COALESCE(value_3, (20)::double precision) OFFSET 20 LIMIT 5 +DEBUG: generating subplan 14_4 for subquery SELECT COALESCE(value_3, (20)::double precision) AS count_pay FROM public.users_table ORDER BY COALESCE(value_3, (20)::double precision) OFFSET 20 LIMIT 5 avg | cnt_1 | cnt_2 | cnt_3 | sum_1 | l_year | pos | count_pay -------------------------+------------------+--------------------+-------+-------+--------+-----+----------- 30.14666771571734992301 | 3308.14619815793 | 2.5000000000000000 | | 31 | 2017 | 0 | 1 @@ -170,7 +187,7 @@ FROM WHERE foo.avg = bar.avg2 ORDER BY 1 DESC, 2 DESC LIMIT 3; -DEBUG: generating subplan 17_1 for subquery SELECT avg(value_3) AS avg FROM public.users_table GROUP BY value_1, value_2 +DEBUG: generating subplan 19_1 for subquery SELECT avg(value_3) AS avg FROM public.users_table GROUP BY value_1, value_2 DEBUG: push down of limit count: 3 avg | avg2 -----+------ @@ -227,9 +244,9 @@ FROM ( ORDER BY 3 DESC, 2 DESC, 1 DESC LIMIT 5; DEBUG: push down of limit count: 3 -DEBUG: generating subplan 19_1 for subquery SELECT user_id FROM public.users_table WHERE (value_1 > 2) GROUP BY user_id HAVING (count(DISTINCT value_1) > 2) ORDER BY user_id DESC LIMIT 3 -DEBUG: generating subplan 19_2 for subquery SELECT value_2 FROM public.users_table WHERE (value_1 > 2) GROUP BY value_2 HAVING (count(DISTINCT value_1) > 2) ORDER BY value_2 DESC LIMIT 3 -DEBUG: generating subplan 19_3 for subquery SELECT avg(user_id) AS avg FROM public.users_table WHERE (value_1 > 2) GROUP BY value_2 HAVING (sum(value_1) > 10) ORDER BY ((sum(value_3) - (avg(value_1))::double precision) - (COALESCE((array_upper(ARRAY[max(user_id)], 1) * 5), 0))::double precision) DESC LIMIT 3 +DEBUG: generating subplan 21_1 for subquery SELECT user_id FROM public.users_table WHERE (value_1 > 2) GROUP BY user_id HAVING (count(DISTINCT value_1) > 2) ORDER BY user_id DESC LIMIT 3 +DEBUG: generating subplan 21_2 for subquery SELECT value_2 FROM public.users_table WHERE (value_1 > 2) GROUP BY value_2 HAVING (count(DISTINCT value_1) > 2) ORDER BY value_2 DESC LIMIT 3 +DEBUG: generating subplan 21_3 for subquery SELECT avg(user_id) AS avg FROM public.users_table WHERE (value_1 > 2) GROUP BY value_2 HAVING (sum(value_1) > 10) ORDER BY ((sum(value_3) - (avg(value_1))::double precision) - (COALESCE((array_upper(ARRAY[max(user_id)], 1) * 5), 0))::double precision) DESC LIMIT 3 user_id | value_2 | avg ---------+---------+-------------------- 4 | 5 | 4.1666666666666667 @@ -264,8 +281,8 @@ FROM WHERE foo.user_id > bar.user_id ORDER BY 1 DESC; DEBUG: push down of limit count: 5 -DEBUG: generating subplan 23_1 for subquery SELECT DISTINCT users_table.user_id FROM public.users_table, public.events_table WHERE ((users_table.user_id = events_table.user_id) AND (events_table.event_type = ANY (ARRAY[1, 2, 3, 4]))) ORDER BY users_table.user_id DESC LIMIT 5 -DEBUG: generating subplan 23_2 for subquery SELECT DISTINCT users_table.user_id FROM public.users_table, public.events_table WHERE ((users_table.user_id = events_table.user_id) AND false AND (events_table.event_type = ANY (ARRAY[1, 2, 3, 4]))) ORDER BY users_table.user_id DESC LIMIT 5 +DEBUG: generating subplan 25_1 for subquery SELECT DISTINCT users_table.user_id FROM public.users_table, public.events_table WHERE ((users_table.user_id = events_table.user_id) AND (events_table.event_type = ANY (ARRAY[1, 2, 3, 4]))) ORDER BY users_table.user_id DESC LIMIT 5 +DEBUG: generating subplan 25_2 for subquery SELECT DISTINCT users_table.user_id FROM public.users_table, public.events_table WHERE ((users_table.user_id = events_table.user_id) AND false AND (events_table.event_type = ANY (ARRAY[1, 2, 3, 4]))) ORDER BY users_table.user_id DESC LIMIT 5 user_id --------- (0 rows) @@ -308,8 +325,8 @@ SELECT * FROM ) bar WHERE foo.user_id = bar.user_id ORDER BY foo.rnk DESC, foo.time DESC, bar.time LIMIT 5; DEBUG: push down of limit count: 4 -DEBUG: generating subplan 26_1 for subquery SELECT user_id, "time", event_type, value_2, value_3, value_4, rnk FROM (SELECT events_table.user_id, events_table."time", events_table.event_type, events_table.value_2, events_table.value_3, events_table.value_4, rank() OVER my_win AS rnk FROM public.events_table WINDOW my_win AS (PARTITION BY events_table.user_id ORDER BY events_table."time" DESC) ORDER BY (rank() OVER my_win) DESC) foo_inner LIMIT 4 -DEBUG: generating subplan 26_2 for subquery SELECT user_id, "time", event_type, value_2, value_3, value_4, rank() OVER my_win AS rnk FROM public.events_table WHERE (user_id = 3) WINDOW my_win AS (PARTITION BY event_type ORDER BY "time" DESC) +DEBUG: generating subplan 28_1 for subquery SELECT user_id, "time", event_type, value_2, value_3, value_4, rnk FROM (SELECT events_table.user_id, events_table."time", events_table.event_type, events_table.value_2, events_table.value_3, events_table.value_4, rank() OVER my_win AS rnk FROM public.events_table WINDOW my_win AS (PARTITION BY events_table.user_id ORDER BY events_table."time" DESC) ORDER BY (rank() OVER my_win) DESC) foo_inner LIMIT 4 +DEBUG: generating subplan 28_2 for subquery SELECT user_id, "time", event_type, value_2, value_3, value_4, rank() OVER my_win AS rnk FROM public.events_table WHERE (user_id = 3) WINDOW my_win AS (PARTITION BY event_type ORDER BY "time" DESC) user_id | time | rnk | user_id | time | rnk ---------+------+-----+---------+------+----- (0 rows) @@ -329,7 +346,7 @@ BEGIN; ORDER BY 1 DESC, 2 DESC LIMIT 3; DEBUG: push down of limit count: 20 -DEBUG: generating subplan 29_1 for subquery SELECT user_id FROM public.users_table GROUP BY user_id ORDER BY (count(*)) DESC LIMIT 20 +DEBUG: generating subplan 31_1 for subquery SELECT user_id FROM public.users_table GROUP BY user_id ORDER BY (count(*)) DESC LIMIT 20 FETCH 1 FROM recursive_subquery; event_type | count ------------+------- @@ -369,7 +386,7 @@ BEGIN; ORDER BY 1 DESC, 2 DESC LIMIT 3; DEBUG: push down of limit count: 20 -DEBUG: generating subplan 31_1 for subquery SELECT user_id FROM public.users_table GROUP BY user_id ORDER BY (count(*)) DESC LIMIT 20 +DEBUG: generating subplan 33_1 for subquery SELECT user_id FROM public.users_table GROUP BY user_id ORDER BY (count(*)) DESC LIMIT 20 FETCH ALL FROM recursive_subquery; event_type | count ------------+------- diff --git a/src/test/regress/expected/with_basics.out b/src/test/regress/expected/with_basics.out index 405aa24d3..00efb1ec0 100644 --- a/src/test/regress/expected/with_basics.out +++ b/src/test/regress/expected/with_basics.out @@ -237,6 +237,107 @@ JOIN 6 (10 rows) +-- column aliases in CTE +WITH top_ten(id, val1) AS ( + SELECT user_id, value_1 FROM users_table ORDER BY value_1 DESC, user_id DESC LIMIT 10 +) +SELECT * FROM top_ten; + id | val1 +----+------ + 6 | 5 + 6 | 5 + 5 | 5 + 5 | 5 + 5 | 5 + 4 | 5 + 4 | 5 + 3 | 5 + 1 | 5 + 5 | 4 +(10 rows) + +-- verify old name is not valid anymore +WITH top_ten(id, val1) AS ( + SELECT user_id, value_1 FROM users_table ORDER BY value_1 DESC, user_id DESC LIMIT 10 +) +SELECT * FROM top_ten ORDER BY user_id DESC; +ERROR: column "user_id" does not exist +LINE 4: SELECT * FROM top_ten ORDER BY user_id DESC; + ^ +-- verify original name is used if alias is missing +WITH top_ten(id) AS ( + SELECT user_id, value_1 FROM users_table ORDER BY value_1 DESC, user_id DESC LIMIT 10 +) +SELECT * FROM top_ten ORDER BY value_1 DESC; + id | value_1 +----+--------- + 6 | 5 + 6 | 5 + 5 | 5 + 5 | 5 + 5 | 5 + 4 | 5 + 4 | 5 + 3 | 5 + 1 | 5 + 5 | 4 +(10 rows) + +-- computed targets from columns also work +WITH top_ten(id, val, val_mul, val_sum) AS ( + SELECT user_id, value_1, value_1*2, value_1 + value_2 FROM users_table ORDER BY value_1 DESC, user_id DESC, value_2 DESC LIMIT 10 +) +SELECT * FROM top_ten ORDER BY id DESC, val_mul DESC, (val_sum + 1) DESC; + id | val | val_mul | val_sum +----+-----+---------+--------- + 6 | 5 | 10 | 7 + 6 | 5 | 10 | 5 + 5 | 5 | 10 | 10 + 5 | 5 | 10 | 7 + 5 | 5 | 10 | 6 + 5 | 4 | 8 | 7 + 4 | 5 | 10 | 9 + 4 | 5 | 10 | 8 + 3 | 5 | 10 | 10 + 1 | 5 | 10 | 9 +(10 rows) + +-- computed targets from columns in outer query +WITH top_ten(id, val, val_mul, val_sum) AS ( + SELECT user_id, value_1, value_1*2, value_1 + value_2 FROM users_table ORDER BY value_1 DESC, value_2 DESC, user_id DESC LIMIT 10 +) +SELECT id, val, id * val, val_sum * 2, val_sum + val_sum FROM top_ten ORDER BY 1 DESC, 2 DESC, 3 DESC, 4 DESC; + id | val | ?column? | ?column? | ?column? +----+-----+----------+----------+---------- + 6 | 5 | 30 | 14 | 14 + 6 | 5 | 30 | 10 | 10 + 5 | 5 | 25 | 20 | 20 + 5 | 5 | 25 | 14 | 14 + 5 | 5 | 25 | 12 | 12 + 4 | 5 | 20 | 18 | 18 + 4 | 5 | 20 | 16 | 16 + 4 | 4 | 16 | 18 | 18 + 3 | 5 | 15 | 20 | 20 + 1 | 5 | 5 | 18 | 18 +(10 rows) + +-- computed targets from columns and group by outside +WITH top_ten(id, val, val_mul, val_sum) AS ( + SELECT user_id, value_1, value_1*2, value_1 + value_2 FROM users_table ORDER BY value_1 DESC, user_id DESC +) +SELECT id, count(*), avg(val), max(val_mul), min(val_sum) FROM top_ten +GROUP BY id +ORDER BY 2 DESC, 1 DESC; + id | count | avg | max | min +----+-------+--------------------+-----+----- + 5 | 26 | 2.6538461538461538 | 10 | 2 + 4 | 23 | 2.7391304347826087 | 10 | 0 + 2 | 18 | 2.3333333333333333 | 8 | 1 + 3 | 17 | 2.3529411764705882 | 10 | 2 + 6 | 10 | 2.1000000000000000 | 10 | 0 + 1 | 7 | 3.2857142857142857 | 10 | 4 +(6 rows) + -- FOR UPDATE in subquery on CTE WITH top_users AS ( SELECT user_id, value_2 FROM users_table ORDER BY user_id DESC LIMIT 10 diff --git a/src/test/regress/sql/subquery_complex_target_list.sql b/src/test/regress/sql/subquery_complex_target_list.sql index 431f57b00..751b3606b 100644 --- a/src/test/regress/sql/subquery_complex_target_list.sql +++ b/src/test/regress/sql/subquery_complex_target_list.sql @@ -19,6 +19,13 @@ GROUP BY ORDER BY 1 DESC, 2 DESC LIMIT 3; +-- column renaming in a subquery +SELECT * +FROM + ( + SELECT user_id, value_1, value_2 FROM users_table OFFSET 0 + ) as foo(x, y) +ORDER BY 1 DESC, 2 DESC, 3 DESC LIMIT 5; -- aggregate distinct in the subqueries -- avg distinct on partition key diff --git a/src/test/regress/sql/with_basics.sql b/src/test/regress/sql/with_basics.sql index 8bd755d99..ca96a8075 100644 --- a/src/test/regress/sql/with_basics.sql +++ b/src/test/regress/sql/with_basics.sql @@ -156,6 +156,44 @@ FROM JOIN users_table USING (user_id); +-- column aliases in CTE +WITH top_ten(id, val1) AS ( + SELECT user_id, value_1 FROM users_table ORDER BY value_1 DESC, user_id DESC LIMIT 10 +) +SELECT * FROM top_ten; + +-- verify old name is not valid anymore +WITH top_ten(id, val1) AS ( + SELECT user_id, value_1 FROM users_table ORDER BY value_1 DESC, user_id DESC LIMIT 10 +) +SELECT * FROM top_ten ORDER BY user_id DESC; + +-- verify original name is used if alias is missing +WITH top_ten(id) AS ( + SELECT user_id, value_1 FROM users_table ORDER BY value_1 DESC, user_id DESC LIMIT 10 +) +SELECT * FROM top_ten ORDER BY value_1 DESC; + +-- computed targets from columns also work +WITH top_ten(id, val, val_mul, val_sum) AS ( + SELECT user_id, value_1, value_1*2, value_1 + value_2 FROM users_table ORDER BY value_1 DESC, user_id DESC, value_2 DESC LIMIT 10 +) +SELECT * FROM top_ten ORDER BY id DESC, val_mul DESC, (val_sum + 1) DESC; + +-- computed targets from columns in outer query +WITH top_ten(id, val, val_mul, val_sum) AS ( + SELECT user_id, value_1, value_1*2, value_1 + value_2 FROM users_table ORDER BY value_1 DESC, value_2 DESC, user_id DESC LIMIT 10 +) +SELECT id, val, id * val, val_sum * 2, val_sum + val_sum FROM top_ten ORDER BY 1 DESC, 2 DESC, 3 DESC, 4 DESC; + +-- computed targets from columns and group by outside +WITH top_ten(id, val, val_mul, val_sum) AS ( + SELECT user_id, value_1, value_1*2, value_1 + value_2 FROM users_table ORDER BY value_1 DESC, user_id DESC +) +SELECT id, count(*), avg(val), max(val_mul), min(val_sum) FROM top_ten +GROUP BY id +ORDER BY 2 DESC, 1 DESC; + -- FOR UPDATE in subquery on CTE WITH top_users AS ( SELECT user_id, value_2 FROM users_table ORDER BY user_id DESC LIMIT 10