From e0d2ac76208aef6ae0be3bb38adc23016f889b3d Mon Sep 17 00:00:00 2001 From: Onder Kalaci Date: Tue, 3 Nov 2020 18:16:05 +0100 Subject: [PATCH] Do not rely on set_rel_pathlist_hook for finding local relations When a relation is used on an OUTER JOIN with FALSE filters, set_rel_pathlist_hook may not be called for the table. There might be other cases as well, so do not rely on the hook for classification of the tables. --- .../distributed/planner/distributed_planner.c | 23 +- .../planner/multi_router_planner.c | 12 +- .../relation_restriction_equivalence.c | 4 - src/include/distributed/distributed_planner.h | 6 +- .../regress/expected/materialized_view.out | 10 + .../expected/recursive_view_local_table.out | 201 ++++++++++++++++++ src/test/regress/multi_schedule | 2 +- src/test/regress/sql/materialized_view.sql | 5 + .../sql/recursive_view_local_table.sql | 55 +++++ 9 files changed, 297 insertions(+), 21 deletions(-) create mode 100644 src/test/regress/expected/recursive_view_local_table.out create mode 100644 src/test/regress/sql/recursive_view_local_table.sql diff --git a/src/backend/distributed/planner/distributed_planner.c b/src/backend/distributed/planner/distributed_planner.c index 5f0795da4..964dfb943 100644 --- a/src/backend/distributed/planner/distributed_planner.c +++ b/src/backend/distributed/planner/distributed_planner.c @@ -1804,7 +1804,6 @@ multi_relation_restriction_hook(PlannerInfo *root, RelOptInfo *relOptInfo, MemoryContext oldMemoryContext = MemoryContextSwitchTo(restrictionsMemoryContext); bool distributedTable = IsCitusTable(rte->relid); - bool localTable = !distributedTable; RelationRestriction *relationRestriction = palloc0(sizeof(RelationRestriction)); relationRestriction->index = restrictionIndex; @@ -1820,8 +1819,6 @@ multi_relation_restriction_hook(PlannerInfo *root, RelOptInfo *relOptInfo, RelationRestrictionContext *relationRestrictionContext = plannerRestrictionContext->relationRestrictionContext; - relationRestrictionContext->hasDistributedRelation |= distributedTable; - relationRestrictionContext->hasLocalRelation |= localTable; /* * We're also keeping track of whether all participant @@ -2308,12 +2305,26 @@ GetRTEListProperties(List *rangeTableList) */ continue; } - else if (rangeTableEntry->relkind == RELKIND_MATVIEW) + + + if (rangeTableEntry->relkind == RELKIND_MATVIEW) { /* - * Skip over materialized views, here we should not consider - * materialized views as local tables. + * Record materialized views as they are similar to postgres local tables + * but it is nice to record them separately. + * + * Regular tables, partitioned tables or foreign tables can be a local or + * distributed tables and we can qualify them accurately. + * + * For regular views, we don't care because their definitions are already + * in the same query tree and we can detect what is inside the view definition. + * + * For materialized views, they are just local tables in the queries. But, when + * REFRESH MATERIALIZED VIEW is used, they behave similar to regular views, adds + * the view definition to the query. Hence, it is useful to record it seperately + * and let the callers decide on what to do. */ + rteListProperties->hasMaterializedView = true; continue; } diff --git a/src/backend/distributed/planner/multi_router_planner.c b/src/backend/distributed/planner/multi_router_planner.c index e314aa4b5..89e544374 100644 --- a/src/backend/distributed/planner/multi_router_planner.c +++ b/src/backend/distributed/planner/multi_router_planner.c @@ -2153,8 +2153,6 @@ PlanRouterQuery(Query *originalQuery, bool replacePrunedQueryWithDummy, bool *multiShardModifyQuery, Const **partitionValueConst) { - RelationRestrictionContext *relationRestrictionContext = - plannerRestrictionContext->relationRestrictionContext; bool isMultiShardQuery = false; DeferredErrorMessage *planningError = NULL; bool shardsPresent = false; @@ -2267,13 +2265,15 @@ PlanRouterQuery(Query *originalQuery, /* we need anchor shard id for select queries with router planner */ uint64 shardId = GetAnchorShardId(*prunedShardIntervalListList); - bool hasLocalRelation = relationRestrictionContext->hasLocalRelation; - + /* both Postgres tables and materialized tables are locally avaliable */ + RTEListProperties *rteProperties = GetRTEListPropertiesForQuery(originalQuery); + bool hasPostgresLocalRelation = + rteProperties->hasPostgresLocalTable || rteProperties->hasMaterializedView; List *taskPlacementList = CreateTaskPlacementListForShardIntervals(*prunedShardIntervalListList, shardsPresent, replacePrunedQueryWithDummy, - hasLocalRelation); + hasPostgresLocalRelation); if (taskPlacementList == NIL) { planningError = DeferredError(ERRCODE_FEATURE_NOT_SUPPORTED, @@ -3554,8 +3554,6 @@ CopyRelationRestrictionContext(RelationRestrictionContext *oldContext) (RelationRestrictionContext *) palloc(sizeof(RelationRestrictionContext)); ListCell *relationRestrictionCell = NULL; - newContext->hasDistributedRelation = oldContext->hasDistributedRelation; - newContext->hasLocalRelation = oldContext->hasLocalRelation; newContext->allReferenceTables = oldContext->allReferenceTables; newContext->relationRestrictionList = NIL; diff --git a/src/backend/distributed/planner/relation_restriction_equivalence.c b/src/backend/distributed/planner/relation_restriction_equivalence.c index 438fac555..b52146611 100644 --- a/src/backend/distributed/planner/relation_restriction_equivalence.c +++ b/src/backend/distributed/planner/relation_restriction_equivalence.c @@ -1820,10 +1820,6 @@ FilterPlannerRestrictionForQuery(PlannerRestrictionContext *plannerRestrictionCo filteredRelationRestrictionContext->allReferenceTables = (totalRelationCount == referenceRelationCount); - /* we currently don't support local relations and we cannot come up to this point */ - filteredRelationRestrictionContext->hasLocalRelation = false; - filteredRelationRestrictionContext->hasDistributedRelation = true; - /* finally set the relation and join restriction contexts */ filteredPlannerRestrictionContext->relationRestrictionContext = filteredRelationRestrictionContext; diff --git a/src/include/distributed/distributed_planner.h b/src/include/distributed/distributed_planner.h index 4abe52d02..fc7af1652 100644 --- a/src/include/distributed/distributed_planner.h +++ b/src/include/distributed/distributed_planner.h @@ -40,8 +40,6 @@ extern int PlannerLevel; typedef struct RelationRestrictionContext { - bool hasDistributedRelation; - bool hasLocalRelation; bool allReferenceTables; List *relationRestrictionList; } RelationRestrictionContext; @@ -148,8 +146,10 @@ typedef struct RTEListProperties /* includes hash, append and range partitioned tables */ bool hasDistributedTable; - /* union of above three */ + /* union of hasReferenceTable, hasCitusLocalTable and hasDistributedTable */ bool hasCitusTable; + + bool hasMaterializedView; } RTEListProperties; diff --git a/src/test/regress/expected/materialized_view.out b/src/test/regress/expected/materialized_view.out index a8299e175..4ef7818a2 100644 --- a/src/test/regress/expected/materialized_view.out +++ b/src/test/regress/expected/materialized_view.out @@ -29,6 +29,15 @@ SELECT count(*) FROM temp_lineitem; 1706 (1 row) +-- can create router materialized views +CREATE MATERIALIZED VIEW mode_counts_router +AS SELECT l_shipmode, count(*) FROM temp_lineitem WHERE l_orderkey = 1 GROUP BY l_shipmode; +SELECT * FROM mode_counts_router; + l_shipmode | count +--------------------------------------------------------------------- + AIR | 1 +(1 row) + -- can create and query materialized views CREATE MATERIALIZED VIEW mode_counts AS SELECT l_shipmode, count(*) FROM temp_lineitem GROUP BY l_shipmode; @@ -59,6 +68,7 @@ SELECT * FROM mode_counts WHERE l_shipmode = 'AIR' ORDER BY 2 DESC, 1 LIMIT 10; DROP MATERIALIZED VIEW mode_counts; DROP TABLE temp_lineitem CASCADE; +NOTICE: drop cascades to materialized view mode_counts_router -- Refresh single-shard materialized view CREATE MATERIALIZED VIEW materialized_view AS SELECT orders_hash_part.o_orderdate, total_price.price_sum diff --git a/src/test/regress/expected/recursive_view_local_table.out b/src/test/regress/expected/recursive_view_local_table.out new file mode 100644 index 000000000..a2306a2e9 --- /dev/null +++ b/src/test/regress/expected/recursive_view_local_table.out @@ -0,0 +1,201 @@ +CREATE SCHEMA postgres_local_table; +SET search_path TO postgres_local_table; +CREATE TABLE local_table(a INT); +INSERT INTO local_table VALUES (1),(2),(3); +CREATE RECURSIVE VIEW recursive_view(val_1, val_2) AS +( + VALUES(0,1) + UNION ALL + SELECT GREATEST(val_1,val_2),val_1 + val_2 AS local_table + FROM + recursive_view + WHERE val_2 < 50 +); +CREATE RECURSIVE VIEW recursive_defined_non_recursive_view(c) AS (SELECT 1 FROM local_table); +CREATE TABLE ref_table(a int, b INT); +SELECT create_reference_table('ref_table'); + create_reference_table +--------------------------------------------------------------------- + +(1 row) + +INSERT INTO ref_table VALUES (1,1); +SELECT ref_table.* FROM ref_table LEFT OUTER JOIN (SELECT * FROM recursive_view WHERE FALSE) AS sub ON FALSE; + a | b +--------------------------------------------------------------------- + 1 | 1 +(1 row) + +SELECT ref_table.* FROM ref_table LEFT OUTER JOIN (SELECT * FROM (SELECT 1, random() FROM local_table) as s WHERE FALSE) AS sub ON FALSE ORDER BY 1,2; + a | b +--------------------------------------------------------------------- + 1 | 1 +(1 row) + +SELECT ref_table.* FROM ref_table LEFT OUTER JOIN (SELECT * FROM recursive_view WHERE FALSE) AS sub ON TRUE ORDER BY 1,2; + a | b +--------------------------------------------------------------------- + 1 | 1 +(1 row) + +SELECT ref_table.* FROM ref_table LEFT OUTER JOIN (SELECT * FROM (SELECT 1, random() FROM local_table) as s WHERE FALSE) AS sub ON TRUE ORDER BY 1,2; + a | b +--------------------------------------------------------------------- + 1 | 1 +(1 row) + +SELECT ref_table.* FROM ref_table LEFT OUTER JOIN (SELECT * FROM recursive_view WHERE TRUE) AS sub ON TRUE ORDER BY 1,2; + a | b +--------------------------------------------------------------------- + 1 | 1 + 1 | 1 + 1 | 1 + 1 | 1 + 1 | 1 + 1 | 1 + 1 | 1 + 1 | 1 + 1 | 1 + 1 | 1 +(10 rows) + +SELECT ref_table.* FROM ref_table LEFT OUTER JOIN (SELECT * FROM (SELECT 1, random() FROM local_table) as s WHERE TRUE) AS sub ON TRUE ORDER BY 1,2; + a | b +--------------------------------------------------------------------- + 1 | 1 + 1 | 1 + 1 | 1 +(3 rows) + +SELECT ref_table.* FROM ref_table JOIN (SELECT * FROM recursive_view WHERE FALSE) AS sub ON FALSE ORDER BY 1,2; + a | b +--------------------------------------------------------------------- +(0 rows) + +SELECT ref_table.* FROM ref_table JOIN (SELECT * FROM (SELECT 1, random() FROM local_table) as s WHERE FALSE) AS sub ON FALSE ORDER BY 1,2; + a | b +--------------------------------------------------------------------- +(0 rows) + +SELECT ref_table.* FROM ref_table JOIN (SELECT * FROM recursive_view WHERE FALSE) AS sub ON TRUE ORDER BY 1,2; + a | b +--------------------------------------------------------------------- +(0 rows) + +SELECT ref_table.* FROM ref_table JOIN (SELECT * FROM (SELECT 1, random() FROM local_table) as s WHERE FALSE) AS sub ON TRUE ORDER BY 1,2; + a | b +--------------------------------------------------------------------- +(0 rows) + +SELECT ref_table.* FROM ref_table JOIN (SELECT * FROM recursive_view WHERE TRUE) AS sub ON TRUE ORDER BY 1,2; + a | b +--------------------------------------------------------------------- + 1 | 1 + 1 | 1 + 1 | 1 + 1 | 1 + 1 | 1 + 1 | 1 + 1 | 1 + 1 | 1 + 1 | 1 + 1 | 1 +(10 rows) + +SELECT ref_table.* FROM ref_table JOIN (SELECT * FROM (SELECT 1, random() FROM local_table) as s WHERE TRUE) AS sub ON TRUE ORDER BY 1,2; + a | b +--------------------------------------------------------------------- + 1 | 1 + 1 | 1 + 1 | 1 +(3 rows) + +SELECT ref_table.* FROM ref_table LEFT OUTER JOIN (SELECT * FROM recursive_defined_non_recursive_view WHERE FALSE) AS sub ON FALSE ORDER BY 1,2; + a | b +--------------------------------------------------------------------- + 1 | 1 +(1 row) + +SELECT ref_table.* FROM ref_table LEFT OUTER JOIN (SELECT * FROM recursive_defined_non_recursive_view WHERE FALSE) AS sub ON TRUE ORDER BY 1,2; + a | b +--------------------------------------------------------------------- + 1 | 1 +(1 row) + +SELECT ref_table.* FROM ref_table LEFT OUTER JOIN (SELECT * FROM recursive_defined_non_recursive_view WHERE TRUE) AS sub ON TRUE ORDER BY 1,2; + a | b +--------------------------------------------------------------------- + 1 | 1 + 1 | 1 + 1 | 1 +(3 rows) + +SELECT ref_table.* FROM ref_table JOIN (SELECT * FROM recursive_defined_non_recursive_view WHERE FALSE) AS sub ON FALSE ORDER BY 1,2; + a | b +--------------------------------------------------------------------- +(0 rows) + +SELECT ref_table.* FROM ref_table JOIN (SELECT * FROM recursive_defined_non_recursive_view WHERE FALSE) AS sub ON TRUE ORDER BY 1,2; + a | b +--------------------------------------------------------------------- +(0 rows) + +SELECT ref_table.* FROM ref_table JOIN (SELECT * FROM recursive_defined_non_recursive_view WHERE TRUE) AS sub ON TRUE ORDER BY 1,2; + a | b +--------------------------------------------------------------------- + 1 | 1 + 1 | 1 + 1 | 1 +(3 rows) + +SELECT ref_table.* FROM ref_table WHERE EXISTS (SELECT * FROM local_table l WHERE l.a = ref_table.a); +ERROR: direct joins between distributed and local tables are not supported +HINT: Use CTE's or subqueries to select from local tables and use them in joins +SELECT ref_table.* FROM ref_table WHERE EXISTS (SELECT * FROM local_table l WHERE l.a = ref_table.a) AND false; + a | b +--------------------------------------------------------------------- +(0 rows) + +SELECT ref_table.* FROM ref_table WHERE EXISTS (SELECT * FROM local_table l WHERE l.a = ref_table.a AND false); + a | b +--------------------------------------------------------------------- +(0 rows) + +SELECT ref_table.* FROM ref_table WHERE EXISTS (SELECT * FROM recursive_view l WHERE l.val_1 = ref_table.a); + a | b +--------------------------------------------------------------------- + 1 | 1 +(1 row) + +SELECT ref_table.* FROM ref_table WHERE EXISTS (SELECT * FROM recursive_view l WHERE l.val_1 = ref_table.a) AND false; + a | b +--------------------------------------------------------------------- +(0 rows) + +SELECT ref_table.* FROM ref_table WHERE EXISTS (SELECT * FROM recursive_view l WHERE l.val_1 = ref_table.a AND false); + a | b +--------------------------------------------------------------------- +(0 rows) + +SELECT ref_table.* FROM ref_table WHERE EXISTS (SELECT * FROM recursive_defined_non_recursive_view l WHERE l.c = ref_table.a); + a | b +--------------------------------------------------------------------- + 1 | 1 +(1 row) + +SELECT ref_table.* FROM ref_table WHERE EXISTS (SELECT * FROM recursive_defined_non_recursive_view l WHERE l.c = ref_table.a) AND false; + a | b +--------------------------------------------------------------------- +(0 rows) + +SELECT ref_table.* FROM ref_table WHERE EXISTS (SELECT * FROM recursive_defined_non_recursive_view l WHERE l.c = ref_table.a AND false); + a | b +--------------------------------------------------------------------- +(0 rows) + +DROP SCHEMA postgres_local_table CASCADE; +NOTICE: drop cascades to 4 other objects +DETAIL: drop cascades to table local_table +drop cascades to view recursive_view +drop cascades to view recursive_defined_non_recursive_view +drop cascades to table ref_table diff --git a/src/test/regress/multi_schedule b/src/test/regress/multi_schedule index c9e60c809..4f6ed8ee4 100644 --- a/src/test/regress/multi_schedule +++ b/src/test/regress/multi_schedule @@ -85,7 +85,7 @@ test: set_operation_and_local_tables test: subqueries_deep subquery_view subquery_partitioning subquery_complex_target_list subqueries_not_supported subquery_in_where test: non_colocated_leaf_subquery_joins non_colocated_subquery_joins non_colocated_join_order -test: subquery_prepared_statements pg12 cte_inline pg13 +test: subquery_prepared_statements pg12 cte_inline pg13 recursive_view_local_table test: tableam # ---------- diff --git a/src/test/regress/sql/materialized_view.sql b/src/test/regress/sql/materialized_view.sql index 4578f6086..c0e05db05 100644 --- a/src/test/regress/sql/materialized_view.sql +++ b/src/test/regress/sql/materialized_view.sql @@ -19,6 +19,11 @@ SELECT count(*) FROM temp_lineitem; INSERT INTO temp_lineitem SELECT * FROM air_shipped_lineitems WHERE l_shipmode = 'MAIL'; SELECT count(*) FROM temp_lineitem; +-- can create router materialized views +CREATE MATERIALIZED VIEW mode_counts_router +AS SELECT l_shipmode, count(*) FROM temp_lineitem WHERE l_orderkey = 1 GROUP BY l_shipmode; +SELECT * FROM mode_counts_router; + -- can create and query materialized views CREATE MATERIALIZED VIEW mode_counts AS SELECT l_shipmode, count(*) FROM temp_lineitem GROUP BY l_shipmode; diff --git a/src/test/regress/sql/recursive_view_local_table.sql b/src/test/regress/sql/recursive_view_local_table.sql new file mode 100644 index 000000000..c33a95e99 --- /dev/null +++ b/src/test/regress/sql/recursive_view_local_table.sql @@ -0,0 +1,55 @@ +CREATE SCHEMA postgres_local_table; +SET search_path TO postgres_local_table; + +CREATE TABLE local_table(a INT); +INSERT INTO local_table VALUES (1),(2),(3); + +CREATE RECURSIVE VIEW recursive_view(val_1, val_2) AS +( + VALUES(0,1) + UNION ALL + SELECT GREATEST(val_1,val_2),val_1 + val_2 AS local_table + FROM + recursive_view + WHERE val_2 < 50 +); + +CREATE RECURSIVE VIEW recursive_defined_non_recursive_view(c) AS (SELECT 1 FROM local_table); + +CREATE TABLE ref_table(a int, b INT); +SELECT create_reference_table('ref_table'); +INSERT INTO ref_table VALUES (1,1); + +SELECT ref_table.* FROM ref_table LEFT OUTER JOIN (SELECT * FROM recursive_view WHERE FALSE) AS sub ON FALSE; +SELECT ref_table.* FROM ref_table LEFT OUTER JOIN (SELECT * FROM (SELECT 1, random() FROM local_table) as s WHERE FALSE) AS sub ON FALSE ORDER BY 1,2; +SELECT ref_table.* FROM ref_table LEFT OUTER JOIN (SELECT * FROM recursive_view WHERE FALSE) AS sub ON TRUE ORDER BY 1,2; +SELECT ref_table.* FROM ref_table LEFT OUTER JOIN (SELECT * FROM (SELECT 1, random() FROM local_table) as s WHERE FALSE) AS sub ON TRUE ORDER BY 1,2; +SELECT ref_table.* FROM ref_table LEFT OUTER JOIN (SELECT * FROM recursive_view WHERE TRUE) AS sub ON TRUE ORDER BY 1,2; +SELECT ref_table.* FROM ref_table LEFT OUTER JOIN (SELECT * FROM (SELECT 1, random() FROM local_table) as s WHERE TRUE) AS sub ON TRUE ORDER BY 1,2; +SELECT ref_table.* FROM ref_table JOIN (SELECT * FROM recursive_view WHERE FALSE) AS sub ON FALSE ORDER BY 1,2; +SELECT ref_table.* FROM ref_table JOIN (SELECT * FROM (SELECT 1, random() FROM local_table) as s WHERE FALSE) AS sub ON FALSE ORDER BY 1,2; +SELECT ref_table.* FROM ref_table JOIN (SELECT * FROM recursive_view WHERE FALSE) AS sub ON TRUE ORDER BY 1,2; +SELECT ref_table.* FROM ref_table JOIN (SELECT * FROM (SELECT 1, random() FROM local_table) as s WHERE FALSE) AS sub ON TRUE ORDER BY 1,2; +SELECT ref_table.* FROM ref_table JOIN (SELECT * FROM recursive_view WHERE TRUE) AS sub ON TRUE ORDER BY 1,2; +SELECT ref_table.* FROM ref_table JOIN (SELECT * FROM (SELECT 1, random() FROM local_table) as s WHERE TRUE) AS sub ON TRUE ORDER BY 1,2; +SELECT ref_table.* FROM ref_table LEFT OUTER JOIN (SELECT * FROM recursive_defined_non_recursive_view WHERE FALSE) AS sub ON FALSE ORDER BY 1,2; +SELECT ref_table.* FROM ref_table LEFT OUTER JOIN (SELECT * FROM recursive_defined_non_recursive_view WHERE FALSE) AS sub ON TRUE ORDER BY 1,2; +SELECT ref_table.* FROM ref_table LEFT OUTER JOIN (SELECT * FROM recursive_defined_non_recursive_view WHERE TRUE) AS sub ON TRUE ORDER BY 1,2; +SELECT ref_table.* FROM ref_table JOIN (SELECT * FROM recursive_defined_non_recursive_view WHERE FALSE) AS sub ON FALSE ORDER BY 1,2; +SELECT ref_table.* FROM ref_table JOIN (SELECT * FROM recursive_defined_non_recursive_view WHERE FALSE) AS sub ON TRUE ORDER BY 1,2; +SELECT ref_table.* FROM ref_table JOIN (SELECT * FROM recursive_defined_non_recursive_view WHERE TRUE) AS sub ON TRUE ORDER BY 1,2; + +SELECT ref_table.* FROM ref_table WHERE EXISTS (SELECT * FROM local_table l WHERE l.a = ref_table.a); +SELECT ref_table.* FROM ref_table WHERE EXISTS (SELECT * FROM local_table l WHERE l.a = ref_table.a) AND false; +SELECT ref_table.* FROM ref_table WHERE EXISTS (SELECT * FROM local_table l WHERE l.a = ref_table.a AND false); + +SELECT ref_table.* FROM ref_table WHERE EXISTS (SELECT * FROM recursive_view l WHERE l.val_1 = ref_table.a); +SELECT ref_table.* FROM ref_table WHERE EXISTS (SELECT * FROM recursive_view l WHERE l.val_1 = ref_table.a) AND false; +SELECT ref_table.* FROM ref_table WHERE EXISTS (SELECT * FROM recursive_view l WHERE l.val_1 = ref_table.a AND false); + +SELECT ref_table.* FROM ref_table WHERE EXISTS (SELECT * FROM recursive_defined_non_recursive_view l WHERE l.c = ref_table.a); +SELECT ref_table.* FROM ref_table WHERE EXISTS (SELECT * FROM recursive_defined_non_recursive_view l WHERE l.c = ref_table.a) AND false; +SELECT ref_table.* FROM ref_table WHERE EXISTS (SELECT * FROM recursive_defined_non_recursive_view l WHERE l.c = ref_table.a AND false); + + +DROP SCHEMA postgres_local_table CASCADE;