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鈥檒l occasionally send you account related emails.

Already on GitHub? Sign in to your account

[Answer Query Using Materialized Views] Compute Aggregations on Materialized Views. #322

Merged
merged 1 commit into from
Dec 19, 2023

Conversation

avamingli
Copy link
Collaborator

@avamingli avamingli commented Dec 6, 2023

Support origin query has aggregations, compute Aggregations on materilized views whose query don't have Aggegations itself.

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

Origin query:

select count(c1)+1, sum(c2) filter (where c2 > 95), stddev(c3) from t1 where c1 > 90;

Could be rewritten to:

select count(mc1)+1, sum(mc2) filter (where mc2 > 95), stddev(mc3) from mv;

All aggregate functions including count(*) are supported in AQUMV which is not limited to IVM's current aggregate functions: count, sum, avg.
Complex expressions have aggregations, and aggregations with Filter clause are also supported.

Aggs in TargetList
aqumv_process_targetlist() could handle that because all Vars under Aggrefs could be rewritten to mv's columns.
Complex expression have Aggs could be processed as we use a Greedy Algorithem to match target expressions.

Aggs Filter Clause
They could be processed automatically as we process post_quals in aqumv_adjust_sub_matched_expr_mutator().

Count(*)
Expressin count(*) has no explicit Vars, but it still need rows from subplan nodes.
NULL values should be taken into account unlike count(a_column).


An example with AGG FILTER clause(See more details in test cases.)

explain(costs off, verbose)
select sum(c2), sum(c2) filter (where c2 > 95) from aqumv_t2 where c1 > 90;
                                    QUERY PLAN                                     
-----------------------------------------------------------------------------------
 Finalize Aggregate
   Output: sum(c2), sum(c2) FILTER (WHERE (c2 > 95))
   ->  Gather Motion 3:1  (slice1; segments: 3)
         Output: (PARTIAL sum(c2)), (PARTIAL sum(c2) FILTER (WHERE (c2 > 95)))
         ->  Partial Aggregate
               Output: PARTIAL sum(c2), PARTIAL sum(c2) FILTER (WHERE (c2 > 95))
               ->  Seq Scan on public.aqumv_t2
                     Output: c1, c2, c3
                     Filter: (aqumv_t2.c1 > 90)
 Settings: enable_answer_query_using_materialized_views = 'off', optimizer = 'off'
 Optimizer: Postgres query optimizer
(11 rows)

select sum(c2), sum(c2) filter (where c2 > 95) from aqumv_t2 where c1 > 90;
 sum | sum 
-----+-----
 965 | 591
(1 row)

Compute Aggregations on Materialized Views

set enable_answer_query_using_materialized_views = on;
explain(costs off, verbose)
select sum(c2), sum(c2) filter (where c2 > 95) from aqumv_t2 where c1 > 90;
                                     QUERY PLAN                                     
------------------------------------------------------------------------------------
 Finalize Aggregate
   Output: sum(mc2), sum(mc2) FILTER (WHERE (mc2 > 95))
   ->  Gather Motion 3:1  (slice1; segments: 3)
         Output: (PARTIAL sum(mc2)), (PARTIAL sum(mc2) FILTER (WHERE (mc2 > 95)))
         ->  Partial Aggregate
               Output: PARTIAL sum(mc2), PARTIAL sum(mc2) FILTER (WHERE (mc2 > 95))
               ->  Seq Scan on public.aqumv_mvt2_0
                     Output: mc1, mc2, mc3
 Settings: enable_answer_query_using_materialized_views = 'on', optimizer = 'off'
 Optimizer: Postgres query optimizer
(10 rows)

select sum(c2), sum(c2) filter (where c2 > 95) from aqumv_t2 where c1 > 90;
 sum | sum 
-----+-----
 965 | 591
(1 row)

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馃コ

@avamingli avamingli self-assigned this Dec 6, 2023
@avamingli avamingli changed the title [AQUMV] Compute Aggregations on Materialized Views. [Answer Query Using Materialized Views] Compute Aggregations on Materialized Views. Dec 6, 2023
@avamingli
Copy link
Collaborator Author

avamingli commented Dec 8, 2023

Hold on this PR, will push later after upcoming RELEASE.

Support origin query has aggregations, compute Aggregations
on materilized views whose query don't have Aggegations itself.

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

Origin query:

select count(c1)+1, sum(c2) filter (where c2 > 95), stddev(c3)
  from t1 where c1 > 90;

Could be rewritten to:

select count(mc1)+1, sum(mc2) filter (where mc2 > 95), stddev(mc3)
  from mv;

All aggregate functions including count(*) are supported
in AQUMV which is not limited to IVM's current aggregate
functions: count, sum, avg.
Complex expressions have aggregations, and aggregations
with Filter clause are also supported.

Authored-by: Zhang Mingli avamingli@gmail.com
@avamingli avamingli merged commit a70f7ee into cloudberrydb:main Dec 19, 2023
9 checks passed
@avamingli avamingli deleted the aqumv_agg_on_query branch December 19, 2023 04:14
@avamingli
Copy link
Collaborator Author

Hold on this PR, will push later after upcoming RELEASE.

Release tag has been checked out, pushed.

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.

None yet

2 participants