From 22eb183dcf444f417281fb749a92e605f4fde507 Mon Sep 17 00:00:00 2001 From: Zhang Mingli Date: Fri, 17 May 2024 16:04:39 +0800 Subject: [PATCH] [AQUMV] Support DISTINCT ON clause on origin query. Since we have supported ORDER BY caluse and DISTINCT ON clause references are processed in target list, open it on origin query. create incremental materialized view mv as select c1 as mc1, c2 as mc2, c3 as mc3, c4 as mc4 from t1 where c1 > 90; Origin querys: select DISTINCT ON(c1 - 1) c1, c2 from t1 where c1 > 90 order by c1 - 1, c2 nulls first; Could be rewritten to: select DISTINCT ON(mc1 - 1) mc1, mc2 from mv order by mc1 - 1, mc2 nulls first; Authored-by: Zhang Mingli avamingli@gmail.com --- src/backend/optimizer/README.cbdb.aqumv | 2 +- src/backend/optimizer/plan/aqumv.c | 2 +- src/test/regress/expected/aqumv.out | 78 +++++++++++++++++++++++++ src/test/regress/sql/aqumv.sql | 10 ++++ 4 files changed, 90 insertions(+), 2 deletions(-) diff --git a/src/backend/optimizer/README.cbdb.aqumv b/src/backend/optimizer/README.cbdb.aqumv index a0a1c349fa7..99dc217d6e3 100644 --- a/src/backend/optimizer/README.cbdb.aqumv +++ b/src/backend/optimizer/README.cbdb.aqumv @@ -228,7 +228,7 @@ Below are not supported now: Window Functions CTE Distinct (on view_query) - Distinct On + Distinct On (on view_query) UNION/INTERSECT/EXCEPT FOR UPDATE, FOR NO KEY UPDATE, FOR SHARE, FOR KEY SHARE Scatter By diff --git a/src/backend/optimizer/plan/aqumv.c b/src/backend/optimizer/plan/aqumv.c index 0ea441dfd52..cefd868771e 100644 --- a/src/backend/optimizer/plan/aqumv.c +++ b/src/backend/optimizer/plan/aqumv.c @@ -119,7 +119,6 @@ answer_query_using_materialized_views(PlannerInfo *root, (parse->cteList != NIL) || (parse->setOperations != NULL) || parse->hasWindowFuncs || - parse->hasDistinctOn || parse->hasModifyingCTE || (parse->parentStmtType == PARENTSTMTTYPE_REFRESH_MATVIEW) || (parse->parentStmtType == PARENTSTMTTYPE_CTAS) || @@ -328,6 +327,7 @@ answer_query_using_materialized_views(PlannerInfo *root, * could be computed from viewQuery. */ viewQuery->hasAggs = parse->hasAggs; + viewQuery->hasDistinctOn = parse->hasDistinctOn; /* * For HAVING quals have aggregations, we have already processed them in * Aggrefs during aqumv_process_targetlist(). diff --git a/src/test/regress/expected/aqumv.out b/src/test/regress/expected/aqumv.out index 3fee06cd8aa..0694dbcae97 100644 --- a/src/test/regress/expected/aqumv.out +++ b/src/test/regress/expected/aqumv.out @@ -2084,6 +2084,84 @@ select c1, c2, c3, sum(c4) from aqumv_t6 where c1 > 97 group by distinct rollup( 98 | NULL | 100 | 202 (13 rows) +-- DISTINCT ON +set local enable_answer_query_using_materialized_views = off; +explain(costs off, verbose) +select distinct on(c1 - 1) c1, c2 from aqumv_t6 where c1 > 90 order by c1 - 1, c2 nulls first; + QUERY PLAN +----------------------------------------------------------------------------------- + Gather Motion 3:1 (slice1; segments: 3) + Output: c1, c2, ((c1 - 1)) + Merge Key: ((c1 - 1)), c2 + -> Unique + Output: c1, c2, ((c1 - 1)) + Group Key: ((c1 - 1)) + -> Sort + Output: c1, c2, ((c1 - 1)) + Sort Key: ((aqumv_t6.c1 - 1)), aqumv_t6.c2 NULLS FIRST + -> Redistribute Motion 3:3 (slice2; segments: 3) + Output: c1, c2, ((c1 - 1)) + Hash Key: ((c1 - 1)) + -> Seq Scan on public.aqumv_t6 + Output: c1, c2, (c1 - 1) + Filter: (aqumv_t6.c1 > 90) + Settings: enable_answer_query_using_materialized_views = 'off', optimizer = 'off' + Optimizer: Postgres query optimizer +(17 rows) + +select distinct on(c1 - 1) c1, c2 from aqumv_t6 where c1 > 90 order by c1 - 1, c2 nulls first; + c1 | c2 +-----+------ + 91 | NULL + 92 | 93 + 93 | 94 + 94 | 95 + 95 | 96 + 96 | 97 + 97 | 98 + 98 | 99 + 99 | 100 + 100 | 101 +(10 rows) + +set local enable_answer_query_using_materialized_views = on; +explain(costs off, verbose) +select distinct on(c1 - 1) c1, c2 from aqumv_t6 where c1 > 90 order by c1 - 1, c2 nulls first; + QUERY PLAN +---------------------------------------------------------------------------------- + Gather Motion 3:1 (slice1; segments: 3) + Output: mc1, mc2, ((mc1 - 1)) + Merge Key: ((mc1 - 1)), mc2 + -> Unique + Output: mc1, mc2, ((mc1 - 1)) + Group Key: ((mc1 - 1)) + -> Sort + Output: mc1, mc2, ((mc1 - 1)) + Sort Key: ((aqumv_mvt6_0.mc1 - 1)), aqumv_mvt6_0.mc2 NULLS FIRST + -> Redistribute Motion 3:3 (slice2; segments: 3) + Output: mc1, mc2, ((mc1 - 1)) + Hash Key: ((mc1 - 1)) + -> Seq Scan on public.aqumv_mvt6_0 + Output: mc1, mc2, (mc1 - 1) + Settings: enable_answer_query_using_materialized_views = 'on', optimizer = 'off' + Optimizer: Postgres query optimizer +(16 rows) + +select distinct on(c1 - 1) c1, c2 from aqumv_t6 where c1 > 90 order by c1 - 1, c2 nulls first; + c1 | c2 +-----+------ + 91 | NULL + 92 | 93 + 93 | 94 + 94 | 95 + 95 | 96 + 96 | 97 + 97 | 98 + 98 | 99 + 99 | 100 + 100 | 101 +(10 rows) + \pset null '' abort; reset optimizer; diff --git a/src/test/regress/sql/aqumv.sql b/src/test/regress/sql/aqumv.sql index cc60dcb6819..86af470541f 100644 --- a/src/test/regress/sql/aqumv.sql +++ b/src/test/regress/sql/aqumv.sql @@ -514,6 +514,16 @@ explain(costs off, verbose) select c1, c2, c3, sum(c4) from aqumv_t6 where c1 > 97 group by distinct rollup(c1, c2), rollup(c1, c3); select c1, c2, c3, sum(c4) from aqumv_t6 where c1 > 97 group by distinct rollup(c1, c2), rollup(c1, c3); +-- DISTINCT ON +set local enable_answer_query_using_materialized_views = off; +explain(costs off, verbose) +select distinct on(c1 - 1) c1, c2 from aqumv_t6 where c1 > 90 order by c1 - 1, c2 nulls first; +select distinct on(c1 - 1) c1, c2 from aqumv_t6 where c1 > 90 order by c1 - 1, c2 nulls first; +set local enable_answer_query_using_materialized_views = on; +explain(costs off, verbose) +select distinct on(c1 - 1) c1, c2 from aqumv_t6 where c1 > 90 order by c1 - 1, c2 nulls first; +select distinct on(c1 - 1) c1, c2 from aqumv_t6 where c1 > 90 order by c1 - 1, c2 nulls first; + \pset null '' abort;