Skip to content

Commit 4413337

Browse files
committed
[AQUMV] Add cases of INSERT-SELECT queries using materialized views.
We already have the ability to use materialized views instead of origin table in the SQL like: INSERT INTO target table SELECT FROM origin table. When valid materialized view candidates exist, the system will automatically use them for the SELECT portion of the query, eliminating the need to access and recompute data from the original tables, providing significant performance benefits for queries involving large datasets or frequent INSERT-SELECT operations by leveraging pre-computed results from materialized views rather than processing raw data each time. Authored-by: Zhang Mingli <[email protected]>
1 parent 86b66ac commit 4413337

File tree

2 files changed

+91
-0
lines changed

2 files changed

+91
-0
lines changed

src/test/regress/expected/aqumv.out

Lines changed: 69 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -3305,6 +3305,75 @@ select count(*) from par_1_prt_2;
33053305
Optimizer: Postgres query optimizer
33063306
(6 rows)
33073307

3308+
abort;
3309+
-- Test INSERT SELECT
3310+
begin;
3311+
create table t_insert(a int);
3312+
NOTICE: Table doesn't have 'DISTRIBUTED BY' clause -- Using column named 'a' as the Apache Cloudberry data distribution key for this table.
3313+
HINT: The 'DISTRIBUTED BY' clause determines the distribution of data. Make sure column(s) chosen are the optimal data distribution key to minimize skew.
3314+
create table t_select(a int);
3315+
NOTICE: Table doesn't have 'DISTRIBUTED BY' clause -- Using column named 'a' as the Apache Cloudberry data distribution key for this table.
3316+
HINT: The 'DISTRIBUTED BY' clause determines the distribution of data. Make sure column(s) chosen are the optimal data distribution key to minimize skew.
3317+
insert into t_select select i from generate_series(1, 1000) i;
3318+
analyze t_insert;
3319+
create materialized view mv_insert_select as
3320+
select count(a) from t_select;
3321+
NOTICE: Table doesn't have 'DISTRIBUTED BY' clause -- Using column(s) named 'count' as the Apache Cloudberry data distribution key for this table.
3322+
HINT: The 'DISTRIBUTED BY' clause determines the distribution of data. Make sure column(s) chosen are the optimal data distribution key to minimize skew.
3323+
analyze mv_insert_select;
3324+
set local enable_answer_query_using_materialized_views = off;
3325+
explain(costs off, verbose) insert into t_insert select count(a) from t_select;
3326+
QUERY PLAN
3327+
-----------------------------------------------------------------------------------
3328+
Insert on aqumv.t_insert
3329+
-> Redistribute Motion 1:3 (slice1; segments: 1)
3330+
Output: (("*SELECT*".count)::integer)
3331+
Hash Key: (("*SELECT*".count)::integer)
3332+
-> Subquery Scan on "*SELECT*"
3333+
Output: "*SELECT*".count
3334+
-> Finalize Aggregate
3335+
Output: count(t_select.a)
3336+
-> Gather Motion 3:1 (slice2; segments: 3)
3337+
Output: (PARTIAL count(t_select.a))
3338+
-> Partial Aggregate
3339+
Output: PARTIAL count(t_select.a)
3340+
-> Seq Scan on aqumv.t_select
3341+
Output: t_select.a
3342+
Settings: enable_answer_query_using_materialized_views = 'off', optimizer = 'off'
3343+
Optimizer: Postgres query optimizer
3344+
(16 rows)
3345+
3346+
insert into t_insert select count(a) from t_select;
3347+
select * from t_insert;
3348+
a
3349+
------
3350+
1000
3351+
(1 row)
3352+
3353+
truncate t_insert;
3354+
set local enable_answer_query_using_materialized_views = on;
3355+
explain(costs off, verbose) insert into t_insert select count(a) from t_select;
3356+
QUERY PLAN
3357+
----------------------------------------------------------------------------------
3358+
Insert on aqumv.t_insert
3359+
-> Redistribute Motion 3:3 (slice1; segments: 3)
3360+
Output: (("*SELECT*".count)::integer)
3361+
Hash Key: (("*SELECT*".count)::integer)
3362+
-> Subquery Scan on "*SELECT*"
3363+
Output: "*SELECT*".count
3364+
-> Seq Scan on aqumv.mv_insert_select
3365+
Output: mv_insert_select.count
3366+
Settings: enable_answer_query_using_materialized_views = 'on', optimizer = 'off'
3367+
Optimizer: Postgres query optimizer
3368+
(10 rows)
3369+
3370+
insert into t_insert select count(a) from t_select;
3371+
select * from t_insert;
3372+
a
3373+
------
3374+
1000
3375+
(1 row)
3376+
33083377
abort;
33093378
reset optimizer;
33103379
reset enable_answer_query_using_materialized_views;

src/test/regress/sql/aqumv.sql

Lines changed: 22 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -852,6 +852,28 @@ explain(costs off, verbose)
852852
select count(*) from par_1_prt_2;
853853
abort;
854854

855+
-- Test INSERT SELECT
856+
begin;
857+
create table t_insert(a int);
858+
create table t_select(a int);
859+
insert into t_select select i from generate_series(1, 1000) i;
860+
analyze t_insert;
861+
create materialized view mv_insert_select as
862+
select count(a) from t_select;
863+
analyze mv_insert_select;
864+
865+
set local enable_answer_query_using_materialized_views = off;
866+
explain(costs off, verbose) insert into t_insert select count(a) from t_select;
867+
insert into t_insert select count(a) from t_select;
868+
select * from t_insert;
869+
truncate t_insert;
870+
871+
set local enable_answer_query_using_materialized_views = on;
872+
explain(costs off, verbose) insert into t_insert select count(a) from t_select;
873+
insert into t_insert select count(a) from t_select;
874+
select * from t_insert;
875+
abort;
876+
855877
reset optimizer;
856878
reset enable_answer_query_using_materialized_views;
857879
-- start_ignore

0 commit comments

Comments
 (0)