diff --git a/src/backend/optimizer/README.cbdb.aqumv b/src/backend/optimizer/README.cbdb.aqumv index 236cf21547a..692d767d43a 100644 --- a/src/backend/optimizer/README.cbdb.aqumv +++ b/src/backend/optimizer/README.cbdb.aqumv @@ -134,7 +134,7 @@ mv5 has all rows {a = 1} and only have column 'a', but the query want additional We couldn't rewrite it by just adding the {b = 2} to MV as no equivalent b in MV relation. Wrong: SELECT a FROM mv5 WHERE b = 2; -The algorithem behind that is: all quals's expression could be computed from a mv_query's target list. +The algorithm behind that is: all quals's expression could be computed from a mv_query's target list. That's what Construct Columns does. Construct Columns @@ -222,7 +222,6 @@ Support SELECT FROM a single relation both for mv_query and the origin_query. Below are not supported now: Aggregation (on mv_query) Subquery - Order by(for origin_query) Join Sublink Group By/Grouping Sets/Rollup/Cube (on mv_query) diff --git a/src/backend/optimizer/plan/aqumv.c b/src/backend/optimizer/plan/aqumv.c index 19516f95e8d..88f3b34dd9d 100644 --- a/src/backend/optimizer/plan/aqumv.c +++ b/src/backend/optimizer/plan/aqumv.c @@ -126,7 +126,6 @@ answer_query_using_materialized_views(PlannerInfo *root, parse->hasWindowFuncs || parse->hasDistinctOn || parse->hasModifyingCTE || - parse->sortClause || (parse->parentStmtType == PARENTSTMTTYPE_REFRESH_MATVIEW) || (parse->parentStmtType == PARENTSTMTTYPE_CTAS) || parse->hasSubLinks; @@ -202,7 +201,7 @@ answer_query_using_materialized_views(PlannerInfo *root, * * AQUMV_FIXME_MVP: mvQuery is a simple query too, like the parse query. * mvQuery->sortClause is ok here, though we can't use the Order by - * clause of mvQuery, and we have disabled the parse->sortClause. + * clause of mvQuery. * The reason is: the Order by clause of materialized view's query is * typically pointless. We can't rely on the order even we wrote the * ordered data into mv, ex: some other access methods except heap. @@ -367,6 +366,7 @@ answer_query_using_materialized_views(PlannerInfo *root, * jointree's quals and would be processed in post_quals later. */ mvQuery->havingQual = parse->havingQual; + mvQuery->sortClause = parse->sortClause; /* * AQUMV @@ -458,11 +458,11 @@ answer_query_using_materialized_views(PlannerInfo *root, /* * Update pathkeys which may be changed by qp_callback. * Set belows if corresponding feature is supported. - * sort_pathkeys * distinct_pathkey * window_pathkeys */ root->group_pathkeys = subroot->group_pathkeys; + root->sort_pathkeys = subroot->sort_pathkeys; root->query_pathkeys = subroot->query_pathkeys; /* diff --git a/src/test/regress/expected/aqumv.out b/src/test/regress/expected/aqumv.out index 0cf24f6fb1b..dd50fcdbf06 100644 --- a/src/test/regress/expected/aqumv.out +++ b/src/test/regress/expected/aqumv.out @@ -1578,6 +1578,295 @@ select c1, c3, avg(c2) from aqumv_t4 where c1 > 90 group by (c1, c3) having c1 > Optimizer: Postgres query optimizer (9 rows) +abort; +-- Test Order By of origin query. +begin; +create table aqumv_t5(c1 int, c2 int, c3 int) distributed by (c1); +insert into aqumv_t5 select i, i+1, i+2 from generate_series(1, 100) i; +insert into aqumv_t5 values (91, NULL, 95); +analyze aqumv_t5; +create incremental materialized view aqumv_mvt5_0 as + select c1 as mc1, c2 as mc2, c3 as mc3 + from aqumv_t5 where c1 > 90; +NOTICE: Table doesn't have 'DISTRIBUTED BY' clause -- Using column(s) named 'mc1' as the Cloudberry Database data distribution key for this table. +HINT: The 'DISTRIBUTED BY' clause determines the distribution of data. Make sure column(s) chosen are the optimal data distribution key to minimize skew. +analyze aqumv_mvt5_0; +-- order by column. +set local enable_answer_query_using_materialized_views = off; +explain(costs off, verbose) +select c1, c3 from aqumv_t5 where c1 > 90 order by c2, c3 asc; + QUERY PLAN +----------------------------------------------------------------------------------- + Gather Motion 3:1 (slice1; segments: 3) + Output: c1, c3, c2 + Merge Key: c2, c3 + -> Sort + Output: c1, c3, c2 + Sort Key: aqumv_t5.c2, aqumv_t5.c3 + -> Seq Scan on public.aqumv_t5 + Output: c1, c3, c2 + Filter: (aqumv_t5.c1 > 90) + Settings: enable_answer_query_using_materialized_views = 'off', optimizer = 'off' + Optimizer: Postgres query optimizer +(11 rows) + +select c1, c3 from aqumv_t5 where c1 > 90 order by c2, c3 asc; + c1 | c3 +-----+----- + 91 | 93 + 92 | 94 + 93 | 95 + 94 | 96 + 95 | 97 + 96 | 98 + 97 | 99 + 98 | 100 + 99 | 101 + 100 | 102 + 91 | 95 +(11 rows) + +set local enable_answer_query_using_materialized_views = on; +explain(costs off, verbose) +select c1, c3 from aqumv_t5 where c1 > 90 order by c2, c3 asc; + QUERY PLAN +---------------------------------------------------------------------------------- + Gather Motion 3:1 (slice1; segments: 3) + Output: mc1, mc3, mc2 + Merge Key: mc2, mc3 + -> Sort + Output: mc1, mc3, mc2 + Sort Key: aqumv_mvt5_0.mc2, aqumv_mvt5_0.mc3 + -> Seq Scan on public.aqumv_mvt5_0 + Output: mc1, mc3, mc2 + Settings: enable_answer_query_using_materialized_views = 'on', optimizer = 'off' + Optimizer: Postgres query optimizer +(10 rows) + +select c1, c3 from aqumv_t5 where c1 > 90 order by c2, c3 asc; + c1 | c3 +-----+----- + 91 | 93 + 92 | 94 + 93 | 95 + 94 | 96 + 95 | 97 + 96 | 98 + 97 | 99 + 98 | 100 + 99 | 101 + 100 | 102 + 91 | 95 +(11 rows) + +-- order by expression. +set local enable_answer_query_using_materialized_views = off; +explain(costs off, verbose) +select c1, c3 from aqumv_t5 where c1 > 90 order by c2 - c1 - 1 asc; + QUERY PLAN +----------------------------------------------------------------------------------- + Gather Motion 3:1 (slice1; segments: 3) + Output: c1, c3, (((c2 - c1) - 1)) + Merge Key: (((c2 - c1) - 1)) + -> Sort + Output: c1, c3, (((c2 - c1) - 1)) + Sort Key: (((aqumv_t5.c2 - aqumv_t5.c1) - 1)) + -> Seq Scan on public.aqumv_t5 + Output: c1, c3, ((c2 - c1) - 1) + Filter: (aqumv_t5.c1 > 90) + Settings: enable_answer_query_using_materialized_views = 'off', optimizer = 'off' + Optimizer: Postgres query optimizer +(11 rows) + +select c1, c3 from aqumv_t5 where c1 > 90 order by c2 - c1 - 1 asc; + c1 | c3 +-----+----- + 92 | 94 + 93 | 95 + 94 | 96 + 97 | 99 + 99 | 101 + 96 | 98 + 100 | 102 + 91 | 93 + 95 | 97 + 98 | 100 + 91 | 95 +(11 rows) + +set local enable_answer_query_using_materialized_views = on; +explain(costs off, verbose) +select c1, c3 from aqumv_t5 where c1 > 90 order by c2 - c1 - 1 asc; + QUERY PLAN +---------------------------------------------------------------------------------- + Gather Motion 3:1 (slice1; segments: 3) + Output: mc1, mc3, (((mc2 - mc1) - 1)) + Merge Key: (((mc2 - mc1) - 1)) + -> Sort + Output: mc1, mc3, (((mc2 - mc1) - 1)) + Sort Key: (((aqumv_mvt5_0.mc2 - aqumv_mvt5_0.mc1) - 1)) + -> Seq Scan on public.aqumv_mvt5_0 + Output: mc1, mc3, ((mc2 - mc1) - 1) + Settings: enable_answer_query_using_materialized_views = 'on', optimizer = 'off' + Optimizer: Postgres query optimizer +(10 rows) + +select c1, c3 from aqumv_t5 where c1 > 90 order by c2 - c1 - 1 asc; + c1 | c3 +-----+----- + 92 | 94 + 93 | 95 + 94 | 96 + 97 | 99 + 99 | 101 + 96 | 98 + 100 | 102 + 91 | 93 + 95 | 97 + 98 | 100 + 91 | 95 +(11 rows) + +-- order by number. +set local enable_answer_query_using_materialized_views = off; +explain(costs off, verbose) +select c1, c3 from aqumv_t5 where c1 > 90 order by 2, 1 asc; + QUERY PLAN +----------------------------------------------------------------------------------- + Gather Motion 3:1 (slice1; segments: 3) + Output: c1, c3 + Merge Key: c3, c1 + -> Sort + Output: c1, c3 + Sort Key: aqumv_t5.c3, aqumv_t5.c1 + -> Seq Scan on public.aqumv_t5 + Output: c1, c3 + Filter: (aqumv_t5.c1 > 90) + Settings: enable_answer_query_using_materialized_views = 'off', optimizer = 'off' + Optimizer: Postgres query optimizer +(11 rows) + +select c1, c3 from aqumv_t5 where c1 > 90 order by 2, 1 asc; + c1 | c3 +-----+----- + 91 | 93 + 92 | 94 + 91 | 95 + 93 | 95 + 94 | 96 + 95 | 97 + 96 | 98 + 97 | 99 + 98 | 100 + 99 | 101 + 100 | 102 +(11 rows) + +set local enable_answer_query_using_materialized_views = on; +explain(costs off, verbose) +select c1, c3 from aqumv_t5 where c1 > 90 order by 2, 1 asc; + QUERY PLAN +---------------------------------------------------------------------------------- + Gather Motion 3:1 (slice1; segments: 3) + Output: mc1, mc3 + Merge Key: mc3, mc1 + -> Sort + Output: mc1, mc3 + Sort Key: aqumv_mvt5_0.mc3, aqumv_mvt5_0.mc1 + -> Seq Scan on public.aqumv_mvt5_0 + Output: mc1, mc3 + Settings: enable_answer_query_using_materialized_views = 'on', optimizer = 'off' + Optimizer: Postgres query optimizer +(10 rows) + +select c1, c3 from aqumv_t5 where c1 > 90 order by 2, 1 asc; + c1 | c3 +-----+----- + 91 | 93 + 92 | 94 + 91 | 95 + 93 | 95 + 94 | 96 + 95 | 97 + 96 | 98 + 97 | 99 + 98 | 100 + 99 | 101 + 100 | 102 +(11 rows) + +-- order by result column. +set local enable_answer_query_using_materialized_views = off; +explain(costs off, verbose) +select c1, sum(c3) as sum_c3 from aqumv_t5 where c1 > 90 group by c1 order by sum_c3 asc; + QUERY PLAN +----------------------------------------------------------------------------------- + Gather Motion 3:1 (slice1; segments: 3) + Output: c1, (sum(c3)) + Merge Key: (sum(c3)) + -> Sort + Output: c1, (sum(c3)) + Sort Key: (sum(aqumv_t5.c3)) + -> HashAggregate + Output: c1, sum(c3) + Group Key: aqumv_t5.c1 + -> Seq Scan on public.aqumv_t5 + Output: c1, c2, c3 + Filter: (aqumv_t5.c1 > 90) + Settings: enable_answer_query_using_materialized_views = 'off', optimizer = 'off' + Optimizer: Postgres query optimizer +(14 rows) + +select c1, sum(c3) as sum_c3 from aqumv_t5 where c1 > 90 group by c1 order by sum_c3 asc; + c1 | sum_c3 +-----+-------- + 92 | 94 + 93 | 95 + 94 | 96 + 95 | 97 + 96 | 98 + 97 | 99 + 98 | 100 + 99 | 101 + 100 | 102 + 91 | 188 +(10 rows) + +set local enable_answer_query_using_materialized_views = on; +explain(costs off, verbose) +select c1, sum(c3) as sum_c3 from aqumv_t5 where c1 > 90 group by c1 order by sum_c3 asc; + QUERY PLAN +---------------------------------------------------------------------------------- + Gather Motion 3:1 (slice1; segments: 3) + Output: mc1, (sum(mc3)) + Merge Key: (sum(mc3)) + -> Sort + Output: mc1, (sum(mc3)) + Sort Key: (sum(aqumv_mvt5_0.mc3)) + -> HashAggregate + Output: mc1, sum(mc3) + Group Key: aqumv_mvt5_0.mc1 + -> Seq Scan on public.aqumv_mvt5_0 + Output: mc1, mc2, mc3 + Settings: enable_answer_query_using_materialized_views = 'on', optimizer = 'off' + Optimizer: Postgres query optimizer +(13 rows) + +select c1, sum(c3) as sum_c3 from aqumv_t5 where c1 > 90 group by c1 order by sum_c3 asc; + c1 | sum_c3 +-----+-------- + 92 | 94 + 93 | 95 + 94 | 96 + 95 | 97 + 96 | 98 + 97 | 99 + 98 | 100 + 99 | 101 + 100 | 102 + 91 | 188 +(10 rows) + abort; reset optimizer; reset enable_answer_query_using_materialized_views; diff --git a/src/test/regress/sql/aqumv.sql b/src/test/regress/sql/aqumv.sql index c812727096d..772a1358b36 100644 --- a/src/test/regress/sql/aqumv.sql +++ b/src/test/regress/sql/aqumv.sql @@ -409,6 +409,59 @@ select c1, c3, avg(c2) from aqumv_t4 where c1 > 90 group by (c1, c3) having c1 > abort; +-- Test Order By of origin query. +begin; +create table aqumv_t5(c1 int, c2 int, c3 int) distributed by (c1); +insert into aqumv_t5 select i, i+1, i+2 from generate_series(1, 100) i; +insert into aqumv_t5 values (91, NULL, 95); +analyze aqumv_t5; + +create incremental materialized view aqumv_mvt5_0 as + select c1 as mc1, c2 as mc2, c3 as mc3 + from aqumv_t5 where c1 > 90; +analyze aqumv_mvt5_0; + +-- order by column. +set local enable_answer_query_using_materialized_views = off; +explain(costs off, verbose) +select c1, c3 from aqumv_t5 where c1 > 90 order by c2, c3 asc; +select c1, c3 from aqumv_t5 where c1 > 90 order by c2, c3 asc; +set local enable_answer_query_using_materialized_views = on; +explain(costs off, verbose) +select c1, c3 from aqumv_t5 where c1 > 90 order by c2, c3 asc; +select c1, c3 from aqumv_t5 where c1 > 90 order by c2, c3 asc; + +-- order by expression. +set local enable_answer_query_using_materialized_views = off; +explain(costs off, verbose) +select c1, c3 from aqumv_t5 where c1 > 90 order by c2 - c1 - 1 asc; +select c1, c3 from aqumv_t5 where c1 > 90 order by c2 - c1 - 1 asc; +set local enable_answer_query_using_materialized_views = on; +explain(costs off, verbose) +select c1, c3 from aqumv_t5 where c1 > 90 order by c2 - c1 - 1 asc; +select c1, c3 from aqumv_t5 where c1 > 90 order by c2 - c1 - 1 asc; + +-- order by number. +set local enable_answer_query_using_materialized_views = off; +explain(costs off, verbose) +select c1, c3 from aqumv_t5 where c1 > 90 order by 2, 1 asc; +select c1, c3 from aqumv_t5 where c1 > 90 order by 2, 1 asc; +set local enable_answer_query_using_materialized_views = on; +explain(costs off, verbose) +select c1, c3 from aqumv_t5 where c1 > 90 order by 2, 1 asc; +select c1, c3 from aqumv_t5 where c1 > 90 order by 2, 1 asc; + +-- order by result column. +set local enable_answer_query_using_materialized_views = off; +explain(costs off, verbose) +select c1, sum(c3) as sum_c3 from aqumv_t5 where c1 > 90 group by c1 order by sum_c3 asc; +select c1, sum(c3) as sum_c3 from aqumv_t5 where c1 > 90 group by c1 order by sum_c3 asc; +set local enable_answer_query_using_materialized_views = on; +explain(costs off, verbose) +select c1, sum(c3) as sum_c3 from aqumv_t5 where c1 > 90 group by c1 order by sum_c3 asc; +select c1, sum(c3) as sum_c3 from aqumv_t5 where c1 > 90 group by c1 order by sum_c3 asc; +abort; + reset optimizer; reset enable_answer_query_using_materialized_views; drop table aqumv_t1 cascade;