Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

[Answer Query Using Materialized Views] Support GROUP BY, GROUPING SETS, ROLLUP, CUBE in origin query. #342

Merged
merged 1 commit into from
Dec 25, 2023

Conversation

avamingli
Copy link
Contributor

Support Clauses like: Group By column(s), GROUPING SETS, ROLLUP, CUBE in origin query if they could be computed from materialized views's target list.

create incremental materialized view mv as
  select c1 as mc1, c2 as mc2, c3 as mc3
  from t1 where c1 > 90;

Origin query:

  select c1, c3, count(c2) from t1 where c1 > 90
  group by c1, c3;

Could be rewritten to:

  select mc1, mc3, count(mc2) from mv
  group by mc1, mc3;

example DDL

create table aqumv_t3(c1 int, c2 int, c3 int) distributed by (c1);
insert into aqumv_t3 select i, i+1, i+2 from generate_series(1, 100) i;
insert into aqumv_t3 values (91, NULL, 95);
analyze aqumv_t3;
create incremental materialized view aqumv_mvt3_0 as
  select c1 as mc1, c2 as mc2, c3 as mc3
  from aqumv_t3 where c1 > 90;
analyze aqumv_mvt3_0;

Group BY(columns)

explain(costs off, verbose)
select c1, c3, count(c2) from aqumv_t3 where c1 > 90 group by c1, c3;
                                    QUERY PLAN                                    
----------------------------------------------------------------------------------
 Gather Motion 3:1  (slice1; segments: 3)
   Output: mc1, mc3, (count(mc2))
   ->  HashAggregate
         Output: mc1, mc3, count(mc2)
         Group Key: aqumv_mvt3_0.mc1, aqumv_mvt3_0.mc3
         ->  Seq Scan on public.aqumv_mvt3_0
               Output: mc1, mc2, mc3
 Settings: enable_answer_query_using_materialized_views = 'on', optimizer = 'off'
 Optimizer: Postgres query optimizer
(9 rows)

Grouping Sets

explain(costs off, verbose)
select c1, c3, count(c2) from aqumv_t3 where c1 > 90 group by grouping sets((c1), (c3));
                                    QUERY PLAN                                    
----------------------------------------------------------------------------------
 HashAggregate
   Output: mc1, mc3, count(mc2)
   Hash Key: aqumv_mvt3_0.mc1
   Hash Key: aqumv_mvt3_0.mc3
   ->  Gather Motion 3:1  (slice1; segments: 3)
         Output: mc1, mc3, mc2
         ->  Seq Scan on public.aqumv_mvt3_0
               Output: mc1, mc3, mc2
 Settings: enable_answer_query_using_materialized_views = 'on', optimizer = 'off'
 Optimizer: Postgres query optimizer
(10 rows)

ROLLUP

explain(costs off, verbose)
select c1, c3, count(c2) from aqumv_t3 where c1 > 90 group by rollup(c1, c3);
                                    QUERY PLAN                                    
----------------------------------------------------------------------------------
 GroupAggregate
   Output: mc1, mc3, count(mc2)
   Group Key: aqumv_mvt3_0.mc1, aqumv_mvt3_0.mc3
   Group Key: aqumv_mvt3_0.mc1
   Group Key: ()
   ->  Gather Motion 3:1  (slice1; segments: 3)
         Output: mc1, mc3, mc2
         Merge Key: mc1, mc3
         ->  Sort
               Output: mc1, mc3, mc2
               Sort Key: aqumv_mvt3_0.mc1, aqumv_mvt3_0.mc3
               ->  Seq Scan on public.aqumv_mvt3_0
                     Output: mc1, mc3, mc2
 Settings: enable_answer_query_using_materialized_views = 'on', optimizer = 'off'
 Optimizer: Postgres query optimizer
(15 rows)

CUBE

explain(costs off, verbose)
select c1, c3, count(c2) from aqumv_t3 where c1 > 90 group by cube(c1, c3);
                                    QUERY PLAN                                    
----------------------------------------------------------------------------------
 MixedAggregate
   Output: mc1, mc3, count(mc2)
   Hash Key: aqumv_mvt3_0.mc3
   Group Key: aqumv_mvt3_0.mc1, aqumv_mvt3_0.mc3
   Group Key: aqumv_mvt3_0.mc1
   Group Key: ()
   ->  Gather Motion 3:1  (slice1; segments: 3)
         Output: mc1, mc3, mc2
         Merge Key: mc1, mc3
         ->  Sort
               Output: mc1, mc3, mc2
               Sort Key: aqumv_mvt3_0.mc1, aqumv_mvt3_0.mc3
               ->  Seq Scan on public.aqumv_mvt3_0
                     Output: mc1, mc3, mc2
 Settings: enable_answer_query_using_materialized_views = 'on', optimizer = 'off'
 Optimizer: Postgres query optimizer
(16 rows)

Authored-by: Zhang Mingli avamingli@gmail.com

fix #ISSUE_Number


Change logs

Describe your change clearly, including what problem is being solved or what feature is being added.

If it has some breaking backward or forward compatibility, please clary.

Why are the changes needed?

Describe why the changes are necessary.

Does this PR introduce any user-facing change?

If yes, please clarify the previous behavior and the change this PR proposes.

How was this patch tested?

Please detail how the changes were tested, including manual tests and any relevant unit or integration tests.

Contributor's Checklist

Here are some reminders and checklists before/when submitting your pull request, please check them:

  • Make sure your Pull Request has a clear title and commit message. You can take git-commit template as a reference.
  • Sign the Contributor License Agreement as prompted for your first-time contribution(One-time setup).
  • Learn the coding contribution guide, including our code conventions, workflow and more.
  • List your communication in the GitHub Issues or Discussions (if has or needed).
  • Document changes.
  • Add tests for the change
  • Pass make installcheck
  • Pass make -C src/test installcheck-cbdb-parallel
  • Feel free to request cloudberrydb/dev team for review and approval when your PR is ready🥳

Support Clauses like: Group By column(s), GROUPING SETS,
ROLLUP, CUBE in origin query if they could be computed
from materialized views's target list.

create incremental materialized view mv as
  select c1 as mc1, c2 as mc2, c3 as mc3
  from t1 where c1 > 90;

Origin query:

  select c1, c3, count(c2) from t1 where c1 > 90
  group by c1, c3;

Could be rewritten to:

  select mc1, mc3, count(mc2) from mv
  group by mc1, mc3;

Authored-by: Zhang Mingli avamingli@gmail.com
@avamingli avamingli self-assigned this Dec 19, 2023
@avamingli avamingli changed the title [AQUMV] Support GROUP BY, GROUPING SETS, ROLLUP, CUBE in origin query. [Answer Query Using Materialized Views] Support GROUP BY, GROUPING SETS, ROLLUP, CUBE in origin query. Dec 19, 2023
@avamingli
Copy link
Contributor Author

Pushed, thanks.

@avamingli avamingli merged commit 2265a17 into apache:main Dec 25, 2023
9 checks passed
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

2 participants