From 68c8209174f48479df34f37b9ad303a737571473 Mon Sep 17 00:00:00 2001 From: Erik Wienhold Date: Fri, 26 Jul 2024 23:33:15 +0200 Subject: [PATCH v5 3/3] Replace matview WITH OLD DATA --- .../sgml/ref/create_materialized_view.sgml | 16 +++++++++-- src/backend/commands/createas.c | 26 +++++++++++------ src/backend/parser/gram.y | 16 +++++++++++ src/include/nodes/primnodes.h | 1 + src/test/regress/expected/matview.out | 28 +++++++++++++++++++ src/test/regress/sql/matview.sql | 15 ++++++++++ 6 files changed, 90 insertions(+), 12 deletions(-) diff --git a/doc/src/sgml/ref/create_materialized_view.sgml b/doc/src/sgml/ref/create_materialized_view.sgml index 5e03320eb7..1352e9de40 100644 --- a/doc/src/sgml/ref/create_materialized_view.sgml +++ b/doc/src/sgml/ref/create_materialized_view.sgml @@ -27,7 +27,7 @@ CREATE [ OR REPLACE ] MATERIALIZED VIEW [ IF NOT EXISTS ] table_nam [ WITH ( storage_parameter [= value] [, ... ] ) ] [ TABLESPACE tablespace_name ] AS query - [ WITH [ NO ] DATA ] + [ WITH [ NO | OLD ] DATA ] @@ -37,7 +37,8 @@ CREATE [ OR REPLACE ] MATERIALIZED VIEW [ IF NOT EXISTS ] table_nam CREATE MATERIALIZED VIEW defines a materialized view of a query. The query is executed and used to populate the view at the time - the command is issued (unless WITH NO DATA is used) and may be + the command is issued (unless WITH NO DATA or + WITH OLD DATA is used) and may be refreshed later using REFRESH MATERIALIZED VIEW. @@ -162,7 +163,7 @@ CREATE [ OR REPLACE ] MATERIALIZED VIEW [ IF NOT EXISTS ] table_nam - WITH [ NO ] DATA + WITH [ NO | OLD ] DATA This clause specifies whether or not the materialized view should be @@ -170,6 +171,15 @@ CREATE [ OR REPLACE ] MATERIALIZED VIEW [ IF NOT EXISTS ] table_nam flagged as unscannable and cannot be queried until REFRESH MATERIALIZED VIEW is used. + + + The form WITH OLD DATA keeps the already stored data + when replacing an existing materialized view to keep it populated. For + newly created materialized views, this has the same effect as + WITH DATA. Use this form if you want to use + REFRESH MATERIALIZED VIEW CONCURRENTLY as it requires + a populated materialized view. + diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c index cba369114b..1af714fe4a 100644 --- a/src/backend/commands/createas.c +++ b/src/backend/commands/createas.c @@ -332,18 +332,26 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt, /* An existing materialized view can be replaced. */ if (is_matview && into->replace) { - RefreshMatViewStmt *refresh; - /* Change the relation to match the new query and other options. */ - (void) create_ctas_nodata(query->targetList, into); + address = create_ctas_nodata(query->targetList, into); - /* Refresh the materialized view with a fake statement. */ - refresh = makeNode(RefreshMatViewStmt); - refresh->relation = into->rel; - refresh->skipData = into->skipData; - refresh->concurrent = false; + /* + * Refresh the materialized view with a fake statement unless we + * must keep the old data. + */ + if (!into->keepData) + { + RefreshMatViewStmt *refresh; + + refresh = makeNode(RefreshMatViewStmt); + refresh->relation = into->rel; + refresh->skipData = into->skipData; + refresh->concurrent = false; + + address = ExecRefreshMatView(refresh, NULL, NULL); + } - return ExecRefreshMatView(refresh, NULL, NULL); + return address; } return InvalidObjectAddress; diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y index cb5647dcb6..9e7041f98e 100644 --- a/src/backend/parser/gram.y +++ b/src/backend/parser/gram.y @@ -4883,6 +4883,22 @@ CreateMatViewStmt: $7->replace = true; $$ = (Node *) ctas; } + | CREATE OR REPLACE OptNoLog MATERIALIZED VIEW create_mv_target AS SelectStmt WITH OLD DATA_P + { + CreateTableAsStmt *ctas = makeNode(CreateTableAsStmt); + + ctas->query = $9; + ctas->into = $7; + ctas->objtype = OBJECT_MATVIEW; + ctas->is_select_into = false; + ctas->if_not_exists = false; + /* cram additional flags into the IntoClause */ + $7->rel->relpersistence = $4; + $7->skipData = false; + $7->keepData = true; + $7->replace = true; + $$ = (Node *) ctas; + } ; create_mv_target: diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h index fce057a8ac..793c971133 100644 --- a/src/include/nodes/primnodes.h +++ b/src/include/nodes/primnodes.h @@ -168,6 +168,7 @@ typedef struct IntoClause /* materialized view's SELECT query */ struct Query *viewQuery pg_node_attr(query_jumble_ignore); bool skipData; /* true for WITH NO DATA */ + bool keepData; /* true for WITH OLD DATA */ bool replace; /* replace existing matview? */ } IntoClause; diff --git a/src/test/regress/expected/matview.out b/src/test/regress/expected/matview.out index d506c615da..04c2095c74 100644 --- a/src/test/regress/expected/matview.out +++ b/src/test/regress/expected/matview.out @@ -751,6 +751,23 @@ SELECT * FROM mvtest_replace; 3 (1 row) +-- replace query but keep old data +CREATE OR REPLACE MATERIALIZED VIEW mvtest_replace AS + SELECT 5 AS a + WITH OLD DATA; +SELECT * FROM mvtest_replace; + a +--- + 3 +(1 row) + +REFRESH MATERIALIZED VIEW mvtest_replace; +SELECT * FROM mvtest_replace; + a +--- + 5 +(1 row) + -- add column CREATE OR REPLACE MATERIALIZED VIEW mvtest_replace AS SELECT 4 AS a, 1 b; @@ -905,3 +922,14 @@ ERROR: syntax error at or near "NOT" LINE 1: CREATE OR REPLACE MATERIALIZED VIEW IF NOT EXISTS mvtest_rep... ^ DROP MATERIALIZED VIEW mvtest_replace; +-- Create new matview WITH OLD DATA. This populates the new matview as if +-- WITH DATA had been specified. +CREATE OR REPLACE MATERIALIZED VIEW mvtest_replace AS + SELECT 17 AS a + WITH OLD DATA; +SELECT * FROM mvtest_replace; + a +---- + 17 +(1 row) + diff --git a/src/test/regress/sql/matview.sql b/src/test/regress/sql/matview.sql index d6a4dc4b85..91f547e9cb 100644 --- a/src/test/regress/sql/matview.sql +++ b/src/test/regress/sql/matview.sql @@ -338,6 +338,14 @@ SELECT * FROM mvtest_replace; -- error: not populated REFRESH MATERIALIZED VIEW mvtest_replace; SELECT * FROM mvtest_replace; +-- replace query but keep old data +CREATE OR REPLACE MATERIALIZED VIEW mvtest_replace AS + SELECT 5 AS a + WITH OLD DATA; +SELECT * FROM mvtest_replace; +REFRESH MATERIALIZED VIEW mvtest_replace; +SELECT * FROM mvtest_replace; + -- add column CREATE OR REPLACE MATERIALIZED VIEW mvtest_replace AS SELECT 4 AS a, 1 b; @@ -422,3 +430,10 @@ CREATE OR REPLACE MATERIALIZED VIEW IF NOT EXISTS mvtest_replace AS SELECT 1 AS a; DROP MATERIALIZED VIEW mvtest_replace; + +-- Create new matview WITH OLD DATA. This populates the new matview as if +-- WITH DATA had been specified. +CREATE OR REPLACE MATERIALIZED VIEW mvtest_replace AS + SELECT 17 AS a + WITH OLD DATA; +SELECT * FROM mvtest_replace; -- 2.48.0