From 449d1f0e91ba227b70c2b14e17d0f0f521aaca56 Mon Sep 17 00:00:00 2001 From: Nils Dijk Date: Mon, 13 Jul 2020 16:29:24 +0200 Subject: [PATCH] force aliases in deparsing for queries with anonymous column references (#4011) DESCRIPTION: Force aliases in deparsing for queries with anonymous column references Fixes: #3985 The root cause has todo with discrepancies in the query tree we create. I think in the future we should spend some time on categorising all changes we made to ruleutils and see if we can change the data structure `query` we pass to the deparser to have an actual valid postgres query for the deparser to render. For now the fix is to keep track, besides changing the names of the entries in the target list, also if we have a reference to an anonymous columns. If there are anonymous columns we set the `printaliases` flag to true which forces the deparser to add the aliases. --- .../distributed/deparser/ruleutils_11.c | 11 +- .../distributed/deparser/ruleutils_12.c | 11 +- .../regress/expected/anonymous_columns.out | 133 ++++++++++++++++++ src/test/regress/expected/cte_inline.out | 4 +- src/test/regress/expected/cte_inline_0.out | 4 +- src/test/regress/expected/dml_recursive.out | 2 +- .../regress/expected/multi_insert_select.out | 2 +- ...ulti_subquery_complex_reference_clause.out | 2 +- src/test/regress/expected/with_modifying.out | 11 +- src/test/regress/multi_schedule | 2 +- src/test/regress/sql/anonymous_columns.sql | 39 +++++ 11 files changed, 207 insertions(+), 14 deletions(-) create mode 100644 src/test/regress/expected/anonymous_columns.out create mode 100644 src/test/regress/sql/anonymous_columns.sql diff --git a/src/backend/distributed/deparser/ruleutils_11.c b/src/backend/distributed/deparser/ruleutils_11.c index 9c8bdef08..393240276 100644 --- a/src/backend/distributed/deparser/ruleutils_11.c +++ b/src/backend/distributed/deparser/ruleutils_11.c @@ -966,6 +966,7 @@ set_relation_column_names(deparse_namespace *dpns, RangeTblEntry *rte, int ncolumns; char **real_colnames; bool changed_any; + bool has_anonymous; int noldcolumns; int i; int j; @@ -1053,6 +1054,7 @@ set_relation_column_names(deparse_namespace *dpns, RangeTblEntry *rte, */ noldcolumns = list_length(rte->eref->colnames); changed_any = false; + has_anonymous = false; j = 0; for (i = 0; i < ncolumns; i++) { @@ -1090,6 +1092,13 @@ set_relation_column_names(deparse_namespace *dpns, RangeTblEntry *rte, /* Remember if any assigned aliases differ from "real" name */ if (!changed_any && strcmp(colname, real_colname) != 0) changed_any = true; + + /* + * Remember if there is a reference to an anonymous column as named by + * char * FigureColname(Node *node) + */ + if (!has_anonymous && strcmp(real_colname, "?column?") == 0) + has_anonymous = true; } /* @@ -1119,7 +1128,7 @@ set_relation_column_names(deparse_namespace *dpns, RangeTblEntry *rte, else if (rte->alias && rte->alias->colnames != NIL) colinfo->printaliases = true; else - colinfo->printaliases = changed_any; + colinfo->printaliases = changed_any || has_anonymous; } /* diff --git a/src/backend/distributed/deparser/ruleutils_12.c b/src/backend/distributed/deparser/ruleutils_12.c index a7326ee64..5ce6fc5e9 100644 --- a/src/backend/distributed/deparser/ruleutils_12.c +++ b/src/backend/distributed/deparser/ruleutils_12.c @@ -966,6 +966,7 @@ set_relation_column_names(deparse_namespace *dpns, RangeTblEntry *rte, int ncolumns; char **real_colnames; bool changed_any; + bool has_anonymous; int noldcolumns; int i; int j; @@ -1053,6 +1054,7 @@ set_relation_column_names(deparse_namespace *dpns, RangeTblEntry *rte, */ noldcolumns = list_length(rte->eref->colnames); changed_any = false; + has_anonymous = false; j = 0; for (i = 0; i < ncolumns; i++) { @@ -1090,6 +1092,13 @@ set_relation_column_names(deparse_namespace *dpns, RangeTblEntry *rte, /* Remember if any assigned aliases differ from "real" name */ if (!changed_any && strcmp(colname, real_colname) != 0) changed_any = true; + + /* + * Remember if there is a reference to an anonymous column as named by + * char * FigureColname(Node *node) + */ + if (!has_anonymous && strcmp(real_colname, "?column?") == 0) + has_anonymous = true; } /* @@ -1119,7 +1128,7 @@ set_relation_column_names(deparse_namespace *dpns, RangeTblEntry *rte, else if (rte->alias && rte->alias->colnames != NIL) colinfo->printaliases = true; else - colinfo->printaliases = changed_any; + colinfo->printaliases = changed_any || has_anonymous; } /* diff --git a/src/test/regress/expected/anonymous_columns.out b/src/test/regress/expected/anonymous_columns.out new file mode 100644 index 000000000..dab8588fd --- /dev/null +++ b/src/test/regress/expected/anonymous_columns.out @@ -0,0 +1,133 @@ +SET citus.next_shard_id TO 20080000; +CREATE SCHEMA anonymous_columns; +SET search_path TO anonymous_columns; +CREATE TABLE t0 (a int PRIMARY KEY, b int, "?column?" text); +SELECT create_distributed_table('t0', 'a'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +INSERT INTO t0 VALUES (1, 2, 'hello'), (2, 4, 'world'); +SELECT "?column?" FROM t0; + ?column? +--------------------------------------------------------------------- + hello + world +(2 rows) + +WITH a AS (SELECT * FROM t0) SELECT "?column?" FROM a; + ?column? +--------------------------------------------------------------------- + hello + world +(2 rows) + +WITH a AS (SELECT '' FROM t0) SELECT * FROM a; + ?column? +--------------------------------------------------------------------- + + +(2 rows) + +-- test CTE's that could be rewritten as subquery +WITH a AS (SELECT '' FROM t0 GROUP BY a) SELECT * FROM a; + ?column? +--------------------------------------------------------------------- + + +(2 rows) + +WITH a AS (SELECT '' FROM t0 GROUP BY b) SELECT * FROM a; + ?column? +--------------------------------------------------------------------- + + +(2 rows) + +WITH a AS (SELECT '','' FROM t0 GROUP BY a) SELECT * FROM a; + ?column? | ?column? +--------------------------------------------------------------------- + | + | +(2 rows) + +WITH a AS (SELECT '','' FROM t0 GROUP BY b) SELECT * FROM a; + ?column? | ?column? +--------------------------------------------------------------------- + | + | +(2 rows) + +WITH a AS (SELECT 1, * FROM t0 WHERE a = 1) SELECT * FROM a; + ?column? | a | b | ?column? +--------------------------------------------------------------------- + 1 | 1 | 2 | hello +(1 row) + +-- test CTE's that are referenced multiple times and hence need to stay CTE's +WITH a AS (SELECT '' FROM t0 WHERE a = 1) SELECT * FROM a, a b; + ?column? | ?column? +--------------------------------------------------------------------- + | +(1 row) + +WITH a AS (SELECT '','' FROM t0 WHERE a = 42) SELECT * FROM a, a b; + ?column? | ?column? | ?column? | ?column? +--------------------------------------------------------------------- +(0 rows) + +-- test with explicit subqueries +SELECT * FROM (SELECT a, '' FROM t0 GROUP BY a ) as foo; + a | ?column? +--------------------------------------------------------------------- + 1 | + 2 | +(2 rows) + +SELECT * FROM (SELECT a, '', '' FROM t0 GROUP BY a ) as foo; + a | ?column? | ?column? +--------------------------------------------------------------------- + 1 | | + 2 | | +(2 rows) + +SELECT * FROM (SELECT b, '' FROM t0 GROUP BY b ) as foo; + b | ?column? +--------------------------------------------------------------------- + 4 | + 2 | +(2 rows) + +SELECT * FROM (SELECT b, '', '' FROM t0 GROUP BY b ) as foo; + b | ?column? | ?column? +--------------------------------------------------------------------- + 4 | | + 2 | | +(2 rows) + +-- some tests that follow very similar codeoaths +SELECT a + 1 FROM t0; + ?column? +--------------------------------------------------------------------- + 2 + 3 +(2 rows) + +SELECT a + 1, a - 1 FROM t0; + ?column? | ?column? +--------------------------------------------------------------------- + 2 | 0 + 3 | 1 +(2 rows) + +WITH cte1 AS (SELECT row_to_json(row(a))->'f1' FROM t0) SELECT * FROM cte1; + ?column? +--------------------------------------------------------------------- + 1 + 2 +(2 rows) + +-- clean up after test +SET client_min_messages TO WARNING; +DROP SCHEMA anonymous_columns CASCADE; diff --git a/src/test/regress/expected/cte_inline.out b/src/test/regress/expected/cte_inline.out index 80f0a9d69..e6bd77db1 100644 --- a/src/test/regress/expected/cte_inline.out +++ b/src/test/regress/expected/cte_inline.out @@ -165,7 +165,7 @@ DEBUG: Router planner cannot handle multi-shard select queries DEBUG: Creating router plan DEBUG: Plan is router executable DEBUG: generating subplan XXX_3 for subquery SELECT key, value, other_value, (SELECT 1) FROM (SELECT cte_1.key, cte_1.value, cte_1.other_value FROM (SELECT intermediate_result.key, intermediate_result.value, intermediate_result.other_value FROM read_intermediate_result('XXX_2'::text, 'binary'::citus_copy_format) intermediate_result(key integer, value text, other_value jsonb)) cte_1) foo -DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT count(*) AS count FROM (SELECT intermediate_result.key, intermediate_result.value, intermediate_result.other_value FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(key integer, value text, other_value jsonb)) top_cte, (SELECT intermediate_result.key, intermediate_result.value, intermediate_result.other_value, intermediate_result."?column?" FROM read_intermediate_result('XXX_3'::text, 'binary'::citus_copy_format) intermediate_result(key integer, value text, other_value jsonb, "?column?" integer)) bar +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT count(*) AS count FROM (SELECT intermediate_result.key, intermediate_result.value, intermediate_result.other_value FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(key integer, value text, other_value jsonb)) top_cte, (SELECT intermediate_result.key, intermediate_result.value, intermediate_result.other_value, intermediate_result."?column?" FROM read_intermediate_result('XXX_3'::text, 'binary'::citus_copy_format) intermediate_result(key integer, value text, other_value jsonb, "?column?" integer)) bar(key, value, other_value, "?column?") DEBUG: Creating router plan DEBUG: Plan is router executable count @@ -249,7 +249,7 @@ DEBUG: CTE cte_2 is going to be inlined via distributed planning DEBUG: Router planner cannot handle multi-shard select queries DEBUG: Router planner cannot handle multi-shard select queries DEBUG: generating subplan XXX_1 for subquery SELECT key, value, other_value FROM cte_inline.test_table -DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT count(*) AS count FROM ((SELECT cte_1.key, cte_1.value, cte_1.other_value, (SELECT 1) FROM (SELECT test_table.key, test_table.value, test_table.other_value FROM cte_inline.test_table) cte_1) foo JOIN (SELECT intermediate_result.key, intermediate_result.value, intermediate_result.other_value FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(key integer, value text, other_value jsonb)) cte_2 ON (true)) +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT count(*) AS count FROM ((SELECT cte_1.key, cte_1.value, cte_1.other_value, (SELECT 1) FROM (SELECT test_table.key, test_table.value, test_table.other_value FROM cte_inline.test_table) cte_1) foo(key, value, other_value, "?column?") JOIN (SELECT intermediate_result.key, intermediate_result.value, intermediate_result.other_value FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(key integer, value text, other_value jsonb)) cte_2 ON (true)) DEBUG: Router planner cannot handle multi-shard select queries count --------------------------------------------------------------------- diff --git a/src/test/regress/expected/cte_inline_0.out b/src/test/regress/expected/cte_inline_0.out index 9c534ffcd..ccf63d875 100644 --- a/src/test/regress/expected/cte_inline_0.out +++ b/src/test/regress/expected/cte_inline_0.out @@ -153,7 +153,7 @@ DEBUG: Router planner cannot handle multi-shard select queries DEBUG: Creating router plan DEBUG: Plan is router executable DEBUG: generating subplan XXX_3 for subquery SELECT key, value, other_value, (SELECT 1) FROM (SELECT cte_1.key, cte_1.value, cte_1.other_value FROM (SELECT intermediate_result.key, intermediate_result.value, intermediate_result.other_value FROM read_intermediate_result('XXX_2'::text, 'binary'::citus_copy_format) intermediate_result(key integer, value text, other_value jsonb)) cte_1) foo -DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT count(*) AS count FROM (SELECT intermediate_result.key, intermediate_result.value, intermediate_result.other_value FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(key integer, value text, other_value jsonb)) top_cte, (SELECT intermediate_result.key, intermediate_result.value, intermediate_result.other_value, intermediate_result."?column?" FROM read_intermediate_result('XXX_3'::text, 'binary'::citus_copy_format) intermediate_result(key integer, value text, other_value jsonb, "?column?" integer)) bar +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT count(*) AS count FROM (SELECT intermediate_result.key, intermediate_result.value, intermediate_result.other_value FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(key integer, value text, other_value jsonb)) top_cte, (SELECT intermediate_result.key, intermediate_result.value, intermediate_result.other_value, intermediate_result."?column?" FROM read_intermediate_result('XXX_3'::text, 'binary'::citus_copy_format) intermediate_result(key integer, value text, other_value jsonb, "?column?" integer)) bar(key, value, other_value, "?column?") DEBUG: Creating router plan DEBUG: Plan is router executable count @@ -237,7 +237,7 @@ DEBUG: CTE cte_2 is going to be inlined via distributed planning DEBUG: Router planner cannot handle multi-shard select queries DEBUG: Router planner cannot handle multi-shard select queries DEBUG: generating subplan XXX_1 for subquery SELECT key, value, other_value FROM cte_inline.test_table -DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT count(*) AS count FROM ((SELECT cte_1.key, cte_1.value, cte_1.other_value, (SELECT 1) FROM (SELECT test_table.key, test_table.value, test_table.other_value FROM cte_inline.test_table) cte_1) foo JOIN (SELECT intermediate_result.key, intermediate_result.value, intermediate_result.other_value FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(key integer, value text, other_value jsonb)) cte_2 ON (true)) +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT count(*) AS count FROM ((SELECT cte_1.key, cte_1.value, cte_1.other_value, (SELECT 1) FROM (SELECT test_table.key, test_table.value, test_table.other_value FROM cte_inline.test_table) cte_1) foo(key, value, other_value, "?column?") JOIN (SELECT intermediate_result.key, intermediate_result.value, intermediate_result.other_value FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(key integer, value text, other_value jsonb)) cte_2 ON (true)) DEBUG: Router planner cannot handle multi-shard select queries count --------------------------------------------------------------------- diff --git a/src/test/regress/expected/dml_recursive.out b/src/test/regress/expected/dml_recursive.out index a629891ad..f464f0cd4 100644 --- a/src/test/regress/expected/dml_recursive.out +++ b/src/test/regress/expected/dml_recursive.out @@ -299,7 +299,7 @@ INSERT INTO VALUES ('3', (WITH vals AS (SELECT 3) select * from vals)); DEBUG: CTE vals is going to be inlined via distributed planning DEBUG: generating subplan XXX_1 for CTE vals: SELECT 3 -DEBUG: Plan XXX query after replacing subqueries and CTEs: INSERT INTO recursive_dml_queries.second_distributed_table (tenant_id, dept) VALUES ('3'::text, (SELECT vals."?column?" FROM (SELECT intermediate_result."?column?" FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result("?column?" integer)) vals)) +DEBUG: Plan XXX query after replacing subqueries and CTEs: INSERT INTO recursive_dml_queries.second_distributed_table (tenant_id, dept) VALUES ('3'::text, (SELECT vals."?column?" FROM (SELECT intermediate_result."?column?" FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result("?column?" integer)) vals("?column?"))) ERROR: subqueries are not supported within INSERT queries HINT: Try rewriting your queries with 'INSERT INTO ... SELECT' syntax. INSERT INTO diff --git a/src/test/regress/expected/multi_insert_select.out b/src/test/regress/expected/multi_insert_select.out index d50595468..c207e6905 100644 --- a/src/test/regress/expected/multi_insert_select.out +++ b/src/test/regress/expected/multi_insert_select.out @@ -716,7 +716,7 @@ DEBUG: CTE sub_cte is going to be inlined via distributed planning DEBUG: Router planner cannot handle multi-shard select queries DEBUG: Router planner cannot handle multi-shard select queries DEBUG: generating subplan XXX_1 for CTE sub_cte: SELECT 1 -DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT user_id, (SELECT sub_cte."?column?" FROM (SELECT intermediate_result."?column?" FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result("?column?" integer)) sub_cte) AS value_1_agg FROM public.raw_events_first +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT user_id, (SELECT sub_cte."?column?" FROM (SELECT intermediate_result."?column?" FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result("?column?" integer)) sub_cte("?column?")) AS value_1_agg FROM public.raw_events_first DEBUG: Router planner cannot handle multi-shard select queries ERROR: could not run distributed query with subquery outside the FROM, WHERE and HAVING clauses HINT: Consider using an equality filter on the distributed table's partition column. diff --git a/src/test/regress/expected/multi_subquery_complex_reference_clause.out b/src/test/regress/expected/multi_subquery_complex_reference_clause.out index 1427e6aea..b2a24608c 100644 --- a/src/test/regress/expected/multi_subquery_complex_reference_clause.out +++ b/src/test/regress/expected/multi_subquery_complex_reference_clause.out @@ -413,7 +413,7 @@ DEBUG: generating subplan XXX_1 for subquery SELECT user_id, (random() OPERATOR DEBUG: Creating router plan DEBUG: Plan is router executable DEBUG: generating subplan XXX_2 for subquery SELECT sub1.id, (random() OPERATOR(pg_catalog.*) (0)::double precision) FROM (SELECT users_ref_test_table.id FROM public.users_ref_test_table) sub1 UNION SELECT intermediate_result.user_id, intermediate_result."?column?" FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(user_id integer, "?column?" double precision) -DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT id, "?column?" FROM (SELECT intermediate_result.id, intermediate_result."?column?" FROM read_intermediate_result('XXX_2'::text, 'binary'::citus_copy_format) intermediate_result(id integer, "?column?" double precision)) sub ORDER BY id DESC +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT id, "?column?" FROM (SELECT intermediate_result.id, intermediate_result."?column?" FROM read_intermediate_result('XXX_2'::text, 'binary'::citus_copy_format) intermediate_result(id integer, "?column?" double precision)) sub(id, "?column?") ORDER BY id DESC DEBUG: Creating router plan DEBUG: Plan is router executable id | ?column? diff --git a/src/test/regress/expected/with_modifying.out b/src/test/regress/expected/with_modifying.out index 45a403572..ab1b5e761 100644 --- a/src/test/regress/expected/with_modifying.out +++ b/src/test/regress/expected/with_modifying.out @@ -915,7 +915,7 @@ DEBUG: Creating router plan DEBUG: Plan is router executable DETAIL: distribution column value: 1 DEBUG: generating subplan XXX_2 for subquery SELECT count(*) AS count FROM with_modifying.modify_table WHERE (id OPERATOR(pg_catalog.=) 1) -DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT count(*) AS count FROM (SELECT intermediate_result."?column?" FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result("?column?" integer)) mu, (SELECT intermediate_result.count FROM read_intermediate_result('XXX_2'::text, 'binary'::citus_copy_format) intermediate_result(count bigint)) ma +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT count(*) AS count FROM (SELECT intermediate_result."?column?" FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result("?column?" integer)) mu("?column?"), (SELECT intermediate_result.count FROM read_intermediate_result('XXX_2'::text, 'binary'::citus_copy_format) intermediate_result(count bigint)) ma DEBUG: Creating router plan DEBUG: Plan is router executable count @@ -935,7 +935,7 @@ DEBUG: Plan XXX query after replacing subqueries and CTEs: UPDATE with_modifyin DEBUG: Creating router plan DEBUG: Plan is router executable DETAIL: distribution column value: 1 -DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT count(*) AS count FROM (SELECT intermediate_result."?column?" FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result("?column?" integer)) mu +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT count(*) AS count FROM (SELECT intermediate_result."?column?" FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result("?column?" integer)) mu("?column?") DEBUG: Creating router plan DEBUG: Plan is router executable count @@ -978,8 +978,11 @@ WITH mb AS (UPDATE modify_table SET val = 3 WHERE id = 3 RETURNING NULL) SELECT (1 row) WITH mb AS (UPDATE modify_table SET val = 3 WHERE id = 3 RETURNING NULL) SELECT * FROM modify_table, mb WHERE id = 3; -ERROR: column mb.?column? does not exist -CONTEXT: while executing command on localhost:xxxxx + id | val | ?column? +--------------------------------------------------------------------- + 3 | 3 | +(1 row) + WITH mb AS (UPDATE modify_table SET val = 3 WHERE id = 3 RETURNING NULL, NULL) SELECT * FROM modify_table WHERE id = 3; id | val --------------------------------------------------------------------- diff --git a/src/test/regress/multi_schedule b/src/test/regress/multi_schedule index f89b0de7b..dde15a85d 100644 --- a/src/test/regress/multi_schedule +++ b/src/test/regress/multi_schedule @@ -97,7 +97,7 @@ test: multi_reference_table multi_select_for_update relation_access_tracking 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 -test: multi_jsonb_agg multi_jsonb_object_agg multi_json_agg multi_json_object_agg bool_agg ch_bench_having chbenchmark_all_queries expression_reference_join +test: multi_jsonb_agg multi_jsonb_object_agg multi_json_agg multi_json_object_agg bool_agg ch_bench_having chbenchmark_all_queries expression_reference_join anonymous_columns test: ch_bench_subquery_repartition test: multi_agg_type_conversion multi_count_type_conversion test: multi_partition_pruning single_hash_repartition_join diff --git a/src/test/regress/sql/anonymous_columns.sql b/src/test/regress/sql/anonymous_columns.sql new file mode 100644 index 000000000..4976af3e6 --- /dev/null +++ b/src/test/regress/sql/anonymous_columns.sql @@ -0,0 +1,39 @@ +SET citus.next_shard_id TO 20080000; + +CREATE SCHEMA anonymous_columns; +SET search_path TO anonymous_columns; + +CREATE TABLE t0 (a int PRIMARY KEY, b int, "?column?" text); +SELECT create_distributed_table('t0', 'a'); +INSERT INTO t0 VALUES (1, 2, 'hello'), (2, 4, 'world'); + +SELECT "?column?" FROM t0; + +WITH a AS (SELECT * FROM t0) SELECT "?column?" FROM a; +WITH a AS (SELECT '' FROM t0) SELECT * FROM a; + +-- test CTE's that could be rewritten as subquery +WITH a AS (SELECT '' FROM t0 GROUP BY a) SELECT * FROM a; +WITH a AS (SELECT '' FROM t0 GROUP BY b) SELECT * FROM a; +WITH a AS (SELECT '','' FROM t0 GROUP BY a) SELECT * FROM a; +WITH a AS (SELECT '','' FROM t0 GROUP BY b) SELECT * FROM a; +WITH a AS (SELECT 1, * FROM t0 WHERE a = 1) SELECT * FROM a; + +-- test CTE's that are referenced multiple times and hence need to stay CTE's +WITH a AS (SELECT '' FROM t0 WHERE a = 1) SELECT * FROM a, a b; +WITH a AS (SELECT '','' FROM t0 WHERE a = 42) SELECT * FROM a, a b; + +-- test with explicit subqueries +SELECT * FROM (SELECT a, '' FROM t0 GROUP BY a ) as foo; +SELECT * FROM (SELECT a, '', '' FROM t0 GROUP BY a ) as foo; +SELECT * FROM (SELECT b, '' FROM t0 GROUP BY b ) as foo; +SELECT * FROM (SELECT b, '', '' FROM t0 GROUP BY b ) as foo; + +-- some tests that follow very similar codeoaths +SELECT a + 1 FROM t0; +SELECT a + 1, a - 1 FROM t0; +WITH cte1 AS (SELECT row_to_json(row(a))->'f1' FROM t0) SELECT * FROM cte1; + +-- clean up after test +SET client_min_messages TO WARNING; +DROP SCHEMA anonymous_columns CASCADE;