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

[AQUMV]Enable answer query using Materialized View for external table. #702

Open
wants to merge 1 commit into
base: main
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
12 changes: 10 additions & 2 deletions src/backend/catalog/gp_matview_aux.c
Original file line number Diff line number Diff line change
Expand Up @@ -88,8 +88,16 @@ GetViewBaseRelids(const Query *viewQuery)
if (rte->rtekind != RTE_RELATION)
return NIL;

/* Only support normal relation now. */
if (get_rel_relkind(rte->relid) != RELKIND_RELATION)
char relkind = get_rel_relkind(rte->relid);

/*
* Allow foreign table here, however we don't know if the data is
* up to date or not of the view.
* But if users want to query matview instead of query foreign tables
* outside CBDB, let them decide with aqumv_allow_foreign_table.
*/
if (relkind != RELKIND_RELATION &&
relkind != RELKIND_FOREIGN_TABLE)
return NIL;

/*
Expand Down
3 changes: 3 additions & 0 deletions src/backend/optimizer/plan/aqumv.c
Original file line number Diff line number Diff line change
Expand Up @@ -151,6 +151,9 @@ answer_query_using_materialized_views(PlannerInfo *root,
has_subclass(origin_rel_oid))
return mv_final_rel;

if (get_rel_relkind(origin_rel_oid) == RELKIND_FOREIGN_TABLE && !aqumv_allow_foreign_table)
Copy link
Member

Choose a reason for hiding this comment

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

create readable external table aqumv_ext_r ()

can we get readable from table ?

Copy link
Contributor Author

Choose a reason for hiding this comment

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

GP forbids creating a matview as select from writable external table.

Copy link
Member

Choose a reason for hiding this comment

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

create readable external table aqumv_ext_r(id int)
location ('demoprot://aqumvtextfile.txt') format 'text';

  1. can we mantain aqumvtextfile.txtstatus in gp_matview_auxuse file timestamp?

Copy link
Contributor Author

Choose a reason for hiding this comment

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

It's just an example, they could be files, remote servers or another databases outside CBDB. You couldn't know the status of them and pointless for that. See more in #693

return mv_final_rel;

ruleDesc = table_open(RewriteRelationId, AccessShareLock);

rcscan = systable_beginscan(ruleDesc, InvalidOid, false,
Expand Down
15 changes: 12 additions & 3 deletions src/backend/utils/misc/guc_gp.c
Original file line number Diff line number Diff line change
Expand Up @@ -446,7 +446,8 @@ bool gp_enable_predicate_pushdown;
int gp_predicate_pushdown_sample_rows;

bool enable_offload_entry_to_qe = false;
bool enable_answer_query_using_materialized_views = false;
bool enable_answer_query_using_materialized_views = false;
bool aqumv_allow_foreign_table = false;

bool gp_log_endpoints = false;

Expand Down Expand Up @@ -3114,8 +3115,16 @@ struct config_bool ConfigureNamesBool_gp[] =
true,
NULL, NULL, NULL
},


{
{"aqumv_allow_foreign_table", PGC_USERSET, DEVELOPER_OPTIONS,
gettext_noop("allow answer query using materialized views which have foreign or external tables."),
NULL,
GUC_EXPLAIN
},
&aqumv_allow_foreign_table,
false,
NULL, NULL, NULL
},
{
{"gp_log_suboverflow_statement", PGC_SUSET, LOGGING_WHAT,
gettext_noop("Enable logging of statements that cause subtransaction overflow."),
Expand Down
1 change: 1 addition & 0 deletions src/include/utils/guc.h
Original file line number Diff line number Diff line change
Expand Up @@ -298,6 +298,7 @@ extern int gp_appendonly_insert_files_tuples_range;
extern int gp_random_insert_segments;
extern bool enable_answer_query_using_materialized_views;
extern bool enable_offload_entry_to_qe;
extern bool aqumv_allow_foreign_table;
/*
* gp_enable_multiphase_limit is not cost based.
* When set to false, the planner will not use multi-phase limit.
Expand Down
1 change: 1 addition & 0 deletions src/include/utils/unsync_guc_name.h
Original file line number Diff line number Diff line change
Expand Up @@ -11,6 +11,7 @@
/* items in this file should be ordered */
"enable_answer_query_using_materialized_views",
"application_name",
"aqumv_allow_foreign_table",
"archive_cleanup_command",
"archive_command",
"archive_mode",
Expand Down
105 changes: 105 additions & 0 deletions src/test/regress/expected/aqumv.out
Original file line number Diff line number Diff line change
Expand Up @@ -2581,6 +2581,111 @@ select c2, c3 from aqumv_t7 where c1 > 90 order by c2, c3 fetch first 3 rows wit
(4 rows)

abort;
--
-- Test external table
--
begin;
CREATE OR REPLACE FUNCTION write_to_file() RETURNS integer as '$libdir/gpextprotocol.so', 'demoprot_export' LANGUAGE C STABLE NO SQL;
CREATE OR REPLACE FUNCTION read_from_file() RETURNS integer as '$libdir/gpextprotocol.so', 'demoprot_import' LANGUAGE C STABLE NO SQL;
--start_ignore
DROP PROTOCOL IF EXISTS demoprot;
NOTICE: protocol "demoprot" does not exist, skipping
--end_ignore
CREATE TRUSTED PROTOCOL demoprot (readfunc = 'read_from_file', writefunc = 'write_to_file'); -- should succeed
CREATE WRITABLE EXTERNAL TABLE aqumv_ext_w(id int)
LOCATION('demoprot://aqumvtextfile.txt')
FORMAT 'text'
DISTRIBUTED BY (id);
INSERT INTO aqumv_ext_w SELECT * FROM generate_series(1, 10);
CREATE READABLE EXTERNAL TABLE aqumv_ext_r(id int)
LOCATION('demoprot://aqumvtextfile.txt')
FORMAT 'text';
create materialized view aqumv_ext_mv as
select * from aqumv_ext_r;
NOTICE: Table doesn't have 'DISTRIBUTED BY' clause -- Using column(s) named 'id' 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_ext_mv;
explain (costs off, verbose)
select * from aqumv_ext_r;
QUERY PLAN
----------------------------------------------------------------------------------
Gather Motion 3:1 (slice1; segments: 3)
Output: id
-> Foreign Scan on aqumv.aqumv_ext_r
Output: id
Settings: enable_answer_query_using_materialized_views = 'on', optimizer = 'off'
Optimizer: Postgres query optimizer
(6 rows)

select * from aqumv_ext_r;
id
----
2
3
4
7
8
5
6
9
10
1
(10 rows)

set local enable_answer_query_using_materialized_views = on;
set local aqumv_allow_foreign_table = on;
explain (costs off, verbose)
select * from aqumv_ext_r;
QUERY PLAN
----------------------------------------------------------------------------------
Gather Motion 3:1 (slice1; segments: 3)
Output: id
-> Seq Scan on aqumv.aqumv_ext_mv
Output: id
Settings: enable_answer_query_using_materialized_views = 'on', optimizer = 'off'
Optimizer: Postgres query optimizer
(6 rows)

select * from aqumv_ext_r;
id
----
1
2
3
4
7
8
5
6
9
10
(10 rows)

create index on aqumv_ext_mv(id);
set local enable_seqscan = off;
explain (costs off, verbose)
select * from aqumv_ext_r where id = 5;
QUERY PLAN
----------------------------------------------------------------------------------------------------------
Gather Motion 1:1 (slice1; segments: 1)
Output: id
-> Index Only Scan using aqumv_ext_mv_id_idx on aqumv.aqumv_ext_mv
Output: id
Index Cond: (aqumv_ext_mv.id = 5)
Settings: enable_answer_query_using_materialized_views = 'on', enable_seqscan = 'off', optimizer = 'off'
Optimizer: Postgres query optimizer
(7 rows)

select * from aqumv_ext_r where id = 5;
id
----
5
(1 row)

abort;
--
-- End of test external table
--
reset optimizer;
reset enable_answer_query_using_materialized_views;
-- start_ignore
Expand Down
48 changes: 48 additions & 0 deletions src/test/regress/sql/aqumv.sql
Original file line number Diff line number Diff line change
Expand Up @@ -626,6 +626,54 @@ select c2, c3 from aqumv_t7 where c1 > 90 order by c2, c3 fetch first 3 rows wit

abort;

--
-- Test external table
--
begin;

CREATE OR REPLACE FUNCTION write_to_file() RETURNS integer as '$libdir/gpextprotocol.so', 'demoprot_export' LANGUAGE C STABLE NO SQL;
CREATE OR REPLACE FUNCTION read_from_file() RETURNS integer as '$libdir/gpextprotocol.so', 'demoprot_import' LANGUAGE C STABLE NO SQL;
--start_ignore
DROP PROTOCOL IF EXISTS demoprot;
--end_ignore
CREATE TRUSTED PROTOCOL demoprot (readfunc = 'read_from_file', writefunc = 'write_to_file'); -- should succeed

CREATE WRITABLE EXTERNAL TABLE aqumv_ext_w(id int)
LOCATION('demoprot://aqumvtextfile.txt')

FORMAT 'text'
DISTRIBUTED BY (id);

INSERT INTO aqumv_ext_w SELECT * FROM generate_series(1, 10);

CREATE READABLE EXTERNAL TABLE aqumv_ext_r(id int)
LOCATION('demoprot://aqumvtextfile.txt')
FORMAT 'text';

create materialized view aqumv_ext_mv as
select * from aqumv_ext_r;
analyze aqumv_ext_mv;

explain (costs off, verbose)
select * from aqumv_ext_r;
select * from aqumv_ext_r;
set local enable_answer_query_using_materialized_views = on;
set local aqumv_allow_foreign_table = on;
explain (costs off, verbose)
select * from aqumv_ext_r;
select * from aqumv_ext_r;

create index on aqumv_ext_mv(id);
set local enable_seqscan = off;
explain (costs off, verbose)
select * from aqumv_ext_r where id = 5;
select * from aqumv_ext_r where id = 5;

abort;
--
-- End of test external table
--

reset optimizer;
reset enable_answer_query_using_materialized_views;
-- start_ignore
Expand Down
Loading