Improve refresh_immv behavior a bit

- Allow to use qualified name
- Confirm if executed by the owner of the IMMV
- Improve the message when specified relation is not an IMMV
- Create a unique index at refresh with no dat if possible
  This is actually required, but we want it behave as same
  as the pgsql-ivm version for now.
This commit is contained in:
Yugo Nagata 2022-06-23 11:33:06 +09:00
parent 1c4408199c
commit 3de95c09fa
6 changed files with 92 additions and 51 deletions

View file

@ -1,6 +1,6 @@
# pg_ivm
The `pg_ivm` module provides Incremental View Maintenance (IVM) feature for PostgreSQL.
The `pg_ivm` module provides Incremental View Maintenance (IVM) feature for PostgreSQL.
The extension is compatible with PostgreSQL 13 and 14.
@ -22,7 +22,7 @@ creates an IMMV with name 'myview' defined as 'SELECT * FROM mytab'. This is cor
CREATE MATERIALIZED VIEW myview AS SELECT * FROM mytab;
```
When an IMMV is created, some triggers are automatically created so that the view's contents are immediately updated when its base tables are modified.
When an IMMV is created, some triggers are automatically created so that the view's contents are immediately updated when its base tables are modified.
```sql
postgres=# SELECT create_immv('m', 'SELECT * FROM t0');
@ -99,7 +99,7 @@ refresh_immv(immv_name text, with_data bool) RETURNS bigint
`refresh_immv` completely replaces the contents of an IMMV as `REFRESH MATERIALIZED VIEW` command does for a materialized view. To execute this function you must be the owner of the IMMV. The old contents are discarded.
The with_data flag is corresponding to `WITH [NO] DATA` option of REFRESH MATERIALIZED VIEW` command. If with_data is true, the backing query is executed to provide the new data, and if the IMMV is unpopulated, triggers for maintaining the view are created. If with_data is false, no new data is generated and the IMMV become unpopulated, and the triggers are dropped from the IMMV. Note that unpopulated IMMV is still scannable although the result is empty. This behaviour may be changed in future to raise an error when an unpopulated IMMV is scanned.
The with_data flag is corresponding to `WITH [NO] DATA` option of REFRESH MATERIALIZED VIEW` command. If with_data is true, the backing query is executed to provide the new data, and if the IMMV is unpopulated, triggers for maintaining the view are created. Also, a unique index is created for IMMV if it is possible and the view doesn't have that yet. If with_data is false, no new data is generated and the IMMV become unpopulated, and the triggers are dropped from the IMMV. Note that unpopulated IMMV is still scannable although the result is empty. This behaviour may be changed in future to raise an error when an unpopulated IMMV is scanned.
### IMMV metadata catalog
@ -194,7 +194,7 @@ Logical replication is not supported, that is, even when a base table at a publi
### Aggregates
Supported aggregate functions are `count`, `sum`, and `avg`. `min` or `max` is not supported. Currently, only built-in aggregate functions are supported and user defined aggregates cannot be used.
Supported aggregate functions are `count`, `sum`, and `avg`. `min` or `max` is not supported. Currently, only built-in aggregate functions are supported and user defined aggregates cannot be used.
When an IMMV including aggregate is created, some extra columns whose name start with `__ivm` are automatically added to the target list. `__ivm_count__` contains the number of tuples aggregated in each group. In addition, more than one extra columns for each column of aggregated value are added in order to maintain the value. For example, columns named like `__ivm_count_avg__` and `__ivm_sum_avg__` are added for maintaining an average value. When a base table is modified, the new aggregated values are incrementally calculated using the old aggregated values and values of related extra columns stored in the IMMV.
@ -226,7 +226,7 @@ If some base tables have row level security policy, rows that are not visible to
### How to Disable or Enable Immediate Maintenance
IVM is effective when we want to keep an IMMV up-to-date and small fraction of a base table is modified infrequently. Due to the overhead of immediate maintenance, IVM is not effective when a base table is modified frequently. Also, when a large part of a base table is modified or large data is inserted into a base table, IVM is not effective and the cost of maintenance can be larger than refresh from scratch.
IVM is effective when we want to keep an IMMV up-to-date and small fraction of a base table is modified infrequently. Due to the overhead of immediate maintenance, IVM is not effective when a base table is modified frequently. Also, when a large part of a base table is modified or large data is inserted into a base table, IVM is not effective and the cost of maintenance can be larger than refresh from scratch.
In such situation, we can use `refesh_immv` function with `with_data = falase` to disable immediate maintenance before modifying a base table. After a base table modification, call `refresh_immv`with `with_data = true` to refresh the view data and enable immediate maintenance.

View file

@ -13,7 +13,7 @@ SELECT immvrelid, ispopulated FROM pg_ivm_immv ORDER BY 1;
mv | t
(1 row)
-- refresh immv without changing the ispopulated flag
-- Refresh IMMV with data
SELECT refresh_immv('mv', true);
refresh_immv
--------------
@ -38,7 +38,7 @@ SELECT i FROM mv ORDER BY 1;
6
(6 rows)
-- change ispopulated to False
-- Make IMMV unpopulated
SELECT refresh_immv('mv', false);
refresh_immv
--------------
@ -56,14 +56,14 @@ SELECT i FROM mv ORDER BY 1;
---
(0 rows)
-- immv remains empty
-- Immediate maintenance is disabled. IMMV can be scannable and is empty.
INSERT INTO t VALUES(7);
SELECT i FROM mv ORDER BY 1;
i
---
(0 rows)
-- chaneg ispopulated to True, immv is updated
-- Refresh the IMMV and make it populated.
SELECT refresh_immv('mv', true);
refresh_immv
--------------
@ -88,7 +88,7 @@ SELECT i FROM mv ORDER BY 1;
7
(7 rows)
-- immediate maintenance
-- Immediate maintenance is enabled.
INSERT INTO t VALUES(8);
SELECT i FROM mv ORDER BY 1;
i
@ -103,3 +103,16 @@ SELECT i FROM mv ORDER BY 1;
8
(8 rows)
-- Use qualified name
SELECT refresh_immv('public.mv', true);
refresh_immv
--------------
8
(1 row)
-- Use not existing IMMV
SELECT refresh_immv('mv_not_existing', true);
ERROR: relation "mv_not_existing" does not exist
-- Try to refresh a normal table -- error
SELECT refresh_immv('t', true);
ERROR: "t" is not an IMMV

View file

@ -202,7 +202,8 @@ PG_FUNCTION_INFO_V1(IVM_immediate_maintenance);
* This imitates PostgreSQL's ExecRefreshMatView().
*/
ObjectAddress
ExecRefreshImmv(const char *relname, bool skipData, QueryCompletion *qc)
ExecRefreshImmv(const RangeVar *relation, bool skipData,
const char *queryString, QueryCompletion *qc)
{
Oid matviewOid;
Relation matviewRel;
@ -220,6 +221,8 @@ ExecRefreshImmv(const char *relname, bool skipData, QueryCompletion *qc)
int save_sec_context;
int save_nestlevel;
ObjectAddress address;
bool oldPopulated;
Relation pgIvmImmv;
TupleDesc tupdesc;
ScanKeyData key;
@ -227,7 +230,6 @@ ExecRefreshImmv(const char *relname, bool skipData, QueryCompletion *qc)
HeapTuple tup;
bool isnull;
Datum datum;
bool oldSkipData;
/* Determine strength of lock needed. */
//concurrent = stmt->concurrent;
@ -237,12 +239,9 @@ ExecRefreshImmv(const char *relname, bool skipData, QueryCompletion *qc)
/*
* Get a lock until end of transaction.
*/
matviewOid = RelnameGetRelid(relname);
if (!OidIsValid(matviewOid))
ereport(ERROR,
(errcode(ERRCODE_UNDEFINED_TABLE),
errmsg("relation \"%s\" does not exist", relname)));
matviewOid = RangeVarGetRelidExtended(relation,
lockmode, 0,
RangeVarCallbackOwnsTable, NULL);
matviewRel = table_open(matviewOid, lockmode);
relowner = matviewRel->rd_rel->relowner;
@ -256,6 +255,10 @@ ExecRefreshImmv(const char *relname, bool skipData, QueryCompletion *qc)
save_sec_context | SECURITY_RESTRICTED_OPERATION);
save_nestlevel = NewGUCNestLevel();
/*
* Get the entry in pg_ivm_immv. If it doesn't exist, the relation
* is not IMMV.
*/
pgIvmImmv = table_open(PgIvmImmvRelationId(), RowExclusiveLock);
tupdesc = RelationGetDescr(pgIvmImmv);
ScanKeyInit(&key,
@ -266,16 +269,19 @@ ExecRefreshImmv(const char *relname, bool skipData, QueryCompletion *qc)
true, NULL, 1, &key);
tup = systable_getnext(scan);
if (!HeapTupleIsValid(tup))
{
elog(ERROR, "could not find tuple for immvrelid %s", relname);
}
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("\"%s\" is not an IMMV",
RelationGetRelationName(matviewRel))));
datum = heap_getattr(tup, Anum_pg_ivm_immv_ispopulated, tupdesc, &isnull);
Assert(!isnull);
oldSkipData = !DatumGetBool(datum);
oldPopulated = DatumGetBool(datum);
/* update pg_ivm_immv view */
if (skipData != oldSkipData)
/* Tentatively mark the IMMV as populated or not (this will roll back
* if we fail later).
*/
if (skipData != (!oldPopulated))
{
Datum values[Natts_pg_ivm_immv];
bool nulls[Natts_pg_ivm_immv];
@ -290,8 +296,14 @@ ExecRefreshImmv(const char *relname, bool skipData, QueryCompletion *qc)
newtup = heap_modify_tuple(tup, tupdesc, values, nulls, replaces);
CatalogTupleUpdate(pgIvmImmv, &newtup->t_self, newtup);
CatalogTupleUpdate(pgIvmImmv, &newtup->t_self, newtup);
heap_freetuple(newtup);
/*
* Advance command counter to make the updated pg_ivm_immv row locally
* visible.
*/
CommandCounterIncrement();
}
systable_endscan(scan);
@ -395,7 +407,7 @@ ExecRefreshImmv(const char *relname, bool skipData, QueryCompletion *qc)
/* Generate the data, if wanted. */
if (!skipData)
processed = refresh_immv_datafill(dest, dataQuery, NULL, NULL, "");
processed = refresh_immv_datafill(dest, dataQuery, NULL, NULL, queryString);
/* Make the matview match the newly generated data. */
refresh_by_heap_swap(matviewOid, OIDNewHeap, relpersistence);
@ -410,9 +422,10 @@ ExecRefreshImmv(const char *relname, bool skipData, QueryCompletion *qc)
if (!skipData)
pgstat_count_heap_insert(matviewRel, processed);
if (!skipData && oldSkipData)
if (!skipData && !oldPopulated)
{
CreateIvmTriggersOnBaseTables(viewQuery, matviewOid, true);
CreateIvmTriggersOnBaseTables(dataQuery, matviewOid, false);
}
table_close(matviewRel, NoLock);
@ -434,7 +447,7 @@ ExecRefreshImmv(const char *relname, bool skipData, QueryCompletion *qc)
* completion tag output might break applications using it.
*/
if (qc)
SetQueryCompletion(qc, CMDTAG_SELECT, processed);
SetQueryCompletion(qc, CMDTAG_REFRESH_MATERIALIZED_VIEW, processed);
return address;
}

View file

@ -149,7 +149,7 @@ end:
}
/*
* User inerface for creating an IMMV
* User interface for creating an IMMV
*/
Datum
create_immv(PG_FUNCTION_ARGS)
@ -210,6 +210,28 @@ create_immv(PG_FUNCTION_ARGS)
PG_RETURN_INT64(qc.nprocessed);
}
/*
* User interface for refreshing an IMMV
*/
Datum
refresh_immv(PG_FUNCTION_ARGS)
{
text *t_relname = PG_GETARG_TEXT_PP(0);
bool ispopulated = PG_GETARG_BOOL(1);
char *relname = text_to_cstring(t_relname);
QueryCompletion qc;
StringInfoData command_buf;
initStringInfo(&command_buf);
appendStringInfo(&command_buf, "SELECT refresh_immv('%s, %s);",
relname, ispopulated ? "true" : "false");
ExecRefreshImmv(makeRangeVarFromNameList(textToQualifiedNameList(t_relname)),
!ispopulated, command_buf.data, &qc);
PG_RETURN_INT64(qc.nprocessed);
}
/*
* Trigger function to prevent IMMV from being changed
*/
@ -228,22 +250,6 @@ IVM_prevent_immv_change(PG_FUNCTION_ARGS)
return PointerGetDatum(NULL);
}
/*
* User inerface for refreshing an IMMV
*/
Datum
refresh_immv(PG_FUNCTION_ARGS)
{
text *t_relname = PG_GETARG_TEXT_PP(0);
bool ispopulated = PG_GETARG_BOOL(1);
char *relname = text_to_cstring(t_relname);
QueryCompletion qc;
ExecRefreshImmv( relname, !(ispopulated), &qc);
PG_RETURN_INT64(qc.nprocessed);
}
/*
* Create triggers to prevent IMMV from being changed
*/

View file

@ -43,7 +43,8 @@ extern void makeIvmAggColumn(ParseState *pstate, Aggref *aggref, char *resname,
/* matview.c */
extern ObjectAddress ExecRefreshImmv(const char *relname, bool skipData, QueryCompletion *qc);
extern ObjectAddress ExecRefreshImmv(const RangeVar *relation, bool skipData,
const char *queryString, QueryCompletion *qc);
extern bool ImmvIncrementalMaintenanceIsEnabled(void);
extern Datum IVM_immediate_before(PG_FUNCTION_ARGS);
extern Datum IVM_immediate_maintenance(PG_FUNCTION_ARGS);

View file

@ -4,28 +4,36 @@ INSERT INTO t SELECT generate_series(1, 5);
SELECT create_immv('mv', 'SELECT * FROM t');
SELECT immvrelid, ispopulated FROM pg_ivm_immv ORDER BY 1;
-- refresh immv without changing the ispopulated flag
-- Refresh IMMV with data
SELECT refresh_immv('mv', true);
SELECT immvrelid, ispopulated FROM pg_ivm_immv ORDER BY 1;
INSERT INTO t VALUES(6);
SELECT i FROM mv ORDER BY 1;
-- change ispopulated to False
-- Make IMMV unpopulated
SELECT refresh_immv('mv', false);
SELECT immvrelid, ispopulated FROM pg_ivm_immv ORDER BY 1;
SELECT i FROM mv ORDER BY 1;
-- immv remains empty
-- Immediate maintenance is disabled. IMMV can be scannable and is empty.
INSERT INTO t VALUES(7);
SELECT i FROM mv ORDER BY 1;
-- chaneg ispopulated to True, immv is updated
-- Refresh the IMMV and make it populated.
SELECT refresh_immv('mv', true);
SELECT immvrelid, ispopulated FROM pg_ivm_immv ORDER BY 1;
SELECT i FROM mv ORDER BY 1;
-- immediate maintenance
-- Immediate maintenance is enabled.
INSERT INTO t VALUES(8);
SELECT i FROM mv ORDER BY 1;
-- Use qualified name
SELECT refresh_immv('public.mv', true);
-- Use not existing IMMV
SELECT refresh_immv('mv_not_existing', true);
-- Try to refresh a normal table -- error
SELECT refresh_immv('t', true);