Commit cc1965a9 authored by Kevin Grittner's avatar Kevin Grittner

Add support for REFRESH MATERIALIZED VIEW CONCURRENTLY.

This allows reads to continue without any blocking while a REFRESH
runs.  The new data appears atomically as part of transaction
commit.

Review questioned the Assert that a matview was not a system
relation.  This will be addressed separately.

Reviewed by Hitoshi Harada, Robert Haas, Andres Freund.
Merged after review with security patch f3ab5d46.
parent 7f7485a0
......@@ -928,8 +928,7 @@ ERROR: could not serialize access due to read/write dependencies among transact
</para>
<para>
This lock mode is not automatically acquired on tables by any
<productname>PostgreSQL</productname> command.
Acquired by <command>REFRESH MATERIALIZED VIEW CONCURRENTLY</command>.
</para>
</listitem>
</varlistentry>
......
......@@ -21,7 +21,7 @@ PostgreSQL documentation
<refsynopsisdiv>
<synopsis>
REFRESH MATERIALIZED VIEW <replaceable class="PARAMETER">name</replaceable>
REFRESH MATERIALIZED VIEW [ CONCURRENTLY ] <replaceable class="PARAMETER">name</replaceable>
[ WITH [ NO ] DATA ]
</synopsis>
</refsynopsisdiv>
......@@ -38,12 +38,44 @@ REFRESH MATERIALIZED VIEW <replaceable class="PARAMETER">name</replaceable>
data is generated and the materialized view is left in an unscannable
state.
</para>
<para>
<literal>CONCURRENTLY</literal> and <literal>WITH NO DATA</literal> may not
be specified together.
</para>
</refsect1>
<refsect1>
<title>Parameters</title>
<variablelist>
<varlistentry>
<term><literal>CONCURRENTLY</literal></term>
<listitem>
<para>
Refresh the materialized view without locking out concurrent selects on
the materialized view. Without this option a refresh which affects a
lot of rows will tend to use fewer resources and complete more quickly,
but could block other connections which are trying to read from the
materialized view. This option may be faster in cases where a small
number of rows are affected.
</para>
<para>
This option is only allowed if there is at least one
<literal>UNIQUE</literal> index on the materialized view which uses only
column names and includes all rows; that is, it must not index on any
expressions nor include a <literal>WHERE</literal> clause.
</para>
<para>
This option may not be used when the materialized view is not already
populated.
</para>
<para>
Even with this option only one <literal>REFRESH</literal> at a time may
run against any one materialized view.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">name</replaceable></term>
<listitem>
......
......@@ -589,7 +589,8 @@ rebuild_relation(Relation OldHeap, Oid indexOid,
heap_close(OldHeap, NoLock);
/* Create the transient table that will receive the re-ordered data */
OIDNewHeap = make_new_heap(tableOid, tableSpace);
OIDNewHeap = make_new_heap(tableOid, tableSpace, false,
AccessExclusiveLock);
/* Copy the heap data into the new table in the desired order */
copy_heap_data(OIDNewHeap, tableOid, indexOid,
......@@ -616,7 +617,8 @@ rebuild_relation(Relation OldHeap, Oid indexOid,
* data, then call finish_heap_swap to complete the operation.
*/
Oid
make_new_heap(Oid OIDOldHeap, Oid NewTableSpace)
make_new_heap(Oid OIDOldHeap, Oid NewTableSpace, bool forcetemp,
LOCKMODE lockmode)
{
TupleDesc OldHeapDesc;
char NewHeapName[NAMEDATALEN];
......@@ -626,8 +628,10 @@ make_new_heap(Oid OIDOldHeap, Oid NewTableSpace)
HeapTuple tuple;
Datum reloptions;
bool isNull;
Oid namespaceid;
char relpersistence;
OldHeap = heap_open(OIDOldHeap, AccessExclusiveLock);
OldHeap = heap_open(OIDOldHeap, lockmode);
OldHeapDesc = RelationGetDescr(OldHeap);
/*
......@@ -648,6 +652,17 @@ make_new_heap(Oid OIDOldHeap, Oid NewTableSpace)
if (isNull)
reloptions = (Datum) 0;
if (forcetemp)
{
namespaceid = LookupCreationNamespace("pg_temp");
relpersistence = RELPERSISTENCE_TEMP;
}
else
{
namespaceid = RelationGetNamespace(OldHeap);
relpersistence = OldHeap->rd_rel->relpersistence;
}
/*
* Create the new heap, using a temporary name in the same namespace as
* the existing table. NOTE: there is some risk of collision with user
......@@ -663,7 +678,7 @@ make_new_heap(Oid OIDOldHeap, Oid NewTableSpace)
snprintf(NewHeapName, sizeof(NewHeapName), "pg_temp_%u", OIDOldHeap);
OIDNewHeap = heap_create_with_catalog(NewHeapName,
RelationGetNamespace(OldHeap),
namespaceid,
NewTableSpace,
InvalidOid,
InvalidOid,
......@@ -671,8 +686,8 @@ make_new_heap(Oid OIDOldHeap, Oid NewTableSpace)
OldHeap->rd_rel->relowner,
OldHeapDesc,
NIL,
OldHeap->rd_rel->relkind,
OldHeap->rd_rel->relpersistence,
RELKIND_RELATION,
relpersistence,
false,
RelationIsMapped(OldHeap),
true,
......
This diff is collapsed.
......@@ -3541,7 +3541,8 @@ ATRewriteTables(List **wqueue, LOCKMODE lockmode)
heap_close(OldHeap, NoLock);
/* Create transient table that will receive the modified data */
OIDNewHeap = make_new_heap(tab->relid, NewTableSpace);
OIDNewHeap = make_new_heap(tab->relid, NewTableSpace, false,
AccessExclusiveLock);
/*
* Copy the heap data into the new table with the desired
......
......@@ -42,6 +42,7 @@
#include "access/transam.h"
#include "access/xact.h"
#include "catalog/namespace.h"
#include "commands/matview.h"
#include "commands/trigger.h"
#include "executor/execdebug.h"
#include "foreign/fdwapi.h"
......@@ -999,10 +1000,11 @@ CheckValidResultRel(Relation resultRel, CmdType operation)
}
break;
case RELKIND_MATVIEW:
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("cannot change materialized view \"%s\"",
RelationGetRelationName(resultRel))));
if (!MatViewIncrementalMaintenanceIsEnabled())
ereport(ERROR,
(errcode(ERRCODE_WRONG_OBJECT_TYPE),
errmsg("cannot change materialized view \"%s\"",
RelationGetRelationName(resultRel))));
break;
case RELKIND_FOREIGN_TABLE:
/* Okay only if the FDW supports it */
......
......@@ -950,7 +950,7 @@ ExecModifyTable(ModifyTableState *node)
bool isNull;
relkind = resultRelInfo->ri_RelationDesc->rd_rel->relkind;
if (relkind == RELKIND_RELATION)
if (relkind == RELKIND_RELATION || relkind == RELKIND_MATVIEW)
{
datum = ExecGetJunkAttribute(slot,
junkfilter->jf_junkAttNo,
......@@ -1280,7 +1280,8 @@ ExecInitModifyTable(ModifyTable *node, EState *estate, int eflags)
char relkind;
relkind = resultRelInfo->ri_RelationDesc->rd_rel->relkind;
if (relkind == RELKIND_RELATION)
if (relkind == RELKIND_RELATION ||
relkind == RELKIND_MATVIEW)
{
j->jf_junkAttNo = ExecFindJunkAttribute(j, "ctid");
if (!AttributeNumberIsValid(j->jf_junkAttNo))
......
......@@ -3241,6 +3241,7 @@ _copyRefreshMatViewStmt(const RefreshMatViewStmt *from)
{
RefreshMatViewStmt *newnode = makeNode(RefreshMatViewStmt);
COPY_SCALAR_FIELD(concurrent);
COPY_SCALAR_FIELD(skipData);
COPY_NODE_FIELD(relation);
......
......@@ -1521,6 +1521,7 @@ _equalCreateTableAsStmt(const CreateTableAsStmt *a, const CreateTableAsStmt *b)
static bool
_equalRefreshMatViewStmt(const RefreshMatViewStmt *a, const RefreshMatViewStmt *b)
{
COMPARE_SCALAR_FIELD(concurrent);
COMPARE_SCALAR_FIELD(skipData);
COMPARE_NODE_FIELD(relation);
......
......@@ -3301,11 +3301,12 @@ OptNoLog: UNLOGGED { $$ = RELPERSISTENCE_UNLOGGED; }
*****************************************************************************/
RefreshMatViewStmt:
REFRESH MATERIALIZED VIEW qualified_name opt_with_data
REFRESH MATERIALIZED VIEW opt_concurrently qualified_name opt_with_data
{
RefreshMatViewStmt *n = makeNode(RefreshMatViewStmt);
n->relation = $4;
n->skipData = !($5);
n->concurrent = $4;
n->relation = $5;
n->skipData = !($6);
$$ = (Node *) n;
}
;
......
......@@ -2871,11 +2871,22 @@ psql_completion(char *text, int start, int end)
else if (pg_strcasecmp(prev3_wd, "REFRESH") == 0 &&
pg_strcasecmp(prev2_wd, "MATERIALIZED") == 0 &&
pg_strcasecmp(prev_wd, "VIEW") == 0)
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_matviews,
" UNION SELECT 'CONCURRENTLY'");
else if (pg_strcasecmp(prev4_wd, "REFRESH") == 0 &&
pg_strcasecmp(prev3_wd, "MATERIALIZED") == 0 &&
pg_strcasecmp(prev2_wd, "VIEW") == 0 &&
pg_strcasecmp(prev_wd, "CONCURRENTLY") == 0)
COMPLETE_WITH_SCHEMA_QUERY(Query_for_list_of_matviews, NULL);
else if (pg_strcasecmp(prev4_wd, "REFRESH") == 0 &&
pg_strcasecmp(prev3_wd, "MATERIALIZED") == 0 &&
pg_strcasecmp(prev2_wd, "VIEW") == 0)
COMPLETE_WITH_CONST("WITH");
else if (pg_strcasecmp(prev5_wd, "REFRESH") == 0 &&
pg_strcasecmp(prev4_wd, "MATERIALIZED") == 0 &&
pg_strcasecmp(prev3_wd, "VIEW") == 0 &&
pg_strcasecmp(prev2_wd, "CONCURRENTLY") == 0)
COMPLETE_WITH_CONST("WITH DATA");
else if (pg_strcasecmp(prev5_wd, "REFRESH") == 0 &&
pg_strcasecmp(prev4_wd, "MATERIALIZED") == 0 &&
pg_strcasecmp(prev3_wd, "VIEW") == 0 &&
......@@ -2886,6 +2897,12 @@ psql_completion(char *text, int start, int end)
COMPLETE_WITH_LIST(list_WITH_DATA);
}
else if (pg_strcasecmp(prev6_wd, "REFRESH") == 0 &&
pg_strcasecmp(prev5_wd, "MATERIALIZED") == 0 &&
pg_strcasecmp(prev4_wd, "VIEW") == 0 &&
pg_strcasecmp(prev3_wd, "CONCURRENTLY") == 0 &&
pg_strcasecmp(prev_wd, "WITH") == 0)
COMPLETE_WITH_CONST("DATA");
else if (pg_strcasecmp(prev6_wd, "REFRESH") == 0 &&
pg_strcasecmp(prev5_wd, "MATERIALIZED") == 0 &&
pg_strcasecmp(prev4_wd, "VIEW") == 0 &&
......
......@@ -25,7 +25,8 @@ extern void check_index_is_clusterable(Relation OldHeap, Oid indexOid,
bool recheck, LOCKMODE lockmode);
extern void mark_index_clustered(Relation rel, Oid indexOid, bool is_internal);
extern Oid make_new_heap(Oid OIDOldHeap, Oid NewTableSpace);
extern Oid make_new_heap(Oid OIDOldHeap, Oid NewTableSpace, bool forcetemp,
LOCKMODE lockmode);
extern void finish_heap_swap(Oid OIDOldHeap, Oid OIDNewHeap,
bool is_system_catalog,
bool swap_toast_by_content,
......
......@@ -27,4 +27,6 @@ extern void ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString
extern DestReceiver *CreateTransientRelDestReceiver(Oid oid);
extern bool MatViewIncrementalMaintenanceIsEnabled(void);
#endif /* MATVIEW_H */
......@@ -2478,6 +2478,7 @@ typedef struct CreateTableAsStmt
typedef struct RefreshMatViewStmt
{
NodeTag type;
bool concurrent; /* allow concurrent access? */
bool skipData; /* true for WITH NO DATA */
RangeVar *relation; /* relation to insert into */
} RefreshMatViewStmt;
......
......@@ -73,6 +73,8 @@ SELECT * FROM tvm;
CREATE MATERIALIZED VIEW tmm AS SELECT sum(totamt) AS grandtot FROM tm;
CREATE MATERIALIZED VIEW tvmm AS SELECT sum(totamt) AS grandtot FROM tvm;
CREATE UNIQUE INDEX tvmm_expr ON tvmm ((grandtot > 0));
CREATE UNIQUE INDEX tvmm_pred ON tvmm (grandtot) WHERE grandtot < 0;
CREATE VIEW tvv AS SELECT sum(totamt) AS grandtot FROM tv;
EXPLAIN (costs off)
CREATE MATERIALIZED VIEW tvvm AS SELECT * FROM tvv;
......@@ -141,6 +143,9 @@ ALTER MATERIALIZED VIEW tvm SET SCHEMA mvschema;
Column | Type | Modifiers | Storage | Stats target | Description
----------+---------+-----------+---------+--------------+-------------
grandtot | numeric | | main | |
Indexes:
"tvmm_expr" UNIQUE, btree ((grandtot > 0::numeric))
"tvmm_pred" UNIQUE, btree (grandtot) WHERE grandtot < 0::numeric
View definition:
SELECT sum(tvm.totamt) AS grandtot
FROM mvschema.tvm;
......@@ -177,7 +182,7 @@ SELECT * FROM tvm ORDER BY type;
z | 11
(3 rows)
REFRESH MATERIALIZED VIEW tm;
REFRESH MATERIALIZED VIEW CONCURRENTLY tm;
REFRESH MATERIALIZED VIEW tvm;
SELECT * FROM tm ORDER BY type;
type | totamt
......@@ -237,6 +242,9 @@ SELECT * FROM tvvm;
(1 row)
REFRESH MATERIALIZED VIEW tmm;
REFRESH MATERIALIZED VIEW CONCURRENTLY tvmm;
ERROR: cannot refresh materialized view "public.tvmm" concurrently
HINT: Create a UNIQUE index with no WHERE clause on one or more columns of the materialized view.
REFRESH MATERIALIZED VIEW tvmm;
REFRESH MATERIALIZED VIEW tvvm;
EXPLAIN (costs off)
......@@ -281,6 +289,9 @@ SELECT * FROM tvvm;
-- test diemv when the mv does not exist
DROP MATERIALIZED VIEW IF EXISTS no_such_mv;
NOTICE: materialized view "no_such_mv" does not exist, skipping
-- make sure invalid comination of options is prohibited
REFRESH MATERIALIZED VIEW CONCURRENTLY tvmm WITH NO DATA;
ERROR: CONCURRENTLY and WITH NO DATA options cannot be used together
-- test join of mv and view
SELECT type, m.totamt AS mtot, v.totamt AS vtot FROM tm m LEFT JOIN tv v USING (type) ORDER BY type;
type | mtot | vtot
......@@ -385,3 +396,28 @@ SELECT * FROM hogeview WHERE i < 10;
DROP TABLE hoge CASCADE;
NOTICE: drop cascades to materialized view hogeview
-- test that duplicate values on unique index prevent refresh
CREATE TABLE foo(a, b) AS VALUES(1, 10);
CREATE MATERIALIZED VIEW mv AS SELECT * FROM foo;
CREATE UNIQUE INDEX ON mv(a);
INSERT INTO foo SELECT * FROM foo;
REFRESH MATERIALIZED VIEW mv;
ERROR: could not create unique index "mv_a_idx"
DETAIL: Key (a)=(1) is duplicated.
REFRESH MATERIALIZED VIEW CONCURRENTLY mv;
ERROR: new data for "mv" contains duplicate rows without any NULL columns
DETAIL: Row: (1,10)
DROP TABLE foo CASCADE;
NOTICE: drop cascades to materialized view mv
-- make sure that all indexes covered by unique indexes works
CREATE TABLE foo(a, b, c) AS VALUES(1, 2, 3);
CREATE MATERIALIZED VIEW mv AS SELECT * FROM foo;
CREATE UNIQUE INDEX ON mv (a);
CREATE UNIQUE INDEX ON mv (b);
CREATE UNIQUE INDEX on mv (c);
INSERT INTO foo VALUES(2, 3, 4);
INSERT INTO foo VALUES(3, 4, 5);
REFRESH MATERIALIZED VIEW mv;
REFRESH MATERIALIZED VIEW CONCURRENTLY mv;
DROP TABLE foo CASCADE;
NOTICE: drop cascades to materialized view mv
......@@ -29,6 +29,8 @@ CREATE MATERIALIZED VIEW tvm AS SELECT * FROM tv ORDER BY type;
SELECT * FROM tvm;
CREATE MATERIALIZED VIEW tmm AS SELECT sum(totamt) AS grandtot FROM tm;
CREATE MATERIALIZED VIEW tvmm AS SELECT sum(totamt) AS grandtot FROM tvm;
CREATE UNIQUE INDEX tvmm_expr ON tvmm ((grandtot > 0));
CREATE UNIQUE INDEX tvmm_pred ON tvmm (grandtot) WHERE grandtot < 0;
CREATE VIEW tvv AS SELECT sum(totamt) AS grandtot FROM tv;
EXPLAIN (costs off)
CREATE MATERIALIZED VIEW tvvm AS SELECT * FROM tvv;
......@@ -57,7 +59,7 @@ INSERT INTO t VALUES (6, 'z', 13);
-- confirm pre- and post-refresh contents of fairly simple materialized views
SELECT * FROM tm ORDER BY type;
SELECT * FROM tvm ORDER BY type;
REFRESH MATERIALIZED VIEW tm;
REFRESH MATERIALIZED VIEW CONCURRENTLY tm;
REFRESH MATERIALIZED VIEW tvm;
SELECT * FROM tm ORDER BY type;
SELECT * FROM tvm ORDER BY type;
......@@ -74,6 +76,7 @@ SELECT * FROM tmm;
SELECT * FROM tvmm;
SELECT * FROM tvvm;
REFRESH MATERIALIZED VIEW tmm;
REFRESH MATERIALIZED VIEW CONCURRENTLY tvmm;
REFRESH MATERIALIZED VIEW tvmm;
REFRESH MATERIALIZED VIEW tvvm;
EXPLAIN (costs off)
......@@ -89,6 +92,9 @@ SELECT * FROM tvvm;
-- test diemv when the mv does not exist
DROP MATERIALIZED VIEW IF EXISTS no_such_mv;
-- make sure invalid comination of options is prohibited
REFRESH MATERIALIZED VIEW CONCURRENTLY tvmm WITH NO DATA;
-- test join of mv and view
SELECT type, m.totamt AS mtot, v.totamt AS vtot FROM tm m LEFT JOIN tv v USING (type) ORDER BY type;
......@@ -124,3 +130,24 @@ SELECT * FROM hogeview WHERE i < 10;
VACUUM ANALYZE;
SELECT * FROM hogeview WHERE i < 10;
DROP TABLE hoge CASCADE;
-- test that duplicate values on unique index prevent refresh
CREATE TABLE foo(a, b) AS VALUES(1, 10);
CREATE MATERIALIZED VIEW mv AS SELECT * FROM foo;
CREATE UNIQUE INDEX ON mv(a);
INSERT INTO foo SELECT * FROM foo;
REFRESH MATERIALIZED VIEW mv;
REFRESH MATERIALIZED VIEW CONCURRENTLY mv;
DROP TABLE foo CASCADE;
-- make sure that all indexes covered by unique indexes works
CREATE TABLE foo(a, b, c) AS VALUES(1, 2, 3);
CREATE MATERIALIZED VIEW mv AS SELECT * FROM foo;
CREATE UNIQUE INDEX ON mv (a);
CREATE UNIQUE INDEX ON mv (b);
CREATE UNIQUE INDEX on mv (c);
INSERT INTO foo VALUES(2, 3, 4);
INSERT INTO foo VALUES(3, 4, 5);
REFRESH MATERIALIZED VIEW mv;
REFRESH MATERIALIZED VIEW CONCURRENTLY mv;
DROP TABLE foo CASCADE;
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment