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] Support HAVING clause in origin query #354

Merged
merged 1 commit into from
Jan 4, 2024

Conversation

avamingli
Copy link
Collaborator

@avamingli avamingli commented Jan 2, 2024

Support HAVING clause of origin query if it could be computed from materialized views.

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, avg(c2) from t1 where c1 > 90
  group by (c1, c3) having avg(c2) > 95;

Could be rewritten to:

  select mc1, mc3, avg(mc2) from mv
  group by (mc1, mc3) having avg(mc2) > 95;

For HAVING quals don't have aggregations, they may be pushed down to jointree's quals and would be processed in post_quals.

DDL:

create table aqumv_t4(c1 int, c2 int, c3 int) distributed by (c1);
insert into aqumv_t4 select i, i+1, i+2 from generate_series(1, 100) i;
insert into aqumv_t4 values (91, NULL, 95);
analyze aqumv_t4;
create incremental materialized view aqumv_mvt4_0 as
  select c1 as mc1, c2 as mc2, c3 as mc3
  from aqumv_t4 where c1 > 90;
analyze aqumv_mvt4_0;
begin;
-- HAVING clause pushed down to where quals.
set local enable_answer_query_using_materialized_views = off;
explain(costs off, verbose)
select c1, c3 from aqumv_t4 where c1 > 90 group by (c1, c3) having c3 > 97 ;
                                    QUERY PLAN                                     
-----------------------------------------------------------------------------------
 Gather Motion 3:1  (slice1; segments: 3)
   Output: c1, c3
   ->  GroupAggregate
         Output: c1, c3
         Group Key: aqumv_t4.c1, aqumv_t4.c3
         ->  Sort
               Output: c1, c3
               Sort Key: aqumv_t4.c1, aqumv_t4.c3
               ->  Seq Scan on public.aqumv_t4
                     Output: c1, c3
                     Filter: ((aqumv_t4.c1 > 90) AND (aqumv_t4.c3 > 97))
 Settings: enable_answer_query_using_materialized_views = 'off', optimizer = 'off'
 Optimizer: Postgres query optimizer
(13 rows)
set local enable_answer_query_using_materialized_views = on;
explain(costs off, verbose)
select c1, c3 from aqumv_t4 where c1 > 90 group by (c1, c3) having c3 > 97 ;
                                    QUERY PLAN                                    
----------------------------------------------------------------------------------
 Gather Motion 3:1  (slice1; segments: 3)
   Output: mc1, mc3
   ->  HashAggregate
         Output: mc1, mc3
         Group Key: aqumv_mvt4_0.mc1, aqumv_mvt4_0.mc3
         ->  Seq Scan on public.aqumv_mvt4_0
               Output: mc1, mc2, mc3
               Filter: (aqumv_mvt4_0.mc3 > 97)
 Settings: enable_answer_query_using_materialized_views = 'on', optimizer = 'off'
 Optimizer: Postgres query optimizer
(10 rows)
end;

For HAVING quals have aggregations, we process them in Aggrefs of target list.

explain(costs off, verbose)
select c1, c3, avg(c2) from aqumv_t4 where c1 > 90 group by (c1, c3) having avg(c2) > 95;
                                    QUERY PLAN                                    
----------------------------------------------------------------------------------
 Gather Motion 3:1  (slice1; segments: 3)
   Output: mc1, mc3, (avg(mc2))
   ->  HashAggregate
         Output: mc1, mc3, avg(mc2)
         Group Key: aqumv_mvt4_0.mc1, aqumv_mvt4_0.mc3
         Filter: (avg(aqumv_mvt4_0.mc2) > '95'::numeric)
         ->  Seq Scan on public.aqumv_mvt4_0
               Output: mc1, mc2, mc3
 Settings: enable_answer_query_using_materialized_views = 'on', optimizer = 'off'
 Optimizer: Postgres query optimizer
(10 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馃コ

@avamingli avamingli self-assigned this Jan 2, 2024
@avamingli avamingli changed the title [Answer Query Using Materialized Views] Support HAVING clause in origin query. [Answer Query Using Materialized Views] Support HAVING clause in origin query Jan 2, 2024
Support HAVING clause of origin query if it could be
computed from materialized views.

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, avg(c2) from t1 where c1 > 90
  group by (c1, c3) having avg(c2) > 95;

Could be rewritten to:

  select mc1, mc3, avg(mc2) from mv
  group by (mc1, mc3) having avg(mc2) > 95;

For HAVING quals have aggregations, we process them
in Aggrefs of target list.
For HAVING quals don't have aggregations, they may be
pushed down to jointree's quals and would be processed
in post_quals.

Authored-by: Zhang Mingli avamingli@gmail.com
Copy link
Collaborator

@yjhjstz yjhjstz left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

LGTM

@avamingli avamingli merged commit aa83847 into cloudberrydb:main Jan 4, 2024
9 checks passed
@avamingli avamingli deleted the having_aqumv branch January 4, 2024 11:31
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