Incremental View Maintenance, take 2
On Thu, 1 Jun 2023 23:59:09 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:
Hello hackers,
Here's a rebased version of the patch-set adding Incremental View
Maintenance support for PostgreSQL. That was discussed in [1].
[1] /messages/by-id/20181227215726.4d166b4874f8983a641123f5@sraoss.co.jp
---------------------------------------------------------------------------------------
* Overview
Incremental View Maintenance (IVM) is a way to make materialized views
up-to-date by computing only incremental changes and applying them on
views. IVM is more efficient than REFRESH MATERIALIZED VIEW when
only small parts of the view are changed.
** Feature
The attached patchset provides a feature that allows materialized views
to be updated automatically and incrementally just after a underlying
table is modified.
You can create an incementally maintainable materialized view (IMMV)
by using CREATE INCREMENTAL MATERIALIZED VIEW command.
The followings are supported in view definition queries:
- SELECT ... FROM ... WHERE ..., joins (inner joins, self-joins)
- some built-in aggregate functions (count, sum, avg, min, max)
- GROUP BY clause
- DISTINCT clause
Views can contain multiple tuples with the same content (duplicate tuples).
** Restriction
The following are not supported in a view definition:
- Outer joins
- Aggregates otehr than above, window functions, HAVING
- Sub-queries, CTEs
- Set operations (UNION, INTERSECT, EXCEPT)
- DISTINCT ON, ORDER BY, LIMIT, OFFSET
Also, a view definition query cannot contain other views, materialized views,
foreign tables, partitioned tables, partitions, VALUES, non-immutable functions,
system columns, or expressions that contains aggregates.
---------------------------------------------------------------------------------------
* Design
An IMMV is maintained using statement-level AFTER triggers.
When an IMMV is created, triggers are automatically created on all base
tables contained in the view definition query.
When a table is modified, changes that occurred in the table are extracted
as transition tables in the AFTER triggers. Then, changes that will occur in
the view are calculated by a rewritten view dequery in which the modified table
is replaced with the transition table.
For example, if the view is defined as "SELECT * FROM R, S", and tuples inserted
into R are stored in a transiton table dR, the tuples that will be inserted into
the view are calculated as the result of "SELECT * FROM dR, S".
** Multiple Tables Modification
Multiple tables can be modified in a statement when using triggers, foreign key
constraint, or modifying CTEs. When multiple tables are modified, we need
the state of tables before the modification.
For example, when some tuples, dR and dS, are inserted into R and S respectively,
the tuples that will be inserted into the view are calculated by the following
two queries:
"SELECT * FROM dR, S_pre"
"SELECT * FROM R, dS"
where S_pre is the table before the modification, R is the current state of
table, that is, after the modification. This pre-update states of table
is calculated by filtering inserted tuples and appending deleted tuples.
The subquery that represents pre-update state is generated in get_prestate_rte().
Specifically, the insterted tuples are filtered by calling IVM_visible_in_prestate()
in WHERE clause. This function checks the visibility of tuples by using
the snapshot taken before table modification. The deleted tuples are contained
in the old transition table, and this table is appended using UNION ALL.
Transition tables for each modification are collected in each AFTER trigger
function call. Then, the view maintenance is performed in the last call of
the trigger.
In the original PostgreSQL, tuplestores of transition tables are freed at the
end of each nested query. However, their lifespan needs to be prolonged to
the end of the out-most query in order to maintain the view in the last AFTER
trigger. For this purpose, SetTransitionTablePreserved is added in trigger.c.
** Duplicate Tulpes
When calculating changes that will occur in the view (= delta tables),
multiplicity of tuples are calculated by using count(*).
When deleting tuples from the view, tuples to be deleted are identified by
joining the delta table with the view, and tuples are deleted as many as
specified multiplicity by numbered using row_number() function.
This is implemented in apply_old_delta().
When inserting tuples into the view, each tuple is duplicated to the
specified multiplicity using generate_series() function. This is implemented
in apply_new_delta().
** DISTINCT clause
When DISTINCT is used, the view has a hidden column __ivm_count__ that
stores multiplicity for tuples. When tuples are deleted from or inserted into
the view, the values of __ivm_count__ column is decreased or increased as many
as specified multiplicity. Eventually, when the values becomes zero, the
corresponding tuple is deleted from the view. This is implemented in
apply_old_delta_with_count() and apply_new_delta_with_count().
** Aggregates
Built-in count sum, avg, min, and max are supported. Whether a given
aggregate function can be used or not is checked by using its OID in
check_aggregate_supports_ivm().
When creating a materialized view containing aggregates, in addition
to __ivm_count__, more than one hidden columns for each aggregate are
added to the target list. For example, columns for storing sum(x),
count(x) are added if we have avg(x). When the view is maintained,
aggregated values are updated using these hidden columns, also hidden
columns are updated at the same time.
The maintenance of aggregated view is performed in
apply_old_delta_with_count() and apply_new_delta_with_count(). The SET
clauses for updating columns are generated by append_set_clause_*().
If the view has min(x) or max(x) and the minimum or maximal value is
deleted from a table, we need to update the value to the new min/max
recalculated from the tables rather than incremental computation. This
is performed in recalc_and_set_values().
---------------------------------------------------------------------------------------
* Details of the patch-set (v28)
The patch-set consists of the following eleven patches.
In the previous version, the number of patches were nine.
In the latest patch-set, the patches are divided more finely
aiming to make the review easier.
- 0001: Add a syntax to create Incrementally Maintainable Materialized Views
The prposed syntax to create an incrementally maintainable materialized
view (IMMV) is;
CREATE INCREMENTAL MATERIALIZED VIEW AS SELECT .....;
However, this syntax is tentative, so any suggestions are welcomed.
- 0002: Add relisivm column to pg_class system catalog
We add a new field in pg_class to indicate a relation is IMMV.
Another alternative is to add a new catalog for managing materialized
views including IMMV, but I am not sure if we want this.
- 0003: Allow to prolong life span of transition tables until transaction end
This patch fixes the trigger system to allow to prolong lifespan of
tuple stores for transition tables until the transaction end. We need
this because multiple transition tables have to be preserved until the
end of the out-most query when multiple tables are modified by nested
triggers. (as explained above in Design - Multiple Tables Modification)
If we don't want to change the trigger system in such way, the alternative
is to copy the contents of transition tables to other tuplestores, although
it needs more time and memory.
- 0004: Add Incremental View Maintenance support to pg_dump
This patch enables pg_dump to output IMMV using the new syntax.
- 0005: Add Incremental View Maintenance support to psql
This patch implements tab-completion for the new syntax and adds
information of IMMV to \d meta-command results.
- 0006: Add Incremental View Maintenance support
This patch implements the basic IVM feature.
DISTINCT and aggregate are not supported here.
When an IMMV is created, the view query is checked, and if any
non-supported feature is used, it raises an error. If it is ok,
triggers are created on base tables and an unique index is
created on the view if possible.
In BEFORE trigger, an entry is created for each IMMV and the number
of trigger firing is counted. Also, the snapshot just before the
table modification is stored.
In AFTER triggers, each transition tables are preserved. The number
of trigger firing is counted also here, and when the firing number of
BEFORE and AFTER trigger reach the same, it is deemed the final AFTER
trigger call.
In the final AFTER trigger, the IMMV is maintained. Rewritten view
query is executed to generate delta tables, and deltas are applied
to the view. If multiple tables are modified simultaneously, this
process is iterated for each modified table. Tables before processed
are represented in "pre-update-state", processed tables are
"post-update-state" in the rewritten query.
- 0007: Add DISTINCT support for IVM
This patch adds DISTINCT clause support.
When an IMMV including DISTINCT is created, a hidden column
"__ivm_count__" is added to the target list. This column has the
number of duplicity of the same tuples. The duplicity is calculated
by adding "count(*)" and GROUP BY to the view query.
When an IMMV is maintained, the duplicity in __ivm_count__ is updated,
and a tuples whose duplicity becomes zero can be deleted from the view.
This logic is implemented by SQL in apply_old_delta_with_count and
apply_new_delta_with_count.
Columns starting with "__ivm_" are deemed hidden columns that doesn't
appear when a view is accessed by "SELECT * FROM ....". This is
implemented by fixing parse_relation.c.
- 0008: Add aggregates support in IVM
This patch provides codes for aggregates support, specifically
for builtin count, sum, and avg.
When an IMMV containing an aggregate is created, it is checked if this
aggregate function is supported, and if it is ok, some hidden columns
are added to the target list.
When the IMMV is maintained, the aggregated value is updated as well as
related hidden columns. The way of update depends the type of aggregate
functions, and SET clause string is generated for each aggregate.
- 0009: Add support for min/max aggregates for IVM
This patch adds min/max aggregates support.
This is separated from #0008 because min/max needs more complicated
work than count, sum, and avg.
If the view has min(x) or max(x) and the minimum or maximal value is
deleted from a table, we need to update the value to the new min/max
recalculated from the tables rather than incremental computation.
This is performed in recalc_and_set_values().
TIDs and keys of tuples that need re-calculation are returned as a
result of the query that deleted min/max values from the view using
RETURNING clause. The plan to recalculate and set the new min/max value
are stored and reused.
- 0010: regression tests
This patch provides regression tests for IVM.
- 0011: documentation
This patch provides documantation for IVM.
---------------------------------------------------------------------------------------
* Changes from the Previous Version (v27)
- Allow TRUNCATE on base tables
When a base table is truncated, the view content will be empty if the
view definition query does not contain an aggregate without a GROUP clause.
Therefore, such views can be truncated.
Aggregate views without a GROUP clause always have one row. Therefore,
if a base table is truncated, the view will not be empty and will contain
a row with NULL value (or 0 for count()). So, in this case, we refresh the
view instead of truncating it.
- Fix bugs reported by huyajun [1]/messages/by-id/tencent_FCAF11BCA5003FD16BDDFDDA5D6A19587809@qq.com
[1]: /messages/by-id/tencent_FCAF11BCA5003FD16BDDFDDA5D6A19587809@qq.com
---------------------------------------------------------------------------------------
* Discussion
** Aggregate support
There were a few suggestions that general aggregate functions should be
supported [2]/messages/by-id/20191128140333.GA25947@alvherre.pgsql[3]/messages/by-id/CAM-w4HOvDrL4ou6m=592zUiKGVzTcOpNj-d_cJqzL00fdsS5kg@mail.gmail.com, which may be possible by extending pg_aggregate catalog.
However, we decided to leave supporting general aggregates to the future work [4]/messages/by-id/20201016193034.9a4c44c79fc1eca7babe093e@sraoss.co.jp
because it would need substantial works and make the patch more complex and
bigger.
There has been no opposite opinion on this. However, if we need more discussion
on the design of aggregate support, we can omit aggregate support for the first
release of IVM.
[2]: /messages/by-id/20191128140333.GA25947@alvherre.pgsql
[3]: /messages/by-id/CAM-w4HOvDrL4ou6m=592zUiKGVzTcOpNj-d_cJqzL00fdsS5kg@mail.gmail.com
[4]: /messages/by-id/20201016193034.9a4c44c79fc1eca7babe093e@sraoss.co.jp
** Hidden columns
In order to support DISTINCT or aggregates, our implementation uses hidden columns.
Columns starting with "__ivm_" are hidden columns that doesn't appear when a
view is accessed by "SELECT * FROM ....". For this aim, parse_relation.c is
fixed. There was a proposal to enable hidden columns by adding a new flag to
pg_attribute [5]/messages/by-id/CAEepm=3ZHh=p0nEEnVbs1Dig_UShPzHUcMNAqvDQUgYgcDo-pA@mail.gmail.com, but this thread is no longer active, so we decided to check
the hidden column by its name [6]/messages/by-id/20201016193034.9a4c44c79fc1eca7babe093e@sraoss.co.jp.
[5]: /messages/by-id/CAEepm=3ZHh=p0nEEnVbs1Dig_UShPzHUcMNAqvDQUgYgcDo-pA@mail.gmail.com
[6]: /messages/by-id/20201016193034.9a4c44c79fc1eca7babe093e@sraoss.co.jp
** Concurrent Transactions
When the view definition has more than one table, we acquire an exclusive
lock before the view maintenance in order to avoid inconsistent results.
This behavior was explained in [7]/messages/by-id/20200909092752.c91758a1bec3479668e82643@sraoss.co.jp. The lock was improved to use weaker lock
when the view has only one table based on a suggestion from Konstantin Knizhnik [8]/messages/by-id/5663f5f0-48af-686c-bf3c-62d279567e2a@postgrespro.ru.
However, due to the implementation that uses ctid for identifying target tuples,
we still have to use an exclusive lock for DELETE and UPDATE.
[7]: /messages/by-id/20200909092752.c91758a1bec3479668e82643@sraoss.co.jp
[8]: /messages/by-id/5663f5f0-48af-686c-bf3c-62d279567e2a@postgrespro.ru
** Automatic Index Creation
When a view is created, a unique index is automatically created if
possible, that is, if the view definition query has a GROUP BY or
DISTINCT, or if the view contains all primary key attributes of
its base tables in the target list. It is necessary for efficient
view maintenance. This feature is based on a suggestion from
Konstantin Knizhnik [9]/messages/by-id/89729da8-9042-7ea0-95af-e415df6da14d@postgrespro.ru.
[9]: /messages/by-id/89729da8-9042-7ea0-95af-e415df6da14d@postgrespro.ru
** Trigger and Transition Tables
We implemented IVM based on triggers. This is because we want to use
transition tables to extract changes on base tables. Also, there are
other constraint that are using triggers in its implementation, like
foreign references. However, if we can use transition table like feature
without relying triggers, we don't have to insist to use triggers and we
might implement IVM in the executor directly as similar as declarative
partitioning.
** Feature to be Supported in the First Release
The current patch-set supports DISTINCT and aggregates for built-in count,
sum, avg, min and max. Do we need all these feature for the first IVM release?
Supporting DISTINCT and aggregates needs discussion on hidden columns, and
for supporting min/max we need to discuss on re-calculation method. Before
handling such relatively advanced feature, maybe, should we focus to design
and implement of the basic feature of IVM?
Any suggestion and discussion are welcomed!
Regards,
Yugo Nagata
--
Yugo NAGATA <nagata@sraoss.co.jp>
Hello hackers,
Here's a rebased version of the patch-set adding Incremental View
Maintenance support for PostgreSQL. That was discussed in [1]/messages/by-id/20181227215726.4d166b4874f8983a641123f5@sraoss.co.jp.
The patch-set consists of the following eleven patches.
- 0001: Add a syntax to create Incrementally Maintainable Materialized Views
- 0002: Add relisivm column to pg_class system catalog
- 0003: Allow to prolong life span of transition tables until transaction end
- 0004: Add Incremental View Maintenance support to pg_dum
- 0005: Add Incremental View Maintenance support to psql
- 0006: Add Incremental View Maintenance support
- 0007: Add DISTINCT support for IVM
- 0008: Add aggregates support in IVM
- 0009: Add support for min/max aggregates for IVM
- 0010: regression tests
- 0011: documentation
[1]: /messages/by-id/20181227215726.4d166b4874f8983a641123f5@sraoss.co.jp
Regards,
Yugo Nagata
--
Yugo NAGATA <nagata@sraoss.co.jp>
Attachments:
v28-0001-Add-a-syntax-to-create-Incrementally-Maintainabl.patchtext/x-diff; name=v28-0001-Add-a-syntax-to-create-Incrementally-Maintainabl.patchDownload
From 59a55af2e1466c75d541939f94a3f4372b725b2f Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:05:02 +0900
Subject: [PATCH v28 01/11] Add a syntax to create Incrementally Maintainable
Materialized Views
Allow to create Incrementally Maintainable Materialized View (IMMV)
by using INCREMENTAL option in CREATE MATERIALIZED VIEW command
as follow:
CREATE [INCREMANTAL] MATERIALIZED VIEW xxxxx AS SELECT ....;
---
src/backend/parser/gram.y | 32 +++++++++++++++++++++-----------
src/include/nodes/primnodes.h | 1 +
src/include/parser/kwlist.h | 1 +
3 files changed, 23 insertions(+), 11 deletions(-)
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 39ab7eac0d..3534b37f81 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -465,6 +465,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <range> OptTempTableName
%type <into> into_clause create_as_target create_mv_target
+%type <boolean> incremental
%type <defelt> createfunc_opt_item common_func_opt_item dostmt_opt_item
%type <fun_param> func_arg func_arg_with_default table_func_column aggr_arg
@@ -721,7 +722,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
HANDLER HAVING HEADER_P HOLD HOUR_P
IDENTITY_P IF_P ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IMPORT_P IN_P INCLUDE
- INCLUDING INCREMENT INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
+ INCLUDING INCREMENT INCREMENTAL INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
@@ -4637,32 +4638,34 @@ opt_with_data:
*****************************************************************************/
CreateMatViewStmt:
- CREATE OptNoLog MATERIALIZED VIEW create_mv_target AS SelectStmt opt_with_data
+ CREATE OptNoLog incremental MATERIALIZED VIEW create_mv_target AS SelectStmt opt_with_data
{
CreateTableAsStmt *ctas = makeNode(CreateTableAsStmt);
- ctas->query = $7;
- ctas->into = $5;
+ ctas->query = $8;
+ ctas->into = $6;
ctas->objtype = OBJECT_MATVIEW;
ctas->is_select_into = false;
ctas->if_not_exists = false;
/* cram additional flags into the IntoClause */
- $5->rel->relpersistence = $2;
- $5->skipData = !($8);
+ $6->rel->relpersistence = $2;
+ $6->skipData = !($9);
+ $6->ivm = $3;
$$ = (Node *) ctas;
}
- | CREATE OptNoLog MATERIALIZED VIEW IF_P NOT EXISTS create_mv_target AS SelectStmt opt_with_data
+ | CREATE OptNoLog incremental MATERIALIZED VIEW IF_P NOT EXISTS create_mv_target AS SelectStmt opt_with_data
{
CreateTableAsStmt *ctas = makeNode(CreateTableAsStmt);
- ctas->query = $10;
- ctas->into = $8;
+ ctas->query = $11;
+ ctas->into = $9;
ctas->objtype = OBJECT_MATVIEW;
ctas->is_select_into = false;
ctas->if_not_exists = true;
/* cram additional flags into the IntoClause */
- $8->rel->relpersistence = $2;
- $8->skipData = !($11);
+ $9->rel->relpersistence = $2;
+ $9->skipData = !($12);
+ $9->ivm = $3;
$$ = (Node *) ctas;
}
;
@@ -4679,9 +4682,14 @@ create_mv_target:
$$->tableSpaceName = $5;
$$->viewQuery = NULL; /* filled at analysis time */
$$->skipData = false; /* might get changed later */
+ $$->ivm = false;
}
;
+incremental: INCREMENTAL { $$ = true; }
+ | /*EMPTY*/ { $$ = false; }
+ ;
+
OptNoLog: UNLOGGED { $$ = RELPERSISTENCE_UNLOGGED; }
| /*EMPTY*/ { $$ = RELPERSISTENCE_PERMANENT; }
;
@@ -17055,6 +17063,7 @@ unreserved_keyword:
| INCLUDE
| INCLUDING
| INCREMENT
+ | INCREMENTAL
| INDENT
| INDEX
| INDEXES
@@ -17621,6 +17630,7 @@ bare_label_keyword:
| INCLUDE
| INCLUDING
| INCREMENT
+ | INCREMENTAL
| INDENT
| INDEX
| INDEXES
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 792a743f72..e87a105707 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -146,6 +146,7 @@ typedef struct IntoClause
/* materialized view's SELECT query */
Node *viewQuery pg_node_attr(query_jumble_ignore);
bool skipData; /* true for WITH NO DATA */
+ bool ivm; /* true for WITH IVM */
} IntoClause;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index f5b2e61ca5..a3fbfedbf4 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -207,6 +207,7 @@ PG_KEYWORD("in", IN_P, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("include", INCLUDE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("including", INCLUDING, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("increment", INCREMENT, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("incremental", INCREMENTAL, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("indent", INDENT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("index", INDEX, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("indexes", INDEXES, UNRESERVED_KEYWORD, BARE_LABEL)
--
2.25.1
v28-0002-Add-relisivm-column-to-pg_class-system-catalog.patchtext/x-diff; name=v28-0002-Add-relisivm-column-to-pg_class-system-catalog.patchDownload
From b2ee047e2bd5b34a8871440cc1e14a4672c3d26a Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:07:23 +0900
Subject: [PATCH v28 02/11] Add relisivm column to pg_class system catalog
If this boolean column is true, a relations is Incrementally Maintainable
Materialized View (IMMV). This is set when IMMV is created.
---
src/backend/catalog/heap.c | 1 +
src/backend/catalog/index.c | 1 +
src/backend/utils/cache/lsyscache.c | 24 ++++++++++++++++++++++++
src/backend/utils/cache/relcache.c | 2 ++
src/include/catalog/pg_class.h | 3 +++
src/include/utils/lsyscache.h | 1 +
src/include/utils/rel.h | 2 ++
7 files changed, 34 insertions(+)
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index 2a0d82aedd..37a7759753 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -924,6 +924,7 @@ InsertPgClassTuple(Relation pg_class_desc,
values[Anum_pg_class_relrewrite - 1] = ObjectIdGetDatum(rd_rel->relrewrite);
values[Anum_pg_class_relfrozenxid - 1] = TransactionIdGetDatum(rd_rel->relfrozenxid);
values[Anum_pg_class_relminmxid - 1] = MultiXactIdGetDatum(rd_rel->relminmxid);
+ values[Anum_pg_class_relisivm - 1] = BoolGetDatum(rd_rel->relisivm);
if (relacl != (Datum) 0)
values[Anum_pg_class_relacl - 1] = relacl;
else
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 352e43d0e6..f715cf31ac 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -994,6 +994,7 @@ index_create(Relation heapRelation,
indexRelation->rd_rel->relowner = heapRelation->rd_rel->relowner;
indexRelation->rd_rel->relam = accessMethodObjectId;
indexRelation->rd_rel->relispartition = OidIsValid(parentIndexRelid);
+ indexRelation->rd_rel->relisivm = false;
/*
* store index's pg_class entry
diff --git a/src/backend/utils/cache/lsyscache.c b/src/backend/utils/cache/lsyscache.c
index 60978f9415..c3bf9aeac6 100644
--- a/src/backend/utils/cache/lsyscache.c
+++ b/src/backend/utils/cache/lsyscache.c
@@ -2024,6 +2024,30 @@ get_rel_relispartition(Oid relid)
return false;
}
+/*
+ * get_rel_relisivm
+ *
+ * Returns the relisivm flag associated with a given relation.
+ */
+bool
+get_rel_relisivm(Oid relid)
+{
+ HeapTuple tp;
+
+ tp = SearchSysCache1(RELOID, ObjectIdGetDatum(relid));
+ if (HeapTupleIsValid(tp))
+ {
+ Form_pg_class reltup = (Form_pg_class) GETSTRUCT(tp);
+ bool result;
+
+ result = reltup->relisivm;
+ ReleaseSysCache(tp);
+ return result;
+ }
+ else
+ return false;
+}
+
/*
* get_rel_tablespace
*
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 8a08463c2b..1ba5c3c883 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -1924,6 +1924,8 @@ formrdesc(const char *relationName, Oid relationReltype,
/* ... and they're always populated, too */
relation->rd_rel->relispopulated = true;
+ /* ... and they're always no ivm, too */
+ relation->rd_rel->relisivm = false;
relation->rd_rel->relreplident = REPLICA_IDENTITY_NOTHING;
relation->rd_rel->relpages = 0;
diff --git a/src/include/catalog/pg_class.h b/src/include/catalog/pg_class.h
index 2d1bb7af3a..62b9c0e5cb 100644
--- a/src/include/catalog/pg_class.h
+++ b/src/include/catalog/pg_class.h
@@ -119,6 +119,9 @@ CATALOG(pg_class,1259,RelationRelationId) BKI_BOOTSTRAP BKI_ROWTYPE_OID(83,Relat
/* is relation a partition? */
bool relispartition BKI_DEFAULT(f);
+ /* is relation a matview with ivm? */
+ bool relisivm BKI_DEFAULT(f);
+
/* link to original rel during table rewrite; otherwise 0 */
Oid relrewrite BKI_DEFAULT(0) BKI_LOOKUP_OPT(pg_class);
diff --git a/src/include/utils/lsyscache.h b/src/include/utils/lsyscache.h
index 4f5418b972..078cdf963b 100644
--- a/src/include/utils/lsyscache.h
+++ b/src/include/utils/lsyscache.h
@@ -137,6 +137,7 @@ extern Oid get_rel_namespace(Oid relid);
extern Oid get_rel_type_id(Oid relid);
extern char get_rel_relkind(Oid relid);
extern bool get_rel_relispartition(Oid relid);
+extern bool get_rel_relisivm(Oid relid);
extern Oid get_rel_tablespace(Oid relid);
extern char get_rel_persistence(Oid relid);
extern Oid get_transform_fromsql(Oid typid, Oid langid, List *trftypes);
diff --git a/src/include/utils/rel.h b/src/include/utils/rel.h
index 1426a353cd..b8961176bb 100644
--- a/src/include/utils/rel.h
+++ b/src/include/utils/rel.h
@@ -677,6 +677,8 @@ RelationCloseSmgr(Relation relation)
*/
#define RelationIsPopulated(relation) ((relation)->rd_rel->relispopulated)
+#define RelationIsIVM(relation) ((relation)->rd_rel->relisivm)
+
/*
* RelationIsAccessibleInLogicalDecoding
* True if we need to log enough information to have access via
--
2.25.1
v28-0003-Allow-to-prolong-life-span-of-transition-tables-.patchtext/x-diff; name=v28-0003-Allow-to-prolong-life-span-of-transition-tables-.patchDownload
From 1b582e0fafcc93fb7efbf6ba39a99787a0953e5a Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:09:45 +0900
Subject: [PATCH v28 03/11] Allow to prolong life span of transition tables
until transaction end
Originally, tuplestores of AFTER trigger's transition tables were
freed for each query depth. For our IVM implementation, we would like
to prolong life of the tuplestores because we have to preserve them
for a whole query assuming that some base tables might be changed
in some trigger functions.
---
src/backend/commands/trigger.c | 83 ++++++++++++++++++++++++++++++++--
src/include/commands/trigger.h | 2 +
2 files changed, 81 insertions(+), 4 deletions(-)
diff --git a/src/backend/commands/trigger.c b/src/backend/commands/trigger.c
index 4b295f8da5..354ea94777 100644
--- a/src/backend/commands/trigger.c
+++ b/src/backend/commands/trigger.c
@@ -3742,6 +3742,10 @@ typedef struct AfterTriggerEventList
* end of the list, so it is relatively easy to discard them. The event
* list chunks themselves are stored in event_cxt.
*
+ * prolonged_tuplestored is a list of transition table tuplestores whose
+ * life are prolonged to the end of the outmost query instead of each nested
+ * query.
+ *
* query_depth is the current depth of nested AfterTriggerBeginQuery calls
* (-1 when the stack is empty).
*
@@ -3807,6 +3811,7 @@ typedef struct AfterTriggersData
SetConstraintState state; /* the active S C state */
AfterTriggerEventList events; /* deferred-event list */
MemoryContext event_cxt; /* memory context for events, if any */
+ List *prolonged_tuplestores; /* list of prolonged tuplestores */
/* per-query-level data: */
AfterTriggersQueryData *query_stack; /* array of structs shown below */
@@ -3842,6 +3847,7 @@ struct AfterTriggersTableData
bool closed; /* true when no longer OK to add tuples */
bool before_trig_done; /* did we already queue BS triggers? */
bool after_trig_done; /* did we already queue AS triggers? */
+ bool prolonged; /* are transition tables prolonged? */
AfterTriggerEventList after_trig_events; /* if so, saved list pointer */
/*
@@ -3891,6 +3897,7 @@ static void TransitionTableAddTuple(EState *estate,
TupleTableSlot *original_insert_tuple,
Tuplestorestate *tuplestore);
static void AfterTriggerFreeQuery(AfterTriggersQueryData *qs);
+static void release_or_prolong_tuplestore(Tuplestorestate *ts, bool prolonged);
static SetConstraintState SetConstraintStateCreate(int numalloc);
static SetConstraintState SetConstraintStateCopy(SetConstraintState origstate);
static SetConstraintState SetConstraintStateAddItem(SetConstraintState state,
@@ -4737,6 +4744,45 @@ afterTriggerInvokeEvents(AfterTriggerEventList *events,
}
+/*
+ * SetTransitionTablePreserved
+ *
+ * Prolong lifespan of transition tables corresponding specified relid and
+ * command type to the end of the outmost query instead of each nested query.
+ * This enables to use nested AFTER trigger's transition tables from outer
+ * query's triggers. Currently, only immediate incremental view maintenance
+ * uses this.
+ */
+void
+SetTransitionTablePreserved(Oid relid, CmdType cmdType)
+{
+ AfterTriggersTableData *table;
+ AfterTriggersQueryData *qs;
+ bool found = false;
+ ListCell *lc;
+
+ /* Check state, like AfterTriggerSaveEvent. */
+ if (afterTriggers.query_depth < 0)
+ elog(ERROR, "SetTransitionTablePreserved() called outside of query");
+
+ qs = &afterTriggers.query_stack[afterTriggers.query_depth];
+
+ foreach(lc, qs->tables)
+ {
+ table = (AfterTriggersTableData *) lfirst(lc);
+ if (table->relid == relid && table->cmdType == cmdType &&
+ table->closed)
+ {
+ table->prolonged = true;
+ found = true;
+ }
+ }
+
+ if (!found)
+ elog(ERROR,"could not find table with OID %d and command type %d", relid, cmdType);
+}
+
+
/*
* GetAfterTriggersTableData
*
@@ -4947,6 +4993,7 @@ AfterTriggerBeginXact(void)
*/
afterTriggers.firing_counter = (CommandId) 1; /* mustn't be 0 */
afterTriggers.query_depth = -1;
+ afterTriggers.prolonged_tuplestores = NIL;
/*
* Verify that there is no leftover state remaining. If these assertions
@@ -5107,19 +5154,19 @@ AfterTriggerFreeQuery(AfterTriggersQueryData *qs)
ts = table->old_upd_tuplestore;
table->old_upd_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->new_upd_tuplestore;
table->new_upd_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->old_del_tuplestore;
table->old_del_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->new_ins_tuplestore;
table->new_ins_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
if (table->storeslot)
{
TupleTableSlot *slot = table->storeslot;
@@ -5136,6 +5183,34 @@ AfterTriggerFreeQuery(AfterTriggersQueryData *qs)
*/
qs->tables = NIL;
list_free_deep(tables);
+
+ /* Release prolonged tuplestores at the end of the outmost query */
+ if (afterTriggers.query_depth == 0)
+ {
+ foreach(lc, afterTriggers.prolonged_tuplestores)
+ {
+ ts = (Tuplestorestate *) lfirst(lc);
+ if (ts)
+ tuplestore_end(ts);
+ }
+ afterTriggers.prolonged_tuplestores = NIL;
+ }
+}
+
+/*
+ * Release the tuplestore, or append it to the prolonged tuplestores list.
+ */
+static void
+release_or_prolong_tuplestore(Tuplestorestate *ts, bool prolonged)
+{
+ if (prolonged && afterTriggers.query_depth > 0)
+ {
+ MemoryContext oldcxt = MemoryContextSwitchTo(CurTransactionContext);
+ afterTriggers.prolonged_tuplestores = lappend(afterTriggers.prolonged_tuplestores, ts);
+ MemoryContextSwitchTo(oldcxt);
+ }
+ else
+ tuplestore_end(ts);
}
diff --git a/src/include/commands/trigger.h b/src/include/commands/trigger.h
index 430e3ca7dd..48a21c4c51 100644
--- a/src/include/commands/trigger.h
+++ b/src/include/commands/trigger.h
@@ -265,6 +265,8 @@ extern void AfterTriggerEndSubXact(bool isCommit);
extern void AfterTriggerSetState(ConstraintsSetStmt *stmt);
extern bool AfterTriggerPendingOnRel(Oid relid);
+extern void SetTransitionTablePreserved(Oid relid, CmdType cmdType);
+
/*
* in utils/adt/ri_triggers.c
--
2.25.1
v28-0004-Add-Incremental-View-Maintenance-support-to-pg_d.patchtext/x-diff; name=v28-0004-Add-Incremental-View-Maintenance-support-to-pg_d.patchDownload
From e71c6142d6e5f0a7599ba77e79f634f0fe6feadd Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 11 Nov 2020 17:01:25 +0900
Subject: [PATCH v28 04/11] Add Incremental View Maintenance support to pg_dump
Support CREATE INCREMENTAL MATERIALIZED VIEW syntax.
---
src/bin/pg_dump/pg_dump.c | 18 +++++++++++++++---
src/bin/pg_dump/pg_dump.h | 1 +
src/bin/pg_dump/t/002_pg_dump.pl | 15 +++++++++++++++
3 files changed, 31 insertions(+), 3 deletions(-)
diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c
index 3af97a6039..48f61b1af8 100644
--- a/src/bin/pg_dump/pg_dump.c
+++ b/src/bin/pg_dump/pg_dump.c
@@ -6352,6 +6352,7 @@ getTables(Archive *fout, int *numTables)
int i_relacl;
int i_acldefault;
int i_ispartition;
+ int i_isivm;
/*
* Find all the tables and table-like objects.
@@ -6454,10 +6455,17 @@ getTables(Archive *fout, int *numTables)
if (fout->remoteVersion >= 100000)
appendPQExpBufferStr(query,
- "c.relispartition AS ispartition ");
+ "c.relispartition AS ispartition, ");
else
appendPQExpBufferStr(query,
- "false AS ispartition ");
+ "false AS ispartition, ");
+
+ if (fout->remoteVersion >= 170000)
+ appendPQExpBufferStr(query,
+ "c.relisivm AS isivm ");
+ else
+ appendPQExpBufferStr(query,
+ "false AS isivm ");
/*
* Left join to pg_depend to pick up dependency info linking sequences to
@@ -6566,6 +6574,7 @@ getTables(Archive *fout, int *numTables)
i_relacl = PQfnumber(res, "relacl");
i_acldefault = PQfnumber(res, "acldefault");
i_ispartition = PQfnumber(res, "ispartition");
+ i_isivm = PQfnumber(res, "isivm");
if (dopt->lockWaitTimeout)
{
@@ -6645,6 +6654,7 @@ getTables(Archive *fout, int *numTables)
tblinfo[i].amname = pg_strdup(PQgetvalue(res, i, i_amname));
tblinfo[i].is_identity_sequence = (strcmp(PQgetvalue(res, i, i_is_identity_sequence), "t") == 0);
tblinfo[i].ispartition = (strcmp(PQgetvalue(res, i, i_ispartition), "t") == 0);
+ tblinfo[i].isivm = (strcmp(PQgetvalue(res, i, i_isivm), "t") == 0);
/* other fields were zeroed above */
@@ -15517,9 +15527,11 @@ dumpTableSchema(Archive *fout, const TableInfo *tbinfo)
binary_upgrade_set_pg_class_oids(fout, q,
tbinfo->dobj.catId.oid, false);
- appendPQExpBuffer(q, "CREATE %s%s %s",
+ appendPQExpBuffer(q, "CREATE %s%s%s %s",
tbinfo->relpersistence == RELPERSISTENCE_UNLOGGED ?
"UNLOGGED " : "",
+ tbinfo->relkind == RELKIND_MATVIEW && tbinfo->isivm ?
+ "INCREMENTAL " : "",
reltypename,
qualrelname);
diff --git a/src/bin/pg_dump/pg_dump.h b/src/bin/pg_dump/pg_dump.h
index ed6ce41ad7..119293a751 100644
--- a/src/bin/pg_dump/pg_dump.h
+++ b/src/bin/pg_dump/pg_dump.h
@@ -322,6 +322,7 @@ typedef struct _tableInfo
int numParents; /* number of (immediate) parent tables */
struct _tableInfo **parents; /* TableInfos of immediate parents */
+ bool isivm; /* is incrementally maintainable materialized view? */
/*
* These fields are computed only if we decide the table is interesting
diff --git a/src/bin/pg_dump/t/002_pg_dump.pl b/src/bin/pg_dump/t/002_pg_dump.pl
index 387c5d3afb..164c9eb110 100644
--- a/src/bin/pg_dump/t/002_pg_dump.pl
+++ b/src/bin/pg_dump/t/002_pg_dump.pl
@@ -2732,6 +2732,21 @@ my %tests = (
},
},
+ 'CREATE MATERIALIZED VIEW matview_ivm' => {
+ create_order => 21,
+ create_sql => 'CREATE INCREMENTAL MATERIALIZED VIEW dump_test.matview_ivm (col1) AS
+ SELECT col1 FROM dump_test.test_table;',
+ regexp => qr/^
+ \QCREATE INCREMENTAL MATERIALIZED VIEW dump_test.matview_ivm AS\E
+ \n\s+\QSELECT test_table.col1\E
+ \n\s+\QFROM dump_test.test_table\E
+ \n\s+\QWITH NO DATA;\E
+ /xm,
+ like =>
+ { %full_runs, %dump_test_schema_runs, section_pre_data => 1, },
+ unlike => { exclude_dump_test_schema => 1, },
+ },
+
'CREATE POLICY p1 ON test_table' => {
create_order => 22,
create_sql => 'CREATE POLICY p1 ON dump_test.test_table
--
2.25.1
v28-0005-Add-Incremental-View-Maintenance-support-to-psql.patchtext/x-diff; name=v28-0005-Add-Incremental-View-Maintenance-support-to-psql.patchDownload
From 750c195536faaf04daa5599cc691dcb13a86f7b7 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:21:54 +0900
Subject: [PATCH v28 05/11] Add Incremental View Maintenance support to psql
Add tab completion and meta-command output for IVM.
---
src/bin/psql/describe.c | 32 +++++++++++++++++++++++++++++++-
src/bin/psql/tab-complete.c | 14 +++++++++-----
2 files changed, 40 insertions(+), 6 deletions(-)
diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c
index 9325a46b8f..f555af7c95 100644
--- a/src/bin/psql/describe.c
+++ b/src/bin/psql/describe.c
@@ -1575,6 +1575,7 @@ describeOneTableDetails(const char *schemaname,
char relpersistence;
char relreplident;
char *relam;
+ bool isivm;
} tableinfo;
bool show_column_details = false;
@@ -1587,7 +1588,26 @@ describeOneTableDetails(const char *schemaname,
initPQExpBuffer(&tmpbuf);
/* Get general table info */
- if (pset.sversion >= 120000)
+ if (pset.sversion >= 170000)
+ {
+ printfPQExpBuffer(&buf,
+ "SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
+ "c.relhastriggers, c.relrowsecurity, c.relforcerowsecurity, "
+ "false AS relhasoids, c.relispartition, %s, c.reltablespace, "
+ "CASE WHEN c.reloftype = 0 THEN '' ELSE c.reloftype::pg_catalog.regtype::pg_catalog.text END, "
+ "c.relpersistence, c.relreplident, am.amname, "
+ "c.relisivm\n"
+ "FROM pg_catalog.pg_class c\n "
+ "LEFT JOIN pg_catalog.pg_class tc ON (c.reltoastrelid = tc.oid)\n"
+ "LEFT JOIN pg_catalog.pg_am am ON (c.relam = am.oid)\n"
+ "WHERE c.oid = '%s';",
+ (verbose ?
+ "pg_catalog.array_to_string(c.reloptions || "
+ "array(select 'toast.' || x from pg_catalog.unnest(tc.reloptions) x), ', ')\n"
+ : "''"),
+ oid);
+ }
+ else if (pset.sversion >= 120000)
{
printfPQExpBuffer(&buf,
"SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
@@ -1707,6 +1727,10 @@ describeOneTableDetails(const char *schemaname,
(char *) NULL : pg_strdup(PQgetvalue(res, 0, 14));
else
tableinfo.relam = NULL;
+ if (pset.sversion >= 170000)
+ tableinfo.isivm = strcmp(PQgetvalue(res, 0, 15), "t") == 0;
+ else
+ tableinfo.isivm = false;
PQclear(res);
res = NULL;
@@ -3508,6 +3532,12 @@ describeOneTableDetails(const char *schemaname,
printfPQExpBuffer(&buf, _("Access method: %s"), tableinfo.relam);
printTableAddFooter(&cont, buf.data);
}
+
+ /* Incremental view maintance info */
+ if (verbose && tableinfo.relkind == RELKIND_MATVIEW && tableinfo.isivm)
+ {
+ printTableAddFooter(&cont, _("Incremental view maintenance: yes"));
+ }
}
/* reloptions, if verbose */
diff --git a/src/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c
index 677847e434..6ec195b2e9 100644
--- a/src/bin/psql/tab-complete.c
+++ b/src/bin/psql/tab-complete.c
@@ -1240,6 +1240,7 @@ static const pgsql_thing_t words_after_create[] = {
{"FOREIGN TABLE", NULL, NULL, NULL},
{"FUNCTION", NULL, NULL, Query_for_list_of_functions},
{"GROUP", Query_for_list_of_roles},
+ {"INCREMENTAL MATERIALIZED VIEW", NULL, NULL, &Query_for_list_of_matviews, NULL, THING_NO_DROP | THING_NO_ALTER},
{"INDEX", NULL, NULL, &Query_for_list_of_indexes},
{"LANGUAGE", Query_for_list_of_languages},
{"LARGE OBJECT", NULL, NULL, NULL, NULL, THING_NO_CREATE | THING_NO_DROP},
@@ -3187,7 +3188,7 @@ psql_completion(const char *text, int start, int end)
COMPLETE_WITH("SEQUENCE", "TABLE", "VIEW");
/* Complete "CREATE UNLOGGED" with TABLE or MATVIEW */
else if (TailMatches("CREATE", "UNLOGGED"))
- COMPLETE_WITH("TABLE", "MATERIALIZED VIEW");
+ COMPLETE_WITH("TABLE", "MATERIALIZED VIEW", "INCREMENTAL MATERIALIZED VIEW");
/* Complete PARTITION BY with RANGE ( or LIST ( or ... */
else if (TailMatches("PARTITION", "BY"))
COMPLETE_WITH("RANGE (", "LIST (", "HASH (");
@@ -3504,13 +3505,16 @@ psql_completion(const char *text, int start, int end)
COMPLETE_WITH("SELECT");
/* CREATE MATERIALIZED VIEW */
- else if (Matches("CREATE", "MATERIALIZED"))
+ else if (Matches("CREATE", "MATERIALIZED") ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED"))
COMPLETE_WITH("VIEW");
- /* Complete CREATE MATERIALIZED VIEW <name> with AS */
- else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny))
+ /* Complete CREATE MATERIALIZED VIEW <name> with AS */
+ else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny) ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED", "VIEW", MatchAny))
COMPLETE_WITH("AS");
/* Complete "CREATE MATERIALIZED VIEW <sth> AS with "SELECT" */
- else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny, "AS"))
+ else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny, "AS") ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED", "VIEW", MatchAny, "AS"))
COMPLETE_WITH("SELECT");
/* CREATE EVENT TRIGGER */
--
2.25.1
v28-0006-Add-Incremental-View-Maintenance-support.patchtext/x-diff; name=v28-0006-Add-Incremental-View-Maintenance-support.patchDownload
From a95d84a53b70ce3a38ba8863ee36f00ac849be04 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 18:59:50 +0900
Subject: [PATCH v28 06/11] Add Incremental View Maintenance support
In this implementation, AFTER triggers are used to collect
tuplestores containing transition table contents. When multiple tables
are changed, multiple AFTER triggers are invoked, then the final AFTER
trigger performs actual update of the matview. In addition, BEFORE
triggers are also used to handle global information for view
maintenance.
To calculate view deltas, we need both pre-state and post-state of base
tables. Post-update states are available in AFTER trigger, and pre-update
states can be calculated by removing inserted tuples and appending deleted
tuples. Insterted tuples are filtered using the snapshot taken before
table modiication, and deleted tuples are contained in the old transition
table.
Incrementally Maintainable Materialized Views (IMMV) can contain
duplicated tuples.
This patch also allows self-join, simultaneous updates of more than
one base table, and multiple updates of the same base table.
---
src/backend/access/transam/xact.c | 5 +
src/backend/commands/createas.c | 680 +++++++++++++
src/backend/commands/matview.c | 1466 ++++++++++++++++++++++++++++-
src/include/catalog/pg_proc.dat | 10 +
src/include/commands/createas.h | 4 +
src/include/commands/matview.h | 9 +
6 files changed, 2139 insertions(+), 35 deletions(-)
diff --git a/src/backend/access/transam/xact.c b/src/backend/access/transam/xact.c
index 8daaa535ed..cd280bdffd 100644
--- a/src/backend/access/transam/xact.c
+++ b/src/backend/access/transam/xact.c
@@ -36,6 +36,7 @@
#include "catalog/pg_enum.h"
#include "catalog/storage.h"
#include "commands/async.h"
+#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/trigger.h"
#include "common/pg_prng.h"
@@ -2803,6 +2804,7 @@ AbortTransaction(void)
AtAbort_Notify();
AtEOXact_RelationMap(false, is_parallel_worker);
AtAbort_Twophase();
+ AtAbort_IVM();
/*
* Advertise the fact that we aborted in pg_xact (assuming that we got as
@@ -5080,6 +5082,9 @@ AbortSubTransaction(void)
pgstat_progress_end_command();
UnlockBuffers();
+ /* Clean up hash entries for incremental view maintenance */
+ AtAbort_IVM();
+
/* Reset WAL record construction state */
XLogResetInsertion();
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index e91920ca14..415f110516 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -32,15 +32,26 @@
#include "access/xact.h"
#include "access/xlog.h"
#include "catalog/namespace.h"
+#include "catalog/index.h"
+#include "catalog/pg_constraint.h"
+#include "catalog/pg_inherits.h"
+#include "catalog/pg_trigger.h"
#include "catalog/toasting.h"
#include "commands/createas.h"
+#include "commands/defrem.h"
#include "commands/matview.h"
#include "commands/prepare.h"
#include "commands/tablecmds.h"
+#include "commands/tablespace.h"
+#include "commands/trigger.h"
#include "commands/view.h"
#include "miscadmin.h"
+#include "optimizer/optimizer.h"
+#include "optimizer/prep.h"
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
+#include "parser/parser.h"
+#include "parser/parsetree.h"
#include "parser/parse_clause.h"
#include "rewrite/rewriteHandler.h"
#include "storage/smgr.h"
@@ -73,6 +84,12 @@ static bool intorel_receive(TupleTableSlot *slot, DestReceiver *self);
static void intorel_shutdown(DestReceiver *self);
static void intorel_destroy(DestReceiver *self);
+static void CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid matviewOid,
+ Relids *relids, bool ex_lock);
+static void CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock);
+static void check_ivm_restriction(Node *node);
+static bool check_ivm_restriction_walker(Node *node, void *context);
+static Bitmapset *get_primary_key_attnos_from_query(Query *query, List **constraintList);
/*
* create_ctas_internal
@@ -282,6 +299,18 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
save_nestlevel = NewGUCNestLevel();
}
+ if (is_matview && into->ivm)
+ {
+ /* check if the query is supported in IMMV definition */
+ if (contain_mutable_functions((Node *) query))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("mutable function is not supported on incrementally maintainable materialized view"),
+ errhint("functions must be marked IMMUTABLE")));
+
+ check_ivm_restriction((Node *) query);
+ }
+
if (into->skipData)
{
/*
@@ -358,6 +387,27 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
/* Restore userid and security context */
SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ if (into->ivm)
+ {
+ Oid matviewOid = address.objectId;
+ Relation matviewRel = table_open(matviewOid, NoLock);
+
+ /*
+ * Mark relisivm field, if it's a matview and into->ivm is true.
+ */
+ SetMatViewIVMState(matviewRel, true);
+
+ if (!into->skipData)
+ {
+ /* Create an index on incremental maintainable materialized view, if possible */
+ CreateIndexOnIMMV((Query *) into->viewQuery, matviewRel);
+
+ /* Create triggers on incremental maintainable materialized view */
+ CreateIvmTriggersOnBaseTables((Query *) into->viewQuery, matviewOid);
+ }
+ table_close(matviewRel, NoLock);
+ }
}
return address;
@@ -635,3 +685,633 @@ intorel_destroy(DestReceiver *self)
{
pfree(self);
}
+
+/*
+ * CreateIvmTriggersOnBaseTables -- create IVM triggers on all base tables
+ */
+void
+CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid)
+{
+ Relids relids = NULL;
+ bool ex_lock = false;
+ RangeTblEntry *rte;
+
+ /* Immediately return if we don't have any base tables. */
+ if (list_length(qry->rtable) < 1)
+ return;
+
+ /*
+ * If the view has more than one base tables, we need an exclusive lock
+ * on the view so that the view would be maintained serially to avoid
+ * the inconsistency that occurs when two base tables are modified in
+ * concurrent transactions. However, if the view has only one table,
+ * we can use a weaker lock.
+ *
+ * The type of lock should be determined here, because if we check the
+ * view definition at maintenance time, we need to acquire a weaker lock,
+ * and upgrading the lock level after this increases probability of
+ * deadlock.
+ */
+
+ rte = list_nth(qry->rtable, 0);
+ if (list_length(qry->rtable) > 1 || rte->rtekind != RTE_RELATION)
+ ex_lock = true;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, (Node *)qry, matviewOid, &relids, ex_lock);
+
+ bms_free(relids);
+}
+
+static void
+CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid matviewOid,
+ Relids *relids, bool ex_lock)
+{
+ if (node == NULL)
+ return;
+
+ /* This can recurse, so check for excessive recursion */
+ check_stack_depth();
+
+ switch (nodeTag(node))
+ {
+ case T_Query:
+ {
+ Query *query = (Query *) node;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, (Node *)query->jointree, matviewOid, relids, ex_lock);
+ }
+ break;
+
+ case T_RangeTblRef:
+ {
+ int rti = ((RangeTblRef *) node)->rtindex;
+ RangeTblEntry *rte = rt_fetch(rti, qry->rtable);
+
+ if (rte->rtekind == RTE_RELATION && !bms_is_member(rte->relid, *relids))
+ {
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_INSERT, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_DELETE, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_UPDATE, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_TRUNCATE, TRIGGER_TYPE_BEFORE, true);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_INSERT, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_DELETE, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_UPDATE, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_TRUNCATE, TRIGGER_TYPE_AFTER, true);
+
+ *relids = bms_add_member(*relids, rte->relid);
+ }
+ }
+ break;
+
+ case T_FromExpr:
+ {
+ FromExpr *f = (FromExpr *) node;
+ ListCell *l;
+
+ foreach(l, f->fromlist)
+ CreateIvmTriggersOnBaseTablesRecurse(qry, lfirst(l), matviewOid, relids, ex_lock);
+ }
+ break;
+
+ case T_JoinExpr:
+ {
+ JoinExpr *j = (JoinExpr *) node;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, j->larg, matviewOid, relids, ex_lock);
+ CreateIvmTriggersOnBaseTablesRecurse(qry, j->rarg, matviewOid, relids, ex_lock);
+ }
+ break;
+
+ default:
+ elog(ERROR, "unrecognized node type: %d", (int) nodeTag(node));
+ }
+}
+
+/*
+ * CreateIvmTrigger -- create IVM trigger on a base table
+ */
+static void
+CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock)
+{
+ ObjectAddress refaddr;
+ ObjectAddress address;
+ CreateTrigStmt *ivm_trigger;
+ List *transitionRels = NIL;
+
+ Assert(timing == TRIGGER_TYPE_BEFORE || timing == TRIGGER_TYPE_AFTER);
+
+ refaddr.classId = RelationRelationId;
+ refaddr.objectId = viewOid;
+ refaddr.objectSubId = 0;
+
+ ivm_trigger = makeNode(CreateTrigStmt);
+ ivm_trigger->relation = NULL;
+ ivm_trigger->row = false;
+
+ ivm_trigger->timing = timing;
+ ivm_trigger->events = type;
+
+ switch (type)
+ {
+ case TRIGGER_TYPE_INSERT:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_ins_before" : "IVM_trigger_ins_after");
+ break;
+ case TRIGGER_TYPE_DELETE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_del_before" : "IVM_trigger_del_after");
+ break;
+ case TRIGGER_TYPE_UPDATE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_upd_before" : "IVM_trigger_upd_after");
+ break;
+ case TRIGGER_TYPE_TRUNCATE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_truncate_before" : "IVM_trigger_truncate_after");
+ break;
+ default:
+ elog(ERROR, "unsupported trigger type");
+ }
+
+ if (timing == TRIGGER_TYPE_AFTER)
+ {
+ if (type == TRIGGER_TYPE_INSERT || type == TRIGGER_TYPE_UPDATE)
+ {
+ TriggerTransition *n = makeNode(TriggerTransition);
+ n->name = "__ivm_newtable";
+ n->isNew = true;
+ n->isTable = true;
+
+ transitionRels = lappend(transitionRels, n);
+ }
+ if (type == TRIGGER_TYPE_DELETE || type == TRIGGER_TYPE_UPDATE)
+ {
+ TriggerTransition *n = makeNode(TriggerTransition);
+ n->name = "__ivm_oldtable";
+ n->isNew = false;
+ n->isTable = true;
+
+ transitionRels = lappend(transitionRels, n);
+ }
+ }
+
+ /*
+ * XXX: When using DELETE or UPDATE, we must use exclusive lock for now
+ * because apply_old_delta(_with_count) uses ctid to identify the tuple
+ * to be deleted/deleted, but doesn't work in concurrent situations.
+ *
+ * If the view doesn't have aggregate, distinct, or tuple duplicate,
+ * then it would work even in concurrent situations. However, we don't have
+ * any way to guarantee the view has a unique key before opening the IMMV
+ * at the maintenance time because users may drop the unique index.
+ */
+
+ if (type == TRIGGER_TYPE_DELETE || type == TRIGGER_TYPE_UPDATE)
+ ex_lock = true;
+
+ ivm_trigger->funcname =
+ (timing == TRIGGER_TYPE_BEFORE ? SystemFuncName("IVM_immediate_before") : SystemFuncName("IVM_immediate_maintenance"));
+
+ ivm_trigger->columns = NIL;
+ ivm_trigger->transitionRels = transitionRels;
+ ivm_trigger->whenClause = NULL;
+ ivm_trigger->isconstraint = false;
+ ivm_trigger->deferrable = false;
+ ivm_trigger->initdeferred = false;
+ ivm_trigger->constrrel = NULL;
+ ivm_trigger->args = list_make2(
+ makeString(DatumGetPointer(DirectFunctionCall1(oidout, ObjectIdGetDatum(viewOid)))),
+ makeString(DatumGetPointer(DirectFunctionCall1(boolout, BoolGetDatum(ex_lock))))
+ );
+
+ address = CreateTrigger(ivm_trigger, NULL, relOid, InvalidOid, InvalidOid,
+ InvalidOid, InvalidOid, InvalidOid, NULL, true, false);
+
+ recordDependencyOn(&address, &refaddr, DEPENDENCY_AUTO);
+
+ /* Make changes-so-far visible */
+ CommandCounterIncrement();
+}
+
+/*
+ * check_ivm_restriction --- look for specify nodes in the query tree
+ */
+static void
+check_ivm_restriction(Node *node)
+{
+ check_ivm_restriction_walker(node, NULL);
+}
+
+static bool
+check_ivm_restriction_walker(Node *node, void *context)
+{
+ if (node == NULL)
+ return false;
+
+ /*
+ * We currently don't support Sub-Query.
+ */
+ if (IsA(node, SubPlan) || IsA(node, SubLink))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("subquery is not supported on incrementally maintainable materialized view")));
+
+ /* This can recurse, so check for excessive recursion */
+ check_stack_depth();
+
+ switch (nodeTag(node))
+ {
+ case T_Query:
+ {
+ Query *qry = (Query *)node;
+ ListCell *lc;
+ List *vars;
+
+ /* if contained CTE, return error */
+ if (qry->cteList != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("CTE is not supported on incrementally maintainable materialized view")));
+ if (qry->havingQual != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg(" HAVING clause is not supported on incrementally maintainable materialized view")));
+ if (qry->sortClause != NIL) /* There is a possibility that we don't need to return an error */
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("ORDER BY clause is not supported on incrementally maintainable materialized view")));
+ if (qry->limitOffset != NULL || qry->limitCount != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view")));
+ if (qry->distinctClause)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("DISTINCT is not supported on incrementally maintainable materialized view")));
+ if (qry->hasDistinctOn)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("DISTINCT ON is not supported on incrementally maintainable materialized view")));
+ if (qry->hasWindowFuncs)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("window functions are not supported on incrementally maintainable materialized view")));
+ if (qry->groupingSets != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUPING SETS, ROLLUP, or CUBE clauses is not supported on incrementally maintainable materialized view")));
+ if (qry->setOperations != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("UNION/INTERSECT/EXCEPT statements are not supported on incrementally maintainable materialized view")));
+ if (list_length(qry->targetList) == 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("empty target list is not supported on incrementally maintainable materialized view")));
+ if (qry->rowMarks != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view")));
+
+ /* system column restrictions */
+ vars = pull_vars_of_level((Node *) qry, 0);
+ foreach(lc, vars)
+ {
+ if (IsA(lfirst(lc), Var))
+ {
+ Var *var = (Var *) lfirst(lc);
+ /* if system column, return error */
+ if (var->varattno < 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("system column is not supported on incrementally maintainable materialized view")));
+ }
+ }
+
+ /* restrictions for rtable */
+ foreach(lc, qry->rtable)
+ {
+ RangeTblEntry *rte = (RangeTblEntry *) lfirst(lc);
+
+ if (rte->subquery)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("subquery is not supported on incrementally maintainable materialized view")));
+
+ if (rte->tablesample != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("TABLESAMPLE clause is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitioned table is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_RELATION && has_superclass(rte->relid))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_RELATION && find_inheritance_children(rte->relid, NoLock) != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("inheritance parent is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_FOREIGN_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("foreign table is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_VIEW ||
+ rte->relkind == RELKIND_MATVIEW)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view")));
+
+ if (rte->rtekind == RTE_VALUES)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("VALUES is not supported on incrementally maintainable materialized view")));
+
+ }
+
+ query_tree_walker(qry, check_ivm_restriction_walker, NULL, QTW_IGNORE_RANGE_TABLE);
+
+ break;
+ }
+ case T_TargetEntry:
+ {
+ TargetEntry *tle = (TargetEntry *)node;
+ if (isIvmName(tle->resname))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("column name %s is not supported on incrementally maintainable materialized view", tle->resname)));
+
+ expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ break;
+ }
+ case T_JoinExpr:
+ {
+ JoinExpr *joinexpr = (JoinExpr *)node;
+
+ if (joinexpr->jointype > JOIN_INNER)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("OUTER JOIN is not supported on incrementally maintainable materialized view")));
+
+ expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ }
+ break;
+ case T_Aggref:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function is not supported on incrementally maintainable materialized view")));
+ break;
+ default:
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
+ break;
+ }
+ return false;
+}
+
+/*
+ * CreateIndexOnIMMV
+ *
+ * Create a unique index on incremental maintainable materialized view.
+ * If the view definition query has a GROUP BY clause, the index is created
+ * on the columns of GROUP BY expressions. Otherwise, if the view contains
+ * all primary key attritubes of its base tables in the target list, the index
+ * is created on these attritubes. In other cases, no index is created.
+ */
+void
+CreateIndexOnIMMV(Query *query, Relation matviewRel)
+{
+ ListCell *lc;
+ IndexStmt *index;
+ ObjectAddress address;
+ List *constraintList = NIL;
+ char idxname[NAMEDATALEN];
+ List *indexoidlist = RelationGetIndexList(matviewRel);
+ ListCell *indexoidscan;
+ Bitmapset *key_attnos;
+
+ snprintf(idxname, sizeof(idxname), "%s_index", RelationGetRelationName(matviewRel));
+
+ index = makeNode(IndexStmt);
+
+ index->unique = true;
+ index->primary = false;
+ index->isconstraint = false;
+ index->deferrable = false;
+ index->initdeferred = false;
+ index->idxname = idxname;
+ index->relation =
+ makeRangeVar(get_namespace_name(RelationGetNamespace(matviewRel)),
+ pstrdup(RelationGetRelationName(matviewRel)),
+ -1);
+ index->accessMethod = DEFAULT_INDEX_TYPE;
+ index->options = NIL;
+ index->tableSpace = get_tablespace_name(matviewRel->rd_rel->reltablespace);
+ index->whereClause = NULL;
+ index->indexParams = NIL;
+ index->indexIncludingParams = NIL;
+ index->excludeOpNames = NIL;
+ index->idxcomment = NULL;
+ index->indexOid = InvalidOid;
+ index->oldNumber = InvalidRelFileNumber;
+ index->oldCreateSubid = InvalidSubTransactionId;
+ index->oldFirstRelfilelocatorSubid = InvalidSubTransactionId;
+ index->transformed = true;
+ index->concurrent = false;
+ index->if_not_exists = false;
+
+ /* create index on the base tables' primary key columns */
+ key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
+ if (key_attnos)
+ {
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ }
+ else
+ {
+ /* create no index, just notice that an appropriate index is necessary for efficient IVM */
+ ereport(NOTICE,
+ (errmsg("could not create an index on materialized view \"%s\" automatically",
+ RelationGetRelationName(matviewRel)),
+ errdetail("This target list does not have all the primary key columns. "),
+ errhint("Create an index on the materialized view for efficient incremental maintenance.")));
+ return;
+ }
+
+ /* If we have a compatible index, we don't need to create another. */
+ foreach(indexoidscan, indexoidlist)
+ {
+ Oid indexoid = lfirst_oid(indexoidscan);
+ Relation indexRel;
+ bool hasCompatibleIndex = false;
+
+ indexRel = index_open(indexoid, AccessShareLock);
+
+ if (CheckIndexCompatible(indexRel->rd_id,
+ index->accessMethod,
+ index->indexParams,
+ index->excludeOpNames))
+ hasCompatibleIndex = true;
+
+ index_close(indexRel, AccessShareLock);
+
+ if (hasCompatibleIndex)
+ return;
+ }
+
+ address = DefineIndex(RelationGetRelid(matviewRel),
+ index,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ -1,
+ false, true, false, false, true);
+
+ ereport(NOTICE,
+ (errmsg("created index \"%s\" on materialized view \"%s\"",
+ idxname, RelationGetRelationName(matviewRel))));
+
+ /*
+ * Make dependencies so that the index is dropped if any base tables's
+ * primary key is dropped.
+ */
+ foreach(lc, constraintList)
+ {
+ Oid constraintOid = lfirst_oid(lc);
+ ObjectAddress refaddr;
+
+ refaddr.classId = ConstraintRelationId;
+ refaddr.objectId = constraintOid;
+ refaddr.objectSubId = 0;
+
+ recordDependencyOn(&address, &refaddr, DEPENDENCY_NORMAL);
+ }
+}
+
+
+/*
+ * get_primary_key_attnos_from_query
+ *
+ * Identify the columns in base tables' primary keys in the target list.
+ *
+ * Returns a Bitmapset of the column attnos of the primary key's columns of
+ * tables that used in the query. The attnos are offset by
+ * FirstLowInvalidHeapAttributeNumber as same as get_primary_key_attnos.
+ *
+ * If any table has no primary key or any primary key's columns is not in
+ * the target list, return NULL. We also return NULL if any pkey constraint
+ * is deferrable.
+ *
+ * constraintList is set to a list of the OIDs of the pkey constraints.
+ */
+static Bitmapset *
+get_primary_key_attnos_from_query(Query *query, List **constraintList)
+{
+ List *key_attnos_list = NIL;
+ ListCell *lc;
+ int i;
+ Bitmapset *keys = NULL;
+ Relids rels_in_from;
+
+ /*
+ * Collect primary key attributes from all tables used in query. The key attributes
+ * sets for each table are stored in key_attnos_list in order by RTE index.
+ */
+ foreach(lc, query->rtable)
+ {
+ RangeTblEntry *r = (RangeTblEntry*) lfirst(lc);
+ Bitmapset *key_attnos;
+ bool has_pkey = true;
+
+ /* for tables, call get_primary_key_attnos */
+ if (r->rtekind == RTE_RELATION)
+ {
+ Oid constraintOid;
+ key_attnos = get_primary_key_attnos(r->relid, false, &constraintOid);
+ *constraintList = lappend_oid(*constraintList, constraintOid);
+ has_pkey = (key_attnos != NULL);
+ }
+ /* for other RTEs, store NULL into key_attnos_list */
+ else
+ key_attnos = NULL;
+
+ /*
+ * If any table or subquery has no primary key or its pkey constraint is deferrable,
+ * we cannot get key attributes for this query, so return NULL.
+ */
+ if (!has_pkey)
+ return NULL;
+
+ key_attnos_list = lappend(key_attnos_list, key_attnos);
+ }
+
+ /* Collect key attributes appearing in the target list */
+ i = 1;
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) flatten_join_alias_vars(NULL, query, lfirst(lc));
+
+ if (IsA(tle->expr, Var))
+ {
+ Var *var = (Var*) tle->expr;
+ Bitmapset *key_attnos = list_nth(key_attnos_list, var->varno - 1);
+
+ /* check if this attribute is from a base table's primary key */
+ if (bms_is_member(var->varattno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ /*
+ * Remove found key attributes from key_attnos_list, and add this
+ * to the result list.
+ */
+ key_attnos = bms_del_member(key_attnos, var->varattno - FirstLowInvalidHeapAttributeNumber);
+ if (bms_is_empty(key_attnos))
+ {
+ key_attnos_list = list_delete_nth_cell(key_attnos_list, var->varno - 1);
+ key_attnos_list = list_insert_nth(key_attnos_list, var->varno - 1, NULL);
+ }
+ keys = bms_add_member(keys, i - FirstLowInvalidHeapAttributeNumber);
+ }
+ }
+ i++;
+ }
+
+ /* Collect RTE indexes of relations appearing in the FROM clause */
+ rels_in_from = get_relids_in_jointree((Node *) query->jointree, false, false);
+
+ /*
+ * Check if all key attributes of relations in FROM are appearing in the target
+ * list. If an attribute remains in key_attnos_list in spite of the table is used
+ * in FROM clause, the target is missing this key attribute, so we return NULL.
+ */
+ i = 1;
+ foreach(lc, key_attnos_list)
+ {
+ Bitmapset *bms = (Bitmapset *)lfirst(lc);
+ if (!bms_is_empty(bms) && bms_is_member(i, rels_in_from))
+ return NULL;
+ i++;
+ }
+
+ return keys;
+}
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index f9a3bdfc3a..fd9d0d99ae 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -25,26 +25,37 @@
#include "catalog/indexing.h"
#include "catalog/namespace.h"
#include "catalog/pg_am.h"
+#include "catalog/pg_depend.h"
+#include "catalog/pg_trigger.h"
#include "catalog/pg_opclass.h"
#include "catalog/pg_operator.h"
#include "commands/cluster.h"
#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
+#include "commands/createas.h"
#include "executor/executor.h"
#include "executor/spi.h"
+#include "executor/tstoreReceiver.h"
#include "miscadmin.h"
+#include "nodes/makefuncs.h"
+#include "parser/analyze.h"
+#include "parser/parse_clause.h"
+#include "parser/parse_func.h"
#include "parser/parse_relation.h"
#include "pgstat.h"
#include "rewrite/rewriteHandler.h"
+#include "rewrite/rowsecurity.h"
#include "storage/lmgr.h"
#include "storage/smgr.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
+#include "utils/fmgroids.h"
#include "utils/lsyscache.h"
#include "utils/rel.h"
#include "utils/snapmgr.h"
#include "utils/syscache.h"
+#include "utils/typcache.h"
typedef struct
@@ -58,6 +69,52 @@ typedef struct
BulkInsertState bistate; /* bulk insert state */
} DR_transientrel;
+#define MV_INIT_QUERYHASHSIZE 16
+
+/*
+ * MV_TriggerHashEntry
+ *
+ * Hash entry for base tables on which IVM trigger is invoked
+ */
+typedef struct MV_TriggerHashEntry
+{
+ Oid matview_id; /* OID of the materialized view */
+ int before_trig_count; /* count of before triggers invoked */
+ int after_trig_count; /* count of after triggers invoked */
+
+ Snapshot snapshot; /* Snapshot just before table change */
+
+ List *tables; /* List of MV_TriggerTable */
+ bool has_old; /* tuples are deleted from any table? */
+ bool has_new; /* tuples are inserted into any table? */
+} MV_TriggerHashEntry;
+
+/*
+ * MV_TriggerTable
+ *
+ * IVM related data for tables on which the trigger is invoked.
+ */
+typedef struct MV_TriggerTable
+{
+ Oid table_id; /* OID of the modified table */
+ List *old_tuplestores; /* tuplestores for deleted tuples */
+ List *new_tuplestores; /* tuplestores for inserted tuples */
+
+ List *rte_indexes; /* List of RTE index of the modified table */
+ RangeTblEntry *original_rte; /* the original RTE saved before rewriting query */
+
+ Relation rel; /* relation of the modified table */
+ TupleTableSlot *slot; /* for checking visibility in the pre-state table */
+} MV_TriggerTable;
+
+static HTAB *mv_trigger_info = NULL;
+
+static bool in_delta_calculation = false;
+
+/* ENR name for materialized view delta */
+#define NEW_DELTA_ENRNAME "new_delta"
+#define OLD_DELTA_ENRNAME "old_delta"
+
static int matview_maintenance_depth = 0;
static void transientrel_startup(DestReceiver *self, int operation, TupleDesc typeinfo);
@@ -65,7 +122,9 @@ static bool transientrel_receive(TupleTableSlot *slot, DestReceiver *self);
static void transientrel_shutdown(DestReceiver *self);
static void transientrel_destroy(DestReceiver *self);
static uint64 refresh_matview_datafill(DestReceiver *dest, Query *query,
- const char *queryString);
+ QueryEnvironment *queryEnv,
+ TupleDesc *resultTupleDesc,
+ const char *queryString);
static char *make_temptable_name_n(char *tempname, int n);
static void refresh_by_match_merge(Oid matviewOid, Oid tempOid, Oid relowner,
int save_sec_context);
@@ -73,6 +132,37 @@ static void refresh_by_heap_swap(Oid matviewOid, Oid OIDNewHeap, char relpersist
static bool is_usable_unique_index(Relation indexRel);
static void OpenMatViewIncrementalMaintenance(void);
static void CloseMatViewIncrementalMaintenance(void);
+static Query *get_matview_query(Relation matviewRel);
+
+static Query *rewrite_query_for_preupdate_state(Query *query, List *tables,
+ ParseState *pstate, Oid matviewid);
+static void register_delta_ENRs(ParseState *pstate, Query *query, List *tables);
+static char *make_delta_enr_name(const char *prefix, Oid relid, int count);
+static RangeTblEntry *get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *table,
+ QueryEnvironment *queryEnv, Oid matviewid);
+static RangeTblEntry *replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
+ QueryEnvironment *queryEnv);
+static Query *rewrite_query_for_counting(Query *query, ParseState *pstate);
+
+static void calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
+ DestReceiver *dest_old, DestReceiver *dest_new,
+ TupleDesc *tupdesc_old, TupleDesc *tupdesc_new,
+ QueryEnvironment *queryEnv);
+static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte_index);
+
+static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
+ TupleDesc tupdesc_old, TupleDesc tupdesc_new,
+ Query *query);
+static void apply_old_delta(const char *matviewname, const char *deltaname_old,
+ List *keys);
+static void apply_new_delta(const char *matviewname, const char *deltaname_new,
+ StringInfo target_list);
+static char *get_matching_condition_string(List *keys);
+static void generate_equal(StringInfo querybuf, Oid opttype,
+ const char *leftop, const char *rightop);
+
+static void mv_InitHashTables(void);
+static void clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort);
/*
* SetMatViewPopulatedState
@@ -114,6 +204,46 @@ SetMatViewPopulatedState(Relation relation, bool newstate)
CommandCounterIncrement();
}
+/*
+ * SetMatViewIVMState
+ * Mark a materialized view as IVM, or not.
+ *
+ * NOTE: caller must be holding an appropriate lock on the relation.
+ */
+void
+SetMatViewIVMState(Relation relation, bool newstate)
+{
+ Relation pgrel;
+ HeapTuple tuple;
+
+ Assert(relation->rd_rel->relkind == RELKIND_MATVIEW);
+
+ /*
+ * Update relation's pg_class entry. Crucial side-effect: other backends
+ * (and this one too!) are sent SI message to make them rebuild relcache
+ * entries.
+ */
+ pgrel = table_open(RelationRelationId, RowExclusiveLock);
+ tuple = SearchSysCacheCopy1(RELOID,
+ ObjectIdGetDatum(RelationGetRelid(relation)));
+ if (!HeapTupleIsValid(tuple))
+ elog(ERROR, "cache lookup failed for relation %u",
+ RelationGetRelid(relation));
+
+ ((Form_pg_class) GETSTRUCT(tuple))->relisivm = newstate;
+
+ CatalogTupleUpdate(pgrel, &tuple->t_self, tuple);
+
+ heap_freetuple(tuple);
+ table_close(pgrel, RowExclusiveLock);
+
+ /*
+ * Advance command counter to make the updated pg_class row locally
+ * visible.
+ */
+ CommandCounterIncrement();
+}
+
/*
* ExecRefreshMatView -- execute a REFRESH MATERIALIZED VIEW command
*
@@ -140,8 +270,6 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
{
Oid matviewOid;
Relation matviewRel;
- RewriteRule *rule;
- List *actions;
Query *dataQuery;
Oid tableSpace;
Oid relowner;
@@ -155,6 +283,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
int save_sec_context;
int save_nestlevel;
ObjectAddress address;
+ bool oldPopulated;
/* Determine strength of lock needed. */
concurrent = stmt->concurrent;
@@ -179,6 +308,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
SetUserIdAndSecContext(relowner,
save_sec_context | SECURITY_RESTRICTED_OPERATION);
save_nestlevel = NewGUCNestLevel();
+ oldPopulated = RelationIsPopulated(matviewRel);
/* Make sure it is a materialized view. */
if (matviewRel->rd_rel->relkind != RELKIND_MATVIEW)
@@ -200,32 +330,9 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
errmsg("%s and %s options cannot be used together",
"CONCURRENTLY", "WITH NO DATA")));
- /*
- * Check that everything is correct for a refresh. Problems at this point
- * are internal errors, so elog is sufficient.
- */
- if (matviewRel->rd_rel->relhasrules == false ||
- matviewRel->rd_rules->numLocks < 1)
- elog(ERROR,
- "materialized view \"%s\" is missing rewrite information",
- RelationGetRelationName(matviewRel));
-
- if (matviewRel->rd_rules->numLocks > 1)
- elog(ERROR,
- "materialized view \"%s\" has too many rules",
- RelationGetRelationName(matviewRel));
- rule = matviewRel->rd_rules->rules[0];
- if (rule->event != CMD_SELECT || !(rule->isInstead))
- elog(ERROR,
- "the rule for materialized view \"%s\" is not a SELECT INSTEAD OF rule",
- RelationGetRelationName(matviewRel));
+ dataQuery = get_matview_query(matviewRel);
- actions = rule->actions;
- if (list_length(actions) != 1)
- elog(ERROR,
- "the rule for materialized view \"%s\" is not a single action",
- RelationGetRelationName(matviewRel));
/*
* Check that there is a unique index with no WHERE clause on one or more
@@ -260,12 +367,6 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
errhint("Create a unique index with no WHERE clause on one or more columns of the materialized view.")));
}
- /*
- * The stored query was rewritten at the time of the MV definition, but
- * has not been scribbled on by the planner.
- */
- dataQuery = linitial_node(Query, actions);
-
/*
* Check for active uses of the relation in the current transaction, such
* as open scans.
@@ -293,6 +394,74 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
relpersistence = matviewRel->rd_rel->relpersistence;
}
+ /* delete IMMV triggers. */
+ if (RelationIsIVM(matviewRel) && stmt->skipData )
+ {
+ Relation tgRel;
+ Relation depRel;
+ ScanKeyData key;
+ SysScanDesc scan;
+ HeapTuple tup;
+ ObjectAddresses *immv_triggers;
+
+ immv_triggers = new_object_addresses();
+
+ tgRel = table_open(TriggerRelationId, RowExclusiveLock);
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ /* search triggers that depends on IMMV. */
+ ScanKeyInit(&key,
+ Anum_pg_depend_refobjid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(matviewOid));
+ scan = systable_beginscan(depRel, DependReferenceIndexId, true,
+ NULL, 1, &key);
+ while ((tup = systable_getnext(scan)) != NULL)
+ {
+ ObjectAddress obj;
+ Form_pg_depend foundDep = (Form_pg_depend) GETSTRUCT(tup);
+
+ if (foundDep->classid == TriggerRelationId)
+ {
+ HeapTuple tgtup;
+ ScanKeyData tgkey[1];
+ SysScanDesc tgscan;
+ Form_pg_trigger tgform;
+
+ /* Find the trigger name. */
+ ScanKeyInit(&tgkey[0],
+ Anum_pg_trigger_oid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(foundDep->objid));
+
+ tgscan = systable_beginscan(tgRel, TriggerOidIndexId, true,
+ NULL, 1, tgkey);
+ tgtup = systable_getnext(tgscan);
+ if (!HeapTupleIsValid(tgtup))
+ elog(ERROR, "could not find tuple for immv trigger %u", foundDep->objid);
+
+ tgform = (Form_pg_trigger) GETSTRUCT(tgtup);
+
+ /* If trigger is created by IMMV, delete it. */
+ if (strncmp(NameStr(tgform->tgname), "IVM_trigger_", 12) == 0)
+ {
+ obj.classId = foundDep->classid;
+ obj.objectId = foundDep->objid;
+ obj.objectSubId = foundDep->refobjsubid;
+ add_exact_object_address(&obj, immv_triggers);
+ }
+ systable_endscan(tgscan);
+ }
+ }
+ systable_endscan(scan);
+
+ performMultipleDeletions(immv_triggers, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ table_close(depRel, RowExclusiveLock);
+ table_close(tgRel, RowExclusiveLock);
+ free_object_addresses(immv_triggers);
+ }
+
/*
* Create the transient table that will receive the regenerated data. Lock
* it against access by any other process until commit (by which time it
@@ -306,7 +475,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
/* Generate the data, if wanted. */
if (!stmt->skipData)
- processed = refresh_matview_datafill(dest, dataQuery, queryString);
+ processed = refresh_matview_datafill(dest, dataQuery, NULL, NULL, queryString);
/* Make the matview match the newly generated data. */
if (concurrent)
@@ -341,6 +510,12 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
pgstat_count_heap_insert(matviewRel, processed);
}
+ if (!stmt->skipData && RelationIsIVM(matviewRel) && !oldPopulated)
+ {
+ CreateIndexOnIMMV(dataQuery, matviewRel);
+ CreateIvmTriggersOnBaseTables(dataQuery, matviewOid);
+ }
+
table_close(matviewRel, NoLock);
/* Roll back any GUC changes */
@@ -375,6 +550,8 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
*/
static uint64
refresh_matview_datafill(DestReceiver *dest, Query *query,
+ QueryEnvironment *queryEnv,
+ TupleDesc *resultTupleDesc,
const char *queryString)
{
List *rewritten;
@@ -411,7 +588,7 @@ refresh_matview_datafill(DestReceiver *dest, Query *query,
/* Create a QueryDesc, redirecting output to our tuple receiver */
queryDesc = CreateQueryDesc(plan, queryString,
GetActiveSnapshot(), InvalidSnapshot,
- dest, NULL, NULL, 0);
+ dest, NULL, queryEnv ? queryEnv: NULL, 0);
/* call ExecutorStart to prepare the plan for execution */
ExecutorStart(queryDesc, 0);
@@ -421,6 +598,9 @@ refresh_matview_datafill(DestReceiver *dest, Query *query,
processed = queryDesc->estate->es_processed;
+ if (resultTupleDesc)
+ *resultTupleDesc = CreateTupleDescCopy(queryDesc->tupDesc);
+
/* and clean up */
ExecutorFinish(queryDesc);
ExecutorEnd(queryDesc);
@@ -932,3 +1112,1219 @@ CloseMatViewIncrementalMaintenance(void)
matview_maintenance_depth--;
Assert(matview_maintenance_depth >= 0);
}
+
+/*
+ * get_matview_query - get the Query from a matview's _RETURN rule.
+ */
+static Query *
+get_matview_query(Relation matviewRel)
+{
+ RewriteRule *rule;
+ List * actions;
+
+ /*
+ * Check that everything is correct for a refresh. Problems at this point
+ * are internal errors, so elog is sufficient.
+ */
+ if (matviewRel->rd_rel->relhasrules == false ||
+ matviewRel->rd_rules->numLocks < 1)
+ elog(ERROR,
+ "materialized view \"%s\" is missing rewrite information",
+ RelationGetRelationName(matviewRel));
+
+ if (matviewRel->rd_rules->numLocks > 1)
+ elog(ERROR,
+ "materialized view \"%s\" has too many rules",
+ RelationGetRelationName(matviewRel));
+
+ rule = matviewRel->rd_rules->rules[0];
+ if (rule->event != CMD_SELECT || !(rule->isInstead))
+ elog(ERROR,
+ "the rule for materialized view \"%s\" is not a SELECT INSTEAD OF rule",
+ RelationGetRelationName(matviewRel));
+
+ actions = rule->actions;
+ if (list_length(actions) != 1)
+ elog(ERROR,
+ "the rule for materialized view \"%s\" is not a single action",
+ RelationGetRelationName(matviewRel));
+
+ /*
+ * The stored query was rewritten at the time of the MV definition, but
+ * has not been scribbled on by the planner.
+ */
+ return linitial_node(Query, actions);
+}
+
+
+/* ----------------------------------------------------
+ * Incremental View Maintenance routines
+ * ---------------------------------------------------
+ */
+
+/*
+ * IVM_immediate_before
+ *
+ * IVM trigger function invoked before base table is modified. If this is
+ * invoked firstly in the same statement, we save the transaction id and the
+ * command id at that time.
+ */
+Datum
+IVM_immediate_before(PG_FUNCTION_ARGS)
+{
+ TriggerData *trigdata = (TriggerData *) fcinfo->context;
+ char *matviewOid_text = trigdata->tg_trigger->tgargs[0];
+ char *ex_lock_text = trigdata->tg_trigger->tgargs[1];
+ Oid matviewOid;
+ MV_TriggerHashEntry *entry;
+ bool found;
+ bool ex_lock;
+
+ matviewOid = DatumGetObjectId(DirectFunctionCall1(oidin, CStringGetDatum(matviewOid_text)));
+ ex_lock = DatumGetBool(DirectFunctionCall1(boolin, CStringGetDatum(ex_lock_text)));
+
+ /* If the view has more than one tables, we have to use an exclusive lock. */
+ if (ex_lock)
+ {
+ /*
+ * Wait for concurrent transactions which update this materialized view at
+ * READ COMMITED. This is needed to see changes committed in other
+ * transactions. No wait and raise an error at REPEATABLE READ or
+ * SERIALIZABLE to prevent update anomalies of matviews.
+ * XXX: dead-lock is possible here.
+ */
+ if (!IsolationUsesXactSnapshot())
+ LockRelationOid(matviewOid, ExclusiveLock);
+ else if (!ConditionalLockRelationOid(matviewOid, ExclusiveLock))
+ {
+ /* try to throw error by name; relation could be deleted... */
+ char *relname = get_rel_name(matviewOid);
+
+ if (!relname)
+ ereport(ERROR,
+ (errcode(ERRCODE_LOCK_NOT_AVAILABLE),
+ errmsg("could not obtain lock on materialized view during incremental maintenance")));
+
+ ereport(ERROR,
+ (errcode(ERRCODE_LOCK_NOT_AVAILABLE),
+ errmsg("could not obtain lock on materialized view \"%s\" during incremental maintenance",
+ relname)));
+ }
+ }
+ else
+ LockRelationOid(matviewOid, RowExclusiveLock);
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_trigger_info)
+ mv_InitHashTables();
+
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_ENTER, &found);
+
+ /* On the first BEFORE to update the view, initialize trigger data */
+ if (!found)
+ {
+ /*
+ * Get a snapshot just before the table was modified for checking
+ * tuple visibility in the pre-update state of the table.
+ */
+ Snapshot snapshot = GetActiveSnapshot();
+
+ entry->matview_id = matviewOid;
+ entry->before_trig_count = 0;
+ entry->after_trig_count = 0;
+ entry->snapshot = RegisterSnapshot(snapshot);
+ entry->tables = NIL;
+ entry->has_old = false;
+ entry->has_new = false;
+ }
+
+ entry->before_trig_count++;
+
+ return PointerGetDatum(NULL);
+}
+
+/*
+ * IVM_immediate_maintenance
+ *
+ * IVM trigger function invoked after base table is modified.
+ * For each table, tuplestores of transition tables are collected.
+ * and after the last modification
+ */
+Datum
+IVM_immediate_maintenance(PG_FUNCTION_ARGS)
+{
+ TriggerData *trigdata = (TriggerData *) fcinfo->context;
+ Relation rel;
+ Oid relid;
+ Oid matviewOid;
+ Query *query;
+ Query *rewritten = NULL;
+ char *matviewOid_text = trigdata->tg_trigger->tgargs[0];
+ Relation matviewRel;
+ int old_depth = matview_maintenance_depth;
+
+ Oid relowner;
+ Tuplestorestate *old_tuplestore = NULL;
+ Tuplestorestate *new_tuplestore = NULL;
+ DestReceiver *dest_new = NULL, *dest_old = NULL;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ MV_TriggerHashEntry *entry;
+ MV_TriggerTable *table;
+ bool found;
+
+ ParseState *pstate;
+ QueryEnvironment *queryEnv = create_queryEnv();
+ MemoryContext oldcxt;
+ ListCell *lc;
+ int i;
+
+
+ /* Create a ParseState for rewriting the view definition query */
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ rel = trigdata->tg_relation;
+ relid = rel->rd_id;
+
+ matviewOid = DatumGetObjectId(DirectFunctionCall1(oidin, CStringGetDatum(matviewOid_text)));
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_trigger_info)
+ mv_InitHashTables();
+
+ /* get the entry for this materialized view */
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_FIND, &found);
+ Assert (found && entry != NULL);
+ entry->after_trig_count++;
+
+ /* search the entry for the modified table and create new entry if not found */
+ found = false;
+ foreach(lc, entry->tables)
+ {
+ table = (MV_TriggerTable *) lfirst(lc);
+ if (table->table_id == relid)
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ table = (MV_TriggerTable *) palloc0(sizeof(MV_TriggerTable));
+ table->table_id = relid;
+ table->old_tuplestores = NIL;
+ table->new_tuplestores = NIL;
+ table->rte_indexes = NIL;
+ table->slot = MakeSingleTupleTableSlot(RelationGetDescr(rel), table_slot_callbacks(rel));
+ table->rel = table_open(RelationGetRelid(rel), NoLock);
+ entry->tables = lappend(entry->tables, table);
+
+ MemoryContextSwitchTo(oldcxt);
+ }
+
+ /* Save the transition tables and make a request to not free immediately */
+ if (trigdata->tg_oldtable)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+ table->old_tuplestores = lappend(table->old_tuplestores, trigdata->tg_oldtable);
+ entry->has_old = true;
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (trigdata->tg_newtable)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+ table->new_tuplestores = lappend(table->new_tuplestores, trigdata->tg_newtable);
+ entry->has_new = true;
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (entry->has_new || entry->has_old)
+ {
+ CmdType cmd;
+
+ if (TRIGGER_FIRED_BY_INSERT(trigdata->tg_event))
+ cmd = CMD_INSERT;
+ else if (TRIGGER_FIRED_BY_DELETE(trigdata->tg_event))
+ cmd = CMD_DELETE;
+ else if (TRIGGER_FIRED_BY_UPDATE(trigdata->tg_event))
+ cmd = CMD_UPDATE;
+ else
+ elog(ERROR,"unsupported trigger type");
+
+ /* Prolong lifespan of transition tables to the end of the last AFTER trigger */
+ SetTransitionTablePreserved(relid, cmd);
+ }
+
+
+ /* If this is not the last AFTER trigger call, immediately exit. */
+ Assert (entry->before_trig_count >= entry->after_trig_count);
+ if (entry->before_trig_count != entry->after_trig_count)
+ return PointerGetDatum(NULL);
+
+ /*
+ * If this is the last AFTER trigger call, continue and update the view.
+ */
+
+ /*
+ * Advance command counter to make the updated base table row locally
+ * visible.
+ */
+ CommandCounterIncrement();
+
+ matviewRel = table_open(matviewOid, NoLock);
+
+ /* Make sure it is a materialized view. */
+ Assert(matviewRel->rd_rel->relkind == RELKIND_MATVIEW);
+
+ /*
+ * Get and push the latast snapshot to see any changes which is committed
+ * during waiting in other transactions at READ COMMITTED level.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /*
+ * Check for active uses of the relation in the current transaction, such
+ * as open scans.
+ *
+ * NB: We count on this to protect us against problems with refreshing the
+ * data using TABLE_INSERT_FROZEN.
+ */
+ CheckTableNotInUse(matviewRel, "refresh a materialized view incrementally");
+
+ /*
+ * Switch to the owner's userid, so that any functions are run as that
+ * user. Also arrange to make GUC variable changes local to this command.
+ * We will switch modes when we are about to execute user code.
+ */
+ relowner = matviewRel->rd_rel->relowner;
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+
+ /* get view query*/
+ query = get_matview_query(matviewRel);
+
+ /*
+ * When a base table is truncated, the view content will be empty if the
+ * view definition query does not contain an aggregate without a GROUP clause.
+ * Therefore, such views can be truncated.
+ */
+ if (TRIGGER_FIRED_BY_TRUNCATE(trigdata->tg_event))
+ {
+ ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
+ NIL, DROP_RESTRICT, false, false);
+
+ /* Clean up hash entry and delete tuplestores */
+ clean_up_IVM_hash_entry(entry, false);
+
+ /* Pop the original snapshot. */
+ PopActiveSnapshot();
+
+ table_close(matviewRel, NoLock);
+
+ /* Roll back any GUC changes */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ return PointerGetDatum(NULL);
+ }
+
+ /*
+ * rewrite query for calculating deltas
+ */
+
+ rewritten = copyObject(query);
+
+ /* Replace resnames in a target list with materialized view's attnames */
+ i = 0;
+ foreach (lc, rewritten->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
+
+ tle->resname = pstrdup(resname);
+ i++;
+ }
+
+ /* Set all tables in the query to pre-update state */
+ rewritten = rewrite_query_for_preupdate_state(rewritten, entry->tables,
+ pstate, matviewOid);
+ /* Rewrite for counting duplicated tuples */
+ rewritten = rewrite_query_for_counting(rewritten, pstate);
+
+ /* Create tuplestores to store view deltas */
+ if (entry->has_old)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ old_tuplestore = tuplestore_begin_heap(false, false, work_mem);
+ dest_old = CreateDestReceiver(DestTuplestore);
+ SetTuplestoreDestReceiverParams(dest_old,
+ old_tuplestore,
+ TopTransactionContext,
+ false,
+ NULL,
+ NULL);
+
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (entry->has_new)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ new_tuplestore = tuplestore_begin_heap(false, false, work_mem);
+ dest_new = CreateDestReceiver(DestTuplestore);
+ SetTuplestoreDestReceiverParams(dest_new,
+ new_tuplestore,
+ TopTransactionContext,
+ false,
+ NULL,
+ NULL);
+ MemoryContextSwitchTo(oldcxt);
+ }
+
+ /* for all modified tables */
+ foreach(lc, entry->tables)
+ {
+ ListCell *lc2;
+
+ table = (MV_TriggerTable *) lfirst(lc);
+
+ /* loop for self-join */
+ foreach(lc2, table->rte_indexes)
+ {
+ int rte_index = lfirst_int(lc2);
+ TupleDesc tupdesc_old;
+ TupleDesc tupdesc_new;
+
+ /* calculate delta tables */
+ calc_delta(table, rte_index, rewritten, dest_old, dest_new,
+ &tupdesc_old, &tupdesc_new, queryEnv);
+
+ /* Set the table in the query to post-update state */
+ rewritten = rewrite_query_for_postupdate_state(rewritten, table, rte_index);
+
+ PG_TRY();
+ {
+ /* apply the delta tables to the materialized view */
+ apply_delta(matviewOid, old_tuplestore, new_tuplestore,
+ tupdesc_old, tupdesc_new, query);
+ }
+ PG_CATCH();
+ {
+ matview_maintenance_depth = old_depth;
+ PG_RE_THROW();
+ }
+ PG_END_TRY();
+
+ /* clear view delta tuplestores */
+ if (old_tuplestore)
+ tuplestore_clear(old_tuplestore);
+ if (new_tuplestore)
+ tuplestore_clear(new_tuplestore);
+ }
+ }
+
+ /* Clean up hash entry and delete tuplestores */
+ clean_up_IVM_hash_entry(entry, false);
+ if (old_tuplestore)
+ {
+ dest_old->rDestroy(dest_old);
+ tuplestore_end(old_tuplestore);
+ }
+ if (new_tuplestore)
+ {
+ dest_new->rDestroy(dest_new);
+ tuplestore_end(new_tuplestore);
+ }
+
+ /* Pop the original snapshot. */
+ PopActiveSnapshot();
+
+ table_close(matviewRel, NoLock);
+
+ /* Roll back any GUC changes */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ return PointerGetDatum(NULL);
+}
+
+/*
+ * rewrite_query_for_preupdate_state
+ *
+ * Rewrite the query so that base tables' RTEs will represent "pre-update"
+ * state of tables. This is necessary to calculate view delta after multiple
+ * tables are modified.
+ */
+static Query*
+rewrite_query_for_preupdate_state(Query *query, List *tables,
+ ParseState *pstate, Oid matviewid)
+{
+ ListCell *lc;
+ int num_rte = list_length(query->rtable);
+ int i;
+
+
+ /* register delta ENRs */
+ register_delta_ENRs(pstate, query, tables);
+
+ /* XXX: Is necessary? Is this right timing? */
+ AcquireRewriteLocks(query, true, false);
+
+ i = 1;
+ foreach(lc, query->rtable)
+ {
+ RangeTblEntry *r = (RangeTblEntry*) lfirst(lc);
+
+ ListCell *lc2;
+ foreach(lc2, tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc2);
+ /*
+ * if the modified table is found then replace the original RTE with
+ * "pre-state" RTE and append its index to the list.
+ */
+ if (r->relid == table->table_id)
+ {
+ List *securityQuals;
+ List *withCheckOptions;
+ bool hasRowSecurity;
+ bool hasSubLinks;
+
+ RangeTblEntry *rte_pre = get_prestate_rte(r, table, pstate->p_queryEnv, matviewid);
+
+ /*
+ * Set a row security poslicies of the modified table to the subquery RTE which
+ * represents the pre-update state of the table.
+ */
+ get_row_security_policies(query, table->original_rte, i,
+ &securityQuals, &withCheckOptions,
+ &hasRowSecurity, &hasSubLinks);
+
+ if (hasRowSecurity)
+ {
+ query->hasRowSecurity = true;
+ rte_pre->security_barrier = true;
+ }
+ if (hasSubLinks)
+ query->hasSubLinks = true;
+
+ rte_pre->securityQuals = securityQuals;
+ lfirst(lc) = rte_pre;
+
+ table->rte_indexes = lappend_int(table->rte_indexes, i);
+ break;
+ }
+ }
+
+ /* finish the loop if we processed all RTE included in the original query */
+ if (i++ >= num_rte)
+ break;
+ }
+
+ return query;
+}
+
+/*
+ * register_delta_ENRs
+ *
+ * For all modified tables, make ENRs for their transition tables
+ * and register them to the queryEnv. ENR's RTEs are also appended
+ * into the list in query tree.
+ */
+static void
+register_delta_ENRs(ParseState *pstate, Query *query, List *tables)
+{
+ QueryEnvironment *queryEnv = pstate->p_queryEnv;
+ ListCell *lc;
+ RangeTblEntry *rte;
+
+ foreach(lc, tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc);
+ ListCell *lc2;
+ int count;
+
+ count = 0;
+ foreach(lc2, table->old_tuplestores)
+ {
+ Tuplestorestate *oldtable = (Tuplestorestate *) lfirst(lc2);
+ EphemeralNamedRelation enr =
+ palloc(sizeof(EphemeralNamedRelationData));
+ ParseNamespaceItem *nsitem;
+
+ enr->md.name = make_delta_enr_name("old", table->table_id, count);
+ enr->md.reliddesc = table->table_id;
+ enr->md.tupdesc = NULL;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(oldtable);
+ enr->reldata = oldtable;
+ register_ENR(queryEnv, enr);
+
+ nsitem = addRangeTableEntryForENR(pstate, makeRangeVar(NULL, enr->md.name, -1), true);
+ rte = nsitem->p_rte;
+
+ query->rtable = lappend(query->rtable, rte);
+
+ count++;
+ }
+
+ count = 0;
+ foreach(lc2, table->new_tuplestores)
+ {
+ Tuplestorestate *newtable = (Tuplestorestate *) lfirst(lc2);
+ EphemeralNamedRelation enr =
+ palloc(sizeof(EphemeralNamedRelationData));
+ ParseNamespaceItem *nsitem;
+
+ enr->md.name = make_delta_enr_name("new", table->table_id, count);
+ enr->md.reliddesc = table->table_id;
+ enr->md.tupdesc = NULL;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(newtable);
+ enr->reldata = newtable;
+ register_ENR(queryEnv, enr);
+
+ nsitem = addRangeTableEntryForENR(pstate, makeRangeVar(NULL, enr->md.name, -1), true);
+ rte = nsitem->p_rte;
+
+ query->rtable = lappend(query->rtable, rte);
+
+ count++;
+ }
+ }
+}
+
+#define DatumGetItemPointer(X) ((ItemPointer) DatumGetPointer(X))
+#define PG_GETARG_ITEMPOINTER(n) DatumGetItemPointer(PG_GETARG_DATUM(n))
+
+/*
+ * ivm_visible_in_prestate
+ *
+ * Check visibility of a tuple specified by the tableoid and item pointer
+ * using the snapshot taken just before the table was modified.
+ */
+Datum
+ivm_visible_in_prestate(PG_FUNCTION_ARGS)
+{
+ Oid tableoid = PG_GETARG_OID(0);
+ ItemPointer itemPtr = PG_GETARG_ITEMPOINTER(1);
+ Oid matviewOid = PG_GETARG_OID(2);
+ MV_TriggerHashEntry *entry;
+ MV_TriggerTable *table = NULL;
+ ListCell *lc;
+ bool found;
+ bool result;
+
+ if (!in_delta_calculation)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("ivm_visible_in_prestate can be called only in delta calculation")));
+
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_FIND, &found);
+ Assert (found && entry != NULL);
+
+ foreach(lc, entry->tables)
+ {
+ table = (MV_TriggerTable *) lfirst(lc);
+ if (table->table_id == tableoid)
+ break;
+ }
+
+ Assert (table != NULL);
+
+ result = table_tuple_fetch_row_version(table->rel, itemPtr, entry->snapshot, table->slot);
+
+ PG_RETURN_BOOL(result);
+}
+
+/*
+ * get_prestate_rte
+ *
+ * Rewrite RTE of the modified table to a subquery which represents
+ * "pre-state" table. The original RTE is saved in table->rte_original.
+ */
+static RangeTblEntry*
+get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *table,
+ QueryEnvironment *queryEnv, Oid matviewid)
+{
+ StringInfoData str;
+ RawStmt *raw;
+ Query *subquery;
+ Relation rel;
+ ParseState *pstate;
+ char *relname;
+ int i;
+
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ /*
+ * We can use NoLock here since AcquireRewriteLocks should
+ * have locked the relation already.
+ */
+ rel = table_open(table->table_id, NoLock);
+ relname = quote_qualified_identifier(
+ get_namespace_name(RelationGetNamespace(rel)),
+ RelationGetRelationName(rel));
+ table_close(rel, NoLock);
+
+ /*
+ * Filtering inserted row using the snapshot taken before the table
+ * is modified. ctid is required for maintaining outer join views.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str,
+ "SELECT t.* FROM %s t"
+ " WHERE pg_catalog.ivm_visible_in_prestate(t.tableoid, t.ctid ,%d::pg_catalog.oid)",
+ relname, matviewid);
+
+ /*
+ * Append deleted rows contained in old transition tables.
+ */
+ for (i = 0; i < list_length(table->old_tuplestores); i++)
+ {
+ appendStringInfo(&str, " UNION ALL ");
+ appendStringInfo(&str," SELECT * FROM %s",
+ make_delta_enr_name("old", table->table_id, i));
+ }
+
+ /* Get a subquery representing pre-state of the table */
+ raw = (RawStmt*)linitial(raw_parser(str.data, RAW_PARSE_DEFAULT));
+ subquery = transformStmt(pstate, raw->stmt);
+
+ /* save the original RTE */
+ table->original_rte = copyObject(rte);
+
+ rte->rtekind = RTE_SUBQUERY;
+ rte->subquery = subquery;
+ rte->security_barrier = false;
+
+ /* Clear fields that should not be set in a subquery RTE */
+ rte->relid = InvalidOid;
+ rte->relkind = 0;
+ rte->rellockmode = 0;
+ rte->tablesample = NULL;
+ rte->perminfoindex = 0; /* no permission checking for this RTE */
+ rte->inh = false; /* must not be set for a subquery */
+
+ return rte;
+}
+
+/*
+ * make_delta_enr_name
+ *
+ * Make a name for ENR of a transition table from the base table's oid.
+ * prefix will be "new" or "old" depending on its transition table kind..
+ */
+static char*
+make_delta_enr_name(const char *prefix, Oid relid, int count)
+{
+ char buf[NAMEDATALEN];
+ char *name;
+
+ snprintf(buf, NAMEDATALEN, "__ivm_%s_%u_%u", prefix, relid, count);
+ name = pstrdup(buf);
+
+ return name;
+}
+
+/*
+ * replace_rte_with_delta
+ *
+ * Replace RTE of the modified table with a single table delta that combine its
+ * all transition tables.
+ */
+static RangeTblEntry*
+replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
+ QueryEnvironment *queryEnv)
+{
+ Oid relid = table->table_id;
+ StringInfoData str;
+ ParseState *pstate;
+ RawStmt *raw;
+ Query *sub;
+ int num_tuplestores = list_length(is_new ? table->new_tuplestores : table->old_tuplestores);
+ int i;
+
+ /* the previous RTE must be a subquery which represents "pre-state" table */
+ Assert(rte->rtekind == RTE_SUBQUERY);
+
+ /* Create a ParseState for rewriting the view definition query */
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ initStringInfo(&str);
+
+ for (i = 0; i < num_tuplestores; i++)
+ {
+ if (i > 0)
+ appendStringInfo(&str, " UNION ALL ");
+
+ appendStringInfo(&str,
+ " SELECT * FROM %s",
+ make_delta_enr_name(is_new ? "new" : "old", relid, i));
+ }
+
+ raw = (RawStmt*)linitial(raw_parser(str.data, RAW_PARSE_DEFAULT));
+ sub = transformStmt(pstate, raw->stmt);
+
+ /*
+ * Update the subquery so that it represent the combined transition
+ * table. Note that we leave the security_barrier and securityQuals
+ * fields so that the subquery relation can be protected by the RLS
+ * policy as same as the modified table.
+ */
+ rte->rtekind = RTE_SUBQUERY;
+ rte->subquery = sub;
+
+ return rte;
+}
+
+/*
+ * rewrite_query_for_counting
+ *
+ * Rewrite query for counting duplicated tuples.
+ */
+static Query *
+rewrite_query_for_counting(Query *query, ParseState *pstate)
+{
+ TargetEntry *tle_count;
+ FuncCall *fn;
+ Node *node;
+
+ /* Add count(*) for counting distinct tuples in views */
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+ fn->agg_star = true;
+ if (!query->groupClause && !query->hasAggs)
+ query->groupClause = transformDistinctClause(NULL, &query->targetList, query->sortClause, false);
+
+ node = ParseFuncOrColumn(pstate, fn->funcname, NIL, NULL, fn, false, -1);
+
+ tle_count = makeTargetEntry((Expr *) node,
+ list_length(query->targetList) + 1,
+ pstrdup("__ivm_count__"),
+ false);
+ query->targetList = lappend(query->targetList, tle_count);
+ query->hasAggs = true;
+
+ return query;
+}
+
+/*
+ * calc_delta
+ *
+ * Calculate view deltas generated under the modification of a table specified
+ * by the RTE index.
+ */
+static void
+calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
+ DestReceiver *dest_old, DestReceiver *dest_new,
+ TupleDesc *tupdesc_old, TupleDesc *tupdesc_new,
+ QueryEnvironment *queryEnv)
+{
+ ListCell *lc = list_nth_cell(query->rtable, rte_index - 1);
+ RangeTblEntry *rte = (RangeTblEntry *) lfirst(lc);
+
+ in_delta_calculation = true;
+
+ /* Generate old delta */
+ if (list_length(table->old_tuplestores) > 0)
+ {
+ /* Replace the modified table with the old delta table and calculate the old view delta. */
+ replace_rte_with_delta(rte, table, false, queryEnv);
+ refresh_matview_datafill(dest_old, query, queryEnv, tupdesc_old, "");
+ }
+
+ /* Generate new delta */
+ if (list_length(table->new_tuplestores) > 0)
+ {
+ /* Replace the modified table with the new delta table and calculate the new view delta*/
+ replace_rte_with_delta(rte, table, true, queryEnv);
+ refresh_matview_datafill(dest_new, query, queryEnv, tupdesc_new, "");
+ }
+
+ in_delta_calculation = false;
+}
+
+/*
+ * rewrite_query_for_postupdate_state
+ *
+ * Rewrite the query so that the specified base table's RTEs will represent
+ * "post-update" state of tables. This is called after the view delta
+ * calculation due to changes on this table finishes.
+ */
+static Query*
+rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte_index)
+{
+ ListCell *lc = list_nth_cell(query->rtable, rte_index - 1);
+
+ /* Retore the original RTE */
+ lfirst(lc) = table->original_rte;
+
+ return query;
+}
+
+/*
+ * apply_delta
+ *
+ * Apply deltas to the materialized view. In outer join cases, this requires
+ * the view maintenance graph.
+ */
+static void
+apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
+ TupleDesc tupdesc_old, TupleDesc tupdesc_new,
+ Query *query)
+{
+ StringInfoData querybuf;
+ StringInfoData target_list_buf;
+ Relation matviewRel;
+ char *matviewname;
+ ListCell *lc;
+ int i;
+ List *keys = NIL;
+
+
+ /*
+ * get names of the materialized view and delta tables
+ */
+
+ matviewRel = table_open(matviewOid, NoLock);
+ matviewname = quote_qualified_identifier(get_namespace_name(RelationGetNamespace(matviewRel)),
+ RelationGetRelationName(matviewRel));
+
+ /*
+ * Build parts of the maintenance queries
+ */
+
+ initStringInfo(&querybuf);
+ initStringInfo(&target_list_buf);
+
+ /* build string of target list */
+ for (i = 0; i < matviewRel->rd_att->natts; i++)
+ {
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
+
+ if (i != 0)
+ appendStringInfo(&target_list_buf, ", ");
+ appendStringInfo(&target_list_buf, "%s", quote_qualified_identifier(NULL, resname));
+ }
+
+ i = 0;
+ foreach (lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+
+ i++;
+
+ if (tle->resjunk)
+ continue;
+
+ keys = lappend(keys, attr);
+ }
+
+ /* Start maintaining the materialized view. */
+ OpenMatViewIncrementalMaintenance();
+
+ /* Open SPI context. */
+ if (SPI_connect() != SPI_OK_CONNECT)
+ elog(ERROR, "SPI_connect failed");
+
+ /* For tuple deletion */
+ if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
+ {
+ EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ int rc;
+
+ /* convert tuplestores to ENR, and register for SPI */
+ enr->md.name = pstrdup(OLD_DELTA_ENRNAME);
+ enr->md.reliddesc = InvalidOid;
+ enr->md.tupdesc = tupdesc_old;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(old_tuplestores);
+ enr->reldata = old_tuplestores;
+
+ rc = SPI_register_relation(enr);
+ if (rc != SPI_OK_REL_REGISTER)
+ elog(ERROR, "SPI_register failed");
+
+ apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+
+ }
+ /* For tuple insertion */
+ if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
+ {
+ EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ int rc;
+
+ /* convert tuplestores to ENR, and register for SPI */
+ enr->md.name = pstrdup(NEW_DELTA_ENRNAME);
+ enr->md.reliddesc = InvalidOid;
+ enr->md.tupdesc = tupdesc_new;;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(new_tuplestores);
+ enr->reldata = new_tuplestores;
+
+ rc = SPI_register_relation(enr);
+ if (rc != SPI_OK_REL_REGISTER)
+ elog(ERROR, "SPI_register failed");
+
+ /* apply new delta */
+ apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
+ }
+
+ /* We're done maintaining the materialized view. */
+ CloseMatViewIncrementalMaintenance();
+
+ table_close(matviewRel, NoLock);
+
+ /* Close SPI context. */
+ if (SPI_finish() != SPI_OK_FINISH)
+ elog(ERROR, "SPI_finish failed");
+}
+
+/*
+ * apply_old_delta
+ *
+ * Execute a query for applying a delta table given by deltname_old
+ * which contains tuples to be deleted from to a materialized view given by
+ * matviewname. This is used when counting is not required.
+ */
+static void
+apply_old_delta(const char *matviewname, const char *deltaname_old,
+ List *keys)
+{
+ StringInfoData querybuf;
+ StringInfoData keysbuf;
+ char *match_cond;
+ ListCell *lc;
+
+ /* build WHERE condition for searching tuples to be deleted */
+ match_cond = get_matching_condition_string(keys);
+
+ /* build string of keys list */
+ initStringInfo(&keysbuf);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&keysbuf, "%s", quote_qualified_identifier("mv", resname));
+ if (lnext(keys, lc))
+ appendStringInfo(&keysbuf, ", ");
+ }
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "DELETE FROM %s WHERE ctid IN ("
+ "SELECT tid FROM (SELECT pg_catalog.row_number() over (partition by %s) AS \"__ivm_row_number__\","
+ "mv.ctid AS tid,"
+ "diff.\"__ivm_count__\""
+ "FROM %s AS mv, %s AS diff "
+ "WHERE %s) v "
+ "WHERE v.\"__ivm_row_number__\" OPERATOR(pg_catalog.<=) v.\"__ivm_count__\")",
+ matviewname,
+ keysbuf.data,
+ matviewname, deltaname_old,
+ match_cond);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
+/*
+ * apply_new_delta
+ *
+ * Execute a query for applying a delta table given by deltname_new
+ * which contains tuples to be inserted into a materialized view given by
+ * matviewname. This is used when counting is not required.
+ */
+static void
+apply_new_delta(const char *matviewname, const char *deltaname_new,
+ StringInfo target_list)
+{
+ StringInfoData querybuf;
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "INSERT INTO %s (%s) SELECT %s FROM ("
+ "SELECT diff.*, pg_catalog.generate_series(1, diff.\"__ivm_count__\")"
+ " AS __ivm_generate_series__ "
+ "FROM %s AS diff) AS v",
+ matviewname, target_list->data, target_list->data,
+ deltaname_new);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_INSERT)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
+/*
+ * get_matching_condition_string
+ *
+ * Build a predicate string for looking for a tuple with given keys.
+ */
+static char *
+get_matching_condition_string(List *keys)
+{
+ StringInfoData match_cond;
+ ListCell *lc;
+
+ /* If there is no key columns, the condition is always true. */
+ if (keys == NIL)
+ return "true";
+
+ initStringInfo(&match_cond);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ char *mv_resname = quote_qualified_identifier("mv", resname);
+ char *diff_resname = quote_qualified_identifier("diff", resname);
+ Oid typid = attr->atttypid;
+
+ /* Considering NULL values, we can not use simple = operator. */
+ appendStringInfo(&match_cond, "(");
+ generate_equal(&match_cond, typid, mv_resname, diff_resname);
+ appendStringInfo(&match_cond, " OR (%s IS NULL AND %s IS NULL))",
+ mv_resname, diff_resname);
+
+ if (lnext(keys, lc))
+ appendStringInfo(&match_cond, " AND ");
+ }
+
+ return match_cond.data;
+}
+
+/*
+ * generate_equals
+ *
+ * Generate an equality clause using given operands' default equality
+ * operator.
+ */
+static void
+generate_equal(StringInfo querybuf, Oid opttype,
+ const char *leftop, const char *rightop)
+{
+ TypeCacheEntry *typentry;
+
+ typentry = lookup_type_cache(opttype, TYPECACHE_EQ_OPR);
+ if (!OidIsValid(typentry->eq_opr))
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_FUNCTION),
+ errmsg("could not identify an equality operator for type %s",
+ format_type_be_qualified(opttype))));
+
+ generate_operator_clause(querybuf,
+ leftop, opttype,
+ typentry->eq_opr,
+ rightop, opttype);
+}
+
+/*
+ * mv_InitHashTables
+ */
+static void
+mv_InitHashTables(void)
+{
+ HASHCTL ctl;
+
+ memset(&ctl, 0, sizeof(ctl));
+ ctl.keysize = sizeof(Oid);
+ ctl.entrysize = sizeof(MV_TriggerHashEntry);
+ mv_trigger_info = hash_create("MV trigger info",
+ MV_INIT_QUERYHASHSIZE,
+ &ctl, HASH_ELEM | HASH_BLOBS);
+}
+
+/*
+ * AtAbort_IVM
+ *
+ * Clean up hash entries for all materialized views. This is called at
+ * transaction abort.
+ */
+void
+AtAbort_IVM()
+{
+ HASH_SEQ_STATUS seq;
+ MV_TriggerHashEntry *entry;
+
+ if (mv_trigger_info)
+ {
+ hash_seq_init(&seq, mv_trigger_info);
+ while ((entry = hash_seq_search(&seq)) != NULL)
+ clean_up_IVM_hash_entry(entry, true);
+ }
+ in_delta_calculation = false;
+}
+
+/*
+ * clean_up_IVM_hash_entry
+ *
+ * Clean up tuple stores and hash entries for a materialized view after its
+ * maintenance finished.
+ */
+static void
+clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort)
+{
+ bool found;
+ ListCell *lc;
+
+ foreach(lc, entry->tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc);
+
+ list_free(table->old_tuplestores);
+ list_free(table->new_tuplestores);
+ if (!is_abort)
+ {
+ ExecDropSingleTupleTableSlot(table->slot);
+ table_close(table->rel, NoLock);
+ }
+ }
+ list_free(entry->tables);
+
+ if (!is_abort)
+ UnregisterSnapshot(entry->snapshot);
+
+ hash_search(mv_trigger_info, (void *) &entry->matview_id, HASH_REMOVE, &found);
+}
+
+/*
+ * isIvmName
+ *
+ * Check if this is a IVM hidden column from the name.
+ */
+bool
+isIvmName(const char *s)
+{
+ if (s)
+ return (strncmp(s, "__ivm_", 6) == 0);
+ return false;
+}
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index 6996073989..1cca12e049 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -12043,4 +12043,14 @@
proname => 'any_value_transfn', prorettype => 'anyelement',
proargtypes => 'anyelement anyelement', prosrc => 'any_value_transfn' },
+# IVM
+{ oid => '786', descr => 'ivm trigger (before)',
+ proname => 'IVM_immediate_before', provolatile => 'v', prorettype => 'trigger',
+ proargtypes => '', prosrc => 'IVM_immediate_before' },
+{ oid => '787', descr => 'ivm trigger (after)',
+ proname => 'IVM_immediate_maintenance', provolatile => 'v', prorettype => 'trigger',
+ proargtypes => '', prosrc => 'IVM_immediate_maintenance' },
+{ oid => '788', descr => 'ivm filetring ',
+ proname => 'ivm_visible_in_prestate', provolatile => 's', prorettype => 'bool',
+ proargtypes => 'oid tid oid', prosrc => 'ivm_visible_in_prestate' },
]
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 3647f96f73..09a64fa2e5 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -16,6 +16,7 @@
#include "catalog/objectaddress.h"
#include "nodes/params.h"
+#include "nodes/pathnodes.h"
#include "parser/parse_node.h"
#include "tcop/dest.h"
#include "utils/queryenvironment.h"
@@ -25,6 +26,9 @@ extern ObjectAddress ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *st
ParamListInfo params, QueryEnvironment *queryEnv,
QueryCompletion *qc);
+extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
+extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
+
extern int GetIntoRelEFlags(IntoClause *intoClause);
extern DestReceiver *CreateIntoRelDestReceiver(IntoClause *intoClause);
diff --git a/src/include/commands/matview.h b/src/include/commands/matview.h
index 9eaa6212a1..504b83a446 100644
--- a/src/include/commands/matview.h
+++ b/src/include/commands/matview.h
@@ -15,6 +15,7 @@
#define MATVIEW_H
#include "catalog/objectaddress.h"
+#include "fmgr.h"
#include "nodes/params.h"
#include "nodes/parsenodes.h"
#include "tcop/dest.h"
@@ -23,6 +24,8 @@
extern void SetMatViewPopulatedState(Relation relation, bool newstate);
+extern void SetMatViewIVMState(Relation relation, bool newstate);
+
extern ObjectAddress ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
ParamListInfo params, QueryCompletion *qc);
@@ -30,4 +33,10 @@ extern DestReceiver *CreateTransientRelDestReceiver(Oid transientoid);
extern bool MatViewIncrementalMaintenanceIsEnabled(void);
+extern Datum IVM_immediate_before(PG_FUNCTION_ARGS);
+extern Datum IVM_immediate_maintenance(PG_FUNCTION_ARGS);
+extern Datum IVM_visible_in_prestate(PG_FUNCTION_ARGS);
+extern void AtAbort_IVM(void);
+extern bool isIvmName(const char *s);
+
#endif /* MATVIEW_H */
--
2.25.1
v28-0007-Add-DISTINCT-support-for-IVM.patchtext/x-diff; name=v28-0007-Add-DISTINCT-support-for-IVM.patchDownload
From 64a72f4edc4392d8fbca111d549a4a8e92bc56c1 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 19:08:51 +0900
Subject: [PATCH v28 07/11] Add DISTINCT support for IVM
When IMMV is created with DISTINCT, multiplicity of tuples is
counted and stored in "__ivm_count__" column, which is a hidden
column of IMMV. The value in __ivm_count__ is updated when IMMV
is maintained incrementally. A tuple in IMMV can be removed if
and only if the count becomes zero.
---
src/backend/commands/createas.c | 141 ++++++++++++++++++++------
src/backend/commands/indexcmds.c | 40 ++++++++
src/backend/commands/matview.c | 148 ++++++++++++++++++++++++++--
src/backend/commands/tablecmds.c | 9 ++
src/backend/parser/parse_relation.c | 18 +++-
src/backend/rewrite/rewriteDefine.c | 3 +-
src/include/commands/createas.h | 2 +
src/include/nodes/parsenodes.h | 1 +
8 files changed, 317 insertions(+), 45 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index 415f110516..076f35ee6b 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -53,6 +53,7 @@
#include "parser/parser.h"
#include "parser/parsetree.h"
#include "parser/parse_clause.h"
+#include "parser/parse_func.h"
#include "rewrite/rewriteHandler.h"
#include "storage/smgr.h"
#include "tcop/tcopprot.h"
@@ -309,6 +310,9 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
errhint("functions must be marked IMMUTABLE")));
check_ivm_restriction((Node *) query);
+
+ /* For IMMV, we need to rewrite matview query */
+ query = rewriteQueryForIMMV(query, into->colNames);
}
if (into->skipData)
@@ -413,6 +417,49 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
return address;
}
+/*
+ * rewriteQueryForIMMV -- rewrite view definition query for IMMV
+ *
+ * count(*) is added for counting distinct tuples in views.
+ */
+Query *
+rewriteQueryForIMMV(Query *query, List *colNames)
+{
+ Query *rewritten;
+
+ Node *node;
+ ParseState *pstate = make_parsestate(NULL);
+ FuncCall *fn;
+
+ rewritten = copyObject(query);
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ /*
+ * Convert DISTINCT to GROUP BY and add count(*) for counting distinct
+ * tuples in views.
+ */
+ if (rewritten->distinctClause)
+ {
+ TargetEntry *tle;
+
+ rewritten->groupClause = transformDistinctClause(NULL, &rewritten->targetList, rewritten->sortClause, false);
+
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+ fn->agg_star = true;
+
+ node = ParseFuncOrColumn(pstate, fn->funcname, NIL, NULL, fn, false, -1);
+
+ tle = makeTargetEntry((Expr *) node,
+ list_length(rewritten->targetList) + 1,
+ pstrdup("__ivm_count__"),
+ false);
+ rewritten->targetList = lappend(rewritten->targetList, tle);
+ rewritten->hasAggs = true;
+ }
+
+ return rewritten;
+}
+
/*
* GetIntoRelEFlags --- compute executor flags needed for CREATE TABLE AS
*
@@ -536,7 +583,8 @@ intorel_startup(DestReceiver *self, int operation, TupleDesc typeinfo)
ColumnDef *col;
char *colname;
- if (lc)
+ /* Don't override hidden columns added for IVM */
+ if (lc && !isIvmName(NameStr(attribute->attname)))
{
colname = strVal(lfirst(lc));
lc = lnext(into->colNames, lc);
@@ -940,10 +988,6 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view")));
- if (qry->distinctClause)
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("DISTINCT is not supported on incrementally maintainable materialized view")));
if (qry->hasDistinctOn)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
@@ -1090,12 +1134,18 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
char idxname[NAMEDATALEN];
List *indexoidlist = RelationGetIndexList(matviewRel);
ListCell *indexoidscan;
- Bitmapset *key_attnos;
snprintf(idxname, sizeof(idxname), "%s_index", RelationGetRelationName(matviewRel));
index = makeNode(IndexStmt);
+ /*
+ * We consider null values not distinct to make sure that views with DISTINCT
+ * or GROUP BY don't contain multiple NULL rows when NULL is inserted to
+ * a base table concurrently.
+ */
+ index->nulls_not_distinct = true;
+
index->unique = true;
index->primary = false;
index->isconstraint = false;
@@ -1122,41 +1172,68 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
index->concurrent = false;
index->if_not_exists = false;
- /* create index on the base tables' primary key columns */
- key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
- if (key_attnos)
+ if (query->distinctClause)
{
+ /* create unique constraint on all columns */
foreach(lc, query->targetList)
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
-
- if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
- {
- IndexElem *iparam;
-
- iparam = makeNode(IndexElem);
- iparam->name = pstrdup(NameStr(attr->attname));
- iparam->expr = NULL;
- iparam->indexcolname = NULL;
- iparam->collation = NIL;
- iparam->opclass = NIL;
- iparam->opclassopts = NIL;
- iparam->ordering = SORTBY_DEFAULT;
- iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
- index->indexParams = lappend(index->indexParams, iparam);
- }
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
}
}
else
{
- /* create no index, just notice that an appropriate index is necessary for efficient IVM */
- ereport(NOTICE,
- (errmsg("could not create an index on materialized view \"%s\" automatically",
- RelationGetRelationName(matviewRel)),
- errdetail("This target list does not have all the primary key columns. "),
- errhint("Create an index on the materialized view for efficient incremental maintenance.")));
- return;
+ Bitmapset *key_attnos;
+
+ /* create index on the base tables' primary key columns */
+ key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
+ if (key_attnos)
+ {
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ }
+ else
+ {
+ /* create no index, just notice that an appropriate index is necessary for efficient IVM */
+ ereport(NOTICE,
+ (errmsg("could not create an index on materialized view \"%s\" automatically",
+ RelationGetRelationName(matviewRel)),
+ errdetail("This target list does not have all the primary key columns, "
+ "or this view does not contain DISTINCT clause."),
+ errhint("Create an index on the materialized view for efficient incremental maintenance.")));
+ return;
+ }
}
/* If we have a compatible index, we don't need to create another. */
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index a5168c9f09..480c3a00ed 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -39,6 +39,7 @@
#include "commands/dbcommands.h"
#include "commands/defrem.h"
#include "commands/event_trigger.h"
+#include "commands/matview.h"
#include "commands/progress.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
@@ -1090,6 +1091,45 @@ DefineIndex(Oid relationId,
safe_index = indexInfo->ii_Expressions == NIL &&
indexInfo->ii_Predicate == NIL;
+ /*
+ * We disallow unique indexes on IVM columns of IMMVs.
+ */
+ if (RelationIsIVM(rel) && stmt->unique)
+ {
+ for (int i = 0; i < indexInfo->ii_NumIndexKeyAttrs; i++)
+ {
+ AttrNumber attno = indexInfo->ii_IndexAttrNumbers[i];
+ if (attno > 0)
+ {
+ char *name = NameStr(TupleDescAttr(rel->rd_att, attno - 1)->attname);
+ if (name && isIvmName(name))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("unique index creation on IVM columns is not supported")));
+ }
+ }
+
+ if (indexInfo->ii_Expressions)
+ {
+ Bitmapset *indexattrs = NULL;
+ int varno = -1;
+
+ pull_varattnos((Node *) indexInfo->ii_Expressions, 1, &indexattrs);
+
+ while ((varno = bms_next_member(indexattrs, varno)) >= 0)
+ {
+ int attno = varno + FirstLowInvalidHeapAttributeNumber;
+ char *name = NameStr(TupleDescAttr(rel->rd_att, attno - 1)->attname);
+ if (name && isIvmName(name))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("unique index creation on IVM columns is not supported")));
+ }
+
+ }
+ }
+
+
/*
* Report index creation if appropriate (delay this till after most of the
* error checks)
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index fd9d0d99ae..6d8382180a 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -152,11 +152,15 @@ static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *
static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
- Query *query);
+ Query *query, bool use_count, char *count_colname);
static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
+static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
+ List *keys, const char *count_colname);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
+static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
+ List *keys, StringInfo target_list, const char* count_colname);
static char *get_matching_condition_string(List *keys);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
@@ -271,6 +275,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
Oid matviewOid;
Relation matviewRel;
Query *dataQuery;
+ Query *viewQuery;
Oid tableSpace;
Oid relowner;
Oid OIDNewHeap;
@@ -331,8 +336,13 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
"CONCURRENTLY", "WITH NO DATA")));
- dataQuery = get_matview_query(matviewRel);
+ viewQuery = get_matview_query(matviewRel);
+ /* For IMMV, we need to rewrite matview query */
+ if (!stmt->skipData && RelationIsIVM(matviewRel))
+ dataQuery = rewriteQueryForIMMV(viewQuery,NIL);
+ else
+ dataQuery = viewQuery;
/*
* Check that there is a unique index with no WHERE clause on one or more
@@ -512,8 +522,8 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
if (!stmt->skipData && RelationIsIVM(matviewRel) && !oldPopulated)
{
- CreateIndexOnIMMV(dataQuery, matviewRel);
- CreateIvmTriggersOnBaseTables(dataQuery, matviewOid);
+ CreateIndexOnIMMV(viewQuery, matviewRel);
+ CreateIvmTriggersOnBaseTables(viewQuery, matviewOid);
}
table_close(matviewRel, NoLock);
@@ -1513,6 +1523,13 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
int rte_index = lfirst_int(lc2);
TupleDesc tupdesc_old;
TupleDesc tupdesc_new;
+ bool use_count = false;
+ char *count_colname = NULL;
+
+ count_colname = pstrdup("__ivm_count__");
+
+ if (query->distinctClause)
+ use_count = true;
/* calculate delta tables */
calc_delta(table, rte_index, rewritten, dest_old, dest_new,
@@ -1525,7 +1542,8 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
{
/* apply the delta tables to the materialized view */
apply_delta(matviewOid, old_tuplestore, new_tuplestore,
- tupdesc_old, tupdesc_new, query);
+ tupdesc_old, tupdesc_new, query, use_count,
+ count_colname);
}
PG_CATCH();
{
@@ -1998,7 +2016,7 @@ rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte
static void
apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
- Query *query)
+ Query *query, bool use_count, char *count_colname)
{
StringInfoData querybuf;
StringInfoData target_list_buf;
@@ -2074,7 +2092,12 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (rc != SPI_OK_REL_REGISTER)
elog(ERROR, "SPI_register failed");
- apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+ if (use_count)
+ /* apply old delta and get rows to be recalculated */
+ apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
+ keys, count_colname);
+ else
+ apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
}
/* For tuple insertion */
@@ -2096,7 +2119,11 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_register failed");
/* apply new delta */
- apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
+ if (use_count)
+ apply_new_delta_with_count(matviewname, NEW_DELTA_ENRNAME,
+ keys, &target_list_buf, count_colname);
+ else
+ apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
}
/* We're done maintaining the materialized view. */
@@ -2109,6 +2136,51 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_finish failed");
}
+/*
+ * apply_old_delta_with_count
+ *
+ * Execute a query for applying a delta table given by deltname_old
+ * which contains tuples to be deleted from to a materialized view given by
+ * matviewname. This is used when counting is required, that is, the view
+ * has aggregate or distinct.
+ */
+static void
+apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
+ List *keys, const char *count_colname)
+{
+ StringInfoData querybuf;
+ char *match_cond;
+
+ /* build WHERE condition for searching tuples to be deleted */
+ match_cond = get_matching_condition_string(keys);
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "WITH t AS (" /* collecting tid of target tuples in the view */
+ "SELECT diff.%s, " /* count column */
+ "(diff.%s OPERATOR(pg_catalog.=) mv.%s) AS for_dlt, "
+ "mv.ctid "
+ "FROM %s AS mv, %s AS diff "
+ "WHERE %s" /* tuple matching condition */
+ "), updt AS (" /* update a tuple if this is not to be deleted */
+ "UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
+ "FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
+ ")"
+ /* delete a tuple if this is to be deleted */
+ "DELETE FROM %s AS mv USING t "
+ "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
+ count_colname,
+ count_colname, count_colname,
+ matviewname, deltaname_old,
+ match_cond,
+ matviewname, count_colname, count_colname, count_colname,
+ matviewname);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
/*
* apply_old_delta
*
@@ -2158,6 +2230,66 @@ apply_old_delta(const char *matviewname, const char *deltaname_old,
elog(ERROR, "SPI_exec failed: %s", querybuf.data);
}
+/*
+ * apply_new_delta_with_count
+ *
+ * Execute a query for applying a delta table given by deltname_new
+ * which contains tuples to be inserted into a materialized view given by
+ * matviewname. This is used when counting is required, that is, the view
+ * has aggregate or distinct. Also, when a table in EXISTS sub queries
+ * is modified.
+ */
+static void
+apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
+ List *keys, StringInfo target_list, const char* count_colname)
+{
+ StringInfoData querybuf;
+ StringInfoData returning_keys;
+ ListCell *lc;
+ char *match_cond = "";
+
+ /* build WHERE condition for searching tuples to be updated */
+ match_cond = get_matching_condition_string(keys);
+
+ /* build string of keys list */
+ initStringInfo(&returning_keys);
+ if (keys)
+ {
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&returning_keys, "%s", quote_qualified_identifier("mv", resname));
+ if (lnext(keys, lc))
+ appendStringInfo(&returning_keys, ", ");
+ }
+ }
+ else
+ appendStringInfo(&returning_keys, "NULL");
+
+ /* Search for matching tuples from the view and update if found or insert if not. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "WITH updt AS (" /* update a tuple if this exists in the view */
+ "UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.+) diff.%s "
+ "FROM %s AS diff "
+ "WHERE %s " /* tuple matching condition */
+ "RETURNING %s" /* returning keys of updated tuples */
+ ") INSERT INTO %s (%s)" /* insert a new tuple if this doesn't existw */
+ "SELECT %s FROM %s AS diff "
+ "WHERE NOT EXISTS (SELECT 1 FROM updt AS mv WHERE %s);",
+ matviewname, count_colname, count_colname, count_colname,
+ deltaname_new,
+ match_cond,
+ returning_keys.data,
+ matviewname, target_list->data,
+ target_list->data, deltaname_new,
+ match_cond);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_INSERT)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
/*
* apply_new_delta
*
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 4d49d70c33..25ff2a23db 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -53,6 +53,7 @@
#include "commands/cluster.h"
#include "commands/comment.h"
#include "commands/defrem.h"
+#include "commands/matview.h"
#include "commands/event_trigger.h"
#include "commands/policy.h"
#include "commands/sequence.h"
@@ -3548,6 +3549,14 @@ renameatt_internal(Oid myrelid,
targetrelation = relation_open(myrelid, AccessExclusiveLock);
renameatt_check(myrelid, RelationGetForm(targetrelation), recursing);
+ /*
+ * Don't rename IVM columns.
+ */
+ if (RelationIsIVM(targetrelation) && isIvmName(oldattname))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("IVM column can not be renamed")));
+
/*
* if the 'recurse' flag is set then we are supposed to rename this
* attribute in all classes that inherit from 'relname' (as well as in
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index 41d60494b9..f516ac91e2 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -36,6 +36,7 @@
#include "utils/rel.h"
#include "utils/syscache.h"
#include "utils/varlena.h"
+#include "commands/matview.h"
/*
@@ -97,7 +98,7 @@ static void expandTupleDesc(TupleDesc tupdesc, Alias *eref,
int count, int offset,
int rtindex, int sublevels_up,
int location, bool include_dropped,
- List **colnames, List **colvars);
+ List **colnames, List **colvars, bool is_ivm);
static int specialAttNum(const char *attname);
static bool rte_visible_if_lateral(ParseState *pstate, RangeTblEntry *rte);
static bool rte_visible_if_qualified(ParseState *pstate, RangeTblEntry *rte);
@@ -1501,6 +1502,7 @@ addRangeTableEntry(ParseState *pstate,
rte->relid = RelationGetRelid(rel);
rte->relkind = rel->rd_rel->relkind;
rte->rellockmode = lockmode;
+ rte->relisivm = rel->rd_rel->relisivm;
/*
* Build the list of effective column names using user-supplied aliases
@@ -1586,6 +1588,7 @@ addRangeTableEntryForRelation(ParseState *pstate,
rte->relid = RelationGetRelid(rel);
rte->relkind = rel->rd_rel->relkind;
rte->rellockmode = lockmode;
+ rte->relisivm = rel->rd_rel->relisivm;
/*
* Build the list of effective column names using user-supplied aliases
@@ -2757,7 +2760,7 @@ expandRTE(RangeTblEntry *rte, int rtindex, int sublevels_up,
expandTupleDesc(tupdesc, rte->eref,
rtfunc->funccolcount, atts_done,
rtindex, sublevels_up, location,
- include_dropped, colnames, colvars);
+ include_dropped, colnames, colvars, false);
}
else if (functypclass == TYPEFUNC_SCALAR)
{
@@ -3025,7 +3028,7 @@ expandRelation(Oid relid, Alias *eref, int rtindex, int sublevels_up,
expandTupleDesc(rel->rd_att, eref, rel->rd_att->natts, 0,
rtindex, sublevels_up,
location, include_dropped,
- colnames, colvars);
+ colnames, colvars, RelationIsIVM(rel));
relation_close(rel, AccessShareLock);
}
@@ -3042,7 +3045,7 @@ static void
expandTupleDesc(TupleDesc tupdesc, Alias *eref, int count, int offset,
int rtindex, int sublevels_up,
int location, bool include_dropped,
- List **colnames, List **colvars)
+ List **colnames, List **colvars, bool is_ivm)
{
ListCell *aliascell;
int varattno;
@@ -3055,6 +3058,9 @@ expandTupleDesc(TupleDesc tupdesc, Alias *eref, int count, int offset,
{
Form_pg_attribute attr = TupleDescAttr(tupdesc, varattno);
+ if (is_ivm && isIvmName(NameStr(attr->attname)) && !MatViewIncrementalMaintenanceIsEnabled())
+ continue;
+
if (attr->attisdropped)
{
if (include_dropped)
@@ -3217,6 +3223,10 @@ expandNSItemAttrs(ParseState *pstate, ParseNamespaceItem *nsitem,
Var *varnode = (Var *) lfirst(var);
TargetEntry *te;
+ /* if transform * into columnlist with IMMV, remove IVM columns */
+ if (rte->relisivm && isIvmName(label) && !MatViewIncrementalMaintenanceIsEnabled())
+ continue;
+
te = makeTargetEntry((Expr *) varnode,
(AttrNumber) pstate->p_next_resno++,
label,
diff --git a/src/backend/rewrite/rewriteDefine.c b/src/backend/rewrite/rewriteDefine.c
index e36fc72e1e..f6dc7ba202 100644
--- a/src/backend/rewrite/rewriteDefine.c
+++ b/src/backend/rewrite/rewriteDefine.c
@@ -621,7 +621,8 @@ checkRuleResultList(List *targetList, TupleDesc resultDesc, bool isSelect,
attr->atttypmod))));
}
- if (i != resultDesc->natts)
+ /* No check for materialized views since this could have special columns for IVM */
+ if ((!isSelect || requireColumnNameMatch) && i != resultDesc->natts)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
isSelect ?
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 09a64fa2e5..76a7873ebf 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -29,6 +29,8 @@ extern ObjectAddress ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *st
extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
+extern Query *rewriteQueryForIMMV(Query *query, List *colNames);
+
extern int GetIntoRelEFlags(IntoClause *intoClause);
extern DestReceiver *CreateIntoRelDestReceiver(IntoClause *intoClause);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 0ca298f5a1..43c4ed49f1 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1074,6 +1074,7 @@ typedef struct RangeTblEntry
int rellockmode; /* lock level that query requires on the rel */
struct TableSampleClause *tablesample; /* sampling info, or NULL */
Index perminfoindex;
+ bool relisivm;
/*
* Fields valid for a subquery RTE (else NULL):
--
2.25.1
v28-0008-Add-aggregates-support-in-IVM.patchtext/x-diff; name=v28-0008-Add-aggregates-support-in-IVM.patchDownload
From 27b652cc15b785e3dcbd9cadd5ea10712f2a2a6d Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 20:46:32 +0900
Subject: [PATCH v28 08/11] Add aggregates support in IVM
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit
count, sum, adn avg are supported.
As a restriction, expressions specified in GROUP BY must appear in
the target list because tuples to be updated in IMMV are identified
by using this group key. However, in the case of aggregates without
GROUP BY, there is only one tuple in the view, so keys are not uses
to identify tuples.
When creating a IMMV, in addition to __ivm_count column, some hidden
columns for each aggregate are added to the target list. For example,
names of these hidden columns are ivm_count_avg and ivm_sum_avg for
the average function, and so on.
When a base table is modified, the aggregated values and related
hidden columns are also updated as well as __ivm_count__. The
way of update depends the kind of aggregate function. Specifically,
sum and count are updated by simply adding or subtracting delta value
calculated from delta tables. avg is updated by using values of sum
and count stored in views as hidden columns and deltas calculated
from delta tables.
About aggregate functions except "count()" (sum and avg), NULLs in input
values are ignored, and the result of aggegate should be NULL when no
rows are selected. To support this specification, the numbers of non-NULL
input values are counted and stored in hidden columns. In the case of
count(), count(x) returns zero when no rows are selected, but count(*)
doesn't ignore NULL input.
---
src/backend/commands/createas.c | 264 +++++++++++++++++--
src/backend/commands/matview.c | 433 ++++++++++++++++++++++++++++++--
src/include/commands/createas.h | 1 +
3 files changed, 661 insertions(+), 37 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index 076f35ee6b..c8aa558f2e 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -54,14 +54,19 @@
#include "parser/parsetree.h"
#include "parser/parse_clause.h"
#include "parser/parse_func.h"
+#include "parser/parse_type.h"
#include "rewrite/rewriteHandler.h"
+#include "rewrite/rewriteManip.h"
#include "storage/smgr.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
#include "utils/lsyscache.h"
+#include "utils/regproc.h"
+#include "utils/fmgroids.h"
#include "utils/rel.h"
#include "utils/rls.h"
#include "utils/snapmgr.h"
+#include "utils/syscache.h"
typedef struct
{
@@ -75,6 +80,11 @@ typedef struct
BulkInsertState bistate; /* bulk insert state */
} DR_intorel;
+typedef struct
+{
+ bool has_agg;
+} check_ivm_restriction_context;
+
/* utility functions for CTAS definition creation */
static ObjectAddress create_ctas_internal(List *attrList, IntoClause *into);
static ObjectAddress create_ctas_nodata(List *tlist, IntoClause *into);
@@ -89,8 +99,9 @@ static void CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid mat
Relids *relids, bool ex_lock);
static void CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock);
static void check_ivm_restriction(Node *node);
-static bool check_ivm_restriction_walker(Node *node, void *context);
+static bool check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context);
static Bitmapset *get_primary_key_attnos_from_query(Query *query, List **constraintList);
+static bool check_aggregate_supports_ivm(Oid aggfnoid);
/*
* create_ctas_internal
@@ -421,6 +432,7 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
* rewriteQueryForIMMV -- rewrite view definition query for IMMV
*
* count(*) is added for counting distinct tuples in views.
+ * Also, additional hidden columns are added for aggregate values.
*/
Query *
rewriteQueryForIMMV(Query *query, List *colNames)
@@ -434,16 +446,49 @@ rewriteQueryForIMMV(Query *query, List *colNames)
rewritten = copyObject(query);
pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
- /*
- * Convert DISTINCT to GROUP BY and add count(*) for counting distinct
- * tuples in views.
- */
- if (rewritten->distinctClause)
+ /* group keys must be in targetlist */
+ if (rewritten->groupClause)
{
- TargetEntry *tle;
+ ListCell *lc;
+ foreach(lc, rewritten->groupClause)
+ {
+ SortGroupClause *scl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(scl, rewritten->targetList);
+ if (tle->resjunk)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUP BY expression not appearing in select list is not supported on incrementally maintainable materialized view")));
+ }
+ }
+ /* Convert DISTINCT to GROUP BY. count(*) will be added afterward. */
+ else if (!rewritten->hasAggs && rewritten->distinctClause)
rewritten->groupClause = transformDistinctClause(NULL, &rewritten->targetList, rewritten->sortClause, false);
+ /* Add additional columns for aggregate values */
+ if (rewritten->hasAggs)
+ {
+ ListCell *lc;
+ List *aggs = NIL;
+ AttrNumber next_resno = list_length(rewritten->targetList) + 1;
+
+ foreach(lc, rewritten->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ char *resname = (colNames == NIL || foreach_current_index(lc) >= list_length(colNames) ?
+ tle->resname : strVal(list_nth(colNames, tle->resno - 1)));
+
+ if (IsA(tle->expr, Aggref))
+ makeIvmAggColumn(pstate, (Aggref *) tle->expr, resname, &next_resno, &aggs);
+ }
+ rewritten->targetList = list_concat(rewritten->targetList, aggs);
+ }
+
+ /* Add count(*) for counting distinct tuples in views */
+ if (rewritten->distinctClause || rewritten->hasAggs)
+ {
+ TargetEntry *tle;
+
fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
fn->agg_star = true;
@@ -460,6 +505,91 @@ rewriteQueryForIMMV(Query *query, List *colNames)
return rewritten;
}
+/*
+ * makeIvmAggColumn -- make additional aggregate columns for IVM
+ *
+ * For an aggregate column specified by aggref, additional aggregate columns
+ * are added, which are used to calculate the new aggregate value in IMMV.
+ * An additional aggregate columns has a name based on resname
+ * (ex. ivm_count_resname), and resno specified by next_resno. The created
+ * columns are returned to aggs, and the resno for the next column is also
+ * returned to next_resno.
+ *
+ * Currently, an additional count() is created for aggref other than count.
+ * In addition, sum() is created for avg aggregate column.
+ */
+void
+makeIvmAggColumn(ParseState *pstate, Aggref *aggref, char *resname, AttrNumber *next_resno, List **aggs)
+{
+ TargetEntry *tle_count;
+ Node *node;
+ FuncCall *fn;
+ Const *dmy_arg = makeConst(INT4OID,
+ -1,
+ InvalidOid,
+ sizeof(int32),
+ Int32GetDatum(1),
+ false,
+ true); /* pass by value */
+ const char *aggname = get_func_name(aggref->aggfnoid);
+
+ /*
+ * For aggregate functions except count, add count() func with the same arg parameters.
+ * This count result is used for determining if the aggregate value should be NULL or not.
+ * Also, add sum() func for avg because we need to calculate an average value as sum/count.
+ *
+ * XXX: If there are same expressions explicitly in the target list, we can use this instead
+ * of adding new duplicated one.
+ */
+ if (strcmp(aggname, "count") != 0)
+ {
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+
+ /* Make a Func with a dummy arg, and then override this by the original agg's args. */
+ node = ParseFuncOrColumn(pstate, fn->funcname, list_make1(dmy_arg), NULL, fn, false, -1);
+ ((Aggref *)node)->args = aggref->args;
+
+ tle_count = makeTargetEntry((Expr *) node,
+ *next_resno,
+ pstrdup(makeObjectName("__ivm_count",resname, "_")),
+ false);
+ *aggs = lappend(*aggs, tle_count);
+ (*next_resno)++;
+ }
+ if (strcmp(aggname, "avg") == 0)
+ {
+ List *dmy_args = NIL;
+ ListCell *lc;
+ foreach(lc, aggref->aggargtypes)
+ {
+ Oid typeid = lfirst_oid(lc);
+ Type type = typeidType(typeid);
+
+ Const *con = makeConst(typeid,
+ -1,
+ typeTypeCollation(type),
+ typeLen(type),
+ (Datum) 0,
+ true,
+ typeByVal(type));
+ dmy_args = lappend(dmy_args, con);
+ ReleaseSysCache(type);
+ }
+ fn = makeFuncCall(SystemFuncName("sum"), NIL, COERCE_EXPLICIT_CALL, -1);
+
+ /* Make a Func with dummy args, and then override this by the original agg's args. */
+ node = ParseFuncOrColumn(pstate, fn->funcname, dmy_args, NULL, fn, false, -1);
+ ((Aggref *)node)->args = aggref->args;
+
+ tle_count = makeTargetEntry((Expr *) node,
+ *next_resno,
+ pstrdup(makeObjectName("__ivm_sum",resname, "_")),
+ false);
+ *aggs = lappend(*aggs, tle_count);
+ (*next_resno)++;
+ }
+}
+
/*
* GetIntoRelEFlags --- compute executor flags needed for CREATE TABLE AS
*
@@ -943,11 +1073,13 @@ CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock
static void
check_ivm_restriction(Node *node)
{
- check_ivm_restriction_walker(node, NULL);
+ check_ivm_restriction_context context = {false};
+
+ check_ivm_restriction_walker(node, &context);
}
static bool
-check_ivm_restriction_walker(Node *node, void *context)
+check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context)
{
if (node == NULL)
return false;
@@ -976,6 +1108,10 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("CTE is not supported on incrementally maintainable materialized view")));
+ if (qry->groupClause != NIL && !qry->hasAggs)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUP BY clause without aggregate is not supported on incrementally maintainable materialized view")));
if (qry->havingQual != NULL)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
@@ -1028,6 +1164,8 @@ check_ivm_restriction_walker(Node *node, void *context)
}
}
+ context->has_agg |= qry->hasAggs;
+
/* restrictions for rtable */
foreach(lc, qry->rtable)
{
@@ -1076,7 +1214,7 @@ check_ivm_restriction_walker(Node *node, void *context)
}
- query_tree_walker(qry, check_ivm_restriction_walker, NULL, QTW_IGNORE_RANGE_TABLE);
+ query_tree_walker(qry, check_ivm_restriction_walker, (void *) context, QTW_IGNORE_RANGE_TABLE);
break;
}
@@ -1087,8 +1225,12 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("column name %s is not supported on incrementally maintainable materialized view", tle->resname)));
+ if (context->has_agg && !IsA(tle->expr, Aggref) && contain_aggs_of_level((Node *) tle->expr, 0))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("expression containing an aggregate in it is not supported on incrementally maintainable materialized view")));
- expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
break;
}
case T_JoinExpr:
@@ -1100,14 +1242,36 @@ check_ivm_restriction_walker(Node *node, void *context)
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("OUTER JOIN is not supported on incrementally maintainable materialized view")));
- expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
+ break;
}
- break;
case T_Aggref:
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("aggregate function is not supported on incrementally maintainable materialized view")));
- break;
+ {
+ /* Check if this supports IVM */
+ Aggref *aggref = (Aggref *) node;
+ const char *aggname = format_procedure(aggref->aggfnoid);
+
+ if (aggref->aggfilter != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with FILTER clause is not supported on incrementally maintainable materialized view")));
+
+ if (aggref->aggdistinct != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with DISTINCT arguments is not supported on incrementally maintainable materialized view")));
+
+ if (aggref->aggorder != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with ORDER clause is not supported on incrementally maintainable materialized view")));
+
+ if (!check_aggregate_supports_ivm(aggref->aggfnoid))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function %s is not supported on incrementally maintainable materialized view", aggname)));
+ break;
+ }
default:
expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
break;
@@ -1115,6 +1279,46 @@ check_ivm_restriction_walker(Node *node, void *context)
return false;
}
+/*
+ * check_aggregate_supports_ivm
+ *
+ * Check if the given aggregate function is supporting IVM
+ */
+static bool
+check_aggregate_supports_ivm(Oid aggfnoid)
+{
+ switch (aggfnoid)
+ {
+ /* count */
+ case F_COUNT_ANY:
+ case F_COUNT_:
+
+ /* sum */
+ case F_SUM_INT8:
+ case F_SUM_INT4:
+ case F_SUM_INT2:
+ case F_SUM_FLOAT4:
+ case F_SUM_FLOAT8:
+ case F_SUM_MONEY:
+ case F_SUM_INTERVAL:
+ case F_SUM_NUMERIC:
+
+ /* avg */
+ case F_AVG_INT8:
+ case F_AVG_INT4:
+ case F_AVG_INT2:
+ case F_AVG_NUMERIC:
+ case F_AVG_FLOAT4:
+ case F_AVG_FLOAT8:
+ case F_AVG_INTERVAL:
+
+ return true;
+
+ default:
+ return false;
+ }
+}
+
/*
* CreateIndexOnIMMV
*
@@ -1172,7 +1376,29 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
index->concurrent = false;
index->if_not_exists = false;
- if (query->distinctClause)
+ if (query->groupClause)
+ {
+ /* create unique constraint on GROUP BY expression columns */
+ foreach(lc, query->groupClause)
+ {
+ SortGroupClause *scl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(scl, query->targetList);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ else if (query->distinctClause)
{
/* create unique constraint on all columns */
foreach(lc, query->targetList)
@@ -1230,7 +1456,7 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
(errmsg("could not create an index on materialized view \"%s\" automatically",
RelationGetRelationName(matviewRel)),
errdetail("This target list does not have all the primary key columns, "
- "or this view does not contain DISTINCT clause."),
+ "or this view does not contain GROUP BY or DISTINCT clause."),
errhint("Create an index on the materialized view for efficient incremental maintenance.")));
return;
}
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index 6d8382180a..aa6bf2694a 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -30,6 +30,7 @@
#include "catalog/pg_opclass.h"
#include "catalog/pg_operator.h"
#include "commands/cluster.h"
+#include "commands/defrem.h"
#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
@@ -39,6 +40,7 @@
#include "executor/tstoreReceiver.h"
#include "miscadmin.h"
#include "nodes/makefuncs.h"
+#include "optimizer/optimizer.h"
#include "parser/analyze.h"
#include "parser/parse_clause.h"
#include "parser/parse_func.h"
@@ -111,6 +113,13 @@ static HTAB *mv_trigger_info = NULL;
static bool in_delta_calculation = false;
+/* kind of IVM operation for the view */
+typedef enum
+{
+ IVM_ADD,
+ IVM_SUB
+} IvmOp;
+
/* ENR name for materialized view delta */
#define NEW_DELTA_ENRNAME "new_delta"
#define OLD_DELTA_ENRNAME "old_delta"
@@ -142,7 +151,7 @@ static RangeTblEntry *get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *tabl
QueryEnvironment *queryEnv, Oid matviewid);
static RangeTblEntry *replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
QueryEnvironment *queryEnv);
-static Query *rewrite_query_for_counting(Query *query, ParseState *pstate);
+static Query *rewrite_query_for_counting_and_aggregates(Query *query, ParseState *pstate);
static void calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
DestReceiver *dest_old, DestReceiver *dest_new,
@@ -153,14 +162,27 @@ static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *
static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
Query *query, bool use_count, char *count_colname);
+static void append_set_clause_for_count(const char *resname, StringInfo buf_old,
+ StringInfo buf_new,StringInfo aggs_list);
+static void append_set_clause_for_sum(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list);
+static void append_set_clause_for_avg(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ const char *aggtype);
+static char *get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
+ const char* count_col, const char *castType);
+static char *get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
+ const char* count_col);
static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
- List *keys, const char *count_colname);
+ List *keys, StringInfo aggs_list, StringInfo aggs_set,
+ const char *count_colname);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
- List *keys, StringInfo target_list, const char* count_colname);
+ List *keys, StringInfo target_list, StringInfo aggs_set,
+ const char* count_colname);
static char *get_matching_condition_string(List *keys);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
@@ -1432,11 +1454,44 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
* When a base table is truncated, the view content will be empty if the
* view definition query does not contain an aggregate without a GROUP clause.
* Therefore, such views can be truncated.
+ *
+ * Aggregate views without a GROUP clause always have one row. Therefore,
+ * if a base table is truncated, the view will not be empty and will contain
+ * a row with NULL value (or 0 for count()). So, in this case, we refresh the
+ * view instead of truncating it.
*/
if (TRIGGER_FIRED_BY_TRUNCATE(trigdata->tg_event))
{
- ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
- NIL, DROP_RESTRICT, false, false);
+ if (!(query->hasAggs && query->groupClause == NIL))
+ ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
+ NIL, DROP_RESTRICT, false, false);
+ else
+ {
+ Oid OIDNewHeap;
+ DestReceiver *dest;
+ uint64 processed = 0;
+ Query *dataQuery = rewriteQueryForIMMV(query, NIL);
+ char relpersistence = matviewRel->rd_rel->relpersistence;
+
+ /*
+ * Create the transient table that will receive the regenerated data. Lock
+ * it against access by any other process until commit (by which time it
+ * will be gone).
+ */
+ OIDNewHeap = make_new_heap(matviewOid, matviewRel->rd_rel->reltablespace,
+ matviewRel->rd_rel->relam,
+ relpersistence, ExclusiveLock);
+ LockRelationOid(OIDNewHeap, AccessExclusiveLock);
+ dest = CreateTransientRelDestReceiver(OIDNewHeap);
+
+ /* Generate the data */
+ processed = refresh_matview_datafill(dest, dataQuery, NULL, NULL, "");
+ refresh_by_heap_swap(matviewOid, OIDNewHeap, relpersistence);
+
+ /* Inform cumulative stats system about our activity */
+ pgstat_count_truncate(matviewRel);
+ pgstat_count_heap_insert(matviewRel, processed);
+ }
/* Clean up hash entry and delete tuplestores */
clean_up_IVM_hash_entry(entry, false);
@@ -1476,8 +1531,8 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
/* Set all tables in the query to pre-update state */
rewritten = rewrite_query_for_preupdate_state(rewritten, entry->tables,
pstate, matviewOid);
- /* Rewrite for counting duplicated tuples */
- rewritten = rewrite_query_for_counting(rewritten, pstate);
+ /* Rewrite for counting duplicated tuples and aggregates functions*/
+ rewritten = rewrite_query_for_counting_and_aggregates(rewritten, pstate);
/* Create tuplestores to store view deltas */
if (entry->has_old)
@@ -1528,7 +1583,7 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
count_colname = pstrdup("__ivm_count__");
- if (query->distinctClause)
+ if (query->hasAggs || query->distinctClause)
use_count = true;
/* calculate delta tables */
@@ -1924,17 +1979,34 @@ replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
}
/*
- * rewrite_query_for_counting
+ * rewrite_query_for_counting_and_aggregates
*
- * Rewrite query for counting duplicated tuples.
+ * Rewrite query for counting duplicated tuples and aggregate functions.
*/
static Query *
-rewrite_query_for_counting(Query *query, ParseState *pstate)
+rewrite_query_for_counting_and_aggregates(Query *query, ParseState *pstate)
{
TargetEntry *tle_count;
FuncCall *fn;
Node *node;
+ /* For aggregate views */
+ if (query->hasAggs)
+ {
+ ListCell *lc;
+ List *aggs = NIL;
+ AttrNumber next_resno = list_length(query->targetList) + 1;
+
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+
+ if (IsA(tle->expr, Aggref))
+ makeIvmAggColumn(pstate, (Aggref *)tle->expr, tle->resname, &next_resno, &aggs);
+ }
+ query->targetList = list_concat(query->targetList, aggs);
+ }
+
/* Add count(*) for counting distinct tuples in views */
fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
fn->agg_star = true;
@@ -2007,6 +2079,8 @@ rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte
return query;
}
+#define IVM_colname(type, col) makeObjectName("__ivm_" type, col, "_")
+
/*
* apply_delta
*
@@ -2020,6 +2094,9 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
{
StringInfoData querybuf;
StringInfoData target_list_buf;
+ StringInfo aggs_list_buf = NULL;
+ StringInfo aggs_set_old = NULL;
+ StringInfo aggs_set_new = NULL;
Relation matviewRel;
char *matviewname;
ListCell *lc;
@@ -2042,6 +2119,15 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
initStringInfo(&querybuf);
initStringInfo(&target_list_buf);
+ if (query->hasAggs)
+ {
+ if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
+ aggs_set_old = makeStringInfo();
+ if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
+ aggs_set_new = makeStringInfo();
+ aggs_list_buf = makeStringInfo();
+ }
+
/* build string of target list */
for (i = 0; i < matviewRel->rd_att->natts; i++)
{
@@ -2058,13 +2144,61 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
i++;
if (tle->resjunk)
continue;
- keys = lappend(keys, attr);
+ /*
+ * For views without aggregates, all attributes are used as keys to identify a
+ * tuple in a view.
+ */
+ if (!query->hasAggs)
+ keys = lappend(keys, attr);
+
+ /* For views with aggregates, we need to build SET clause for updating aggregate
+ * values. */
+ if (query->hasAggs && IsA(tle->expr, Aggref))
+ {
+ Aggref *aggref = (Aggref *) tle->expr;
+ const char *aggname = get_func_name(aggref->aggfnoid);
+
+ /*
+ * We can use function names here because it is already checked if these
+ * can be used in IMMV by its OID at the definition time.
+ */
+
+ /* count */
+ if (!strcmp(aggname, "count"))
+ append_set_clause_for_count(resname, aggs_set_old, aggs_set_new, aggs_list_buf);
+
+ /* sum */
+ else if (!strcmp(aggname, "sum"))
+ append_set_clause_for_sum(resname, aggs_set_old, aggs_set_new, aggs_list_buf);
+
+ /* avg */
+ else if (!strcmp(aggname, "avg"))
+ append_set_clause_for_avg(resname, aggs_set_old, aggs_set_new, aggs_list_buf,
+ format_type_be(aggref->aggtype));
+
+ else
+ elog(ERROR, "unsupported aggregate function: %s", aggname);
+ }
+ }
+
+ /* If we have GROUP BY clause, we use its entries as keys. */
+ if (query->hasAggs && query->groupClause)
+ {
+ foreach (lc, query->groupClause)
+ {
+ SortGroupClause *sgcl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(sgcl, query->targetList);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ keys = lappend(keys, attr);
+ }
}
/* Start maintaining the materialized view. */
@@ -2095,7 +2229,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (use_count)
/* apply old delta and get rows to be recalculated */
apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
- keys, count_colname);
+ keys, aggs_list_buf, aggs_set_old,
+ count_colname);
else
apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
@@ -2121,7 +2256,7 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
/* apply new delta */
if (use_count)
apply_new_delta_with_count(matviewname, NEW_DELTA_ENRNAME,
- keys, &target_list_buf, count_colname);
+ keys, aggs_set_new, &target_list_buf, count_colname);
else
apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
}
@@ -2136,6 +2271,250 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_finish failed");
}
+/*
+ * append_set_clause_for_count
+ *
+ * Append SET clause string for count aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_count(const char *resname, StringInfo buf_old,
+ StringInfo buf_new,StringInfo aggs_list)
+{
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* resname = mv.resname - t.resname */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, resname, "mv", "t", NULL, NULL));
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* resname = mv.resname + diff.resname */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, resname, "mv", "diff", NULL, NULL));
+ }
+
+ appendStringInfo(aggs_list, ", %s",
+ quote_qualified_identifier("diff", resname)
+ );
+}
+
+/*
+ * append_set_clause_for_sum
+ *
+ * Append SET clause string for sum aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_sum(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list)
+{
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* sum = mv.sum - t.sum */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, resname, "mv", "t", count_col, NULL)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* sum = mv.sum + diff.sum */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, resname, "mv", "diff", count_col, NULL)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
+/*
+ * append_set_clause_for_avg
+ *
+ * Append SET clause string for avg aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_avg(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ const char *aggtype)
+{
+ char *sum_col = IVM_colname("sum", resname);
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* avg = (mv.sum - t.sum)::aggtype / (mv.count - t.count) */
+ appendStringInfo(buf_old,
+ ", %s = %s OPERATOR(pg_catalog./) %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, sum_col, "mv", "t", count_col, aggtype),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ /* sum = mv.sum - t.sum */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, sum_col),
+ get_operation_string(IVM_SUB, sum_col, "mv", "t", count_col, NULL)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* avg = (mv.sum + diff.sum)::aggtype / (mv.count + diff.count) */
+ appendStringInfo(buf_new,
+ ", %s = %s OPERATOR(pg_catalog./) %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, sum_col, "mv", "diff", count_col, aggtype),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ /* sum = mv.sum + diff.sum */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, sum_col),
+ get_operation_string(IVM_ADD, sum_col, "mv", "diff", count_col, NULL)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("sum", resname)),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
+/*
+ * get_operation_string
+ *
+ * Build a string to calculate the new aggregate values.
+ */
+static char *
+get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
+ const char* count_col, const char *castType)
+{
+ StringInfoData buf;
+ StringInfoData castString;
+ char *col1 = quote_qualified_identifier(arg1, col);
+ char *col2 = quote_qualified_identifier(arg2, col);
+ char op_char = (op == IVM_SUB ? '-' : '+');
+
+ initStringInfo(&buf);
+ initStringInfo(&castString);
+
+ if (castType)
+ appendStringInfo(&castString, "::%s", castType);
+
+ if (!count_col)
+ {
+ /*
+ * If the attributes don't have count columns then calc the result
+ * by using the operator simply.
+ */
+ appendStringInfo(&buf, "(%s OPERATOR(pg_catalog.%c) %s)%s",
+ col1, op_char, col2, castString.data);
+ }
+ else
+ {
+ /*
+ * If the attributes have count columns then consider the condition
+ * where the result becomes NULL.
+ */
+ char *null_cond = get_null_condition_string(op, arg1, arg2, count_col);
+
+ appendStringInfo(&buf,
+ "(CASE WHEN %s THEN NULL "
+ "WHEN %s IS NULL THEN %s "
+ "WHEN %s IS NULL THEN %s "
+ "ELSE (%s OPERATOR(pg_catalog.%c) %s)%s END)",
+ null_cond,
+ col1, col2,
+ col2, col1,
+ col1, op_char, col2, castString.data
+ );
+ }
+
+ return buf.data;
+}
+
+/*
+ * get_null_condition_string
+ *
+ * Build a predicate string for CASE clause to check if an aggregate value
+ * will became NULL after the given operation is applied.
+ */
+static char *
+get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
+ const char* count_col)
+{
+ StringInfoData null_cond;
+ initStringInfo(&null_cond);
+
+ switch (op)
+ {
+ case IVM_ADD:
+ appendStringInfo(&null_cond,
+ "%s OPERATOR(pg_catalog.=) 0 AND %s OPERATOR(pg_catalog.=) 0",
+ quote_qualified_identifier(arg1, count_col),
+ quote_qualified_identifier(arg2, count_col)
+ );
+ break;
+ case IVM_SUB:
+ appendStringInfo(&null_cond,
+ "%s OPERATOR(pg_catalog.=) %s",
+ quote_qualified_identifier(arg1, count_col),
+ quote_qualified_identifier(arg2, count_col)
+ );
+ break;
+ default:
+ elog(ERROR,"unknown operation");
+ }
+
+ return null_cond.data;
+}
+
+
/*
* apply_old_delta_with_count
*
@@ -2143,13 +2522,20 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
* which contains tuples to be deleted from to a materialized view given by
* matviewname. This is used when counting is required, that is, the view
* has aggregate or distinct.
+ *
+ * If the view desn't have aggregates or has GROUP BY, this requires a keys
+ * list to identify a tuple in the view. If the view has aggregates, this
+ * requires strings representing resnames of aggregates and SET clause for
+ * updating aggregate values.
*/
static void
apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
- List *keys, const char *count_colname)
+ List *keys, StringInfo aggs_list, StringInfo aggs_set,
+ const char *count_colname)
{
StringInfoData querybuf;
char *match_cond;
+ bool agg_without_groupby = (list_length(keys) == 0);
/* build WHERE condition for searching tuples to be deleted */
match_cond = get_matching_condition_string(keys);
@@ -2159,22 +2545,26 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
appendStringInfo(&querybuf,
"WITH t AS (" /* collecting tid of target tuples in the view */
"SELECT diff.%s, " /* count column */
- "(diff.%s OPERATOR(pg_catalog.=) mv.%s) AS for_dlt, "
+ "(diff.%s OPERATOR(pg_catalog.=) mv.%s AND %s) AS for_dlt, "
"mv.ctid "
+ "%s " /* aggregate columns */
"FROM %s AS mv, %s AS diff "
"WHERE %s" /* tuple matching condition */
"), updt AS (" /* update a tuple if this is not to be deleted */
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
+ "%s" /* SET clauses for aggregates */
"FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
")"
/* delete a tuple if this is to be deleted */
"DELETE FROM %s AS mv USING t "
"WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
count_colname,
- count_colname, count_colname,
+ count_colname, count_colname, (agg_without_groupby ? "false" : "true"),
+ (aggs_list != NULL ? aggs_list->data : ""),
matviewname, deltaname_old,
match_cond,
matviewname, count_colname, count_colname, count_colname,
+ (aggs_set != NULL ? aggs_set->data : ""),
matviewname);
if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
@@ -2238,10 +2628,15 @@ apply_old_delta(const char *matviewname, const char *deltaname_old,
* matviewname. This is used when counting is required, that is, the view
* has aggregate or distinct. Also, when a table in EXISTS sub queries
* is modified.
+ *
+ * If the view desn't have aggregates or has GROUP BY, this requires a keys
+ * list to identify a tuple in the view. If the view has aggregates, this
+ * requires strings representing SET clause for updating aggregate values.
*/
static void
apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
- List *keys, StringInfo target_list, const char* count_colname)
+ List *keys, StringInfo aggs_set, StringInfo target_list,
+ const char* count_colname)
{
StringInfoData querybuf;
StringInfoData returning_keys;
@@ -2272,6 +2667,7 @@ apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
appendStringInfo(&querybuf,
"WITH updt AS (" /* update a tuple if this exists in the view */
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.+) diff.%s "
+ "%s " /* SET clauses for aggregates */
"FROM %s AS diff "
"WHERE %s " /* tuple matching condition */
"RETURNING %s" /* returning keys of updated tuples */
@@ -2279,6 +2675,7 @@ apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
"SELECT %s FROM %s AS diff "
"WHERE NOT EXISTS (SELECT 1 FROM updt AS mv WHERE %s);",
matviewname, count_colname, count_colname, count_colname,
+ (aggs_set != NULL ? aggs_set->data : ""),
deltaname_new,
match_cond,
returning_keys.data,
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 76a7873ebf..599bae3b5a 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -30,6 +30,7 @@ extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
extern Query *rewriteQueryForIMMV(Query *query, List *colNames);
+extern void makeIvmAggColumn(ParseState *pstate, Aggref *aggref, char *resname, AttrNumber *next_resno, List **aggs);
extern int GetIntoRelEFlags(IntoClause *intoClause);
--
2.25.1
v28-0009-Add-support-for-min-max-aggregates-for-IVM.patchtext/x-diff; name=v28-0009-Add-support-for-min-max-aggregates-for-IVM.patchDownload
From 53e22a9da26c31864165490ec71112848e03cda2 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 20:58:25 +0900
Subject: [PATCH v28 09/11] Add support for min/max aggregates for IVM
Supporting min and max is more complicated than count, sum, or avg.
For an example of min, when tuples are inserted, the current min value
in the view and the min value in the inseteted tuples are compared,
then the smaller one is used as the latest min value. On the other
hand, when tuples are deleted, if the current min value in the view
equals to the min in the deleted tuples, we need re-computation the
latest min value from base tables. Otherwise, the current value in
the view remains.
---
src/backend/commands/createas.c | 45 +++
src/backend/commands/matview.c | 644 +++++++++++++++++++++++++++++++-
2 files changed, 680 insertions(+), 9 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index c8aa558f2e..c40ea6b2bc 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -1312,6 +1312,51 @@ check_aggregate_supports_ivm(Oid aggfnoid)
case F_AVG_FLOAT8:
case F_AVG_INTERVAL:
+ /* min */
+ case F_MIN_ANYARRAY:
+ case F_MIN_INT8:
+ case F_MIN_INT4:
+ case F_MIN_INT2:
+ case F_MIN_OID:
+ case F_MIN_FLOAT4:
+ case F_MIN_FLOAT8:
+ case F_MIN_DATE:
+ case F_MIN_TIME:
+ case F_MIN_TIMETZ:
+ case F_MIN_MONEY:
+ case F_MIN_TIMESTAMP:
+ case F_MIN_TIMESTAMPTZ:
+ case F_MIN_INTERVAL:
+ case F_MIN_TEXT:
+ case F_MIN_NUMERIC:
+ case F_MIN_BPCHAR:
+ case F_MIN_TID:
+ case F_MIN_ANYENUM:
+ case F_MIN_INET:
+ case F_MIN_PG_LSN:
+
+ /* max */
+ case F_MAX_ANYARRAY:
+ case F_MAX_INT8:
+ case F_MAX_INT4:
+ case F_MAX_INT2:
+ case F_MAX_OID:
+ case F_MAX_FLOAT4:
+ case F_MAX_FLOAT8:
+ case F_MAX_DATE:
+ case F_MAX_TIME:
+ case F_MAX_TIMETZ:
+ case F_MAX_MONEY:
+ case F_MAX_TIMESTAMP:
+ case F_MAX_TIMESTAMPTZ:
+ case F_MAX_INTERVAL:
+ case F_MAX_TEXT:
+ case F_MAX_NUMERIC:
+ case F_MAX_BPCHAR:
+ case F_MAX_TID:
+ case F_MAX_ANYENUM:
+ case F_MAX_INET:
+ case F_MAX_PG_LSN:
return true;
default:
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index aa6bf2694a..fa65e4aeb0 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -73,6 +73,34 @@ typedef struct
#define MV_INIT_QUERYHASHSIZE 16
+/* MV query type codes */
+#define MV_PLAN_RECALC 1
+#define MV_PLAN_SET_VALUE 2
+
+/*
+ * MI_QueryKey
+ *
+ * The key identifying a prepared SPI plan in our query hashtable
+ */
+typedef struct MV_QueryKey
+{
+ Oid matview_id; /* OID of materialized view */
+ int32 query_type; /* query type ID, see MV_PLAN_XXX above */
+} MV_QueryKey;
+
+/*
+ * MV_QueryHashEntry
+ *
+ * Hash entry for cached plans used to maintain materialized views.
+ */
+typedef struct MV_QueryHashEntry
+{
+ MV_QueryKey key;
+ SPIPlanPtr plan;
+ OverrideSearchPath *search_path; /* search_path used for parsing
+ * and planning */
+} MV_QueryHashEntry;
+
/*
* MV_TriggerHashEntry
*
@@ -109,6 +137,7 @@ typedef struct MV_TriggerTable
TupleTableSlot *slot; /* for checking visibility in the pre-state table */
} MV_TriggerTable;
+static HTAB *mv_query_cache = NULL;
static HTAB *mv_trigger_info = NULL;
static bool in_delta_calculation = false;
@@ -169,6 +198,9 @@ static void append_set_clause_for_sum(const char *resname, StringInfo buf_old,
static void append_set_clause_for_avg(const char *resname, StringInfo buf_old,
StringInfo buf_new, StringInfo aggs_list,
const char *aggtype);
+static void append_set_clause_for_minmax(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ bool is_min);
static char *get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
const char* count_col, const char *castType);
static char *get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
@@ -177,17 +209,30 @@ static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
List *keys, StringInfo aggs_list, StringInfo aggs_set,
- const char *count_colname);
+ List *minmax_list, List *is_min_list,
+ const char *count_colname,
+ SPITupleTable **tuptable_recalc, uint64 *num_recalc);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
List *keys, StringInfo target_list, StringInfo aggs_set,
const char* count_colname);
static char *get_matching_condition_string(List *keys);
+static char *get_returning_string(List *minmax_list, List *is_min_list, List *keys);
+static char *get_minmax_recalc_condition_string(List *minmax_list, List *is_min_list);
+static char *get_select_for_recalc_string(List *keys);
+static void recalc_and_set_values(SPITupleTable *tuptable_recalc, int64 num_tuples,
+ List *namelist, List *keys, Relation matviewRel);
+static SPIPlanPtr get_plan_for_recalc(Oid matviewOid, List *namelist, List *keys, Oid *keyTypes);
+static SPIPlanPtr get_plan_for_set_values(Oid matviewOid, char *matviewname, List *namelist,
+ Oid *valTypes);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
static void mv_InitHashTables(void);
+static SPIPlanPtr mv_FetchPreparedPlan(MV_QueryKey *key);
+static void mv_HashPreparedPlan(MV_QueryKey *key, SPIPlanPtr plan);
+static void mv_BuildQueryKey(MV_QueryKey *key, Oid matview_id, int32 query_type);
static void clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort);
/*
@@ -2102,6 +2147,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
ListCell *lc;
int i;
List *keys = NIL;
+ List *minmax_list = NIL;
+ List *is_min_list = NIL;
/*
@@ -2183,6 +2230,17 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
append_set_clause_for_avg(resname, aggs_set_old, aggs_set_new, aggs_list_buf,
format_type_be(aggref->aggtype));
+ /* min/max */
+ else if (!strcmp(aggname, "min") || !strcmp(aggname, "max"))
+ {
+ bool is_min = (!strcmp(aggname, "min"));
+
+ append_set_clause_for_minmax(resname, aggs_set_old, aggs_set_new, aggs_list_buf, is_min);
+
+ /* make a resname list of min and max aggregates */
+ minmax_list = lappend(minmax_list, resname);
+ is_min_list = lappend_int(is_min_list, is_min);
+ }
else
elog(ERROR, "unsupported aggregate function: %s", aggname);
}
@@ -2212,6 +2270,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
{
EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ SPITupleTable *tuptable_recalc = NULL;
+ uint64 num_recalc;
int rc;
/* convert tuplestores to ENR, and register for SPI */
@@ -2230,10 +2290,18 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
/* apply old delta and get rows to be recalculated */
apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
keys, aggs_list_buf, aggs_set_old,
- count_colname);
+ minmax_list, is_min_list,
+ count_colname, &tuptable_recalc, &num_recalc);
else
apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+ /*
+ * If we have min or max, we might have to recalculate aggregate values from base tables
+ * on some tuples. TIDs and keys such tuples are returned as a result of the above query.
+ */
+ if (minmax_list && tuptable_recalc)
+ recalc_and_set_values(tuptable_recalc, num_recalc, minmax_list, keys, matviewRel);
+
}
/* For tuple insertion */
if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
@@ -2425,6 +2493,70 @@ append_set_clause_for_avg(const char *resname, StringInfo buf_old,
);
}
+/*
+ * append_set_clause_for_minmax
+ *
+ * Append SET clause string for min or max aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ * is_min is true if this is min, false if not.
+ */
+static void
+append_set_clause_for_minmax(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ bool is_min)
+{
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /*
+ * If the new value doesn't became NULL then use the value remaining
+ * in the view although this will be recomputated afterwords.
+ */
+ appendStringInfo(buf_old,
+ ", %s = CASE WHEN %s THEN NULL ELSE %s END",
+ quote_qualified_identifier(NULL, resname),
+ get_null_condition_string(IVM_SUB, "mv", "t", count_col),
+ quote_qualified_identifier("mv", resname)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /*
+ * min = LEAST(mv.min, diff.min)
+ * max = GREATEST(mv.max, diff.max)
+ */
+ appendStringInfo(buf_new,
+ ", %s = CASE WHEN %s THEN NULL ELSE %s(%s,%s) END",
+ quote_qualified_identifier(NULL, resname),
+ get_null_condition_string(IVM_ADD, "mv", "diff", count_col),
+
+ is_min ? "LEAST" : "GREATEST",
+ quote_qualified_identifier("mv", resname),
+ quote_qualified_identifier("diff", resname)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
/*
* get_operation_string
*
@@ -2527,19 +2659,44 @@ get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
* list to identify a tuple in the view. If the view has aggregates, this
* requires strings representing resnames of aggregates and SET clause for
* updating aggregate values.
+ *
+ * If the view has min or max aggregate, this requires a list of resnames of
+ * min/max aggregates and a list of boolean which represents which entries in
+ * minmax_list is min. These are necessary to check if we need to recalculate
+ * min or max aggregate values. In this case, this query returns TID and keys
+ * of tuples which need to be recalculated. This result and the number of rows
+ * are stored in tuptables and num_recalc repectedly.
+ *
*/
static void
apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
List *keys, StringInfo aggs_list, StringInfo aggs_set,
- const char *count_colname)
+ List *minmax_list, List *is_min_list,
+ const char *count_colname,
+ SPITupleTable **tuptable_recalc, uint64 *num_recalc)
{
StringInfoData querybuf;
char *match_cond;
+ char *updt_returning = "";
+ char *select_for_recalc = "SELECT";
bool agg_without_groupby = (list_length(keys) == 0);
+ Assert(tuptable_recalc != NULL);
+ Assert(num_recalc != NULL);
+
/* build WHERE condition for searching tuples to be deleted */
match_cond = get_matching_condition_string(keys);
+ /*
+ * We need a special RETURNING clause and SELECT statement for min/max to
+ * check which tuple needs re-calculation from base tables.
+ */
+ if (minmax_list)
+ {
+ updt_returning = get_returning_string(minmax_list, is_min_list, keys);
+ select_for_recalc = get_select_for_recalc_string(keys);
+ }
+
/* Search for matching tuples from the view and update or delete if found. */
initStringInfo(&querybuf);
appendStringInfo(&querybuf,
@@ -2554,10 +2711,11 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
"%s" /* SET clauses for aggregates */
"FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
- ")"
- /* delete a tuple if this is to be deleted */
- "DELETE FROM %s AS mv USING t "
- "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
+ "%s" /* RETURNING clause for recalc infomation */
+ "), dlt AS (" /* delete a tuple if this is to be deleted */
+ "DELETE FROM %s AS mv USING t "
+ "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt"
+ ") %s", /* SELECT returning which tuples need to be recalculated */
count_colname,
count_colname, count_colname, (agg_without_groupby ? "false" : "true"),
(aggs_list != NULL ? aggs_list->data : ""),
@@ -2565,10 +2723,25 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
match_cond,
matviewname, count_colname, count_colname, count_colname,
(aggs_set != NULL ? aggs_set->data : ""),
- matviewname);
+ updt_returning,
+ matviewname,
+ select_for_recalc);
- if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_SELECT)
elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+
+
+ /* Return tuples to be recalculated. */
+ if (minmax_list)
+ {
+ *tuptable_recalc = SPI_tuptable;
+ *num_recalc = SPI_processed;
+ }
+ else
+ {
+ *tuptable_recalc = NULL;
+ *num_recalc = 0;
+ }
}
/*
@@ -2751,6 +2924,349 @@ get_matching_condition_string(List *keys)
return match_cond.data;
}
+/*
+ * get_returning_string
+ *
+ * Build a string for RETURNING clause of UPDATE used in apply_old_delta_with_count.
+ * This clause returns ctid and a boolean value that indicates if we need to
+ * recalculate min or max value, for each updated row.
+ */
+static char *
+get_returning_string(List *minmax_list, List *is_min_list, List *keys)
+{
+ StringInfoData returning;
+ char *recalc_cond;
+ ListCell *lc;
+
+ Assert(minmax_list != NIL && is_min_list != NIL);
+ recalc_cond = get_minmax_recalc_condition_string(minmax_list, is_min_list);
+
+ initStringInfo(&returning);
+
+ appendStringInfo(&returning, "RETURNING mv.ctid AS tid, (%s) AS recalc", recalc_cond);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&returning, ", %s", quote_qualified_identifier("mv", resname));
+ }
+
+ return returning.data;
+}
+
+/*
+ * get_minmax_recalc_condition_string
+ *
+ * Build a predicate string for checking if any min/max aggregate
+ * value needs to be recalculated.
+ */
+static char *
+get_minmax_recalc_condition_string(List *minmax_list, List *is_min_list)
+{
+ StringInfoData recalc_cond;
+ ListCell *lc1, *lc2;
+
+ initStringInfo(&recalc_cond);
+
+ Assert (list_length(minmax_list) == list_length(is_min_list));
+
+ forboth (lc1, minmax_list, lc2, is_min_list)
+ {
+ char *resname = (char *) lfirst(lc1);
+ bool is_min = (bool) lfirst_int(lc2);
+ char *op_str = (is_min ? ">=" : "<=");
+
+ appendStringInfo(&recalc_cond, "%s OPERATOR(pg_catalog.%s) %s",
+ quote_qualified_identifier("mv", resname),
+ op_str,
+ quote_qualified_identifier("t", resname)
+ );
+
+ if (lnext(minmax_list, lc1))
+ appendStringInfo(&recalc_cond, " OR ");
+ }
+
+ return recalc_cond.data;
+}
+
+/*
+ * get_select_for_recalc_string
+ *
+ * Build a query to return tid and keys of tuples which need
+ * recalculation. This is used as the result of the query
+ * built by apply_old_delta.
+ */
+static char *
+get_select_for_recalc_string(List *keys)
+{
+ StringInfoData qry;
+ ListCell *lc;
+
+ initStringInfo(&qry);
+
+ appendStringInfo(&qry, "SELECT tid");
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ appendStringInfo(&qry, ", %s", NameStr(attr->attname));
+ }
+
+ appendStringInfo(&qry, " FROM updt WHERE recalc");
+
+ return qry.data;
+}
+
+/*
+ * recalc_and_set_values
+ *
+ * Recalculate tuples in a materialized from base tables and update these.
+ * The tuples which needs recalculation are specified by keys, and resnames
+ * of columns to be updated are specified by namelist. TIDs and key values
+ * are given by tuples in tuptable_recalc. Its first attribute must be TID
+ * and key values must be following this.
+ */
+static void
+recalc_and_set_values(SPITupleTable *tuptable_recalc, int64 num_tuples,
+ List *namelist, List *keys, Relation matviewRel)
+{
+ TupleDesc tupdesc_recalc = tuptable_recalc->tupdesc;
+ Oid *keyTypes = NULL, *types = NULL;
+ char *keyNulls = NULL, *nulls = NULL;
+ Datum *keyVals = NULL, *vals = NULL;
+ int num_vals = list_length(namelist);
+ int num_keys = list_length(keys);
+ uint64 i;
+ Oid matviewOid;
+ char *matviewname;
+
+ matviewOid = RelationGetRelid(matviewRel);
+ matviewname = quote_qualified_identifier(get_namespace_name(RelationGetNamespace(matviewRel)),
+ RelationGetRelationName(matviewRel));
+
+ /* If we have keys, initialize arrays for them. */
+ if (keys)
+ {
+ keyTypes = palloc(sizeof(Oid) * num_keys);
+ keyNulls = palloc(sizeof(char) * num_keys);
+ keyVals = palloc(sizeof(Datum) * num_keys);
+ /* a tuple contains keys to be recalculated and ctid to be updated*/
+ Assert(tupdesc_recalc->natts == num_keys + 1);
+
+ /* Types of key attributes */
+ for (i = 0; i < num_keys; i++)
+ keyTypes[i] = TupleDescAttr(tupdesc_recalc, i + 1)->atttypid;
+ }
+
+ /* allocate memory for all attribute names and tid */
+ types = palloc(sizeof(Oid) * (num_vals + 1));
+ nulls = palloc(sizeof(char) * (num_vals + 1));
+ vals = palloc(sizeof(Datum) * (num_vals + 1));
+
+ /* For each tuple which needs recalculation */
+ for (i = 0; i < num_tuples; i++)
+ {
+ int j;
+ bool isnull;
+ SPIPlanPtr plan;
+ SPITupleTable *tuptable_newvals;
+ TupleDesc tupdesc_newvals;
+
+ /* Set group key values as parameters if needed. */
+ if (keys)
+ {
+ for (j = 0; j < num_keys; j++)
+ {
+ keyVals[j] = SPI_getbinval(tuptable_recalc->vals[i], tupdesc_recalc, j + 2, &isnull);
+ if (isnull)
+ keyNulls[j] = 'n';
+ else
+ keyNulls[j] = ' ';
+ }
+ }
+
+ /*
+ * Get recalculated values from base tables. The result must be
+ * only one tuple thich contains the new values for specified keys.
+ */
+ plan = get_plan_for_recalc(matviewOid, namelist, keys, keyTypes);
+ if (SPI_execute_plan(plan, keyVals, keyNulls, false, 0) != SPI_OK_SELECT)
+ elog(ERROR, "SPI_execute_plan");
+ if (SPI_processed != 1)
+ elog(ERROR, "SPI_execute_plan returned zero or more than one rows");
+
+ tuptable_newvals = SPI_tuptable;
+ tupdesc_newvals = tuptable_newvals->tupdesc;
+
+ Assert(tupdesc_newvals->natts == num_vals);
+
+ /* Set the new values as parameters */
+ for (j = 0; j < tupdesc_newvals->natts; j++)
+ {
+ if (i == 0)
+ types[j] = TupleDescAttr(tupdesc_newvals, j)->atttypid;
+
+ vals[j] = SPI_getbinval(tuptable_newvals->vals[0], tupdesc_newvals, j + 1, &isnull);
+ if (isnull)
+ nulls[j] = 'n';
+ else
+ nulls[j] = ' ';
+ }
+ /* Set TID of the view tuple to be updated as a parameter */
+ types[j] = TIDOID;
+ vals[j] = SPI_getbinval(tuptable_recalc->vals[i], tupdesc_recalc, 1, &isnull);
+ nulls[j] = ' ';
+
+ /* Update the view tuple to the new values */
+ plan = get_plan_for_set_values(matviewOid, matviewname, namelist, types);
+ if (SPI_execute_plan(plan, vals, nulls, false, 0) != SPI_OK_UPDATE)
+ elog(ERROR, "SPI_execute_plan");
+ }
+}
+
+
+/*
+ * get_plan_for_recalc
+ *
+ * Create or fetch a plan for recalculating value in the view's target list
+ * from base tables using the definition query of materialized view specified
+ * by matviewOid. namelist is a list of resnames of values to be recalculated.
+ *
+ * keys is a list of keys to identify tuples to be recalculated if this is not
+ * empty. KeyTypes is an array of types of keys.
+ */
+static SPIPlanPtr
+get_plan_for_recalc(Oid matviewOid, List *namelist, List *keys, Oid *keyTypes)
+{
+ MV_QueryKey hash_key;
+ SPIPlanPtr plan;
+
+ /* Fetch or prepare a saved plan for the recalculation */
+ mv_BuildQueryKey(&hash_key, matviewOid, MV_PLAN_RECALC);
+ if ((plan = mv_FetchPreparedPlan(&hash_key)) == NULL)
+ {
+ ListCell *lc;
+ StringInfoData str;
+ char *viewdef;
+
+ /* get view definition of matview */
+ viewdef = text_to_cstring((text *) DatumGetPointer(
+ DirectFunctionCall1(pg_get_viewdef, ObjectIdGetDatum(matviewOid))));
+ /* get rid of trailing semi-colon */
+ viewdef[strlen(viewdef)-1] = '\0';
+
+ /*
+ * Build a query string for recalculating values. This is like
+ *
+ * SELECT x1, x2, x3, ... FROM ( ... view definition query ...) mv
+ * WHERE (key1, key2, ...) = ($1, $2, ...);
+ */
+
+ initStringInfo(&str);
+ appendStringInfo(&str, "SELECT ");
+ foreach (lc, namelist)
+ {
+ appendStringInfo(&str, "%s", (char *) lfirst(lc));
+ if (lnext(namelist, lc))
+ appendStringInfoString(&str, ", ");
+ }
+ appendStringInfo(&str, " FROM (%s) mv", viewdef);
+
+ if (keys)
+ {
+ int i = 1;
+ char paramname[16];
+
+ appendStringInfo(&str, " WHERE (");
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ Oid typid = attr->atttypid;
+
+ sprintf(paramname, "$%d", i);
+ appendStringInfo(&str, "(");
+ generate_equal(&str, typid, resname, paramname);
+ appendStringInfo(&str, " OR (%s IS NULL AND %s IS NULL))",
+ resname, paramname);
+
+ if (lnext(keys, lc))
+ appendStringInfoString(&str, " AND ");
+ i++;
+ }
+ appendStringInfo(&str, ")");
+ }
+ else
+ keyTypes = NULL;
+
+ plan = SPI_prepare(str.data, list_length(keys), keyTypes);
+ if (plan == NULL)
+ elog(ERROR, "SPI_prepare returned %s for %s", SPI_result_code_string(SPI_result), str.data);
+
+ SPI_keepplan(plan);
+ mv_HashPreparedPlan(&hash_key, plan);
+ }
+
+ return plan;
+}
+
+/*
+ * get_plan_for_set_values
+ *
+ * Create or fetch a plan for applying new values calculated by
+ * get_plan_for_recalc to a materialized view specified by matviewOid.
+ * matviewname is the name of the view. namelist is a list of resnames
+ * of attributes to be updated, and valTypes is an array of types of the
+ * values.
+ */
+static SPIPlanPtr
+get_plan_for_set_values(Oid matviewOid, char *matviewname, List *namelist,
+ Oid *valTypes)
+{
+ MV_QueryKey key;
+ SPIPlanPtr plan;
+
+ /* Fetch or prepare a saved plan for the real check */
+ mv_BuildQueryKey(&key, matviewOid, MV_PLAN_SET_VALUE);
+ if ((plan = mv_FetchPreparedPlan(&key)) == NULL)
+ {
+ ListCell *lc;
+ StringInfoData str;
+ int i;
+
+ /*
+ * Build a query string for applying min/max values. This is like
+ *
+ * UPDATE matviewname AS mv
+ * SET (x1, x2, x3, x4) = ($1, $2, $3, $4)
+ * WHERE ctid = $5;
+ */
+
+ initStringInfo(&str);
+ appendStringInfo(&str, "UPDATE %s AS mv SET (", matviewname);
+ foreach (lc, namelist)
+ {
+ appendStringInfo(&str, "%s", (char *) lfirst(lc));
+ if (lnext(namelist, lc))
+ appendStringInfoString(&str, ", ");
+ }
+ appendStringInfo(&str, ") = ROW(");
+
+ for (i = 1; i <= list_length(namelist); i++)
+ appendStringInfo(&str, "%s$%d", (i==1 ? "" : ", "), i);
+
+ appendStringInfo(&str, ") WHERE ctid OPERATOR(pg_catalog.=) $%d", i);
+
+ plan = SPI_prepare(str.data, list_length(namelist) + 1, valTypes);
+ if (plan == NULL)
+ elog(ERROR, "SPI_prepare returned %s for %s", SPI_result_code_string(SPI_result), str.data);
+
+ SPI_keepplan(plan);
+ mv_HashPreparedPlan(&key, plan);
+ }
+
+ return plan;
+}
+
/*
* generate_equals
*
@@ -2784,6 +3300,13 @@ mv_InitHashTables(void)
{
HASHCTL ctl;
+ memset(&ctl, 0, sizeof(ctl));
+ ctl.keysize = sizeof(MV_QueryKey);
+ ctl.entrysize = sizeof(MV_QueryHashEntry);
+ mv_query_cache = hash_create("MV query cache",
+ MV_INIT_QUERYHASHSIZE,
+ &ctl, HASH_ELEM | HASH_BLOBS);
+
memset(&ctl, 0, sizeof(ctl));
ctl.keysize = sizeof(Oid);
ctl.entrysize = sizeof(MV_TriggerHashEntry);
@@ -2792,6 +3315,109 @@ mv_InitHashTables(void)
&ctl, HASH_ELEM | HASH_BLOBS);
}
+/*
+ * mv_FetchPreparedPlan
+ */
+static SPIPlanPtr
+mv_FetchPreparedPlan(MV_QueryKey *key)
+{
+ MV_QueryHashEntry *entry;
+ SPIPlanPtr plan;
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_query_cache)
+ mv_InitHashTables();
+
+ /*
+ * Lookup for the key
+ */
+ entry = (MV_QueryHashEntry *) hash_search(mv_query_cache,
+ (void *) key,
+ HASH_FIND, NULL);
+ if (entry == NULL)
+ return NULL;
+
+ /*
+ * Check whether the plan is still valid. If it isn't, we don't want to
+ * simply rely on plancache.c to regenerate it; rather we should start
+ * from scratch and rebuild the query text too. This is to cover cases
+ * such as table/column renames. We depend on the plancache machinery to
+ * detect possible invalidations, though.
+ *
+ * CAUTION: this check is only trustworthy if the caller has already
+ * locked both materialized views and base tables.
+ *
+ * Also, check whether the search_path is still the same as when we made it.
+ * If it isn't, we need to rebuild the query text because the result of
+ * pg_ivm_get_viewdef() will change.
+ */
+ plan = entry->plan;
+ if (plan && SPI_plan_is_valid(plan) &&
+ OverrideSearchPathMatchesCurrent(entry->search_path))
+ return plan;
+
+ /*
+ * Otherwise we might as well flush the cached plan now, to free a little
+ * memory space before we make a new one.
+ */
+ if (plan)
+ SPI_freeplan(plan);
+ if (entry->search_path)
+ pfree(entry->search_path);
+
+ entry->plan = NULL;
+ entry->search_path = NULL;
+
+ return NULL;
+}
+
+/*
+ * mv_HashPreparedPlan
+ *
+ * Add another plan to our private SPI query plan hashtable.
+ */
+static void
+mv_HashPreparedPlan(MV_QueryKey *key, SPIPlanPtr plan)
+{
+ MV_QueryHashEntry *entry;
+ bool found;
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_query_cache)
+ mv_InitHashTables();
+
+ /*
+ * Add the new plan. We might be overwriting an entry previously found
+ * invalid by mv_FetchPreparedPlan.
+ */
+ entry = (MV_QueryHashEntry *) hash_search(mv_query_cache,
+ (void *) key,
+ HASH_ENTER, &found);
+ Assert(!found || entry->plan == NULL);
+ entry->plan = plan;
+ entry->search_path = GetOverrideSearchPath(TopMemoryContext);
+}
+
+/*
+ * mv_BuildQueryKey
+ *
+ * Construct a hashtable key for a prepared SPI plan for IVM.
+ */
+static void
+mv_BuildQueryKey(MV_QueryKey *key, Oid matview_id, int32 query_type)
+{
+ /*
+ * We assume struct MV_QueryKey contains no padding bytes, else we'd need
+ * to use memset to clear them.
+ */
+ key->matview_id = matview_id;
+ key->query_type = query_type;
+}
+
/*
* AtAbort_IVM
*
--
2.25.1
v28-0010-Add-regression-tests-for-Incremental-View-Mainte.patchtext/x-diff; name=v28-0010-Add-regression-tests-for-Incremental-View-Mainte.patchDownload
From 7be3cc47d45a280f8bffd5b689d3a5fa360e1902 Mon Sep 17 00:00:00 2001
From: Takuma Hoshiai <takuma.hoshiai@gmail.com>
Date: Wed, 10 Mar 2021 11:11:13 +0900
Subject: [PATCH v28 10/11] Add regression tests for Incremental View
Maintenance
---
src/bin/pg_dump/pg_dump.h | 1 +
.../regress/expected/incremental_matview.out | 1031 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/incremental_matview.sql | 534 +++++++++
4 files changed, 1567 insertions(+), 1 deletion(-)
create mode 100644 src/test/regress/expected/incremental_matview.out
create mode 100644 src/test/regress/sql/incremental_matview.sql
diff --git a/src/bin/pg_dump/pg_dump.h b/src/bin/pg_dump/pg_dump.h
index 119293a751..c3960a4192 100644
--- a/src/bin/pg_dump/pg_dump.h
+++ b/src/bin/pg_dump/pg_dump.h
@@ -322,6 +322,7 @@ typedef struct _tableInfo
int numParents; /* number of (immediate) parent tables */
struct _tableInfo **parents; /* TableInfos of immediate parents */
+
bool isivm; /* is incrementally maintainable materialized view? */
/*
diff --git a/src/test/regress/expected/incremental_matview.out b/src/test/regress/expected/incremental_matview.out
new file mode 100644
index 0000000000..b1e9424508
--- /dev/null
+++ b/src/test/regress/expected/incremental_matview.out
@@ -0,0 +1,1031 @@
+-- create a table to use as a basis for views and materialized views in various combinations
+CREATE TABLE mv_base_a (i int, j int);
+INSERT INTO mv_base_a VALUES
+ (1,10),
+ (2,20),
+ (3,30),
+ (4,40),
+ (5,50);
+CREATE TABLE mv_base_b (i int, k int);
+INSERT INTO mv_base_b VALUES
+ (1,101),
+ (2,102),
+ (3,103),
+ (4,104);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_1 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) WITH NO DATA;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ERROR: materialized view "mv_ivm_1" has not been populated
+HINT: Use the REFRESH MATERIALIZED VIEW command.
+REFRESH MATERIALIZED VIEW mv_ivm_1;
+NOTICE: could not create an index on materialized view "mv_ivm_1" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+-- REFRESH WITH NO DATA
+BEGIN;
+CREATE FUNCTION dummy_ivm_trigger_func() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+CREATE CONSTRAINT TRIGGER dummy_ivm_trigger AFTER INSERT
+ON mv_base_a FROM mv_ivm_1 FOR EACH ROW
+EXECUTE PROCEDURE dummy_ivm_trigger_func();
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ count
+-------
+ 17
+(1 row)
+
+REFRESH MATERIALIZED VIEW mv_ivm_1 WITH NO DATA;
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+-- immediate maintenance
+BEGIN;
+INSERT INTO mv_base_b VALUES(5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+ 5 | 50 | 105
+(5 rows)
+
+UPDATE mv_base_a SET j = 0 WHERE i = 1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 0 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+ 5 | 50 | 105
+(5 rows)
+
+DELETE FROM mv_base_b WHERE (i,k) = (5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 0 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+ROLLBACK;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+-- rename of IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS SELECT DISTINCT * FROM mv_base_a;
+NOTICE: created index "mv_ivm_rename_index" on materialized view "mv_ivm_rename"
+ALTER MATERIALIZED VIEW mv_ivm_rename RENAME COLUMN __ivm_count__ TO xxx;
+ERROR: IVM column can not be renamed
+DROP MATERIALIZED VIEW mv_ivm_rename;
+-- unique index on IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_unique AS SELECT DISTINCT * FROM mv_base_a;
+NOTICE: created index "mv_ivm_unique_index" on materialized view "mv_ivm_unique"
+CREATE UNIQUE INDEX ON mv_ivm_unique(__ivm_count__);
+ERROR: unique index creation on IVM columns is not supported
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__));
+ERROR: unique index creation on IVM columns is not supported
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__ + 1));
+ERROR: unique index creation on IVM columns is not supported
+DROP MATERIALIZED VIEW mv_ivm_unique;
+-- TRUNCATE a base table in join views
+BEGIN;
+TRUNCATE mv_base_a;
+SELECT * FROM mv_ivm_1;
+ i | j | k
+---+---+---
+(0 rows)
+
+ROLLBACK;
+BEGIN;
+TRUNCATE mv_base_b;
+SELECT * FROM mv_ivm_1;
+ i | j | k
+---+---+---
+(0 rows)
+
+ROLLBACK;
+-- some query syntax
+BEGIN;
+CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql'
+ AS 'SELECT 1' IMMUTABLE;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_func AS SELECT * FROM ivm_func();
+NOTICE: could not create an index on materialized view "mv_ivm_func" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_no_tbl AS SELECT 1;
+NOTICE: could not create an index on materialized view "mv_ivm_no_tbl" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+ROLLBACK;
+-- result of materialized view have DISTINCT clause or the duplicate result.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_duplicate AS SELECT j FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_duplicate" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_distinct AS SELECT DISTINCT j FROM mv_base_a;
+NOTICE: created index "mv_ivm_distinct_index" on materialized view "mv_ivm_distinct"
+INSERT INTO mv_base_a VALUES(6,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 20
+ 30
+ 40
+ 50
+(6 rows)
+
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+ROLLBACK;
+-- support SUM(), COUNT() and AVG() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 120 | 2 | 60.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+UPDATE mv_base_a SET j = 200 WHERE (i,j) = (2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+----------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 220 | 2 | 110.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (2,200);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+ROLLBACK;
+-- support COUNT(*) aggregate function
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ i | sum | count
+---+-----+-------
+ 1 | 10 | 1
+ 2 | 20 | 1
+ 3 | 30 | 1
+ 4 | 40 | 1
+ 5 | 50 | 1
+(5 rows)
+
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ i | sum | count
+---+-----+-------
+ 1 | 10 | 1
+ 2 | 120 | 2
+ 3 | 30 | 1
+ 4 | 40 | 1
+ 5 | 50 | 1
+(5 rows)
+
+ROLLBACK;
+-- TRUNCATE a base table in aggregate views
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+TRUNCATE mv_base_a;
+SELECT sum, count FROM mv_ivm_agg;
+ sum | count
+-----+-------
+(0 rows)
+
+SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+ i | sum | count
+---+-----+-------
+(0 rows)
+
+ROLLBACK;
+-- support aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_group" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+---------------------
+ 150 | 5 | 30.0000000000000000
+(1 row)
+
+INSERT INTO mv_base_a VALUES(6,60);
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+---------------------
+ 210 | 6 | 35.0000000000000000
+(1 row)
+
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+ROLLBACK;
+-- TRUNCATE a base table in aggregate views without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_group" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+TRUNCATE mv_base_a;
+SELECT sum, count, avg FROM mv_ivm_group;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+ROLLBACK;
+-- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_avg_bug AS SELECT i, SUM(j), COUNT(j), AVG(j) FROM mv_base_A GROUP BY i;
+NOTICE: created index "mv_ivm_avg_bug_index" on materialized view "mv_ivm_avg_bug"
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+INSERT INTO mv_base_a VALUES
+ (1,0),
+ (1,0),
+ (2,30),
+ (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 3 | 3.3333333333333333
+ 2 | 80 | 3 | 26.6666666666666667
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (1,0);
+DELETE FROM mv_base_a WHERE (i,j) = (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+ROLLBACK;
+-- support MIN(), MAX() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_min_max_index" on materialized view "mv_ivm_min_max"
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 10 | 10
+ 2 | 20 | 20
+ 3 | 30 | 30
+ 4 | 40 | 40
+ 5 | 50 | 50
+(5 rows)
+
+INSERT INTO mv_base_a VALUES
+ (1,11), (1,12),
+ (2,21), (2,22),
+ (3,31), (3,32),
+ (4,41), (4,42),
+ (5,51), (5,52);
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 10 | 12
+ 2 | 20 | 22
+ 3 | 30 | 32
+ 4 | 40 | 42
+ 5 | 50 | 52
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) IN ((1,10), (2,21), (3,32));
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 11 | 12
+ 2 | 20 | 22
+ 3 | 30 | 31
+ 4 | 40 | 42
+ 5 | 50 | 52
+(5 rows)
+
+ROLLBACK;
+-- support MIN(), MAX() aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT MIN(j), MAX(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_min_max" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 10 | 50
+(1 row)
+
+INSERT INTO mv_base_a VALUES
+ (0,0), (6,60), (7,70);
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 0 | 70
+(1 row)
+
+DELETE FROM mv_base_a WHERE (i,j) IN ((0,0), (7,70));
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 10 | 60
+(1 row)
+
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ |
+(1 row)
+
+ROLLBACK;
+-- Test MIN/MAX after search_path change
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min AS SELECT MIN(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_min" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 10
+(1 row)
+
+CREATE SCHEMA myschema;
+GRANT ALL ON SCHEMA myschema TO public;
+CREATE TABLE myschema.mv_base_a (j int);
+INSERT INTO myschema.mv_base_a VALUES (1);
+DELETE FROM mv_base_a WHERE (i,j) = (1,10);
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 20
+(1 row)
+
+SET search_path TO myschema,public,pg_catalog;
+DELETE FROM public.mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 30
+(1 row)
+
+ROLLBACK;
+-- aggregate views with column names specified
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ a | sum
+---+------
+ 1 | 110
+ 2 | 2200
+ 3 | 300
+ 4 | 40
+ 5 | 50
+(5 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ a | b
+---+------
+ 1 | 110
+ 2 | 2200
+ 3 | 300
+ 4 | 40
+ 5 | 50
+(5 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b,c) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+ERROR: too many column names were specified
+ROLLBACK;
+-- support self join view and multiple change on the same table
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_self(v1, v2) AS
+ SELECT t1.v, t2.v FROM base_t AS t1 JOIN base_t AS t2 ON t1.i = t2.i;
+NOTICE: could not create an index on materialized view "mv_self" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+----+----
+ 10 | 10
+ 20 | 20
+ 30 | 30
+(3 rows)
+
+INSERT INTO base_t VALUES (4,40);
+DELETE FROM base_t WHERE i = 1;
+UPDATE base_t SET v = v*10 WHERE i=2;
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+-----+-----
+ 30 | 30
+ 40 | 40
+ 200 | 200
+(3 rows)
+
+WITH
+ ins_t1 AS (INSERT INTO base_t VALUES (5,50) RETURNING 1),
+ ins_t2 AS (INSERT INTO base_t VALUES (6,60) RETURNING 1),
+ upd_t AS (UPDATE base_t SET v = v + 100 RETURNING 1),
+ dlt_t AS (DELETE FROM base_t WHERE i IN (4,5) RETURNING 1)
+SELECT NULL;
+ ?column?
+----------
+
+(1 row)
+
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+-----+-----
+ 50 | 50
+ 60 | 60
+ 130 | 130
+ 300 | 300
+(4 rows)
+
+--- with sub-transactions
+SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,70);
+RELEASE SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,77);
+SELECT * FROM mv_self ORDER BY v1, v2;
+ v1 | v2
+-----+-----
+ 50 | 50
+ 60 | 60
+ 70 | 70
+ 70 | 77
+ 77 | 70
+ 77 | 77
+ 130 | 130
+ 300 | 300
+(8 rows)
+
+ROLLBACK;
+-- support simultaneous table changes
+BEGIN;
+CREATE TABLE base_r (i int, v int);
+CREATE TABLE base_s (i int, v int);
+INSERT INTO base_r VALUES (1, 10), (2, 20), (3, 30);
+INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300);
+CREATE INCREMENTAL MATERIALIZED VIEW mv(v1, v2) AS
+ SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i);
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY v1;
+ v1 | v2
+----+-----
+ 10 | 100
+ 20 | 200
+ 30 | 300
+(3 rows)
+
+WITH
+ ins_r AS (INSERT INTO base_r VALUES (1,11) RETURNING 1),
+ ins_r2 AS (INSERT INTO base_r VALUES (3,33) RETURNING 1),
+ ins_s AS (INSERT INTO base_s VALUES (2,222) RETURNING 1),
+ upd_r AS (UPDATE base_r SET v = v + 1000 WHERE i = 2 RETURNING 1),
+ dlt_s AS (DELETE FROM base_s WHERE i = 3 RETURNING 1)
+SELECT NULL;
+ ?column?
+----------
+
+(1 row)
+
+SELECT * FROM mv ORDER BY v1;
+ v1 | v2
+------+-----
+ 10 | 100
+ 11 | 100
+ 1020 | 200
+ 1020 | 222
+(4 rows)
+
+ROLLBACK;
+-- support foreign reference constraints
+BEGIN;
+CREATE TABLE ri1 (i int PRIMARY KEY);
+CREATE TABLE ri2 (i int PRIMARY KEY REFERENCES ri1(i) ON UPDATE CASCADE ON DELETE CASCADE, v int);
+INSERT INTO ri1 VALUES (1),(2),(3);
+INSERT INTO ri2 VALUES (1),(2),(3);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ri(i1, i2) AS
+ SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i);
+NOTICE: created index "mv_ri_index" on materialized view "mv_ri"
+SELECT * FROM mv_ri ORDER BY i1;
+ i1 | i2
+----+----
+ 1 | 1
+ 2 | 2
+ 3 | 3
+(3 rows)
+
+UPDATE ri1 SET i=10 where i=1;
+DELETE FROM ri1 WHERE i=2;
+SELECT * FROM mv_ri ORDER BY i2;
+ i1 | i2
+----+----
+ 3 | 3
+ 10 | 10
+(2 rows)
+
+ROLLBACK;
+-- views including NULL
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1,10),(2, NULL);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY i;
+ i | v
+---+----
+ 1 | 10
+ 2 |
+(2 rows)
+
+UPDATE base_t SET v = 20 WHERE i = 2;
+SELECT * FROM mv ORDER BY i;
+ i | v
+---+----
+ 1 | 10
+ 2 | 20
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY i;
+ i
+---
+(0 rows)
+
+INSERT INTO base_t VALUES (1),(NULL);
+SELECT * FROM mv ORDER BY i;
+ i
+---
+ 1
+
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, sum(v) FROM base_t GROUP BY i;
+NOTICE: created index "mv_index" on materialized view "mv"
+SELECT * FROM mv ORDER BY i;
+ i | sum
+---+-----
+ 1 | 30
+ | 3
+(2 rows)
+
+UPDATE base_t SET v = v * 10;
+SELECT * FROM mv ORDER BY i;
+ i | sum
+---+-----
+ 1 | 300
+ | 30
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, min(v), max(v) FROM base_t GROUP BY i;
+NOTICE: created index "mv_index" on materialized view "mv"
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 1 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 1;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 3;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 5;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 4
+(1 row)
+
+ROLLBACK;
+-- IMMV containing user defined type
+BEGIN;
+CREATE TYPE mytype;
+CREATE FUNCTION mytype_in(cstring)
+ RETURNS mytype AS 'int4in'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+NOTICE: return type mytype is only a shell
+CREATE FUNCTION mytype_out(mytype)
+ RETURNS cstring AS 'int4out'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+NOTICE: argument type mytype is only a shell
+CREATE TYPE mytype (
+ LIKE = int4,
+ INPUT = mytype_in,
+ OUTPUT = mytype_out
+);
+CREATE FUNCTION mytype_eq(mytype, mytype)
+ RETURNS bool AS 'int4eq'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_lt(mytype, mytype)
+ RETURNS bool AS 'int4lt'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_cmp(mytype, mytype)
+ RETURNS integer AS 'btint4cmp'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE OPERATOR = (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_eq);
+CREATE OPERATOR < (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_lt);
+CREATE OPERATOR CLASS mytype_ops
+ DEFAULT FOR TYPE mytype USING btree AS
+ OPERATOR 1 <,
+ OPERATOR 3 = ,
+ FUNCTION 1 mytype_cmp(mytype,mytype);
+CREATE TABLE t_mytype (x mytype);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_mytype AS
+ SELECT * FROM t_mytype;
+NOTICE: could not create an index on materialized view "mv_mytype" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+INSERT INTO t_mytype VALUES ('1'::mytype);
+SELECT * FROM mv_mytype;
+ x
+---
+ 1
+(1 row)
+
+ROLLBACK;
+-- outer join is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv(a,b) AS SELECT a.i, b.i FROM mv_base_a a LEFT JOIN mv_base_b b ON a.i=b.i;
+ERROR: OUTER JOIN is not supported on incrementally maintainable materialized view
+-- CTE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS
+ WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i;
+ERROR: CTE is not supported on incrementally maintainable materialized view
+-- contain system column
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm01 AS SELECT i,j,xmin FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT i,j,xmin::text AS x_min FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm06 AS SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+-- contain subquery
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm03 AS SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 );
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT * FROM mv_base_b) b WHERE a.i = b.i;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm05 AS SELECT i,j, (SELECT k FROM mv_base_b b WHERE a.i = b.i) FROM mv_base_a a;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+-- contain ORDER BY
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) ORDER BY i,j,k;
+ERROR: ORDER BY clause is not supported on incrementally maintainable materialized view
+-- contain HAVING
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) GROUP BY i,j,k HAVING SUM(i) > 5;
+ERROR: HAVING clause is not supported on incrementally maintainable materialized view
+-- contain view or materialized view
+CREATE VIEW b_view AS SELECT i,k FROM mv_base_b;
+CREATE MATERIALIZED VIEW b_mview AS SELECT i,k FROM mv_base_b;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT a.i,a.j FROM mv_base_a a,b_view b WHERE a.i = b.i;
+ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT a.i,a.j FROM mv_base_a a,b_mview b WHERE a.i = b.i;
+ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm09 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) b WHERE a.i = b.i;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm10 AS SELECT a.i,a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) OR a.i > 5;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+-- contain mutable functions
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+ERROR: mutable function is not supported on incrementally maintainable materialized view
+HINT: functions must be marked IMMUTABLE
+-- LIMIT/OFFSET is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm13 AS SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5;
+ERROR: LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view
+-- DISTINCT ON is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm14 AS SELECT DISTINCT ON(i) i, j FROM mv_base_a;
+ERROR: DISTINCT ON is not supported on incrementally maintainable materialized view
+-- TABLESAMPLE clause is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm15 AS SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50);
+ERROR: TABLESAMPLE clause is not supported on incrementally maintainable materialized view
+-- window functions are not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm16 AS SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a;
+ERROR: window functions are not supported on incrementally maintainable materialized view
+-- aggregate function with some options is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm17 AS SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a;
+ERROR: aggregate function with FILTER clause is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm18 AS SELECT COUNT(DISTINCT i) FROM mv_base_a;
+ERROR: aggregate function with DISTINCT arguments is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm19 AS SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a;
+ERROR: aggregate function with ORDER clause is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm20 AS SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),());
+ERROR: GROUPING SETS, ROLLUP, or CUBE clauses is not supported on incrementally maintainable materialized view
+-- inheritance parent is not supported
+BEGIN;
+CREATE TABLE parent (i int, v int);
+CREATE TABLE child_a(options text) INHERITS(parent);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm21 AS SELECT * FROM parent;
+ERROR: inheritance parent is not supported on incrementally maintainable materialized view
+ROLLBACK;
+-- UNION statement is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm22 AS SELECT i,j FROM mv_base_a UNION ALL SELECT i,k FROM mv_base_b;;
+ERROR: UNION/INTERSECT/EXCEPT statements are not supported on incrementally maintainable materialized view
+-- empty target list is not allowed with IVM
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm25 AS SELECT FROM mv_base_a;
+ERROR: empty target list is not supported on incrementally maintainable materialized view
+-- FOR UPDATE/SHARE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm26 AS SELECT i,j FROM mv_base_a FOR UPDATE;
+ERROR: FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view
+-- tartget list cannot contain ivm column that start with '__ivm'
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm28 AS SELECT i AS "__ivm_count__" FROM mv_base_a;
+ERROR: column name __ivm_count__ is not supported on incrementally maintainable materialized view
+-- expressions specified in GROUP BY must appear in the target list.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm29 AS SELECT COUNT(i) FROM mv_base_a GROUP BY i;
+ERROR: GROUP BY expression not appearing in select list is not supported on incrementally maintainable materialized view
+-- experssions containing an aggregate is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm30 AS SELECT sum(i)*0.5 FROM mv_base_a;
+ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm31 AS SELECT sum(i)/sum(j) FROM mv_base_a;
+ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view
+-- VALUES is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_only_values1 AS values(1);
+ERROR: VALUES is not supported on incrementally maintainable materialized view
+-- views containing base tables with Row Level Security
+DROP USER IF EXISTS ivm_admin;
+NOTICE: role "ivm_admin" does not exist, skipping
+DROP USER IF EXISTS ivm_user;
+NOTICE: role "ivm_user" does not exist, skipping
+CREATE USER ivm_admin;
+CREATE USER ivm_user;
+--- create a table with RLS
+SET SESSION AUTHORIZATION ivm_admin;
+CREATE TABLE rls_tbl(id int, data text, owner name);
+INSERT INTO rls_tbl VALUES
+ (1,'foo','ivm_user'),
+ (2,'bar','postgres');
+CREATE TABLE num_tbl(id int, num text);
+INSERT INTO num_tbl VALUES
+ (1,'one'),
+ (2,'two'),
+ (3,'three'),
+ (4,'four'),
+ (5,'five'),
+ (6,'six');
+--- Users can access only their own rows
+CREATE POLICY rls_tbl_policy ON rls_tbl FOR SELECT TO PUBLIC USING(owner = current_user);
+ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
+GRANT ALL on rls_tbl TO PUBLIC;
+GRANT ALL on num_tbl TO PUBLIC;
+--- create a view owned by ivm_user
+SET SESSION AUTHORIZATION ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls AS SELECT * FROM rls_tbl;
+NOTICE: could not create an index on materialized view "ivm_rls" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+------+----------
+ 1 | foo | ivm_user
+(1 row)
+
+RESET SESSION AUTHORIZATION;
+--- inserts rows owned by different users
+INSERT INTO rls_tbl VALUES
+ (3,'baz','ivm_user'),
+ (4,'qux','postgres');
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+------+----------
+ 1 | foo | ivm_user
+ 3 | baz | ivm_user
+(2 rows)
+
+--- combination of diffent kinds of commands
+WITH
+ i AS (INSERT INTO rls_tbl VALUES(5,'quux','postgres'), (6,'corge','ivm_user')),
+ u AS (UPDATE rls_tbl SET owner = 'postgres' WHERE id = 1),
+ u2 AS (UPDATE rls_tbl SET owner = 'ivm_user' WHERE id = 2)
+SELECT;
+--
+(1 row)
+
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+-------+----------
+ 2 | bar | ivm_user
+ 3 | baz | ivm_user
+ 6 | corge | ivm_user
+(3 rows)
+
+---
+SET SESSION AUTHORIZATION ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls2 AS SELECT * FROM rls_tbl JOIN num_tbl USING(id);
+NOTICE: could not create an index on materialized view "ivm_rls2" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+RESET SESSION AUTHORIZATION;
+WITH
+ x AS (UPDATE rls_tbl SET data = data || '_2' where id in (3,4)),
+ y AS (UPDATE num_tbl SET num = num || '_2' where id in (3,4))
+SELECT;
+--
+(1 row)
+
+SELECT * FROM ivm_rls2 ORDER BY 1,2,3;
+ id | data | owner | num
+----+-------+----------+---------
+ 2 | bar | ivm_user | two
+ 3 | baz_2 | ivm_user | three_2
+ 6 | corge | ivm_user | six
+(3 rows)
+
+-- automatic index creation
+BEGIN;
+CREATE TABLE base_a (i int primary key, j int);
+CREATE TABLE base_b (i int primary key, j int);
+--- group by: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx1 AS SELECT i, sum(j) FROM base_a GROUP BY i;
+NOTICE: created index "mv_idx1_index" on materialized view "mv_idx1"
+--- distinct: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx2 AS SELECT DISTINCT j FROM base_a;
+NOTICE: created index "mv_idx2_index" on materialized view "mv_idx2"
+--- with all pkey columns: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx3(i_a, i_b) AS SELECT a.i, b.i FROM base_a a, base_b b;
+NOTICE: created index "mv_idx3_index" on materialized view "mv_idx3"
+--- missing some pkey columns: no index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx4 AS SELECT j FROM base_a;
+NOTICE: could not create an index on materialized view "mv_idx4" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx5 AS SELECT a.i, b.j FROM base_a a, base_b b;
+NOTICE: could not create an index on materialized view "mv_idx5" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+-- cleanup
+DROP TABLE rls_tbl CASCADE;
+NOTICE: drop cascades to 2 other objects
+DETAIL: drop cascades to materialized view ivm_rls
+drop cascades to materialized view ivm_rls2
+DROP TABLE num_tbl CASCADE;
+DROP USER ivm_user;
+DROP USER ivm_admin;
+DROP TABLE mv_base_b CASCADE;
+NOTICE: drop cascades to 3 other objects
+DETAIL: drop cascades to materialized view mv_ivm_1
+drop cascades to view b_view
+drop cascades to materialized view b_mview
+DROP TABLE mv_base_a CASCADE;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index cf46fa3359..013f5db7fb 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -78,7 +78,7 @@ test: brin_bloom brin_multi
# psql depends on create_am
# amutils depends on geometry, create_index_spgist, hash_index, brin
# ----------
-test: create_table_like alter_generic alter_operator misc async dbsize merge misc_functions sysviews tsrf tid tidscan tidrangescan collate.icu.utf8 incremental_sort create_role
+test: create_table_like alter_generic alter_operator misc async dbsize merge misc_functions sysviews tsrf tid tidscan tidrangescan collate.icu.utf8 incremental_sort create_role incremental_matview
# collate.*.utf8 tests cannot be run in parallel with each other
test: rules psql psql_crosstab amutils stats_ext collate.linux.utf8 collate.windows.win1252
diff --git a/src/test/regress/sql/incremental_matview.sql b/src/test/regress/sql/incremental_matview.sql
new file mode 100644
index 0000000000..63e26da767
--- /dev/null
+++ b/src/test/regress/sql/incremental_matview.sql
@@ -0,0 +1,534 @@
+-- create a table to use as a basis for views and materialized views in various combinations
+CREATE TABLE mv_base_a (i int, j int);
+INSERT INTO mv_base_a VALUES
+ (1,10),
+ (2,20),
+ (3,30),
+ (4,40),
+ (5,50);
+CREATE TABLE mv_base_b (i int, k int);
+INSERT INTO mv_base_b VALUES
+ (1,101),
+ (2,102),
+ (3,103),
+ (4,104);
+
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_1 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) WITH NO DATA;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+REFRESH MATERIALIZED VIEW mv_ivm_1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+
+-- REFRESH WITH NO DATA
+BEGIN;
+CREATE FUNCTION dummy_ivm_trigger_func() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+
+CREATE CONSTRAINT TRIGGER dummy_ivm_trigger AFTER INSERT
+ON mv_base_a FROM mv_ivm_1 FOR EACH ROW
+EXECUTE PROCEDURE dummy_ivm_trigger_func();
+
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+
+REFRESH MATERIALIZED VIEW mv_ivm_1 WITH NO DATA;
+
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ROLLBACK;
+
+-- immediate maintenance
+BEGIN;
+INSERT INTO mv_base_b VALUES(5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+UPDATE mv_base_a SET j = 0 WHERE i = 1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+DELETE FROM mv_base_b WHERE (i,k) = (5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ROLLBACK;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+
+-- rename of IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS SELECT DISTINCT * FROM mv_base_a;
+ALTER MATERIALIZED VIEW mv_ivm_rename RENAME COLUMN __ivm_count__ TO xxx;
+DROP MATERIALIZED VIEW mv_ivm_rename;
+
+-- unique index on IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_unique AS SELECT DISTINCT * FROM mv_base_a;
+CREATE UNIQUE INDEX ON mv_ivm_unique(__ivm_count__);
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__));
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__ + 1));
+DROP MATERIALIZED VIEW mv_ivm_unique;
+
+-- TRUNCATE a base table in join views
+BEGIN;
+TRUNCATE mv_base_a;
+SELECT * FROM mv_ivm_1;
+ROLLBACK;
+
+BEGIN;
+TRUNCATE mv_base_b;
+SELECT * FROM mv_ivm_1;
+ROLLBACK;
+
+-- some query syntax
+BEGIN;
+CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql'
+ AS 'SELECT 1' IMMUTABLE;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_func AS SELECT * FROM ivm_func();
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_no_tbl AS SELECT 1;
+ROLLBACK;
+
+-- result of materialized view have DISTINCT clause or the duplicate result.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_duplicate AS SELECT j FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_distinct AS SELECT DISTINCT j FROM mv_base_a;
+INSERT INTO mv_base_a VALUES(6,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+DELETE FROM mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ROLLBACK;
+
+-- support SUM(), COUNT() and AVG() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+UPDATE mv_base_a SET j = 200 WHERE (i,j) = (2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+DELETE FROM mv_base_a WHERE (i,j) = (2,200);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ROLLBACK;
+
+-- support COUNT(*) aggregate function
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ROLLBACK;
+
+-- TRUNCATE a base table in aggregate views
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+TRUNCATE mv_base_a;
+SELECT sum, count FROM mv_ivm_agg;
+SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+ROLLBACK;
+
+-- support aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+INSERT INTO mv_base_a VALUES(6,60);
+SELECT * FROM mv_ivm_group ORDER BY 1;
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ROLLBACK;
+
+-- TRUNCATE a base table in aggregate views without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+TRUNCATE mv_base_a;
+SELECT sum, count, avg FROM mv_ivm_group;
+SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+ROLLBACK;
+
+-- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_avg_bug AS SELECT i, SUM(j), COUNT(j), AVG(j) FROM mv_base_A GROUP BY i;
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES
+ (1,0),
+ (1,0),
+ (2,30),
+ (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+DELETE FROM mv_base_a WHERE (i,j) = (1,0);
+DELETE FROM mv_base_a WHERE (i,j) = (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ROLLBACK;
+
+-- support MIN(), MAX() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES
+ (1,11), (1,12),
+ (2,21), (2,22),
+ (3,31), (3,32),
+ (4,41), (4,42),
+ (5,51), (5,52);
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+DELETE FROM mv_base_a WHERE (i,j) IN ((1,10), (2,21), (3,32));
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ROLLBACK;
+
+-- support MIN(), MAX() aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT MIN(j), MAX(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+INSERT INTO mv_base_a VALUES
+ (0,0), (6,60), (7,70);
+SELECT * FROM mv_ivm_min_max;
+DELETE FROM mv_base_a WHERE (i,j) IN ((0,0), (7,70));
+SELECT * FROM mv_ivm_min_max;
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+ROLLBACK;
+
+-- Test MIN/MAX after search_path change
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min AS SELECT MIN(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_min;
+
+CREATE SCHEMA myschema;
+GRANT ALL ON SCHEMA myschema TO public;
+CREATE TABLE myschema.mv_base_a (j int);
+INSERT INTO myschema.mv_base_a VALUES (1);
+
+DELETE FROM mv_base_a WHERE (i,j) = (1,10);
+SELECT * FROM mv_ivm_min;
+
+SET search_path TO myschema,public,pg_catalog;
+DELETE FROM public.mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_min;
+ROLLBACK;
+
+-- aggregate views with column names specified
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b,c) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+ROLLBACK;
+
+-- support self join view and multiple change on the same table
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_self(v1, v2) AS
+ SELECT t1.v, t2.v FROM base_t AS t1 JOIN base_t AS t2 ON t1.i = t2.i;
+SELECT * FROM mv_self ORDER BY v1;
+INSERT INTO base_t VALUES (4,40);
+DELETE FROM base_t WHERE i = 1;
+UPDATE base_t SET v = v*10 WHERE i=2;
+SELECT * FROM mv_self ORDER BY v1;
+WITH
+ ins_t1 AS (INSERT INTO base_t VALUES (5,50) RETURNING 1),
+ ins_t2 AS (INSERT INTO base_t VALUES (6,60) RETURNING 1),
+ upd_t AS (UPDATE base_t SET v = v + 100 RETURNING 1),
+ dlt_t AS (DELETE FROM base_t WHERE i IN (4,5) RETURNING 1)
+SELECT NULL;
+SELECT * FROM mv_self ORDER BY v1;
+
+--- with sub-transactions
+SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,70);
+RELEASE SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,77);
+SELECT * FROM mv_self ORDER BY v1, v2;
+
+ROLLBACK;
+
+-- support simultaneous table changes
+BEGIN;
+CREATE TABLE base_r (i int, v int);
+CREATE TABLE base_s (i int, v int);
+INSERT INTO base_r VALUES (1, 10), (2, 20), (3, 30);
+INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300);
+CREATE INCREMENTAL MATERIALIZED VIEW mv(v1, v2) AS
+ SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i);
+SELECT * FROM mv ORDER BY v1;
+WITH
+ ins_r AS (INSERT INTO base_r VALUES (1,11) RETURNING 1),
+ ins_r2 AS (INSERT INTO base_r VALUES (3,33) RETURNING 1),
+ ins_s AS (INSERT INTO base_s VALUES (2,222) RETURNING 1),
+ upd_r AS (UPDATE base_r SET v = v + 1000 WHERE i = 2 RETURNING 1),
+ dlt_s AS (DELETE FROM base_s WHERE i = 3 RETURNING 1)
+SELECT NULL;
+SELECT * FROM mv ORDER BY v1;
+ROLLBACK;
+
+-- support foreign reference constraints
+BEGIN;
+CREATE TABLE ri1 (i int PRIMARY KEY);
+CREATE TABLE ri2 (i int PRIMARY KEY REFERENCES ri1(i) ON UPDATE CASCADE ON DELETE CASCADE, v int);
+INSERT INTO ri1 VALUES (1),(2),(3);
+INSERT INTO ri2 VALUES (1),(2),(3);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ri(i1, i2) AS
+ SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i);
+SELECT * FROM mv_ri ORDER BY i1;
+UPDATE ri1 SET i=10 where i=1;
+DELETE FROM ri1 WHERE i=2;
+SELECT * FROM mv_ri ORDER BY i2;
+ROLLBACK;
+
+-- views including NULL
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1,10),(2, NULL);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+SELECT * FROM mv ORDER BY i;
+UPDATE base_t SET v = 20 WHERE i = 2;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+SELECT * FROM mv ORDER BY i;
+INSERT INTO base_t VALUES (1),(NULL);
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, sum(v) FROM base_t GROUP BY i;
+SELECT * FROM mv ORDER BY i;
+UPDATE base_t SET v = v * 10;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, min(v), max(v) FROM base_t GROUP BY i;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 1;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 3;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 5;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+-- IMMV containing user defined type
+BEGIN;
+
+CREATE TYPE mytype;
+CREATE FUNCTION mytype_in(cstring)
+ RETURNS mytype AS 'int4in'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_out(mytype)
+ RETURNS cstring AS 'int4out'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE TYPE mytype (
+ LIKE = int4,
+ INPUT = mytype_in,
+ OUTPUT = mytype_out
+);
+
+CREATE FUNCTION mytype_eq(mytype, mytype)
+ RETURNS bool AS 'int4eq'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_lt(mytype, mytype)
+ RETURNS bool AS 'int4lt'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_cmp(mytype, mytype)
+ RETURNS integer AS 'btint4cmp'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+
+CREATE OPERATOR = (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_eq);
+CREATE OPERATOR < (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_lt);
+
+CREATE OPERATOR CLASS mytype_ops
+ DEFAULT FOR TYPE mytype USING btree AS
+ OPERATOR 1 <,
+ OPERATOR 3 = ,
+ FUNCTION 1 mytype_cmp(mytype,mytype);
+
+CREATE TABLE t_mytype (x mytype);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_mytype AS
+ SELECT * FROM t_mytype;
+INSERT INTO t_mytype VALUES ('1'::mytype);
+SELECT * FROM mv_mytype;
+
+ROLLBACK;
+
+-- outer join is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv(a,b) AS SELECT a.i, b.i FROM mv_base_a a LEFT JOIN mv_base_b b ON a.i=b.i;
+-- CTE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS
+ WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i;
+-- contain system column
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm01 AS SELECT i,j,xmin FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT i,j,xmin::text AS x_min FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm06 AS SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a;
+-- contain subquery
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm03 AS SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 );
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT * FROM mv_base_b) b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm05 AS SELECT i,j, (SELECT k FROM mv_base_b b WHERE a.i = b.i) FROM mv_base_a a;
+-- contain ORDER BY
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) ORDER BY i,j,k;
+-- contain HAVING
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) GROUP BY i,j,k HAVING SUM(i) > 5;
+
+-- contain view or materialized view
+CREATE VIEW b_view AS SELECT i,k FROM mv_base_b;
+CREATE MATERIALIZED VIEW b_mview AS SELECT i,k FROM mv_base_b;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT a.i,a.j FROM mv_base_a a,b_view b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT a.i,a.j FROM mv_base_a a,b_mview b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm09 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm10 AS SELECT a.i,a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) OR a.i > 5;
+
+-- contain mutable functions
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+
+-- LIMIT/OFFSET is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm13 AS SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5;
+
+-- DISTINCT ON is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm14 AS SELECT DISTINCT ON(i) i, j FROM mv_base_a;
+
+-- TABLESAMPLE clause is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm15 AS SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50);
+
+-- window functions are not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm16 AS SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a;
+
+-- aggregate function with some options is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm17 AS SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm18 AS SELECT COUNT(DISTINCT i) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm19 AS SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm20 AS SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),());
+
+-- inheritance parent is not supported
+BEGIN;
+CREATE TABLE parent (i int, v int);
+CREATE TABLE child_a(options text) INHERITS(parent);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm21 AS SELECT * FROM parent;
+ROLLBACK;
+
+-- UNION statement is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm22 AS SELECT i,j FROM mv_base_a UNION ALL SELECT i,k FROM mv_base_b;;
+
+-- empty target list is not allowed with IVM
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm25 AS SELECT FROM mv_base_a;
+
+-- FOR UPDATE/SHARE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm26 AS SELECT i,j FROM mv_base_a FOR UPDATE;
+
+-- tartget list cannot contain ivm column that start with '__ivm'
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm28 AS SELECT i AS "__ivm_count__" FROM mv_base_a;
+
+-- expressions specified in GROUP BY must appear in the target list.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm29 AS SELECT COUNT(i) FROM mv_base_a GROUP BY i;
+
+-- experssions containing an aggregate is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm30 AS SELECT sum(i)*0.5 FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm31 AS SELECT sum(i)/sum(j) FROM mv_base_a;
+
+-- VALUES is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_only_values1 AS values(1);
+
+-- views containing base tables with Row Level Security
+DROP USER IF EXISTS ivm_admin;
+DROP USER IF EXISTS ivm_user;
+CREATE USER ivm_admin;
+CREATE USER ivm_user;
+
+--- create a table with RLS
+SET SESSION AUTHORIZATION ivm_admin;
+CREATE TABLE rls_tbl(id int, data text, owner name);
+INSERT INTO rls_tbl VALUES
+ (1,'foo','ivm_user'),
+ (2,'bar','postgres');
+CREATE TABLE num_tbl(id int, num text);
+INSERT INTO num_tbl VALUES
+ (1,'one'),
+ (2,'two'),
+ (3,'three'),
+ (4,'four'),
+ (5,'five'),
+ (6,'six');
+
+--- Users can access only their own rows
+CREATE POLICY rls_tbl_policy ON rls_tbl FOR SELECT TO PUBLIC USING(owner = current_user);
+ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
+GRANT ALL on rls_tbl TO PUBLIC;
+GRANT ALL on num_tbl TO PUBLIC;
+
+--- create a view owned by ivm_user
+SET SESSION AUTHORIZATION ivm_user;
+
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls AS SELECT * FROM rls_tbl;
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+RESET SESSION AUTHORIZATION;
+
+--- inserts rows owned by different users
+INSERT INTO rls_tbl VALUES
+ (3,'baz','ivm_user'),
+ (4,'qux','postgres');
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+
+--- combination of diffent kinds of commands
+WITH
+ i AS (INSERT INTO rls_tbl VALUES(5,'quux','postgres'), (6,'corge','ivm_user')),
+ u AS (UPDATE rls_tbl SET owner = 'postgres' WHERE id = 1),
+ u2 AS (UPDATE rls_tbl SET owner = 'ivm_user' WHERE id = 2)
+SELECT;
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+
+---
+SET SESSION AUTHORIZATION ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls2 AS SELECT * FROM rls_tbl JOIN num_tbl USING(id);
+RESET SESSION AUTHORIZATION;
+
+WITH
+ x AS (UPDATE rls_tbl SET data = data || '_2' where id in (3,4)),
+ y AS (UPDATE num_tbl SET num = num || '_2' where id in (3,4))
+SELECT;
+SELECT * FROM ivm_rls2 ORDER BY 1,2,3;
+
+-- automatic index creation
+BEGIN;
+CREATE TABLE base_a (i int primary key, j int);
+CREATE TABLE base_b (i int primary key, j int);
+
+--- group by: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx1 AS SELECT i, sum(j) FROM base_a GROUP BY i;
+
+--- distinct: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx2 AS SELECT DISTINCT j FROM base_a;
+
+--- with all pkey columns: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx3(i_a, i_b) AS SELECT a.i, b.i FROM base_a a, base_b b;
+
+--- missing some pkey columns: no index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx4 AS SELECT j FROM base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx5 AS SELECT a.i, b.j FROM base_a a, base_b b;
+
+-- cleanup
+
+DROP TABLE rls_tbl CASCADE;
+DROP TABLE num_tbl CASCADE;
+DROP USER ivm_user;
+DROP USER ivm_admin;
+
+DROP TABLE mv_base_b CASCADE;
+DROP TABLE mv_base_a CASCADE;
--
2.25.1
v28-0011-Add-documentations-about-Incremental-View-Mainte.patchtext/x-diff; name=v28-0011-Add-documentations-about-Incremental-View-Mainte.patchDownload
From 39c2bd57c6809b9093331aa8213fb283fd445b0f Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:25:34 +0900
Subject: [PATCH v28 11/11] Add documentations about Incremental View
Maintenance
---
doc/src/sgml/catalogs.sgml | 9 +
.../sgml/ref/create_materialized_view.sgml | 131 +++++-
.../sgml/ref/refresh_materialized_view.sgml | 8 +-
doc/src/sgml/rules.sgml | 443 ++++++++++++++++++
4 files changed, 587 insertions(+), 4 deletions(-)
diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index ed32ca0349..51378358a1 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -2223,6 +2223,15 @@ SCRAM-SHA-256$<replaceable><iteration count></replaceable>:<replaceable>&l
</para></entry>
</row>
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>relisivm</structfield> <type>bool</type>
+ </para>
+ <para>
+ True if materialized view enables incremental view maintenance
+ </para></entry>
+ </row>
+
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>relrewrite</structfield> <type>oid</type>
diff --git a/doc/src/sgml/ref/create_materialized_view.sgml b/doc/src/sgml/ref/create_materialized_view.sgml
index 0d2fea2b97..52a4d206b1 100644
--- a/doc/src/sgml/ref/create_materialized_view.sgml
+++ b/doc/src/sgml/ref/create_materialized_view.sgml
@@ -21,7 +21,7 @@ PostgreSQL documentation
<refsynopsisdiv>
<synopsis>
-CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
+CREATE [ INCREMENTAL ] MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
[ (<replaceable>column_name</replaceable> [, ...] ) ]
[ USING <replaceable class="parameter">method</replaceable> ]
[ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
@@ -60,6 +60,132 @@ CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
<title>Parameters</title>
<variablelist>
+ <varlistentry>
+ <term><literal>INCREMENTAL</literal></term>
+ <listitem>
+ <para>
+ If specified, some triggers are automatically created so that the rows
+ of the materialized view are immediately updated when base tables of the
+ materialized view are updated. In general, this allows faster update of
+ the materialized view at a price of slower update of the base tables
+ because the triggers will be invoked. We call this form of materialized
+ view as "Incrementally Maintainable Materialized View" (IMMV).
+ </para>
+ <para>
+ When <acronym>IMMV</acronym> is defined without using <command>WITH NO DATA</command>,
+ a unique index is created on the view automatically if possible. If the view
+ definition query has a GROUP BY clause, a unique index is created on the columns
+ of GROUP BY expressions. Also, if the view has DISTINCT clause, a unique index
+ is created on all columns in the target list. Otherwise, if the view contains all
+ primary key attritubes of its base tables in the target list, a unique index is
+ created on these attritubes. In other cases, no index is created.
+ </para>
+ <para>
+ There are restrictions of query definitions allowed to use this
+ option. The following are supported in query definitions for IMMV:
+ <itemizedlist>
+
+ <listitem>
+ <para>
+ Inner joins (including self-joins).
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Some built-in aggregate functions (count, sum, avg, min, max) without a HAVING
+ clause.
+ </para>
+ </listitem>
+ </itemizedlist>
+
+ Unsupported queries with this option include the following:
+
+ <itemizedlist>
+ <listitem>
+ <para>
+ Outer joins.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Sub-queries.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Aggregate functions other than built-in count, sum, avg, min and max.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ Aggregate functions with a HAVING clause.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ DISTINCT ON, WINDOW, VALUES, LIMIT and OFFSET clause.
+ </para>
+ </listitem>
+ </itemizedlist>
+
+ Other restrictions include:
+ <itemizedlist>
+
+ <listitem>
+ <para>
+ IMMVs must be based on simple base tables. It's not supported to
+ create them on top of views or materialized views.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ When the TRUNCATE command is executed on a base table,
+ no changes are made to the materialized view.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ It is not supported to include system columns in an IMMV.
+ <programlisting>
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+ERROR: system column is not supported with IVM
+ </programlisting>
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Non-immutable functions are not supported.
+ <programlisting>
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+ERROR: functions in IMMV must be marked IMMUTABLE
+ </programlisting>
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ IMMVs do not support expressions that contains aggregates
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Logical replication does not support IMMVs.
+ </para>
+ </listitem>
+
+ </itemizedlist>
+
+ </para>
+ </listitem>
+ </varlistentry>
+
<varlistentry>
<term><literal>IF NOT EXISTS</literal></term>
<listitem>
@@ -155,7 +281,8 @@ CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
This clause specifies whether or not the materialized view should be
populated at creation time. If not, the materialized view will be
flagged as unscannable and cannot be queried until <command>REFRESH
- MATERIALIZED VIEW</command> is used.
+ MATERIALIZED VIEW</command> is used. Also, if the view is IMMV,
+ triggers for maintaining the view are not created.
</para>
</listitem>
</varlistentry>
diff --git a/doc/src/sgml/ref/refresh_materialized_view.sgml b/doc/src/sgml/ref/refresh_materialized_view.sgml
index 4d79b6ae7f..4e27e29e35 100644
--- a/doc/src/sgml/ref/refresh_materialized_view.sgml
+++ b/doc/src/sgml/ref/refresh_materialized_view.sgml
@@ -38,9 +38,13 @@ REFRESH MATERIALIZED VIEW [ CONCURRENTLY ] <replaceable class="parameter">name</
privilege on the materialized view. The old contents are discarded. If
<literal>WITH DATA</literal> is specified (or defaults) the backing query
is executed to provide the new data, and the materialized view is left in a
- scannable state. If <literal>WITH NO DATA</literal> is specified no new
+ scannable state. If the view is an incrementally maintainable materialized
+ view (IMMV) and was 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 <literal>WITH NO DATA</literal> is specified no new
data is generated and the materialized view is left in an unscannable
- state.
+ state. If the view is IMMV, the triggers are dropped.
</para>
<para>
<literal>CONCURRENTLY</literal> and <literal>WITH NO DATA</literal> may not
diff --git a/doc/src/sgml/rules.sgml b/doc/src/sgml/rules.sgml
index d229b94d39..d000beacdf 100644
--- a/doc/src/sgml/rules.sgml
+++ b/doc/src/sgml/rules.sgml
@@ -1096,6 +1096,449 @@ SELECT word FROM words ORDER BY word <-> 'caterpiler' LIMIT 10;
</sect1>
+<sect1 id="rules-ivm">
+<title>Incremental View Maintenance</title>
+
+<indexterm zone="rules-ivm">
+ <primary>incremental view maintenance</primary>
+</indexterm>
+
+<indexterm zone="rules-ivm">
+ <primary>materialized view</primary>
+ <secondary>incremental view maintenance</secondary>
+</indexterm>
+
+<indexterm zone="rules-ivm">
+ <primary>view</primary>
+ <secondary>incremental view maintenance</secondary>
+</indexterm>
+
+<sect2 id="rules-ivm-overview">
+<title>Overview</title>
+
+<para>
+ Incremental View Maintenance (<acronym>IVM</acronym>) is a way to make
+ materialized views up-to-date in which only incremental changes are computed
+ and applied on views rather than recomputing the contents from scratch as
+ <command>REFRESH MATERIALIZED VIEW</command> does. <acronym>IVM</acronym>
+ can update materialized views more efficiently than recomputation when only
+ small parts of the view are changed.
+</para>
+
+<para>
+ There are two approaches with regard to timing of view maintenance:
+ immediate and deferred. In immediate maintenance, views are updated in the
+ same transaction that its base table is modified. In deferred maintenance,
+ views are updated after the transaction is committed, for example, when the
+ view is accessed, as a response to user command like <command>REFRESH
+ MATERIALIZED VIEW</command>, or periodically in background, and so on.
+ <productname>PostgreSQL</productname> currently implements only a kind of
+ immediate maintenance, in which materialized views are updated immediately
+ in AFTER triggers when a base table is modified.
+</para>
+
+<para>
+ To create materialized views supporting <acronym>IVM</acronym>, use the
+ <command>CREATE INCREMENTAL MATERIALIZED VIEW</command>, for example:
+<programlisting>
+CREATE <emphasis>INCREMENTAL</emphasis> MATERIALIZED VIEW mymatview AS SELECT * FROM mytab;
+</programlisting>
+ When a materialized view is created with the <literal>INCREMENTAL</literal>
+ keyword, some triggers are automatically created so that the view's contents are
+ immediately updated when its base tables are modified. We call this form
+ of materialized view an Incrementally Maintainable Materialized View
+ (<acronym>IMMV</acronym>).
+<programlisting>
+postgres=# CREATE INCREMENTAL MATERIALIZED VIEW m AS SELECT * FROM t0;
+NOTICE: could not create an index on materialized view "m" automatically
+HINT: Create an index on the materialized view for effcient incremental maintenance.
+SELECT 3
+postgres=# SELECT * FROM m;
+ i
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+postgres=# INSERT INTO t0 VALUES (4);
+INSERT 0 1
+postgres=# SELECT * FROM m; -- automatically updated
+ i
+---
+ 1
+ 2
+ 3
+ 4
+(4 rows)
+</programlisting>
+</para>
+
+<para>
+ Some <acronym>IMMV</acronym>s have hidden columns which are added
+ automatically when a materialized view is created. Their name starts
+ with <literal>__ivm_</literal> and they contain information required
+ for maintaining the <acronym>IMMV</acronym>. Such columns are not visible
+ when the <acronym>IMMV</acronym> is accessed by <literal>SELECT *</literal>
+ but are visible if the column name is explicitly specified in the target
+ list. We can also see the hidden columns in <literal>\d</literal>
+ meta-commands of <command>psql</command> commands.
+</para>
+
+<para>
+ In general, <acronym>IMMV</acronym>s allow faster updates of materialized
+ views at the price of slower updates to their base tables. Updates of
+ <acronym>IMMV</acronym> is slower because triggers will be invoked and the
+ view is updated in triggers per modification statement.
+</para>
+
+<para>
+ For example, suppose a normal materialized view defined as below:
+
+<programlisting>
+test=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm AS
+ SELECT a.aid, b.bid, a.abalance, b.bbalance
+ FROM pgbench_accounts a JOIN pgbench_branches b USING(bid);
+SELECT 10000000
+
+</programlisting>
+
+ Updating a tuple in a base table of this materialized view is rapid but the
+ <command>REFRESH MATERIALIZED VIEW</command> command on this view takes a long time:
+
+<programlisting>
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 0.990 ms
+
+test=# REFRESH MATERIALIZED VIEW mv_normal ;
+REFRESH MATERIALIZED VIEW
+Time: 33533.952 ms (00:33.534)
+</programlisting>
+</para>
+
+<para>
+ On the other hand, after creating <acronym>IMMV</acronym> with the same view
+ definition as below:
+
+<programlisting>
+test=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm AS
+ SELECT a.aid, b.bid, a.abalance, b.bbalance
+ FROM pgbench_accounts a JOIN pgbench_branches b USING(bid);
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+NOTICE: created index "mv_ivm_index" on materialized view "mv_ivm"
+</programlisting>
+
+ updating a tuple in a base table takes more than the normal view,
+ but its content is updated automatically and this is faster than the
+ <command>REFRESH MATERIALIZED VIEW</command> command.
+
+<programlisting>
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 13.068 ms
+</programlisting>
+
+</para>
+
+<para>
+ Appropriate indexes on <acronym>IMMV</acronym>s are necessary for
+ efficient <acronym>IVM</acronym> because it looks for tuples to be
+ updated in <acronym>IMMV</acronym>. If there are no indexes, it
+ will take a long time.
+</para>
+
+<para>
+ Therefore, when <acronym>IMMV</acronym> is defined, a unique index is created on the view
+ automatically if possible. If the view definition query has a GROUP BY clause, a unique
+ index is created on the columns of GROUP BY expressions. Also, if the view has DISTINCT
+ clause, a unique index is created on all columns in the target list. Otherwise, if the
+ view contains all primary key attritubes of its base tables in the target list, a unique
+ index is created on these attritubes. In other cases, no index is created.
+</para>
+
+<para>
+ In the previous example, a unique index "mv_ivm_index" is created on aid and bid
+ columns of materialized view "mv_ivm", and this enables the rapid update of the view.
+ Dropping this index make updating the view take a loger time.
+<programlisting>
+test=# DROP INDEX mv_ivm_index;
+DROP INDEX
+Time: 67.081 ms
+
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 16386.245 ms (00:16.386)
+</programlisting>
+
+</para>
+
+<para>
+ <acronym>IVM</acronym> is effective when we want to keep a materialized
+ view up-to-date and small fraction of a base table is modified
+ infrequently. Due to the overhead of immediate maintenance, <acronym>IVM</acronym>
+ 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, <acronym>IVM</acronym> is not effective and the cost of
+ maintenance can be larger than the <command>REFRESH MATERIALIZED VIEW</command>
+ command. In such situation, we can use <command>REFRESH MATERIALIZED VIEW</command>
+ and specify <literal>WITH NO DATA</literal> to disable immediate
+ maintenance before modifying a base table. After a base table modification,
+ execute the <command>REFRESH MATERIALIZED VIEW</command> (with <literal>WITH DATA</literal>)
+ command to refresh the view data and enable immediate maintenance.
+</para>
+
+</sect2>
+
+<sect2>
+<title>Supported View Definitions and Restrictions</title>
+
+<para>
+ Currently, we can create <acronym>IMMV</acronym>s using inner joins, and some
+ aggregates. However, several restrictions apply to the definition of IMMV.
+</para>
+
+<sect3>
+<title>Joins</title>
+<para>
+ Inner joins including self-join are supported. Outer joins are not supported.
+</para>
+</sect3>
+
+<sect3>
+<title>Aggregates</title>
+<para>
+ Supported aggregate functions are <function>count</function>, <function>sum</function>,
+ <function>avg</function>, <function>min</function>, and <function>max</function>.
+ Currently, only built-in aggregate functions are supported and user defined
+ aggregates cannot be used. When a base table is modified, the new aggregated
+ values are incrementally calculated using the old aggregated values and values
+ of related hidden columns stored in <acronym>IMMV</acronym>.
+</para>
+
+<para>
+ Note that for <function>min</function> or <function>max</function>, the new values
+ could be re-calculated from base tables with regard to the affected groups when a
+ tuple containing the current minimal or maximal values are deleted from a base table.
+ Therefore, it can takes a long time to update an <acronym>IMMV</acronym> containing
+ these functions.
+</para>
+
+<para>
+ Also note that using <function>sum</function> or <function>avg</function> on
+ <type>real</type> (<type>float4</type>) type or <type>double precision</type>
+ (<type>float8</type>) type in <acronym>IMMV</acronym> is unsafe. This is
+ because aggregated values in <acronym>IMMV</acronym> can become different from
+ results calculated from base tables due to the limited precision of these types.
+ To avoid this problem, use the <type>numeric</type> type instead.
+</para>
+
+ <sect4>
+ <title>Restrictions on Aggregates</title>
+ <para>
+ There are the following restrictions:
+ <itemizedlist>
+ <listitem>
+ <para>
+ If we have a <literal>GROUP BY</literal> clause, expressions specified in
+ <literal>GROUP BY</literal> must appear in the target list. This is
+ how tuples to be updated in the <acronym>IMMV</acronym> are identified.
+ These attributes are used as scan keys for searching tuples in the
+ <acronym>IMMV</acronym>, so indexes on them are required for efficient
+ <acronym>IVM</acronym>.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <literal>HAVING</literal> clause cannot be used.
+ </para>
+ </listitem>
+ </itemizedlist>
+ </para>
+ </sect4>
+</sect3>
+
+<sect3>
+<title>Other General Restrictions</title>
+<para>
+ There are other restrictions which generally apply to <acronym>IMMV</acronym>:
+ <itemizedlist>
+ <listitem>
+ <para>
+ Sub-queries cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ CTEs cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Window functions cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s must be based on simple base tables. It's not
+ supported to create them on top of views, materialized views, foreign tables, inhe.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ LIMIT and OFFSET clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s cannot contain system columns.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s cannot contain non-immutable functions.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ UNION/INTERSECT/EXCEPT clauses cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ DISTINCT ON clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ TABLESAMPLE parameter cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ inheritance parent tables cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ VALUES clause cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <literal>GROUPING SETS</literal> and <literal>FILTER</literal> clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ FOR UPDATE/SHARE cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ targetlist cannot contain columns whose name start with <literal>__ivm_</literal>.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ targetlist cannot contain expressions which contain an aggregate in it.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Logical replication is not supported, that is, even when a base table
+ at a publisher node is modified, <acronym>IMMV</acronym>s at subscriber
+ nodes are not updated.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ When the <literal>TRUNCATE</literal> command is executed on a base table,
+ nothing is changed on the <acronym>IMMV</acronym>.
+ </para>
+ </listitem>
+
+ </itemizedlist>
+</para>
+</sect3>
+
+</sect2>
+
+<sect2>
+<title><literal>DISTINCT</literal></title>
+
+<para>
+ <productname>PostgreSQL</productname> supports <acronym>IMMV</acronym> with
+ <literal>DISTINCT</literal>. For example, suppose a <acronym>IMMV</acronym>
+ defined with <literal>DISTINCT</literal> on a base table containing duplicate
+ tuples. When tuples are deleted from the base table, a tuple in the view is
+ deleted if and only if the multiplicity of the tuple becomes zero. Moreover,
+ when tuples are inserted into the base table, a tuple is inserted into the
+ view only if the same tuple doesn't already exist in it.
+</para>
+
+<para>
+ Physically, an <acronym>IMMV</acronym> defined with <literal>DISTINCT</literal>
+ contains tuples after eliminating duplicates, and the multiplicity of each tuple
+ is stored in a hidden column named <literal>__ivm_count__</literal>.
+</para>
+</sect2>
+
+<sect2>
+<title>Concurrent Transactions</title>
+<para>
+ Suppose an <acronym>IMMV</acronym> is defined on two base tables and each
+ table was modified in different a concurrent transaction simultaneously.
+ In the transaction which was committed first, <acronym>IMMV</acronym> can
+ be updated considering only the change which happened in this transaction.
+ On the other hand, in order to update the view correctly in the transaction
+ which was committed later, we need to know the changes occurred in
+ both transactions. For this reason, <literal>ExclusiveLock</literal>
+ is held on an <acronym>IMMV</acronym> immediately after a base table is
+ modified in <literal>READ COMMITTED</literal> mode to make sure that
+ the <acronym>IMMV</acronym> is updated in the latter transaction after
+ the former transaction is committed. In <literal>REPEATABLE READ</literal>
+ or <literal>SERIALIZABLE</literal> mode, an error is raised immediately
+ if lock acquisition fails because any changes which occurred in
+ other transactions are not be visible in these modes and
+ <acronym>IMMV</acronym> cannot be updated correctly in such situations.
+ However, as an exception if the view has only one base table,
+ the lock held on thew view is <literal>RowExclusiveLock</literal>.
+</para>
+</sect2>
+
+<sect2>
+<title>Row Level Security</title>
+<para>
+ If some base tables have row level security policy, rows that are not visible
+ to the materialized view's owner are excluded from the result. In addition, such
+ rows are excluded as well when views are incrementally maintained. However, if a
+ new policy is defined or policies are changed after the materialized view was created,
+ the new policy will not be applied to the view contents. To apply the new policy,
+ you need to refresh materialized views.
+</para>
+</sect2>
+
+</sect1>
+
<sect1 id="rules-update">
<title>Rules on <command>INSERT</command>, <command>UPDATE</command>, and <command>DELETE</command></title>
--
2.25.1
On Thu, Jun 1, 2023 at 2:47 AM Yugo NAGATA <nagata@sraoss.co.jp> wrote:
On Thu, 1 Jun 2023 23:59:09 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:Hello hackers,
Here's a rebased version of the patch-set adding Incremental View
Maintenance support for PostgreSQL. That was discussed in [1].[1] /messages/by-id/20181227215726.4d166b4874f8983a641123f5@sraoss.co.jp
---------------------------------------------------------------------------------------
* OverviewIncremental View Maintenance (IVM) is a way to make materialized views
up-to-date by computing only incremental changes and applying them on
views. IVM is more efficient than REFRESH MATERIALIZED VIEW when
only small parts of the view are changed.** Feature
The attached patchset provides a feature that allows materialized views
to be updated automatically and incrementally just after a underlying
table is modified.You can create an incementally maintainable materialized view (IMMV)
by using CREATE INCREMENTAL MATERIALIZED VIEW command.The followings are supported in view definition queries:
- SELECT ... FROM ... WHERE ..., joins (inner joins, self-joins)
- some built-in aggregate functions (count, sum, avg, min, max)
- GROUP BY clause
- DISTINCT clauseViews can contain multiple tuples with the same content (duplicate tuples).
** Restriction
The following are not supported in a view definition:
- Outer joins
- Aggregates otehr than above, window functions, HAVING
- Sub-queries, CTEs
- Set operations (UNION, INTERSECT, EXCEPT)
- DISTINCT ON, ORDER BY, LIMIT, OFFSETAlso, a view definition query cannot contain other views, materialized views,
foreign tables, partitioned tables, partitions, VALUES, non-immutable functions,
system columns, or expressions that contains aggregates.---------------------------------------------------------------------------------------
* DesignAn IMMV is maintained using statement-level AFTER triggers.
When an IMMV is created, triggers are automatically created on all base
tables contained in the view definition query.When a table is modified, changes that occurred in the table are extracted
as transition tables in the AFTER triggers. Then, changes that will occur in
the view are calculated by a rewritten view dequery in which the modified table
is replaced with the transition table.For example, if the view is defined as "SELECT * FROM R, S", and tuples inserted
into R are stored in a transiton table dR, the tuples that will be inserted into
the view are calculated as the result of "SELECT * FROM dR, S".** Multiple Tables Modification
Multiple tables can be modified in a statement when using triggers, foreign key
constraint, or modifying CTEs. When multiple tables are modified, we need
the state of tables before the modification.For example, when some tuples, dR and dS, are inserted into R and S respectively,
the tuples that will be inserted into the view are calculated by the following
two queries:"SELECT * FROM dR, S_pre"
"SELECT * FROM R, dS"where S_pre is the table before the modification, R is the current state of
table, that is, after the modification. This pre-update states of table
is calculated by filtering inserted tuples and appending deleted tuples.
The subquery that represents pre-update state is generated in get_prestate_rte().
Specifically, the insterted tuples are filtered by calling IVM_visible_in_prestate()
in WHERE clause. This function checks the visibility of tuples by using
the snapshot taken before table modification. The deleted tuples are contained
in the old transition table, and this table is appended using UNION ALL.Transition tables for each modification are collected in each AFTER trigger
function call. Then, the view maintenance is performed in the last call of
the trigger.In the original PostgreSQL, tuplestores of transition tables are freed at the
end of each nested query. However, their lifespan needs to be prolonged to
the end of the out-most query in order to maintain the view in the last AFTER
trigger. For this purpose, SetTransitionTablePreserved is added in trigger.c.** Duplicate Tulpes
When calculating changes that will occur in the view (= delta tables),
multiplicity of tuples are calculated by using count(*).When deleting tuples from the view, tuples to be deleted are identified by
joining the delta table with the view, and tuples are deleted as many as
specified multiplicity by numbered using row_number() function.
This is implemented in apply_old_delta().When inserting tuples into the view, each tuple is duplicated to the
specified multiplicity using generate_series() function. This is implemented
in apply_new_delta().** DISTINCT clause
When DISTINCT is used, the view has a hidden column __ivm_count__ that
stores multiplicity for tuples. When tuples are deleted from or inserted into
the view, the values of __ivm_count__ column is decreased or increased as many
as specified multiplicity. Eventually, when the values becomes zero, the
corresponding tuple is deleted from the view. This is implemented in
apply_old_delta_with_count() and apply_new_delta_with_count().** Aggregates
Built-in count sum, avg, min, and max are supported. Whether a given
aggregate function can be used or not is checked by using its OID in
check_aggregate_supports_ivm().When creating a materialized view containing aggregates, in addition
to __ivm_count__, more than one hidden columns for each aggregate are
added to the target list. For example, columns for storing sum(x),
count(x) are added if we have avg(x). When the view is maintained,
aggregated values are updated using these hidden columns, also hidden
columns are updated at the same time.The maintenance of aggregated view is performed in
apply_old_delta_with_count() and apply_new_delta_with_count(). The SET
clauses for updating columns are generated by append_set_clause_*().If the view has min(x) or max(x) and the minimum or maximal value is
deleted from a table, we need to update the value to the new min/max
recalculated from the tables rather than incremental computation. This
is performed in recalc_and_set_values().---------------------------------------------------------------------------------------
* Details of the patch-set (v28)The patch-set consists of the following eleven patches.
In the previous version, the number of patches were nine.
In the latest patch-set, the patches are divided more finely
aiming to make the review easier.- 0001: Add a syntax to create Incrementally Maintainable Materialized Views
The prposed syntax to create an incrementally maintainable materialized
view (IMMV) is;CREATE INCREMENTAL MATERIALIZED VIEW AS SELECT .....;
However, this syntax is tentative, so any suggestions are welcomed.
- 0002: Add relisivm column to pg_class system catalog
We add a new field in pg_class to indicate a relation is IMMV.
Another alternative is to add a new catalog for managing materialized
views including IMMV, but I am not sure if we want this.- 0003: Allow to prolong life span of transition tables until transaction end
This patch fixes the trigger system to allow to prolong lifespan of
tuple stores for transition tables until the transaction end. We need
this because multiple transition tables have to be preserved until the
end of the out-most query when multiple tables are modified by nested
triggers. (as explained above in Design - Multiple Tables Modification)If we don't want to change the trigger system in such way, the alternative
is to copy the contents of transition tables to other tuplestores, although
it needs more time and memory.- 0004: Add Incremental View Maintenance support to pg_dump
This patch enables pg_dump to output IMMV using the new syntax.
- 0005: Add Incremental View Maintenance support to psql
This patch implements tab-completion for the new syntax and adds
information of IMMV to \d meta-command results.- 0006: Add Incremental View Maintenance support
This patch implements the basic IVM feature.
DISTINCT and aggregate are not supported here.When an IMMV is created, the view query is checked, and if any
non-supported feature is used, it raises an error. If it is ok,
triggers are created on base tables and an unique index is
created on the view if possible.In BEFORE trigger, an entry is created for each IMMV and the number
of trigger firing is counted. Also, the snapshot just before the
table modification is stored.In AFTER triggers, each transition tables are preserved. The number
of trigger firing is counted also here, and when the firing number of
BEFORE and AFTER trigger reach the same, it is deemed the final AFTER
trigger call.In the final AFTER trigger, the IMMV is maintained. Rewritten view
query is executed to generate delta tables, and deltas are applied
to the view. If multiple tables are modified simultaneously, this
process is iterated for each modified table. Tables before processed
are represented in "pre-update-state", processed tables are
"post-update-state" in the rewritten query.- 0007: Add DISTINCT support for IVM
This patch adds DISTINCT clause support.
When an IMMV including DISTINCT is created, a hidden column
"__ivm_count__" is added to the target list. This column has the
number of duplicity of the same tuples. The duplicity is calculated
by adding "count(*)" and GROUP BY to the view query.When an IMMV is maintained, the duplicity in __ivm_count__ is updated,
and a tuples whose duplicity becomes zero can be deleted from the view.
This logic is implemented by SQL in apply_old_delta_with_count and
apply_new_delta_with_count.Columns starting with "__ivm_" are deemed hidden columns that doesn't
appear when a view is accessed by "SELECT * FROM ....". This is
implemented by fixing parse_relation.c.- 0008: Add aggregates support in IVM
This patch provides codes for aggregates support, specifically
for builtin count, sum, and avg.When an IMMV containing an aggregate is created, it is checked if this
aggregate function is supported, and if it is ok, some hidden columns
are added to the target list.When the IMMV is maintained, the aggregated value is updated as well as
related hidden columns. The way of update depends the type of aggregate
functions, and SET clause string is generated for each aggregate.- 0009: Add support for min/max aggregates for IVM
This patch adds min/max aggregates support.
This is separated from #0008 because min/max needs more complicated
work than count, sum, and avg.If the view has min(x) or max(x) and the minimum or maximal value is
deleted from a table, we need to update the value to the new min/max
recalculated from the tables rather than incremental computation.
This is performed in recalc_and_set_values().TIDs and keys of tuples that need re-calculation are returned as a
result of the query that deleted min/max values from the view using
RETURNING clause. The plan to recalculate and set the new min/max value
are stored and reused.- 0010: regression tests
This patch provides regression tests for IVM.
- 0011: documentation
This patch provides documantation for IVM.
---------------------------------------------------------------------------------------
* Changes from the Previous Version (v27)- Allow TRUNCATE on base tables
When a base table is truncated, the view content will be empty if the
view definition query does not contain an aggregate without a GROUP clause.
Therefore, such views can be truncated.Aggregate views without a GROUP clause always have one row. Therefore,
if a base table is truncated, the view will not be empty and will contain
a row with NULL value (or 0 for count()). So, in this case, we refresh the
view instead of truncating it.- Fix bugs reported by huyajun [1]
[1] /messages/by-id/tencent_FCAF11BCA5003FD16BDDFDDA5D6A19587809@qq.com
---------------------------------------------------------------------------------------
* Discussion** Aggregate support
There were a few suggestions that general aggregate functions should be
supported [2][3], which may be possible by extending pg_aggregate catalog.
However, we decided to leave supporting general aggregates to the future work [4]
because it would need substantial works and make the patch more complex and
bigger.There has been no opposite opinion on this. However, if we need more discussion
on the design of aggregate support, we can omit aggregate support for the first
release of IVM.[2] /messages/by-id/20191128140333.GA25947@alvherre.pgsql
[3] /messages/by-id/CAM-w4HOvDrL4ou6m=592zUiKGVzTcOpNj-d_cJqzL00fdsS5kg@mail.gmail.com
[4] /messages/by-id/20201016193034.9a4c44c79fc1eca7babe093e@sraoss.co.jp** Hidden columns
In order to support DISTINCT or aggregates, our implementation uses hidden columns.
Columns starting with "__ivm_" are hidden columns that doesn't appear when a
view is accessed by "SELECT * FROM ....". For this aim, parse_relation.c is
fixed. There was a proposal to enable hidden columns by adding a new flag to
pg_attribute [5], but this thread is no longer active, so we decided to check
the hidden column by its name [6].[5] /messages/by-id/CAEepm=3ZHh=p0nEEnVbs1Dig_UShPzHUcMNAqvDQUgYgcDo-pA@mail.gmail.com
[6] /messages/by-id/20201016193034.9a4c44c79fc1eca7babe093e@sraoss.co.jp** Concurrent Transactions
When the view definition has more than one table, we acquire an exclusive
lock before the view maintenance in order to avoid inconsistent results.
This behavior was explained in [7]. The lock was improved to use weaker lock
when the view has only one table based on a suggestion from Konstantin Knizhnik [8].
However, due to the implementation that uses ctid for identifying target tuples,
we still have to use an exclusive lock for DELETE and UPDATE.[7] /messages/by-id/20200909092752.c91758a1bec3479668e82643@sraoss.co.jp
[8] /messages/by-id/5663f5f0-48af-686c-bf3c-62d279567e2a@postgrespro.ru** Automatic Index Creation
When a view is created, a unique index is automatically created if
possible, that is, if the view definition query has a GROUP BY or
DISTINCT, or if the view contains all primary key attributes of
its base tables in the target list. It is necessary for efficient
view maintenance. This feature is based on a suggestion from
Konstantin Knizhnik [9].[9] /messages/by-id/89729da8-9042-7ea0-95af-e415df6da14d@postgrespro.ru
** Trigger and Transition Tables
We implemented IVM based on triggers. This is because we want to use
transition tables to extract changes on base tables. Also, there are
other constraint that are using triggers in its implementation, like
foreign references. However, if we can use transition table like feature
without relying triggers, we don't have to insist to use triggers and we
might implement IVM in the executor directly as similar as declarative
partitioning.** Feature to be Supported in the First Release
The current patch-set supports DISTINCT and aggregates for built-in count,
sum, avg, min and max. Do we need all these feature for the first IVM release?
Supporting DISTINCT and aggregates needs discussion on hidden columns, and
for supporting min/max we need to discuss on re-calculation method. Before
handling such relatively advanced feature, maybe, should we focus to design
and implement of the basic feature of IVM?Any suggestion and discussion are welcomed!
Regards,
Yugo Nagata--
Yugo NAGATA <nagata@sraoss.co.jp>
The followings are supported in view definition queries:
- SELECT ... FROM ... WHERE ..., joins (inner joins, self-joins)
Also, a view definition query cannot contain other views, materialized views,
foreign tables, partitioned tables, partitions, VALUES, non-immutable functions,
system columns, or expressions that contains aggregates.
Does this also apply to tableoid? but tableoid is a constant, so it
should be fine?
can following two queries apply to this feature.
select tableoid, unique1 from tenk1;
select 1 as constant, unique1 from tenk1;
I didn't apply the patch.(will do later, for someone to test, it would
be a better idea to dump a whole file separately....).
On Wed, 28 Jun 2023 00:01:02 +0800
jian he <jian.universality@gmail.com> wrote:
On Thu, Jun 1, 2023 at 2:47 AM Yugo NAGATA <nagata@sraoss.co.jp> wrote:
On Thu, 1 Jun 2023 23:59:09 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:Hello hackers,
Here's a rebased version of the patch-set adding Incremental View
Maintenance support for PostgreSQL. That was discussed in [1].[1] /messages/by-id/20181227215726.4d166b4874f8983a641123f5@sraoss.co.jp
---------------------------------------------------------------------------------------
* OverviewIncremental View Maintenance (IVM) is a way to make materialized views
up-to-date by computing only incremental changes and applying them on
views. IVM is more efficient than REFRESH MATERIALIZED VIEW when
only small parts of the view are changed.** Feature
The attached patchset provides a feature that allows materialized views
to be updated automatically and incrementally just after a underlying
table is modified.You can create an incementally maintainable materialized view (IMMV)
by using CREATE INCREMENTAL MATERIALIZED VIEW command.The followings are supported in view definition queries:
- SELECT ... FROM ... WHERE ..., joins (inner joins, self-joins)
- some built-in aggregate functions (count, sum, avg, min, max)
- GROUP BY clause
- DISTINCT clauseViews can contain multiple tuples with the same content (duplicate tuples).
** Restriction
The following are not supported in a view definition:
- Outer joins
- Aggregates otehr than above, window functions, HAVING
- Sub-queries, CTEs
- Set operations (UNION, INTERSECT, EXCEPT)
- DISTINCT ON, ORDER BY, LIMIT, OFFSETAlso, a view definition query cannot contain other views, materialized views,
foreign tables, partitioned tables, partitions, VALUES, non-immutable functions,
system columns, or expressions that contains aggregates.---------------------------------------------------------------------------------------
* DesignAn IMMV is maintained using statement-level AFTER triggers.
When an IMMV is created, triggers are automatically created on all base
tables contained in the view definition query.When a table is modified, changes that occurred in the table are extracted
as transition tables in the AFTER triggers. Then, changes that will occur in
the view are calculated by a rewritten view dequery in which the modified table
is replaced with the transition table.For example, if the view is defined as "SELECT * FROM R, S", and tuples inserted
into R are stored in a transiton table dR, the tuples that will be inserted into
the view are calculated as the result of "SELECT * FROM dR, S".** Multiple Tables Modification
Multiple tables can be modified in a statement when using triggers, foreign key
constraint, or modifying CTEs. When multiple tables are modified, we need
the state of tables before the modification.For example, when some tuples, dR and dS, are inserted into R and S respectively,
the tuples that will be inserted into the view are calculated by the following
two queries:"SELECT * FROM dR, S_pre"
"SELECT * FROM R, dS"where S_pre is the table before the modification, R is the current state of
table, that is, after the modification. This pre-update states of table
is calculated by filtering inserted tuples and appending deleted tuples.
The subquery that represents pre-update state is generated in get_prestate_rte().
Specifically, the insterted tuples are filtered by calling IVM_visible_in_prestate()
in WHERE clause. This function checks the visibility of tuples by using
the snapshot taken before table modification. The deleted tuples are contained
in the old transition table, and this table is appended using UNION ALL.Transition tables for each modification are collected in each AFTER trigger
function call. Then, the view maintenance is performed in the last call of
the trigger.In the original PostgreSQL, tuplestores of transition tables are freed at the
end of each nested query. However, their lifespan needs to be prolonged to
the end of the out-most query in order to maintain the view in the last AFTER
trigger. For this purpose, SetTransitionTablePreserved is added in trigger.c.** Duplicate Tulpes
When calculating changes that will occur in the view (= delta tables),
multiplicity of tuples are calculated by using count(*).When deleting tuples from the view, tuples to be deleted are identified by
joining the delta table with the view, and tuples are deleted as many as
specified multiplicity by numbered using row_number() function.
This is implemented in apply_old_delta().When inserting tuples into the view, each tuple is duplicated to the
specified multiplicity using generate_series() function. This is implemented
in apply_new_delta().** DISTINCT clause
When DISTINCT is used, the view has a hidden column __ivm_count__ that
stores multiplicity for tuples. When tuples are deleted from or inserted into
the view, the values of __ivm_count__ column is decreased or increased as many
as specified multiplicity. Eventually, when the values becomes zero, the
corresponding tuple is deleted from the view. This is implemented in
apply_old_delta_with_count() and apply_new_delta_with_count().** Aggregates
Built-in count sum, avg, min, and max are supported. Whether a given
aggregate function can be used or not is checked by using its OID in
check_aggregate_supports_ivm().When creating a materialized view containing aggregates, in addition
to __ivm_count__, more than one hidden columns for each aggregate are
added to the target list. For example, columns for storing sum(x),
count(x) are added if we have avg(x). When the view is maintained,
aggregated values are updated using these hidden columns, also hidden
columns are updated at the same time.The maintenance of aggregated view is performed in
apply_old_delta_with_count() and apply_new_delta_with_count(). The SET
clauses for updating columns are generated by append_set_clause_*().If the view has min(x) or max(x) and the minimum or maximal value is
deleted from a table, we need to update the value to the new min/max
recalculated from the tables rather than incremental computation. This
is performed in recalc_and_set_values().---------------------------------------------------------------------------------------
* Details of the patch-set (v28)The patch-set consists of the following eleven patches.
In the previous version, the number of patches were nine.
In the latest patch-set, the patches are divided more finely
aiming to make the review easier.- 0001: Add a syntax to create Incrementally Maintainable Materialized Views
The prposed syntax to create an incrementally maintainable materialized
view (IMMV) is;CREATE INCREMENTAL MATERIALIZED VIEW AS SELECT .....;
However, this syntax is tentative, so any suggestions are welcomed.
- 0002: Add relisivm column to pg_class system catalog
We add a new field in pg_class to indicate a relation is IMMV.
Another alternative is to add a new catalog for managing materialized
views including IMMV, but I am not sure if we want this.- 0003: Allow to prolong life span of transition tables until transaction end
This patch fixes the trigger system to allow to prolong lifespan of
tuple stores for transition tables until the transaction end. We need
this because multiple transition tables have to be preserved until the
end of the out-most query when multiple tables are modified by nested
triggers. (as explained above in Design - Multiple Tables Modification)If we don't want to change the trigger system in such way, the alternative
is to copy the contents of transition tables to other tuplestores, although
it needs more time and memory.- 0004: Add Incremental View Maintenance support to pg_dump
This patch enables pg_dump to output IMMV using the new syntax.
- 0005: Add Incremental View Maintenance support to psql
This patch implements tab-completion for the new syntax and adds
information of IMMV to \d meta-command results.- 0006: Add Incremental View Maintenance support
This patch implements the basic IVM feature.
DISTINCT and aggregate are not supported here.When an IMMV is created, the view query is checked, and if any
non-supported feature is used, it raises an error. If it is ok,
triggers are created on base tables and an unique index is
created on the view if possible.In BEFORE trigger, an entry is created for each IMMV and the number
of trigger firing is counted. Also, the snapshot just before the
table modification is stored.In AFTER triggers, each transition tables are preserved. The number
of trigger firing is counted also here, and when the firing number of
BEFORE and AFTER trigger reach the same, it is deemed the final AFTER
trigger call.In the final AFTER trigger, the IMMV is maintained. Rewritten view
query is executed to generate delta tables, and deltas are applied
to the view. If multiple tables are modified simultaneously, this
process is iterated for each modified table. Tables before processed
are represented in "pre-update-state", processed tables are
"post-update-state" in the rewritten query.- 0007: Add DISTINCT support for IVM
This patch adds DISTINCT clause support.
When an IMMV including DISTINCT is created, a hidden column
"__ivm_count__" is added to the target list. This column has the
number of duplicity of the same tuples. The duplicity is calculated
by adding "count(*)" and GROUP BY to the view query.When an IMMV is maintained, the duplicity in __ivm_count__ is updated,
and a tuples whose duplicity becomes zero can be deleted from the view.
This logic is implemented by SQL in apply_old_delta_with_count and
apply_new_delta_with_count.Columns starting with "__ivm_" are deemed hidden columns that doesn't
appear when a view is accessed by "SELECT * FROM ....". This is
implemented by fixing parse_relation.c.- 0008: Add aggregates support in IVM
This patch provides codes for aggregates support, specifically
for builtin count, sum, and avg.When an IMMV containing an aggregate is created, it is checked if this
aggregate function is supported, and if it is ok, some hidden columns
are added to the target list.When the IMMV is maintained, the aggregated value is updated as well as
related hidden columns. The way of update depends the type of aggregate
functions, and SET clause string is generated for each aggregate.- 0009: Add support for min/max aggregates for IVM
This patch adds min/max aggregates support.
This is separated from #0008 because min/max needs more complicated
work than count, sum, and avg.If the view has min(x) or max(x) and the minimum or maximal value is
deleted from a table, we need to update the value to the new min/max
recalculated from the tables rather than incremental computation.
This is performed in recalc_and_set_values().TIDs and keys of tuples that need re-calculation are returned as a
result of the query that deleted min/max values from the view using
RETURNING clause. The plan to recalculate and set the new min/max value
are stored and reused.- 0010: regression tests
This patch provides regression tests for IVM.
- 0011: documentation
This patch provides documantation for IVM.
---------------------------------------------------------------------------------------
* Changes from the Previous Version (v27)- Allow TRUNCATE on base tables
When a base table is truncated, the view content will be empty if the
view definition query does not contain an aggregate without a GROUP clause.
Therefore, such views can be truncated.Aggregate views without a GROUP clause always have one row. Therefore,
if a base table is truncated, the view will not be empty and will contain
a row with NULL value (or 0 for count()). So, in this case, we refresh the
view instead of truncating it.- Fix bugs reported by huyajun [1]
[1] /messages/by-id/tencent_FCAF11BCA5003FD16BDDFDDA5D6A19587809@qq.com
---------------------------------------------------------------------------------------
* Discussion** Aggregate support
There were a few suggestions that general aggregate functions should be
supported [2][3], which may be possible by extending pg_aggregate catalog.
However, we decided to leave supporting general aggregates to the future work [4]
because it would need substantial works and make the patch more complex and
bigger.There has been no opposite opinion on this. However, if we need more discussion
on the design of aggregate support, we can omit aggregate support for the first
release of IVM.[2] /messages/by-id/20191128140333.GA25947@alvherre.pgsql
[3] /messages/by-id/CAM-w4HOvDrL4ou6m=592zUiKGVzTcOpNj-d_cJqzL00fdsS5kg@mail.gmail.com
[4] /messages/by-id/20201016193034.9a4c44c79fc1eca7babe093e@sraoss.co.jp** Hidden columns
In order to support DISTINCT or aggregates, our implementation uses hidden columns.
Columns starting with "__ivm_" are hidden columns that doesn't appear when a
view is accessed by "SELECT * FROM ....". For this aim, parse_relation.c is
fixed. There was a proposal to enable hidden columns by adding a new flag to
pg_attribute [5], but this thread is no longer active, so we decided to check
the hidden column by its name [6].[5] /messages/by-id/CAEepm=3ZHh=p0nEEnVbs1Dig_UShPzHUcMNAqvDQUgYgcDo-pA@mail.gmail.com
[6] /messages/by-id/20201016193034.9a4c44c79fc1eca7babe093e@sraoss.co.jp** Concurrent Transactions
When the view definition has more than one table, we acquire an exclusive
lock before the view maintenance in order to avoid inconsistent results.
This behavior was explained in [7]. The lock was improved to use weaker lock
when the view has only one table based on a suggestion from Konstantin Knizhnik [8].
However, due to the implementation that uses ctid for identifying target tuples,
we still have to use an exclusive lock for DELETE and UPDATE.[7] /messages/by-id/20200909092752.c91758a1bec3479668e82643@sraoss.co.jp
[8] /messages/by-id/5663f5f0-48af-686c-bf3c-62d279567e2a@postgrespro.ru** Automatic Index Creation
When a view is created, a unique index is automatically created if
possible, that is, if the view definition query has a GROUP BY or
DISTINCT, or if the view contains all primary key attributes of
its base tables in the target list. It is necessary for efficient
view maintenance. This feature is based on a suggestion from
Konstantin Knizhnik [9].[9] /messages/by-id/89729da8-9042-7ea0-95af-e415df6da14d@postgrespro.ru
** Trigger and Transition Tables
We implemented IVM based on triggers. This is because we want to use
transition tables to extract changes on base tables. Also, there are
other constraint that are using triggers in its implementation, like
foreign references. However, if we can use transition table like feature
without relying triggers, we don't have to insist to use triggers and we
might implement IVM in the executor directly as similar as declarative
partitioning.** Feature to be Supported in the First Release
The current patch-set supports DISTINCT and aggregates for built-in count,
sum, avg, min and max. Do we need all these feature for the first IVM release?
Supporting DISTINCT and aggregates needs discussion on hidden columns, and
for supporting min/max we need to discuss on re-calculation method. Before
handling such relatively advanced feature, maybe, should we focus to design
and implement of the basic feature of IVM?Any suggestion and discussion are welcomed!
Regards,
Yugo Nagata--
Yugo NAGATA <nagata@sraoss.co.jp>The followings are supported in view definition queries:
- SELECT ... FROM ... WHERE ..., joins (inner joins, self-joins)Also, a view definition query cannot contain other views, materialized views,
foreign tables, partitioned tables, partitions, VALUES, non-immutable functions,
system columns, or expressions that contains aggregates.Does this also apply to tableoid? but tableoid is a constant, so it
should be fine?
can following two queries apply to this feature.
select tableoid, unique1 from tenk1;
Currently, this is not allowed because tableoid is a system column.
As you say, tableoid is a constant, so we can allow. Should we do this?
select 1 as constant, unique1 from tenk1;
This is allowed, of course.
I didn't apply the patch.(will do later, for someone to test, it would
be a better idea to dump a whole file separately....).
Thank you! I'm looking forward to your feedback.
(I didn't attach a whole patch separately because I wouldn't like
cfbot to be unhappy...)
Regards,
Yugo Nagata
--
Yugo NAGATA <nagata@sraoss.co.jp>
On Wed, Jun 28, 2023 at 4:06 PM Yugo NAGATA <nagata@sraoss.co.jp> wrote:
On Wed, 28 Jun 2023 00:01:02 +0800
jian he <jian.universality@gmail.com> wrote:On Thu, Jun 1, 2023 at 2:47 AM Yugo NAGATA <nagata@sraoss.co.jp> wrote:
On Thu, 1 Jun 2023 23:59:09 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:Hello hackers,
Here's a rebased version of the patch-set adding Incremental View
Maintenance support for PostgreSQL. That was discussed in [1].[1] /messages/by-id/20181227215726.4d166b4874f8983a641123f5@sraoss.co.jp
---------------------------------------------------------------------------------------
* OverviewIncremental View Maintenance (IVM) is a way to make materialized views
up-to-date by computing only incremental changes and applying them on
views. IVM is more efficient than REFRESH MATERIALIZED VIEW when
only small parts of the view are changed.** Feature
The attached patchset provides a feature that allows materialized views
to be updated automatically and incrementally just after a underlying
table is modified.You can create an incementally maintainable materialized view (IMMV)
by using CREATE INCREMENTAL MATERIALIZED VIEW command.The followings are supported in view definition queries:
- SELECT ... FROM ... WHERE ..., joins (inner joins, self-joins)
- some built-in aggregate functions (count, sum, avg, min, max)
- GROUP BY clause
- DISTINCT clauseViews can contain multiple tuples with the same content (duplicate tuples).
** Restriction
The following are not supported in a view definition:
- Outer joins
- Aggregates otehr than above, window functions, HAVING
- Sub-queries, CTEs
- Set operations (UNION, INTERSECT, EXCEPT)
- DISTINCT ON, ORDER BY, LIMIT, OFFSETAlso, a view definition query cannot contain other views, materialized views,
foreign tables, partitioned tables, partitions, VALUES, non-immutable functions,
system columns, or expressions that contains aggregates.---------------------------------------------------------------------------------------
* DesignAn IMMV is maintained using statement-level AFTER triggers.
When an IMMV is created, triggers are automatically created on all base
tables contained in the view definition query.When a table is modified, changes that occurred in the table are extracted
as transition tables in the AFTER triggers. Then, changes that will occur in
the view are calculated by a rewritten view dequery in which the modified table
is replaced with the transition table.For example, if the view is defined as "SELECT * FROM R, S", and tuples inserted
into R are stored in a transiton table dR, the tuples that will be inserted into
the view are calculated as the result of "SELECT * FROM dR, S".** Multiple Tables Modification
Multiple tables can be modified in a statement when using triggers, foreign key
constraint, or modifying CTEs. When multiple tables are modified, we need
the state of tables before the modification.For example, when some tuples, dR and dS, are inserted into R and S respectively,
the tuples that will be inserted into the view are calculated by the following
two queries:"SELECT * FROM dR, S_pre"
"SELECT * FROM R, dS"where S_pre is the table before the modification, R is the current state of
table, that is, after the modification. This pre-update states of table
is calculated by filtering inserted tuples and appending deleted tuples.
The subquery that represents pre-update state is generated in get_prestate_rte().
Specifically, the insterted tuples are filtered by calling IVM_visible_in_prestate()
in WHERE clause. This function checks the visibility of tuples by using
the snapshot taken before table modification. The deleted tuples are contained
in the old transition table, and this table is appended using UNION ALL.Transition tables for each modification are collected in each AFTER trigger
function call. Then, the view maintenance is performed in the last call of
the trigger.In the original PostgreSQL, tuplestores of transition tables are freed at the
end of each nested query. However, their lifespan needs to be prolonged to
the end of the out-most query in order to maintain the view in the last AFTER
trigger. For this purpose, SetTransitionTablePreserved is added in trigger.c.** Duplicate Tulpes
When calculating changes that will occur in the view (= delta tables),
multiplicity of tuples are calculated by using count(*).When deleting tuples from the view, tuples to be deleted are identified by
joining the delta table with the view, and tuples are deleted as many as
specified multiplicity by numbered using row_number() function.
This is implemented in apply_old_delta().When inserting tuples into the view, each tuple is duplicated to the
specified multiplicity using generate_series() function. This is implemented
in apply_new_delta().** DISTINCT clause
When DISTINCT is used, the view has a hidden column __ivm_count__ that
stores multiplicity for tuples. When tuples are deleted from or inserted into
the view, the values of __ivm_count__ column is decreased or increased as many
as specified multiplicity. Eventually, when the values becomes zero, the
corresponding tuple is deleted from the view. This is implemented in
apply_old_delta_with_count() and apply_new_delta_with_count().** Aggregates
Built-in count sum, avg, min, and max are supported. Whether a given
aggregate function can be used or not is checked by using its OID in
check_aggregate_supports_ivm().When creating a materialized view containing aggregates, in addition
to __ivm_count__, more than one hidden columns for each aggregate are
added to the target list. For example, columns for storing sum(x),
count(x) are added if we have avg(x). When the view is maintained,
aggregated values are updated using these hidden columns, also hidden
columns are updated at the same time.The maintenance of aggregated view is performed in
apply_old_delta_with_count() and apply_new_delta_with_count(). The SET
clauses for updating columns are generated by append_set_clause_*().If the view has min(x) or max(x) and the minimum or maximal value is
deleted from a table, we need to update the value to the new min/max
recalculated from the tables rather than incremental computation. This
is performed in recalc_and_set_values().---------------------------------------------------------------------------------------
* Details of the patch-set (v28)The patch-set consists of the following eleven patches.
In the previous version, the number of patches were nine.
In the latest patch-set, the patches are divided more finely
aiming to make the review easier.- 0001: Add a syntax to create Incrementally Maintainable Materialized Views
The prposed syntax to create an incrementally maintainable materialized
view (IMMV) is;CREATE INCREMENTAL MATERIALIZED VIEW AS SELECT .....;
However, this syntax is tentative, so any suggestions are welcomed.
- 0002: Add relisivm column to pg_class system catalog
We add a new field in pg_class to indicate a relation is IMMV.
Another alternative is to add a new catalog for managing materialized
views including IMMV, but I am not sure if we want this.- 0003: Allow to prolong life span of transition tables until transaction end
This patch fixes the trigger system to allow to prolong lifespan of
tuple stores for transition tables until the transaction end. We need
this because multiple transition tables have to be preserved until the
end of the out-most query when multiple tables are modified by nested
triggers. (as explained above in Design - Multiple Tables Modification)If we don't want to change the trigger system in such way, the alternative
is to copy the contents of transition tables to other tuplestores, although
it needs more time and memory.- 0004: Add Incremental View Maintenance support to pg_dump
This patch enables pg_dump to output IMMV using the new syntax.
- 0005: Add Incremental View Maintenance support to psql
This patch implements tab-completion for the new syntax and adds
information of IMMV to \d meta-command results.- 0006: Add Incremental View Maintenance support
This patch implements the basic IVM feature.
DISTINCT and aggregate are not supported here.When an IMMV is created, the view query is checked, and if any
non-supported feature is used, it raises an error. If it is ok,
triggers are created on base tables and an unique index is
created on the view if possible.In BEFORE trigger, an entry is created for each IMMV and the number
of trigger firing is counted. Also, the snapshot just before the
table modification is stored.In AFTER triggers, each transition tables are preserved. The number
of trigger firing is counted also here, and when the firing number of
BEFORE and AFTER trigger reach the same, it is deemed the final AFTER
trigger call.In the final AFTER trigger, the IMMV is maintained. Rewritten view
query is executed to generate delta tables, and deltas are applied
to the view. If multiple tables are modified simultaneously, this
process is iterated for each modified table. Tables before processed
are represented in "pre-update-state", processed tables are
"post-update-state" in the rewritten query.- 0007: Add DISTINCT support for IVM
This patch adds DISTINCT clause support.
When an IMMV including DISTINCT is created, a hidden column
"__ivm_count__" is added to the target list. This column has the
number of duplicity of the same tuples. The duplicity is calculated
by adding "count(*)" and GROUP BY to the view query.When an IMMV is maintained, the duplicity in __ivm_count__ is updated,
and a tuples whose duplicity becomes zero can be deleted from the view.
This logic is implemented by SQL in apply_old_delta_with_count and
apply_new_delta_with_count.Columns starting with "__ivm_" are deemed hidden columns that doesn't
appear when a view is accessed by "SELECT * FROM ....". This is
implemented by fixing parse_relation.c.- 0008: Add aggregates support in IVM
This patch provides codes for aggregates support, specifically
for builtin count, sum, and avg.When an IMMV containing an aggregate is created, it is checked if this
aggregate function is supported, and if it is ok, some hidden columns
are added to the target list.When the IMMV is maintained, the aggregated value is updated as well as
related hidden columns. The way of update depends the type of aggregate
functions, and SET clause string is generated for each aggregate.- 0009: Add support for min/max aggregates for IVM
This patch adds min/max aggregates support.
This is separated from #0008 because min/max needs more complicated
work than count, sum, and avg.If the view has min(x) or max(x) and the minimum or maximal value is
deleted from a table, we need to update the value to the new min/max
recalculated from the tables rather than incremental computation.
This is performed in recalc_and_set_values().TIDs and keys of tuples that need re-calculation are returned as a
result of the query that deleted min/max values from the view using
RETURNING clause. The plan to recalculate and set the new min/max value
are stored and reused.- 0010: regression tests
This patch provides regression tests for IVM.
- 0011: documentation
This patch provides documantation for IVM.
---------------------------------------------------------------------------------------
* Changes from the Previous Version (v27)- Allow TRUNCATE on base tables
When a base table is truncated, the view content will be empty if the
view definition query does not contain an aggregate without a GROUP clause.
Therefore, such views can be truncated.Aggregate views without a GROUP clause always have one row. Therefore,
if a base table is truncated, the view will not be empty and will contain
a row with NULL value (or 0 for count()). So, in this case, we refresh the
view instead of truncating it.- Fix bugs reported by huyajun [1]
[1] /messages/by-id/tencent_FCAF11BCA5003FD16BDDFDDA5D6A19587809@qq.com
---------------------------------------------------------------------------------------
* Discussion** Aggregate support
There were a few suggestions that general aggregate functions should be
supported [2][3], which may be possible by extending pg_aggregate catalog.
However, we decided to leave supporting general aggregates to the future work [4]
because it would need substantial works and make the patch more complex and
bigger.There has been no opposite opinion on this. However, if we need more discussion
on the design of aggregate support, we can omit aggregate support for the first
release of IVM.[2] /messages/by-id/20191128140333.GA25947@alvherre.pgsql
[3] /messages/by-id/CAM-w4HOvDrL4ou6m=592zUiKGVzTcOpNj-d_cJqzL00fdsS5kg@mail.gmail.com
[4] /messages/by-id/20201016193034.9a4c44c79fc1eca7babe093e@sraoss.co.jp** Hidden columns
In order to support DISTINCT or aggregates, our implementation uses hidden columns.
Columns starting with "__ivm_" are hidden columns that doesn't appear when a
view is accessed by "SELECT * FROM ....". For this aim, parse_relation.c is
fixed. There was a proposal to enable hidden columns by adding a new flag to
pg_attribute [5], but this thread is no longer active, so we decided to check
the hidden column by its name [6].[5] /messages/by-id/CAEepm=3ZHh=p0nEEnVbs1Dig_UShPzHUcMNAqvDQUgYgcDo-pA@mail.gmail.com
[6] /messages/by-id/20201016193034.9a4c44c79fc1eca7babe093e@sraoss.co.jp** Concurrent Transactions
When the view definition has more than one table, we acquire an exclusive
lock before the view maintenance in order to avoid inconsistent results.
This behavior was explained in [7]. The lock was improved to use weaker lock
when the view has only one table based on a suggestion from Konstantin Knizhnik [8].
However, due to the implementation that uses ctid for identifying target tuples,
we still have to use an exclusive lock for DELETE and UPDATE.[7] /messages/by-id/20200909092752.c91758a1bec3479668e82643@sraoss.co.jp
[8] /messages/by-id/5663f5f0-48af-686c-bf3c-62d279567e2a@postgrespro.ru** Automatic Index Creation
When a view is created, a unique index is automatically created if
possible, that is, if the view definition query has a GROUP BY or
DISTINCT, or if the view contains all primary key attributes of
its base tables in the target list. It is necessary for efficient
view maintenance. This feature is based on a suggestion from
Konstantin Knizhnik [9].[9] /messages/by-id/89729da8-9042-7ea0-95af-e415df6da14d@postgrespro.ru
** Trigger and Transition Tables
We implemented IVM based on triggers. This is because we want to use
transition tables to extract changes on base tables. Also, there are
other constraint that are using triggers in its implementation, like
foreign references. However, if we can use transition table like feature
without relying triggers, we don't have to insist to use triggers and we
might implement IVM in the executor directly as similar as declarative
partitioning.** Feature to be Supported in the First Release
The current patch-set supports DISTINCT and aggregates for built-in count,
sum, avg, min and max. Do we need all these feature for the first IVM release?
Supporting DISTINCT and aggregates needs discussion on hidden columns, and
for supporting min/max we need to discuss on re-calculation method. Before
handling such relatively advanced feature, maybe, should we focus to design
and implement of the basic feature of IVM?Any suggestion and discussion are welcomed!
Regards,
Yugo Nagata--
Yugo NAGATA <nagata@sraoss.co.jp>The followings are supported in view definition queries:
- SELECT ... FROM ... WHERE ..., joins (inner joins, self-joins)Also, a view definition query cannot contain other views, materialized views,
foreign tables, partitioned tables, partitions, VALUES, non-immutable functions,
system columns, or expressions that contains aggregates.Does this also apply to tableoid? but tableoid is a constant, so it
should be fine?
can following two queries apply to this feature.
select tableoid, unique1 from tenk1;Currently, this is not allowed because tableoid is a system column.
As you say, tableoid is a constant, so we can allow. Should we do this?select 1 as constant, unique1 from tenk1;
This is allowed, of course.
I didn't apply the patch.(will do later, for someone to test, it would
be a better idea to dump a whole file separately....).Thank you! I'm looking forward to your feedback.
(I didn't attach a whole patch separately because I wouldn't like
cfbot to be unhappy...)Regards,
Yugo Nagata--
Yugo NAGATA <nagata@sraoss.co.jp>
I played around first half of regress patch.
these all following queries fails.
CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS
SELECT DISTINCT * , 1 as "__ivm_count__" FROM mv_base_a;
CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS
SELECT DISTINCT * , 1 as "__ivm_countblablabla" FROM mv_base_a;
CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS
SELECT DISTINCT * , 1 as "__ivm_count" FROM mv_base_a;
CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS
SELECT DISTINCT * , 1 as "__ivm_count_____" FROM mv_base_a;
CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS
SELECT DISTINCT * , 1 as "__ivm_countblabla" FROM mv_base_a;
so the hidden column reserved pattern "__ivm_count.*"? that would be a lot....
select * from pg_matviews where matviewname = 'mv_ivm_1';
don't have relisivm option. it's reasonable to make it in view pg_matviews?
On Thu, Jun 29, 2023 at 12:40 AM jian he <jian.universality@gmail.com> wrote:
On Wed, Jun 28, 2023 at 4:06 PM Yugo NAGATA <nagata@sraoss.co.jp> wrote:
On Wed, 28 Jun 2023 00:01:02 +0800
jian he <jian.universality@gmail.com> wrote:On Thu, Jun 1, 2023 at 2:47 AM Yugo NAGATA <nagata@sraoss.co.jp> wrote:
On Thu, 1 Jun 2023 23:59:09 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:Hello hackers,
Here's a rebased version of the patch-set adding Incremental View
Maintenance support for PostgreSQL. That was discussed in [1].[1] /messages/by-id/20181227215726.4d166b4874f8983a641123f5@sraoss.co.jp
---------------------------------------------------------------------------------------
* OverviewIncremental View Maintenance (IVM) is a way to make materialized views
up-to-date by computing only incremental changes and applying them on
views. IVM is more efficient than REFRESH MATERIALIZED VIEW when
only small parts of the view are changed.** Feature
The attached patchset provides a feature that allows materialized views
to be updated automatically and incrementally just after a underlying
table is modified.You can create an incementally maintainable materialized view (IMMV)
by using CREATE INCREMENTAL MATERIALIZED VIEW command.The followings are supported in view definition queries:
- SELECT ... FROM ... WHERE ..., joins (inner joins, self-joins)
- some built-in aggregate functions (count, sum, avg, min, max)
- GROUP BY clause
- DISTINCT clauseViews can contain multiple tuples with the same content (duplicate tuples).
** Restriction
The following are not supported in a view definition:
- Outer joins
- Aggregates otehr than above, window functions, HAVING
- Sub-queries, CTEs
- Set operations (UNION, INTERSECT, EXCEPT)
- DISTINCT ON, ORDER BY, LIMIT, OFFSETAlso, a view definition query cannot contain other views, materialized views,
foreign tables, partitioned tables, partitions, VALUES, non-immutable functions,
system columns, or expressions that contains aggregates.---------------------------------------------------------------------------------------
* DesignAn IMMV is maintained using statement-level AFTER triggers.
When an IMMV is created, triggers are automatically created on all base
tables contained in the view definition query.When a table is modified, changes that occurred in the table are extracted
as transition tables in the AFTER triggers. Then, changes that will occur in
the view are calculated by a rewritten view dequery in which the modified table
is replaced with the transition table.For example, if the view is defined as "SELECT * FROM R, S", and tuples inserted
into R are stored in a transiton table dR, the tuples that will be inserted into
the view are calculated as the result of "SELECT * FROM dR, S".** Multiple Tables Modification
Multiple tables can be modified in a statement when using triggers, foreign key
constraint, or modifying CTEs. When multiple tables are modified, we need
the state of tables before the modification.For example, when some tuples, dR and dS, are inserted into R and S respectively,
the tuples that will be inserted into the view are calculated by the following
two queries:"SELECT * FROM dR, S_pre"
"SELECT * FROM R, dS"where S_pre is the table before the modification, R is the current state of
table, that is, after the modification. This pre-update states of table
is calculated by filtering inserted tuples and appending deleted tuples.
The subquery that represents pre-update state is generated in get_prestate_rte().
Specifically, the insterted tuples are filtered by calling IVM_visible_in_prestate()
in WHERE clause. This function checks the visibility of tuples by using
the snapshot taken before table modification. The deleted tuples are contained
in the old transition table, and this table is appended using UNION ALL.Transition tables for each modification are collected in each AFTER trigger
function call. Then, the view maintenance is performed in the last call of
the trigger.In the original PostgreSQL, tuplestores of transition tables are freed at the
end of each nested query. However, their lifespan needs to be prolonged to
the end of the out-most query in order to maintain the view in the last AFTER
trigger. For this purpose, SetTransitionTablePreserved is added in trigger.c.** Duplicate Tulpes
When calculating changes that will occur in the view (= delta tables),
multiplicity of tuples are calculated by using count(*).When deleting tuples from the view, tuples to be deleted are identified by
joining the delta table with the view, and tuples are deleted as many as
specified multiplicity by numbered using row_number() function.
This is implemented in apply_old_delta().When inserting tuples into the view, each tuple is duplicated to the
specified multiplicity using generate_series() function. This is implemented
in apply_new_delta().** DISTINCT clause
When DISTINCT is used, the view has a hidden column __ivm_count__ that
stores multiplicity for tuples. When tuples are deleted from or inserted into
the view, the values of __ivm_count__ column is decreased or increased as many
as specified multiplicity. Eventually, when the values becomes zero, the
corresponding tuple is deleted from the view. This is implemented in
apply_old_delta_with_count() and apply_new_delta_with_count().** Aggregates
Built-in count sum, avg, min, and max are supported. Whether a given
aggregate function can be used or not is checked by using its OID in
check_aggregate_supports_ivm().When creating a materialized view containing aggregates, in addition
to __ivm_count__, more than one hidden columns for each aggregate are
added to the target list. For example, columns for storing sum(x),
count(x) are added if we have avg(x). When the view is maintained,
aggregated values are updated using these hidden columns, also hidden
columns are updated at the same time.The maintenance of aggregated view is performed in
apply_old_delta_with_count() and apply_new_delta_with_count(). The SET
clauses for updating columns are generated by append_set_clause_*().If the view has min(x) or max(x) and the minimum or maximal value is
deleted from a table, we need to update the value to the new min/max
recalculated from the tables rather than incremental computation. This
is performed in recalc_and_set_values().---------------------------------------------------------------------------------------
* Details of the patch-set (v28)The patch-set consists of the following eleven patches.
In the previous version, the number of patches were nine.
In the latest patch-set, the patches are divided more finely
aiming to make the review easier.- 0001: Add a syntax to create Incrementally Maintainable Materialized Views
The prposed syntax to create an incrementally maintainable materialized
view (IMMV) is;CREATE INCREMENTAL MATERIALIZED VIEW AS SELECT .....;
However, this syntax is tentative, so any suggestions are welcomed.
- 0002: Add relisivm column to pg_class system catalog
We add a new field in pg_class to indicate a relation is IMMV.
Another alternative is to add a new catalog for managing materialized
views including IMMV, but I am not sure if we want this.- 0003: Allow to prolong life span of transition tables until transaction end
This patch fixes the trigger system to allow to prolong lifespan of
tuple stores for transition tables until the transaction end. We need
this because multiple transition tables have to be preserved until the
end of the out-most query when multiple tables are modified by nested
triggers. (as explained above in Design - Multiple Tables Modification)If we don't want to change the trigger system in such way, the alternative
is to copy the contents of transition tables to other tuplestores, although
it needs more time and memory.- 0004: Add Incremental View Maintenance support to pg_dump
This patch enables pg_dump to output IMMV using the new syntax.
- 0005: Add Incremental View Maintenance support to psql
This patch implements tab-completion for the new syntax and adds
information of IMMV to \d meta-command results.- 0006: Add Incremental View Maintenance support
This patch implements the basic IVM feature.
DISTINCT and aggregate are not supported here.When an IMMV is created, the view query is checked, and if any
non-supported feature is used, it raises an error. If it is ok,
triggers are created on base tables and an unique index is
created on the view if possible.In BEFORE trigger, an entry is created for each IMMV and the number
of trigger firing is counted. Also, the snapshot just before the
table modification is stored.In AFTER triggers, each transition tables are preserved. The number
of trigger firing is counted also here, and when the firing number of
BEFORE and AFTER trigger reach the same, it is deemed the final AFTER
trigger call.In the final AFTER trigger, the IMMV is maintained. Rewritten view
query is executed to generate delta tables, and deltas are applied
to the view. If multiple tables are modified simultaneously, this
process is iterated for each modified table. Tables before processed
are represented in "pre-update-state", processed tables are
"post-update-state" in the rewritten query.- 0007: Add DISTINCT support for IVM
This patch adds DISTINCT clause support.
When an IMMV including DISTINCT is created, a hidden column
"__ivm_count__" is added to the target list. This column has the
number of duplicity of the same tuples. The duplicity is calculated
by adding "count(*)" and GROUP BY to the view query.When an IMMV is maintained, the duplicity in __ivm_count__ is updated,
and a tuples whose duplicity becomes zero can be deleted from the view.
This logic is implemented by SQL in apply_old_delta_with_count and
apply_new_delta_with_count.Columns starting with "__ivm_" are deemed hidden columns that doesn't
appear when a view is accessed by "SELECT * FROM ....". This is
implemented by fixing parse_relation.c.- 0008: Add aggregates support in IVM
This patch provides codes for aggregates support, specifically
for builtin count, sum, and avg.When an IMMV containing an aggregate is created, it is checked if this
aggregate function is supported, and if it is ok, some hidden columns
are added to the target list.When the IMMV is maintained, the aggregated value is updated as well as
related hidden columns. The way of update depends the type of aggregate
functions, and SET clause string is generated for each aggregate.- 0009: Add support for min/max aggregates for IVM
This patch adds min/max aggregates support.
This is separated from #0008 because min/max needs more complicated
work than count, sum, and avg.If the view has min(x) or max(x) and the minimum or maximal value is
deleted from a table, we need to update the value to the new min/max
recalculated from the tables rather than incremental computation.
This is performed in recalc_and_set_values().TIDs and keys of tuples that need re-calculation are returned as a
result of the query that deleted min/max values from the view using
RETURNING clause. The plan to recalculate and set the new min/max value
are stored and reused.- 0010: regression tests
This patch provides regression tests for IVM.
- 0011: documentation
This patch provides documantation for IVM.
---------------------------------------------------------------------------------------
* Changes from the Previous Version (v27)- Allow TRUNCATE on base tables
When a base table is truncated, the view content will be empty if the
view definition query does not contain an aggregate without a GROUP clause.
Therefore, such views can be truncated.Aggregate views without a GROUP clause always have one row. Therefore,
if a base table is truncated, the view will not be empty and will contain
a row with NULL value (or 0 for count()). So, in this case, we refresh the
view instead of truncating it.- Fix bugs reported by huyajun [1]
[1] /messages/by-id/tencent_FCAF11BCA5003FD16BDDFDDA5D6A19587809@qq.com
---------------------------------------------------------------------------------------
* Discussion** Aggregate support
There were a few suggestions that general aggregate functions should be
supported [2][3], which may be possible by extending pg_aggregate catalog.
However, we decided to leave supporting general aggregates to the future work [4]
because it would need substantial works and make the patch more complex and
bigger.There has been no opposite opinion on this. However, if we need more discussion
on the design of aggregate support, we can omit aggregate support for the first
release of IVM.[2] /messages/by-id/20191128140333.GA25947@alvherre.pgsql
[3] /messages/by-id/CAM-w4HOvDrL4ou6m=592zUiKGVzTcOpNj-d_cJqzL00fdsS5kg@mail.gmail.com
[4] /messages/by-id/20201016193034.9a4c44c79fc1eca7babe093e@sraoss.co.jp** Hidden columns
In order to support DISTINCT or aggregates, our implementation uses hidden columns.
Columns starting with "__ivm_" are hidden columns that doesn't appear when a
view is accessed by "SELECT * FROM ....". For this aim, parse_relation.c is
fixed. There was a proposal to enable hidden columns by adding a new flag to
pg_attribute [5], but this thread is no longer active, so we decided to check
the hidden column by its name [6].[5] /messages/by-id/CAEepm=3ZHh=p0nEEnVbs1Dig_UShPzHUcMNAqvDQUgYgcDo-pA@mail.gmail.com
[6] /messages/by-id/20201016193034.9a4c44c79fc1eca7babe093e@sraoss.co.jp** Concurrent Transactions
When the view definition has more than one table, we acquire an exclusive
lock before the view maintenance in order to avoid inconsistent results.
This behavior was explained in [7]. The lock was improved to use weaker lock
when the view has only one table based on a suggestion from Konstantin Knizhnik [8].
However, due to the implementation that uses ctid for identifying target tuples,
we still have to use an exclusive lock for DELETE and UPDATE.[7] /messages/by-id/20200909092752.c91758a1bec3479668e82643@sraoss.co.jp
[8] /messages/by-id/5663f5f0-48af-686c-bf3c-62d279567e2a@postgrespro.ru** Automatic Index Creation
When a view is created, a unique index is automatically created if
possible, that is, if the view definition query has a GROUP BY or
DISTINCT, or if the view contains all primary key attributes of
its base tables in the target list. It is necessary for efficient
view maintenance. This feature is based on a suggestion from
Konstantin Knizhnik [9].[9] /messages/by-id/89729da8-9042-7ea0-95af-e415df6da14d@postgrespro.ru
** Trigger and Transition Tables
We implemented IVM based on triggers. This is because we want to use
transition tables to extract changes on base tables. Also, there are
other constraint that are using triggers in its implementation, like
foreign references. However, if we can use transition table like feature
without relying triggers, we don't have to insist to use triggers and we
might implement IVM in the executor directly as similar as declarative
partitioning.** Feature to be Supported in the First Release
The current patch-set supports DISTINCT and aggregates for built-in count,
sum, avg, min and max. Do we need all these feature for the first IVM release?
Supporting DISTINCT and aggregates needs discussion on hidden columns, and
for supporting min/max we need to discuss on re-calculation method. Before
handling such relatively advanced feature, maybe, should we focus to design
and implement of the basic feature of IVM?Any suggestion and discussion are welcomed!
Regards,
Yugo Nagata--
Yugo NAGATA <nagata@sraoss.co.jp>The followings are supported in view definition queries:
- SELECT ... FROM ... WHERE ..., joins (inner joins, self-joins)Also, a view definition query cannot contain other views, materialized views,
foreign tables, partitioned tables, partitions, VALUES, non-immutable functions,
system columns, or expressions that contains aggregates.Does this also apply to tableoid? but tableoid is a constant, so it
should be fine?
can following two queries apply to this feature.
select tableoid, unique1 from tenk1;Currently, this is not allowed because tableoid is a system column.
As you say, tableoid is a constant, so we can allow. Should we do this?select 1 as constant, unique1 from tenk1;
This is allowed, of course.
I didn't apply the patch.(will do later, for someone to test, it would
be a better idea to dump a whole file separately....).Thank you! I'm looking forward to your feedback.
(I didn't attach a whole patch separately because I wouldn't like
cfbot to be unhappy...)Regards,
Yugo Nagata--
Yugo NAGATA <nagata@sraoss.co.jp>I played around first half of regress patch.
these all following queries fails.CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS
SELECT DISTINCT * , 1 as "__ivm_count__" FROM mv_base_a;CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS
SELECT DISTINCT * , 1 as "__ivm_countblablabla" FROM mv_base_a;CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS
SELECT DISTINCT * , 1 as "__ivm_count" FROM mv_base_a;CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS
SELECT DISTINCT * , 1 as "__ivm_count_____" FROM mv_base_a;CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS
SELECT DISTINCT * , 1 as "__ivm_countblabla" FROM mv_base_a;so the hidden column reserved pattern "__ivm_count.*"? that would be a lot....
select * from pg_matviews where matviewname = 'mv_ivm_1';
don't have relisivm option. it's reasonable to make it in view pg_matviews?
another trivial:
incremental_matview.out (last few lines) last transaction seems to
need COMMIT command.
I cannot build the doc.
git clean -fdx
git am ~/Desktop/tmp/*.patch
Applying: Add a syntax to create Incrementally Maintainable Materialized Views
Applying: Add relisivm column to pg_class system catalog
Applying: Allow to prolong life span of transition tables until transaction end
Applying: Add Incremental View Maintenance support to pg_dump
Applying: Add Incremental View Maintenance support to psql
Applying: Add Incremental View Maintenance support
Applying: Add DISTINCT support for IVM
Applying: Add aggregates support in IVM
Applying: Add support for min/max aggregates for IVM
Applying: Add regression tests for Incremental View Maintenance
Applying: Add documentations about Incremental View Maintenance
.git/rebase-apply/patch:79: trailing whitespace.
clause.
warning: 1 line adds whitespace errors.
Because of this, the {ninja docs} command failed. ERROR message:
[6/6] Generating doc/src/sgml/html with a custom command
FAILED: doc/src/sgml/html
/usr/bin/python3
../../Desktop/pg_sources/main/postgres/doc/src/sgml/xmltools_dep_wrapper
--targetname doc/src/sgml/html --depfile doc/src/sgml/html.d --tool
/usr/bin/xsltproc -- -o doc/src/sgml/ --nonet --stringparam pg.version
16beta2 --path doc/src/sgml --path
../../Desktop/pg_sources/main/postgres/doc/src/sgml
../../Desktop/pg_sources/main/postgres/doc/src/sgml/stylesheet.xsl
doc/src/sgml/postgres-full.xml
ERROR: id attribute missing on <sect2> element under /book[@id =
'postgres']/part[@id = 'server-programming']/chapter[@id =
'rules']/sect1[@id = 'rules-ivm']
error: file doc/src/sgml/postgres-full.xml
xsltRunStylesheet : run failed
ninja: build stopped: subcommand failed.
On Thu, Jun 29, 2023 at 6:51 PM jian he <jian.universality@gmail.com> wrote:
I cannot build the doc.
git clean -fdx
git am ~/Desktop/tmp/*.patchApplying: Add a syntax to create Incrementally Maintainable Materialized Views
Applying: Add relisivm column to pg_class system catalog
Applying: Allow to prolong life span of transition tables until transaction end
Applying: Add Incremental View Maintenance support to pg_dump
Applying: Add Incremental View Maintenance support to psql
Applying: Add Incremental View Maintenance support
Applying: Add DISTINCT support for IVM
Applying: Add aggregates support in IVM
Applying: Add support for min/max aggregates for IVM
Applying: Add regression tests for Incremental View Maintenance
Applying: Add documentations about Incremental View Maintenance
.git/rebase-apply/patch:79: trailing whitespace.
clause.
warning: 1 line adds whitespace errors.Because of this, the {ninja docs} command failed. ERROR message:
[6/6] Generating doc/src/sgml/html with a custom command
FAILED: doc/src/sgml/html
/usr/bin/python3
../../Desktop/pg_sources/main/postgres/doc/src/sgml/xmltools_dep_wrapper
--targetname doc/src/sgml/html --depfile doc/src/sgml/html.d --tool
/usr/bin/xsltproc -- -o doc/src/sgml/ --nonet --stringparam pg.version
16beta2 --path doc/src/sgml --path
../../Desktop/pg_sources/main/postgres/doc/src/sgml
../../Desktop/pg_sources/main/postgres/doc/src/sgml/stylesheet.xsl
doc/src/sgml/postgres-full.xml
ERROR: id attribute missing on <sect2> element under /book[@id =
'postgres']/part[@id = 'server-programming']/chapter[@id =
'rules']/sect1[@id = 'rules-ivm']
error: file doc/src/sgml/postgres-full.xml
xsltRunStylesheet : run failed
ninja: build stopped: subcommand failed.
so far what I tried:
git am --ignore-whitespace --whitespace=nowarn ~/Desktop/tmp/*.patch
git am --whitespace=fix ~/Desktop/tmp/*.patch
git am --whitespace=error ~/Desktop/tmp/*.patch
I still cannot generate html docs.
Hi there.
in v28-0005-Add-Incremental-View-Maintenance-support-to-psql.patch
I don't know how to set psql to get the output
"Incremental view maintenance: yes"
This is probably not trivial.
In function apply_new_delta_with_count.
appendStringInfo(&querybuf,
"WITH updt AS (" /* update a tuple if this exists in the view */
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.+) diff.%s "
"%s " /* SET clauses for aggregates */
"FROM %s AS diff "
"WHERE %s " /* tuple matching condition */
"RETURNING %s" /* returning keys of updated tuples */
") INSERT INTO %s (%s)" /* insert a new tuple if this doesn't existw */
"SELECT %s FROM %s AS diff "
"WHERE NOT EXISTS (SELECT 1 FROM updt AS mv WHERE %s);",
---------------------
") INSERT INTO %s (%s)" /* insert a new tuple if this doesn't existw */
"SELECT %s FROM %s AS diff "
the INSERT INTO line, should have one white space in the end?
also "existw" should be "exists"
ok. Now I really found a small bug.
this works as intended:
BEGIN;
CREATE INCREMENTAL MATERIALIZED VIEW test_ivm AS SELECT i, MIN(j) as
min_j FROM mv_base_a group by 1;
INSERT INTO mv_base_a select 1,-2 where false;
rollback;
however the following one:
BEGIN;
CREATE INCREMENTAL MATERIALIZED VIEW test_ivm1 AS SELECT MIN(j) as
min_j FROM mv_base_a;
INSERT INTO mv_base_a select 1, -2 where false;
rollback;
will evaluate
tuplestore_tuple_count(new_tuplestores) to 1, it will walk through
IVM_immediate_maintenance function to apply_delta.
but should it be zero?
On Thu, 29 Jun 2023 00:40:45 +0800
jian he <jian.universality@gmail.com> wrote:
On Wed, Jun 28, 2023 at 4:06 PM Yugo NAGATA <nagata@sraoss.co.jp> wrote:
On Wed, 28 Jun 2023 00:01:02 +0800
jian he <jian.universality@gmail.com> wrote:On Thu, Jun 1, 2023 at 2:47 AM Yugo NAGATA <nagata@sraoss.co.jp> wrote:
On Thu, 1 Jun 2023 23:59:09 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:Hello hackers,
Here's a rebased version of the patch-set adding Incremental View
Maintenance support for PostgreSQL. That was discussed in [1].[1] /messages/by-id/20181227215726.4d166b4874f8983a641123f5@sraoss.co.jp
---------------------------------------------------------------------------------------
* OverviewIncremental View Maintenance (IVM) is a way to make materialized views
up-to-date by computing only incremental changes and applying them on
views. IVM is more efficient than REFRESH MATERIALIZED VIEW when
only small parts of the view are changed.** Feature
The attached patchset provides a feature that allows materialized views
to be updated automatically and incrementally just after a underlying
table is modified.You can create an incementally maintainable materialized view (IMMV)
by using CREATE INCREMENTAL MATERIALIZED VIEW command.The followings are supported in view definition queries:
- SELECT ... FROM ... WHERE ..., joins (inner joins, self-joins)
- some built-in aggregate functions (count, sum, avg, min, max)
- GROUP BY clause
- DISTINCT clauseViews can contain multiple tuples with the same content (duplicate tuples).
** Restriction
The following are not supported in a view definition:
- Outer joins
- Aggregates otehr than above, window functions, HAVING
- Sub-queries, CTEs
- Set operations (UNION, INTERSECT, EXCEPT)
- DISTINCT ON, ORDER BY, LIMIT, OFFSETAlso, a view definition query cannot contain other views, materialized views,
foreign tables, partitioned tables, partitions, VALUES, non-immutable functions,
system columns, or expressions that contains aggregates.---------------------------------------------------------------------------------------
* DesignAn IMMV is maintained using statement-level AFTER triggers.
When an IMMV is created, triggers are automatically created on all base
tables contained in the view definition query.When a table is modified, changes that occurred in the table are extracted
as transition tables in the AFTER triggers. Then, changes that will occur in
the view are calculated by a rewritten view dequery in which the modified table
is replaced with the transition table.For example, if the view is defined as "SELECT * FROM R, S", and tuples inserted
into R are stored in a transiton table dR, the tuples that will be inserted into
the view are calculated as the result of "SELECT * FROM dR, S".** Multiple Tables Modification
Multiple tables can be modified in a statement when using triggers, foreign key
constraint, or modifying CTEs. When multiple tables are modified, we need
the state of tables before the modification.For example, when some tuples, dR and dS, are inserted into R and S respectively,
the tuples that will be inserted into the view are calculated by the following
two queries:"SELECT * FROM dR, S_pre"
"SELECT * FROM R, dS"where S_pre is the table before the modification, R is the current state of
table, that is, after the modification. This pre-update states of table
is calculated by filtering inserted tuples and appending deleted tuples.
The subquery that represents pre-update state is generated in get_prestate_rte().
Specifically, the insterted tuples are filtered by calling IVM_visible_in_prestate()
in WHERE clause. This function checks the visibility of tuples by using
the snapshot taken before table modification. The deleted tuples are contained
in the old transition table, and this table is appended using UNION ALL.Transition tables for each modification are collected in each AFTER trigger
function call. Then, the view maintenance is performed in the last call of
the trigger.In the original PostgreSQL, tuplestores of transition tables are freed at the
end of each nested query. However, their lifespan needs to be prolonged to
the end of the out-most query in order to maintain the view in the last AFTER
trigger. For this purpose, SetTransitionTablePreserved is added in trigger.c.** Duplicate Tulpes
When calculating changes that will occur in the view (= delta tables),
multiplicity of tuples are calculated by using count(*).When deleting tuples from the view, tuples to be deleted are identified by
joining the delta table with the view, and tuples are deleted as many as
specified multiplicity by numbered using row_number() function.
This is implemented in apply_old_delta().When inserting tuples into the view, each tuple is duplicated to the
specified multiplicity using generate_series() function. This is implemented
in apply_new_delta().** DISTINCT clause
When DISTINCT is used, the view has a hidden column __ivm_count__ that
stores multiplicity for tuples. When tuples are deleted from or inserted into
the view, the values of __ivm_count__ column is decreased or increased as many
as specified multiplicity. Eventually, when the values becomes zero, the
corresponding tuple is deleted from the view. This is implemented in
apply_old_delta_with_count() and apply_new_delta_with_count().** Aggregates
Built-in count sum, avg, min, and max are supported. Whether a given
aggregate function can be used or not is checked by using its OID in
check_aggregate_supports_ivm().When creating a materialized view containing aggregates, in addition
to __ivm_count__, more than one hidden columns for each aggregate are
added to the target list. For example, columns for storing sum(x),
count(x) are added if we have avg(x). When the view is maintained,
aggregated values are updated using these hidden columns, also hidden
columns are updated at the same time.The maintenance of aggregated view is performed in
apply_old_delta_with_count() and apply_new_delta_with_count(). The SET
clauses for updating columns are generated by append_set_clause_*().If the view has min(x) or max(x) and the minimum or maximal value is
deleted from a table, we need to update the value to the new min/max
recalculated from the tables rather than incremental computation. This
is performed in recalc_and_set_values().---------------------------------------------------------------------------------------
* Details of the patch-set (v28)The patch-set consists of the following eleven patches.
In the previous version, the number of patches were nine.
In the latest patch-set, the patches are divided more finely
aiming to make the review easier.- 0001: Add a syntax to create Incrementally Maintainable Materialized Views
The prposed syntax to create an incrementally maintainable materialized
view (IMMV) is;CREATE INCREMENTAL MATERIALIZED VIEW AS SELECT .....;
However, this syntax is tentative, so any suggestions are welcomed.
- 0002: Add relisivm column to pg_class system catalog
We add a new field in pg_class to indicate a relation is IMMV.
Another alternative is to add a new catalog for managing materialized
views including IMMV, but I am not sure if we want this.- 0003: Allow to prolong life span of transition tables until transaction end
This patch fixes the trigger system to allow to prolong lifespan of
tuple stores for transition tables until the transaction end. We need
this because multiple transition tables have to be preserved until the
end of the out-most query when multiple tables are modified by nested
triggers. (as explained above in Design - Multiple Tables Modification)If we don't want to change the trigger system in such way, the alternative
is to copy the contents of transition tables to other tuplestores, although
it needs more time and memory.- 0004: Add Incremental View Maintenance support to pg_dump
This patch enables pg_dump to output IMMV using the new syntax.
- 0005: Add Incremental View Maintenance support to psql
This patch implements tab-completion for the new syntax and adds
information of IMMV to \d meta-command results.- 0006: Add Incremental View Maintenance support
This patch implements the basic IVM feature.
DISTINCT and aggregate are not supported here.When an IMMV is created, the view query is checked, and if any
non-supported feature is used, it raises an error. If it is ok,
triggers are created on base tables and an unique index is
created on the view if possible.In BEFORE trigger, an entry is created for each IMMV and the number
of trigger firing is counted. Also, the snapshot just before the
table modification is stored.In AFTER triggers, each transition tables are preserved. The number
of trigger firing is counted also here, and when the firing number of
BEFORE and AFTER trigger reach the same, it is deemed the final AFTER
trigger call.In the final AFTER trigger, the IMMV is maintained. Rewritten view
query is executed to generate delta tables, and deltas are applied
to the view. If multiple tables are modified simultaneously, this
process is iterated for each modified table. Tables before processed
are represented in "pre-update-state", processed tables are
"post-update-state" in the rewritten query.- 0007: Add DISTINCT support for IVM
This patch adds DISTINCT clause support.
When an IMMV including DISTINCT is created, a hidden column
"__ivm_count__" is added to the target list. This column has the
number of duplicity of the same tuples. The duplicity is calculated
by adding "count(*)" and GROUP BY to the view query.When an IMMV is maintained, the duplicity in __ivm_count__ is updated,
and a tuples whose duplicity becomes zero can be deleted from the view.
This logic is implemented by SQL in apply_old_delta_with_count and
apply_new_delta_with_count.Columns starting with "__ivm_" are deemed hidden columns that doesn't
appear when a view is accessed by "SELECT * FROM ....". This is
implemented by fixing parse_relation.c.- 0008: Add aggregates support in IVM
This patch provides codes for aggregates support, specifically
for builtin count, sum, and avg.When an IMMV containing an aggregate is created, it is checked if this
aggregate function is supported, and if it is ok, some hidden columns
are added to the target list.When the IMMV is maintained, the aggregated value is updated as well as
related hidden columns. The way of update depends the type of aggregate
functions, and SET clause string is generated for each aggregate.- 0009: Add support for min/max aggregates for IVM
This patch adds min/max aggregates support.
This is separated from #0008 because min/max needs more complicated
work than count, sum, and avg.If the view has min(x) or max(x) and the minimum or maximal value is
deleted from a table, we need to update the value to the new min/max
recalculated from the tables rather than incremental computation.
This is performed in recalc_and_set_values().TIDs and keys of tuples that need re-calculation are returned as a
result of the query that deleted min/max values from the view using
RETURNING clause. The plan to recalculate and set the new min/max value
are stored and reused.- 0010: regression tests
This patch provides regression tests for IVM.
- 0011: documentation
This patch provides documantation for IVM.
---------------------------------------------------------------------------------------
* Changes from the Previous Version (v27)- Allow TRUNCATE on base tables
When a base table is truncated, the view content will be empty if the
view definition query does not contain an aggregate without a GROUP clause.
Therefore, such views can be truncated.Aggregate views without a GROUP clause always have one row. Therefore,
if a base table is truncated, the view will not be empty and will contain
a row with NULL value (or 0 for count()). So, in this case, we refresh the
view instead of truncating it.- Fix bugs reported by huyajun [1]
[1] /messages/by-id/tencent_FCAF11BCA5003FD16BDDFDDA5D6A19587809@qq.com
---------------------------------------------------------------------------------------
* Discussion** Aggregate support
There were a few suggestions that general aggregate functions should be
supported [2][3], which may be possible by extending pg_aggregate catalog.
However, we decided to leave supporting general aggregates to the future work [4]
because it would need substantial works and make the patch more complex and
bigger.There has been no opposite opinion on this. However, if we need more discussion
on the design of aggregate support, we can omit aggregate support for the first
release of IVM.[2] /messages/by-id/20191128140333.GA25947@alvherre.pgsql
[3] /messages/by-id/CAM-w4HOvDrL4ou6m=592zUiKGVzTcOpNj-d_cJqzL00fdsS5kg@mail.gmail.com
[4] /messages/by-id/20201016193034.9a4c44c79fc1eca7babe093e@sraoss.co.jp** Hidden columns
In order to support DISTINCT or aggregates, our implementation uses hidden columns.
Columns starting with "__ivm_" are hidden columns that doesn't appear when a
view is accessed by "SELECT * FROM ....". For this aim, parse_relation.c is
fixed. There was a proposal to enable hidden columns by adding a new flag to
pg_attribute [5], but this thread is no longer active, so we decided to check
the hidden column by its name [6].[5] /messages/by-id/CAEepm=3ZHh=p0nEEnVbs1Dig_UShPzHUcMNAqvDQUgYgcDo-pA@mail.gmail.com
[6] /messages/by-id/20201016193034.9a4c44c79fc1eca7babe093e@sraoss.co.jp** Concurrent Transactions
When the view definition has more than one table, we acquire an exclusive
lock before the view maintenance in order to avoid inconsistent results.
This behavior was explained in [7]. The lock was improved to use weaker lock
when the view has only one table based on a suggestion from Konstantin Knizhnik [8].
However, due to the implementation that uses ctid for identifying target tuples,
we still have to use an exclusive lock for DELETE and UPDATE.[7] /messages/by-id/20200909092752.c91758a1bec3479668e82643@sraoss.co.jp
[8] /messages/by-id/5663f5f0-48af-686c-bf3c-62d279567e2a@postgrespro.ru** Automatic Index Creation
When a view is created, a unique index is automatically created if
possible, that is, if the view definition query has a GROUP BY or
DISTINCT, or if the view contains all primary key attributes of
its base tables in the target list. It is necessary for efficient
view maintenance. This feature is based on a suggestion from
Konstantin Knizhnik [9].[9] /messages/by-id/89729da8-9042-7ea0-95af-e415df6da14d@postgrespro.ru
** Trigger and Transition Tables
We implemented IVM based on triggers. This is because we want to use
transition tables to extract changes on base tables. Also, there are
other constraint that are using triggers in its implementation, like
foreign references. However, if we can use transition table like feature
without relying triggers, we don't have to insist to use triggers and we
might implement IVM in the executor directly as similar as declarative
partitioning.** Feature to be Supported in the First Release
The current patch-set supports DISTINCT and aggregates for built-in count,
sum, avg, min and max. Do we need all these feature for the first IVM release?
Supporting DISTINCT and aggregates needs discussion on hidden columns, and
for supporting min/max we need to discuss on re-calculation method. Before
handling such relatively advanced feature, maybe, should we focus to design
and implement of the basic feature of IVM?Any suggestion and discussion are welcomed!
Regards,
Yugo Nagata--
Yugo NAGATA <nagata@sraoss.co.jp>The followings are supported in view definition queries:
- SELECT ... FROM ... WHERE ..., joins (inner joins, self-joins)Also, a view definition query cannot contain other views, materialized views,
foreign tables, partitioned tables, partitions, VALUES, non-immutable functions,
system columns, or expressions that contains aggregates.Does this also apply to tableoid? but tableoid is a constant, so it
should be fine?
can following two queries apply to this feature.
select tableoid, unique1 from tenk1;Currently, this is not allowed because tableoid is a system column.
As you say, tableoid is a constant, so we can allow. Should we do this?select 1 as constant, unique1 from tenk1;
This is allowed, of course.
I didn't apply the patch.(will do later, for someone to test, it would
be a better idea to dump a whole file separately....).Thank you! I'm looking forward to your feedback.
(I didn't attach a whole patch separately because I wouldn't like
cfbot to be unhappy...)Regards,
Yugo Nagata--
Yugo NAGATA <nagata@sraoss.co.jp>I played around first half of regress patch.
I'm so sorry for the late reply.
these all following queries fails.
CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS
SELECT DISTINCT * , 1 as "__ivm_count__" FROM mv_base_a;CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS
SELECT DISTINCT * , 1 as "__ivm_countblablabla" FROM mv_base_a;CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS
SELECT DISTINCT * , 1 as "__ivm_count" FROM mv_base_a;CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS
SELECT DISTINCT * , 1 as "__ivm_count_____" FROM mv_base_a;CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS
SELECT DISTINCT * , 1 as "__ivm_countblabla" FROM mv_base_a;so the hidden column reserved pattern "__ivm_count.*"? that would be a lot....
Column names which start with "__ivm_" are prohibited because hidden columns
using this pattern are used for handling views with aggregate or DISTINCT.
Even when neither aggregate or DISINCT is used, such column name is used
for handling tuple duplicates in views. So, if we choose not to allow
tuple duplicates in the initial version of IVM, we would remove this
restriction for now....
select * from pg_matviews where matviewname = 'mv_ivm_1';
don't have relisivm option. it's reasonable to make it in view pg_matviews?
Make sense. I'll do it.
Regards,
Yugo Nagata
--
Yugo NAGATA <nagata@sraoss.co.jp>
On Thu, 29 Jun 2023 18:20:32 +0800
jian he <jian.universality@gmail.com> wrote:
On Thu, Jun 29, 2023 at 12:40 AM jian he <jian.universality@gmail.com> wrote:
On Wed, Jun 28, 2023 at 4:06 PM Yugo NAGATA <nagata@sraoss.co.jp> wrote:
On Wed, 28 Jun 2023 00:01:02 +0800
jian he <jian.universality@gmail.com> wrote:On Thu, Jun 1, 2023 at 2:47 AM Yugo NAGATA <nagata@sraoss.co.jp> wrote:
On Thu, 1 Jun 2023 23:59:09 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:Hello hackers,
Here's a rebased version of the patch-set adding Incremental View
Maintenance support for PostgreSQL. That was discussed in [1].[1] /messages/by-id/20181227215726.4d166b4874f8983a641123f5@sraoss.co.jp
---------------------------------------------------------------------------------------
* OverviewIncremental View Maintenance (IVM) is a way to make materialized views
up-to-date by computing only incremental changes and applying them on
views. IVM is more efficient than REFRESH MATERIALIZED VIEW when
only small parts of the view are changed.** Feature
The attached patchset provides a feature that allows materialized views
to be updated automatically and incrementally just after a underlying
table is modified.You can create an incementally maintainable materialized view (IMMV)
by using CREATE INCREMENTAL MATERIALIZED VIEW command.The followings are supported in view definition queries:
- SELECT ... FROM ... WHERE ..., joins (inner joins, self-joins)
- some built-in aggregate functions (count, sum, avg, min, max)
- GROUP BY clause
- DISTINCT clauseViews can contain multiple tuples with the same content (duplicate tuples).
** Restriction
The following are not supported in a view definition:
- Outer joins
- Aggregates otehr than above, window functions, HAVING
- Sub-queries, CTEs
- Set operations (UNION, INTERSECT, EXCEPT)
- DISTINCT ON, ORDER BY, LIMIT, OFFSETAlso, a view definition query cannot contain other views, materialized views,
foreign tables, partitioned tables, partitions, VALUES, non-immutable functions,
system columns, or expressions that contains aggregates.---------------------------------------------------------------------------------------
* DesignAn IMMV is maintained using statement-level AFTER triggers.
When an IMMV is created, triggers are automatically created on all base
tables contained in the view definition query.When a table is modified, changes that occurred in the table are extracted
as transition tables in the AFTER triggers. Then, changes that will occur in
the view are calculated by a rewritten view dequery in which the modified table
is replaced with the transition table.For example, if the view is defined as "SELECT * FROM R, S", and tuples inserted
into R are stored in a transiton table dR, the tuples that will be inserted into
the view are calculated as the result of "SELECT * FROM dR, S".** Multiple Tables Modification
Multiple tables can be modified in a statement when using triggers, foreign key
constraint, or modifying CTEs. When multiple tables are modified, we need
the state of tables before the modification.For example, when some tuples, dR and dS, are inserted into R and S respectively,
the tuples that will be inserted into the view are calculated by the following
two queries:"SELECT * FROM dR, S_pre"
"SELECT * FROM R, dS"where S_pre is the table before the modification, R is the current state of
table, that is, after the modification. This pre-update states of table
is calculated by filtering inserted tuples and appending deleted tuples.
The subquery that represents pre-update state is generated in get_prestate_rte().
Specifically, the insterted tuples are filtered by calling IVM_visible_in_prestate()
in WHERE clause. This function checks the visibility of tuples by using
the snapshot taken before table modification. The deleted tuples are contained
in the old transition table, and this table is appended using UNION ALL.Transition tables for each modification are collected in each AFTER trigger
function call. Then, the view maintenance is performed in the last call of
the trigger.In the original PostgreSQL, tuplestores of transition tables are freed at the
end of each nested query. However, their lifespan needs to be prolonged to
the end of the out-most query in order to maintain the view in the last AFTER
trigger. For this purpose, SetTransitionTablePreserved is added in trigger.c.** Duplicate Tulpes
When calculating changes that will occur in the view (= delta tables),
multiplicity of tuples are calculated by using count(*).When deleting tuples from the view, tuples to be deleted are identified by
joining the delta table with the view, and tuples are deleted as many as
specified multiplicity by numbered using row_number() function.
This is implemented in apply_old_delta().When inserting tuples into the view, each tuple is duplicated to the
specified multiplicity using generate_series() function. This is implemented
in apply_new_delta().** DISTINCT clause
When DISTINCT is used, the view has a hidden column __ivm_count__ that
stores multiplicity for tuples. When tuples are deleted from or inserted into
the view, the values of __ivm_count__ column is decreased or increased as many
as specified multiplicity. Eventually, when the values becomes zero, the
corresponding tuple is deleted from the view. This is implemented in
apply_old_delta_with_count() and apply_new_delta_with_count().** Aggregates
Built-in count sum, avg, min, and max are supported. Whether a given
aggregate function can be used or not is checked by using its OID in
check_aggregate_supports_ivm().When creating a materialized view containing aggregates, in addition
to __ivm_count__, more than one hidden columns for each aggregate are
added to the target list. For example, columns for storing sum(x),
count(x) are added if we have avg(x). When the view is maintained,
aggregated values are updated using these hidden columns, also hidden
columns are updated at the same time.The maintenance of aggregated view is performed in
apply_old_delta_with_count() and apply_new_delta_with_count(). The SET
clauses for updating columns are generated by append_set_clause_*().If the view has min(x) or max(x) and the minimum or maximal value is
deleted from a table, we need to update the value to the new min/max
recalculated from the tables rather than incremental computation. This
is performed in recalc_and_set_values().---------------------------------------------------------------------------------------
* Details of the patch-set (v28)The patch-set consists of the following eleven patches.
In the previous version, the number of patches were nine.
In the latest patch-set, the patches are divided more finely
aiming to make the review easier.- 0001: Add a syntax to create Incrementally Maintainable Materialized Views
The prposed syntax to create an incrementally maintainable materialized
view (IMMV) is;CREATE INCREMENTAL MATERIALIZED VIEW AS SELECT .....;
However, this syntax is tentative, so any suggestions are welcomed.
- 0002: Add relisivm column to pg_class system catalog
We add a new field in pg_class to indicate a relation is IMMV.
Another alternative is to add a new catalog for managing materialized
views including IMMV, but I am not sure if we want this.- 0003: Allow to prolong life span of transition tables until transaction end
This patch fixes the trigger system to allow to prolong lifespan of
tuple stores for transition tables until the transaction end. We need
this because multiple transition tables have to be preserved until the
end of the out-most query when multiple tables are modified by nested
triggers. (as explained above in Design - Multiple Tables Modification)If we don't want to change the trigger system in such way, the alternative
is to copy the contents of transition tables to other tuplestores, although
it needs more time and memory.- 0004: Add Incremental View Maintenance support to pg_dump
This patch enables pg_dump to output IMMV using the new syntax.
- 0005: Add Incremental View Maintenance support to psql
This patch implements tab-completion for the new syntax and adds
information of IMMV to \d meta-command results.- 0006: Add Incremental View Maintenance support
This patch implements the basic IVM feature.
DISTINCT and aggregate are not supported here.When an IMMV is created, the view query is checked, and if any
non-supported feature is used, it raises an error. If it is ok,
triggers are created on base tables and an unique index is
created on the view if possible.In BEFORE trigger, an entry is created for each IMMV and the number
of trigger firing is counted. Also, the snapshot just before the
table modification is stored.In AFTER triggers, each transition tables are preserved. The number
of trigger firing is counted also here, and when the firing number of
BEFORE and AFTER trigger reach the same, it is deemed the final AFTER
trigger call.In the final AFTER trigger, the IMMV is maintained. Rewritten view
query is executed to generate delta tables, and deltas are applied
to the view. If multiple tables are modified simultaneously, this
process is iterated for each modified table. Tables before processed
are represented in "pre-update-state", processed tables are
"post-update-state" in the rewritten query.- 0007: Add DISTINCT support for IVM
This patch adds DISTINCT clause support.
When an IMMV including DISTINCT is created, a hidden column
"__ivm_count__" is added to the target list. This column has the
number of duplicity of the same tuples. The duplicity is calculated
by adding "count(*)" and GROUP BY to the view query.When an IMMV is maintained, the duplicity in __ivm_count__ is updated,
and a tuples whose duplicity becomes zero can be deleted from the view.
This logic is implemented by SQL in apply_old_delta_with_count and
apply_new_delta_with_count.Columns starting with "__ivm_" are deemed hidden columns that doesn't
appear when a view is accessed by "SELECT * FROM ....". This is
implemented by fixing parse_relation.c.- 0008: Add aggregates support in IVM
This patch provides codes for aggregates support, specifically
for builtin count, sum, and avg.When an IMMV containing an aggregate is created, it is checked if this
aggregate function is supported, and if it is ok, some hidden columns
are added to the target list.When the IMMV is maintained, the aggregated value is updated as well as
related hidden columns. The way of update depends the type of aggregate
functions, and SET clause string is generated for each aggregate.- 0009: Add support for min/max aggregates for IVM
This patch adds min/max aggregates support.
This is separated from #0008 because min/max needs more complicated
work than count, sum, and avg.If the view has min(x) or max(x) and the minimum or maximal value is
deleted from a table, we need to update the value to the new min/max
recalculated from the tables rather than incremental computation.
This is performed in recalc_and_set_values().TIDs and keys of tuples that need re-calculation are returned as a
result of the query that deleted min/max values from the view using
RETURNING clause. The plan to recalculate and set the new min/max value
are stored and reused.- 0010: regression tests
This patch provides regression tests for IVM.
- 0011: documentation
This patch provides documantation for IVM.
---------------------------------------------------------------------------------------
* Changes from the Previous Version (v27)- Allow TRUNCATE on base tables
When a base table is truncated, the view content will be empty if the
view definition query does not contain an aggregate without a GROUP clause.
Therefore, such views can be truncated.Aggregate views without a GROUP clause always have one row. Therefore,
if a base table is truncated, the view will not be empty and will contain
a row with NULL value (or 0 for count()). So, in this case, we refresh the
view instead of truncating it.- Fix bugs reported by huyajun [1]
[1] /messages/by-id/tencent_FCAF11BCA5003FD16BDDFDDA5D6A19587809@qq.com
---------------------------------------------------------------------------------------
* Discussion** Aggregate support
There were a few suggestions that general aggregate functions should be
supported [2][3], which may be possible by extending pg_aggregate catalog.
However, we decided to leave supporting general aggregates to the future work [4]
because it would need substantial works and make the patch more complex and
bigger.There has been no opposite opinion on this. However, if we need more discussion
on the design of aggregate support, we can omit aggregate support for the first
release of IVM.[2] /messages/by-id/20191128140333.GA25947@alvherre.pgsql
[3] /messages/by-id/CAM-w4HOvDrL4ou6m=592zUiKGVzTcOpNj-d_cJqzL00fdsS5kg@mail.gmail.com
[4] /messages/by-id/20201016193034.9a4c44c79fc1eca7babe093e@sraoss.co.jp** Hidden columns
In order to support DISTINCT or aggregates, our implementation uses hidden columns.
Columns starting with "__ivm_" are hidden columns that doesn't appear when a
view is accessed by "SELECT * FROM ....". For this aim, parse_relation.c is
fixed. There was a proposal to enable hidden columns by adding a new flag to
pg_attribute [5], but this thread is no longer active, so we decided to check
the hidden column by its name [6].[5] /messages/by-id/CAEepm=3ZHh=p0nEEnVbs1Dig_UShPzHUcMNAqvDQUgYgcDo-pA@mail.gmail.com
[6] /messages/by-id/20201016193034.9a4c44c79fc1eca7babe093e@sraoss.co.jp** Concurrent Transactions
When the view definition has more than one table, we acquire an exclusive
lock before the view maintenance in order to avoid inconsistent results.
This behavior was explained in [7]. The lock was improved to use weaker lock
when the view has only one table based on a suggestion from Konstantin Knizhnik [8].
However, due to the implementation that uses ctid for identifying target tuples,
we still have to use an exclusive lock for DELETE and UPDATE.[7] /messages/by-id/20200909092752.c91758a1bec3479668e82643@sraoss.co.jp
[8] /messages/by-id/5663f5f0-48af-686c-bf3c-62d279567e2a@postgrespro.ru** Automatic Index Creation
When a view is created, a unique index is automatically created if
possible, that is, if the view definition query has a GROUP BY or
DISTINCT, or if the view contains all primary key attributes of
its base tables in the target list. It is necessary for efficient
view maintenance. This feature is based on a suggestion from
Konstantin Knizhnik [9].[9] /messages/by-id/89729da8-9042-7ea0-95af-e415df6da14d@postgrespro.ru
** Trigger and Transition Tables
We implemented IVM based on triggers. This is because we want to use
transition tables to extract changes on base tables. Also, there are
other constraint that are using triggers in its implementation, like
foreign references. However, if we can use transition table like feature
without relying triggers, we don't have to insist to use triggers and we
might implement IVM in the executor directly as similar as declarative
partitioning.** Feature to be Supported in the First Release
The current patch-set supports DISTINCT and aggregates for built-in count,
sum, avg, min and max. Do we need all these feature for the first IVM release?
Supporting DISTINCT and aggregates needs discussion on hidden columns, and
for supporting min/max we need to discuss on re-calculation method. Before
handling such relatively advanced feature, maybe, should we focus to design
and implement of the basic feature of IVM?Any suggestion and discussion are welcomed!
Regards,
Yugo Nagata--
Yugo NAGATA <nagata@sraoss.co.jp>The followings are supported in view definition queries:
- SELECT ... FROM ... WHERE ..., joins (inner joins, self-joins)Also, a view definition query cannot contain other views, materialized views,
foreign tables, partitioned tables, partitions, VALUES, non-immutable functions,
system columns, or expressions that contains aggregates.Does this also apply to tableoid? but tableoid is a constant, so it
should be fine?
can following two queries apply to this feature.
select tableoid, unique1 from tenk1;Currently, this is not allowed because tableoid is a system column.
As you say, tableoid is a constant, so we can allow. Should we do this?select 1 as constant, unique1 from tenk1;
This is allowed, of course.
I didn't apply the patch.(will do later, for someone to test, it would
be a better idea to dump a whole file separately....).Thank you! I'm looking forward to your feedback.
(I didn't attach a whole patch separately because I wouldn't like
cfbot to be unhappy...)Regards,
Yugo Nagata--
Yugo NAGATA <nagata@sraoss.co.jp>I played around first half of regress patch.
these all following queries fails.CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS
SELECT DISTINCT * , 1 as "__ivm_count__" FROM mv_base_a;CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS
SELECT DISTINCT * , 1 as "__ivm_countblablabla" FROM mv_base_a;CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS
SELECT DISTINCT * , 1 as "__ivm_count" FROM mv_base_a;CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS
SELECT DISTINCT * , 1 as "__ivm_count_____" FROM mv_base_a;CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS
SELECT DISTINCT * , 1 as "__ivm_countblabla" FROM mv_base_a;so the hidden column reserved pattern "__ivm_count.*"? that would be a lot....
select * from pg_matviews where matviewname = 'mv_ivm_1';
don't have relisivm option. it's reasonable to make it in view pg_matviews?another trivial:
incremental_matview.out (last few lines) last transaction seems to
need COMMIT command.
Thank you for pointing out it.
There is a unnecessary BEGIN, so I'll remove it.
Regards,
Yugo Nagata
--
Yugo NAGATA <nagata@sraoss.co.jp>
On Thu, 29 Jun 2023 18:51:06 +0800
jian he <jian.universality@gmail.com> wrote:
I cannot build the doc.
git clean -fdx
git am ~/Desktop/tmp/*.patchApplying: Add a syntax to create Incrementally Maintainable Materialized Views
Applying: Add relisivm column to pg_class system catalog
Applying: Allow to prolong life span of transition tables until transaction end
Applying: Add Incremental View Maintenance support to pg_dump
Applying: Add Incremental View Maintenance support to psql
Applying: Add Incremental View Maintenance support
Applying: Add DISTINCT support for IVM
Applying: Add aggregates support in IVM
Applying: Add support for min/max aggregates for IVM
Applying: Add regression tests for Incremental View Maintenance
Applying: Add documentations about Incremental View Maintenance
.git/rebase-apply/patch:79: trailing whitespace.
clause.
warning: 1 line adds whitespace errors.Because of this, the {ninja docs} command failed. ERROR message:
[6/6] Generating doc/src/sgml/html with a custom command
FAILED: doc/src/sgml/html
/usr/bin/python3
../../Desktop/pg_sources/main/postgres/doc/src/sgml/xmltools_dep_wrapper
--targetname doc/src/sgml/html --depfile doc/src/sgml/html.d --tool
/usr/bin/xsltproc -- -o doc/src/sgml/ --nonet --stringparam pg.version
16beta2 --path doc/src/sgml --path
../../Desktop/pg_sources/main/postgres/doc/src/sgml
../../Desktop/pg_sources/main/postgres/doc/src/sgml/stylesheet.xsl
doc/src/sgml/postgres-full.xml
ERROR: id attribute missing on <sect2> element under /book[@id =
'postgres']/part[@id = 'server-programming']/chapter[@id =
'rules']/sect1[@id = 'rules-ivm']
error: file doc/src/sgml/postgres-full.xml
xsltRunStylesheet : run failed
ninja: build stopped: subcommand failed.
Thank your for pointing out this.
I'll add ids for all sections to suppress the errors.
Regards,
Yugo Nagata
--
Yugo NAGATA <nagata@sraoss.co.jp>
On Fri, 30 Jun 2023 08:00:00 +0800
jian he <jian.universality@gmail.com> wrote:
Hi there.
in v28-0005-Add-Incremental-View-Maintenance-support-to-psql.patch
I don't know how to set psql to get the output
"Incremental view maintenance: yes"
This information will appear when you use "d+" command for an
incrementally maintained materialized view.
Regards,
Yugo Nagata
--
Yugo NAGATA <nagata@sraoss.co.jp>
On Sun, 2 Jul 2023 08:25:12 +0800
jian he <jian.universality@gmail.com> wrote:
This is probably not trivial.
In function apply_new_delta_with_count.appendStringInfo(&querybuf,
"WITH updt AS (" /* update a tuple if this exists in the view */
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.+) diff.%s "
"%s " /* SET clauses for aggregates */
"FROM %s AS diff "
"WHERE %s " /* tuple matching condition */
"RETURNING %s" /* returning keys of updated tuples */
") INSERT INTO %s (%s)" /* insert a new tuple if this doesn't existw */
"SELECT %s FROM %s AS diff "
"WHERE NOT EXISTS (SELECT 1 FROM updt AS mv WHERE %s);",---------------------
") INSERT INTO %s (%s)" /* insert a new tuple if this doesn't existw */
"SELECT %s FROM %s AS diff "the INSERT INTO line, should have one white space in the end?
also "existw" should be "exists"
Yes, we should need a space although it works. I'll fix as well as the typo.
Thank you.
Regards,
Yugo Nagata
--
Yugo NAGATA <nagata@sraoss.co.jp>
On Sun, 2 Jul 2023 10:38:20 +0800
jian he <jian.universality@gmail.com> wrote:
ok. Now I really found a small bug.
this works as intended:
BEGIN;
CREATE INCREMENTAL MATERIALIZED VIEW test_ivm AS SELECT i, MIN(j) as
min_j FROM mv_base_a group by 1;
INSERT INTO mv_base_a select 1,-2 where false;
rollback;however the following one:
BEGIN;
CREATE INCREMENTAL MATERIALIZED VIEW test_ivm1 AS SELECT MIN(j) as
min_j FROM mv_base_a;
INSERT INTO mv_base_a select 1, -2 where false;
rollback;will evaluate
tuplestore_tuple_count(new_tuplestores) to 1, it will walk through
IVM_immediate_maintenance function to apply_delta.
but should it be zero?
This is not a bug because an aggregate without GROUP BY always
results one row whose value is NULL.
The contents of test_imv1 would be always same as " SELECT MIN(j) as min_j
FROM mv_base_a;", isn't it?
Regards,
Yugo Nagata
--
Yugo NAGATA <nagata@sraoss.co.jp>
On Mon, 28 Aug 2023 02:49:08 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:
On Sun, 2 Jul 2023 10:38:20 +0800
jian he <jian.universality@gmail.com> wrote:
I attahed the patches v29 updated to comments from jian he.
The changes from the previous includes:
- errors in documentations is fixed.
- remove unnecessary BEGIN from the test
- add isimmv column to pg_matviews system view
- fix a typo
- rebase to the master branch
ok. Now I really found a small bug.
this works as intended:
BEGIN;
CREATE INCREMENTAL MATERIALIZED VIEW test_ivm AS SELECT i, MIN(j) as
min_j FROM mv_base_a group by 1;
INSERT INTO mv_base_a select 1,-2 where false;
rollback;however the following one:
BEGIN;
CREATE INCREMENTAL MATERIALIZED VIEW test_ivm1 AS SELECT MIN(j) as
min_j FROM mv_base_a;
INSERT INTO mv_base_a select 1, -2 where false;
rollback;will evaluate
tuplestore_tuple_count(new_tuplestores) to 1, it will walk through
IVM_immediate_maintenance function to apply_delta.
but should it be zero?This is not a bug because an aggregate without GROUP BY always
results one row whose value is NULL.The contents of test_imv1 would be always same as " SELECT MIN(j) as min_j
FROM mv_base_a;", isn't it?Regards,
Yugo Nagata--
Yugo NAGATA <nagata@sraoss.co.jp>
--
Yugo NAGATA <nagata@sraoss.co.jp>
Attachments:
v29-0001-Add-a-syntax-to-create-Incrementally-Maintainabl.patchtext/x-diff; name=v29-0001-Add-a-syntax-to-create-Incrementally-Maintainabl.patchDownload
From 13b7d84579d5e2557012501169ecaad931eb3ff3 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:05:02 +0900
Subject: [PATCH v29 01/11] Add a syntax to create Incrementally Maintainable
Materialized Views
Allow to create Incrementally Maintainable Materialized View (IMMV)
by using INCREMENTAL option in CREATE MATERIALIZED VIEW command
as follow:
CREATE [INCREMANTAL] MATERIALIZED VIEW xxxxx AS SELECT ....;
---
src/backend/parser/gram.y | 32 +++++++++++++++++++++-----------
src/include/nodes/primnodes.h | 1 +
src/include/parser/kwlist.h | 1 +
3 files changed, 23 insertions(+), 11 deletions(-)
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 7d2032885e..33c647b0c7 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -465,6 +465,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <range> OptTempTableName
%type <into> into_clause create_as_target create_mv_target
+%type <boolean> incremental
%type <defelt> createfunc_opt_item common_func_opt_item dostmt_opt_item
%type <fun_param> func_arg func_arg_with_default table_func_column aggr_arg
@@ -718,7 +719,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
HANDLER HAVING HEADER_P HOLD HOUR_P
IDENTITY_P IF_P ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IMPORT_P IN_P INCLUDE
- INCLUDING INCREMENT INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
+ INCLUDING INCREMENT INCREMENTAL INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
@@ -4652,32 +4653,34 @@ opt_with_data:
*****************************************************************************/
CreateMatViewStmt:
- CREATE OptNoLog MATERIALIZED VIEW create_mv_target AS SelectStmt opt_with_data
+ CREATE OptNoLog incremental MATERIALIZED VIEW create_mv_target AS SelectStmt opt_with_data
{
CreateTableAsStmt *ctas = makeNode(CreateTableAsStmt);
- ctas->query = $7;
- ctas->into = $5;
+ ctas->query = $8;
+ ctas->into = $6;
ctas->objtype = OBJECT_MATVIEW;
ctas->is_select_into = false;
ctas->if_not_exists = false;
/* cram additional flags into the IntoClause */
- $5->rel->relpersistence = $2;
- $5->skipData = !($8);
+ $6->rel->relpersistence = $2;
+ $6->skipData = !($9);
+ $6->ivm = $3;
$$ = (Node *) ctas;
}
- | CREATE OptNoLog MATERIALIZED VIEW IF_P NOT EXISTS create_mv_target AS SelectStmt opt_with_data
+ | CREATE OptNoLog incremental MATERIALIZED VIEW IF_P NOT EXISTS create_mv_target AS SelectStmt opt_with_data
{
CreateTableAsStmt *ctas = makeNode(CreateTableAsStmt);
- ctas->query = $10;
- ctas->into = $8;
+ ctas->query = $11;
+ ctas->into = $9;
ctas->objtype = OBJECT_MATVIEW;
ctas->is_select_into = false;
ctas->if_not_exists = true;
/* cram additional flags into the IntoClause */
- $8->rel->relpersistence = $2;
- $8->skipData = !($11);
+ $9->rel->relpersistence = $2;
+ $9->skipData = !($12);
+ $9->ivm = $3;
$$ = (Node *) ctas;
}
;
@@ -4694,9 +4697,14 @@ create_mv_target:
$$->tableSpaceName = $5;
$$->viewQuery = NULL; /* filled at analysis time */
$$->skipData = false; /* might get changed later */
+ $$->ivm = false;
}
;
+incremental: INCREMENTAL { $$ = true; }
+ | /*EMPTY*/ { $$ = false; }
+ ;
+
OptNoLog: UNLOGGED { $$ = RELPERSISTENCE_UNLOGGED; }
| /*EMPTY*/ { $$ = RELPERSISTENCE_PERMANENT; }
;
@@ -17141,6 +17149,7 @@ unreserved_keyword:
| INCLUDE
| INCLUDING
| INCREMENT
+ | INCREMENTAL
| INDENT
| INDEX
| INDEXES
@@ -17709,6 +17718,7 @@ bare_label_keyword:
| INCLUDE
| INCLUDING
| INCREMENT
+ | INCREMENTAL
| INDENT
| INDEX
| INDEXES
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 60d72a876b..cecb968b36 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -146,6 +146,7 @@ typedef struct IntoClause
/* materialized view's SELECT query */
Node *viewQuery pg_node_attr(query_jumble_ignore);
bool skipData; /* true for WITH NO DATA */
+ bool ivm; /* true for WITH IVM */
} IntoClause;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 5984dcfa4b..d60eb98d65 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -207,6 +207,7 @@ PG_KEYWORD("in", IN_P, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("include", INCLUDE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("including", INCLUDING, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("increment", INCREMENT, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("incremental", INCREMENTAL, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("indent", INDENT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("index", INDEX, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("indexes", INDEXES, UNRESERVED_KEYWORD, BARE_LABEL)
--
2.25.1
v29-0002-Add-relisivm-column-to-pg_class-system-catalog.patchtext/x-diff; name=v29-0002-Add-relisivm-column-to-pg_class-system-catalog.patchDownload
From 58c47c07db111e78279ec5d043243a389d0bbe16 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:07:23 +0900
Subject: [PATCH v29 02/11] Add relisivm column to pg_class system catalog
If this boolean column is true, a relations is Incrementally Maintainable
Materialized View (IMMV). This is set when IMMV is created.
Also, isimmv columns is added to pg_matviews system view.
isimmv
---
src/backend/catalog/heap.c | 1 +
src/backend/catalog/index.c | 1 +
src/backend/catalog/system_views.sql | 1 +
src/backend/utils/cache/lsyscache.c | 24 ++++++++++++++++++++++++
src/backend/utils/cache/relcache.c | 2 ++
src/include/catalog/pg_class.h | 3 +++
src/include/utils/lsyscache.h | 1 +
src/include/utils/rel.h | 2 ++
src/test/regress/expected/rules.out | 1 +
9 files changed, 36 insertions(+)
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index b534da7d80..d9eac41463 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -924,6 +924,7 @@ InsertPgClassTuple(Relation pg_class_desc,
values[Anum_pg_class_relrewrite - 1] = ObjectIdGetDatum(rd_rel->relrewrite);
values[Anum_pg_class_relfrozenxid - 1] = TransactionIdGetDatum(rd_rel->relfrozenxid);
values[Anum_pg_class_relminmxid - 1] = MultiXactIdGetDatum(rd_rel->relminmxid);
+ values[Anum_pg_class_relisivm - 1] = BoolGetDatum(rd_rel->relisivm);
if (relacl != (Datum) 0)
values[Anum_pg_class_relacl - 1] = relacl;
else
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index fd09378848..e4b52fdd21 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -993,6 +993,7 @@ index_create(Relation heapRelation,
indexRelation->rd_rel->relowner = heapRelation->rd_rel->relowner;
indexRelation->rd_rel->relam = accessMethodId;
indexRelation->rd_rel->relispartition = OidIsValid(parentIndexRelid);
+ indexRelation->rd_rel->relisivm = false;
/*
* store index's pg_class entry
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index 77b06e2a7a..2b60ed9e52 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -146,6 +146,7 @@ CREATE VIEW pg_matviews AS
T.spcname AS tablespace,
C.relhasindex AS hasindexes,
C.relispopulated AS ispopulated,
+ C.relisivm AS isimmv,
pg_get_viewdef(C.oid) AS definition
FROM pg_class C LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
LEFT JOIN pg_tablespace T ON (T.oid = C.reltablespace)
diff --git a/src/backend/utils/cache/lsyscache.c b/src/backend/utils/cache/lsyscache.c
index fc6d267e44..2b29ab4409 100644
--- a/src/backend/utils/cache/lsyscache.c
+++ b/src/backend/utils/cache/lsyscache.c
@@ -2046,6 +2046,30 @@ get_rel_relispartition(Oid relid)
return false;
}
+/*
+ * get_rel_relisivm
+ *
+ * Returns the relisivm flag associated with a given relation.
+ */
+bool
+get_rel_relisivm(Oid relid)
+{
+ HeapTuple tp;
+
+ tp = SearchSysCache1(RELOID, ObjectIdGetDatum(relid));
+ if (HeapTupleIsValid(tp))
+ {
+ Form_pg_class reltup = (Form_pg_class) GETSTRUCT(tp);
+ bool result;
+
+ result = reltup->relisivm;
+ ReleaseSysCache(tp);
+ return result;
+ }
+ else
+ return false;
+}
+
/*
* get_rel_tablespace
*
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 7234cb3da6..96cd510780 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -1924,6 +1924,8 @@ formrdesc(const char *relationName, Oid relationReltype,
/* ... and they're always populated, too */
relation->rd_rel->relispopulated = true;
+ /* ... and they're always no ivm, too */
+ relation->rd_rel->relisivm = false;
relation->rd_rel->relreplident = REPLICA_IDENTITY_NOTHING;
relation->rd_rel->relpages = 0;
diff --git a/src/include/catalog/pg_class.h b/src/include/catalog/pg_class.h
index 2d1bb7af3a..62b9c0e5cb 100644
--- a/src/include/catalog/pg_class.h
+++ b/src/include/catalog/pg_class.h
@@ -119,6 +119,9 @@ CATALOG(pg_class,1259,RelationRelationId) BKI_BOOTSTRAP BKI_ROWTYPE_OID(83,Relat
/* is relation a partition? */
bool relispartition BKI_DEFAULT(f);
+ /* is relation a matview with ivm? */
+ bool relisivm BKI_DEFAULT(f);
+
/* link to original rel during table rewrite; otherwise 0 */
Oid relrewrite BKI_DEFAULT(0) BKI_LOOKUP_OPT(pg_class);
diff --git a/src/include/utils/lsyscache.h b/src/include/utils/lsyscache.h
index f5fdbfe116..7b433749f5 100644
--- a/src/include/utils/lsyscache.h
+++ b/src/include/utils/lsyscache.h
@@ -138,6 +138,7 @@ extern Oid get_rel_namespace(Oid relid);
extern Oid get_rel_type_id(Oid relid);
extern char get_rel_relkind(Oid relid);
extern bool get_rel_relispartition(Oid relid);
+extern bool get_rel_relisivm(Oid relid);
extern Oid get_rel_tablespace(Oid relid);
extern char get_rel_persistence(Oid relid);
extern Oid get_transform_fromsql(Oid typid, Oid langid, List *trftypes);
diff --git a/src/include/utils/rel.h b/src/include/utils/rel.h
index 1426a353cd..b8961176bb 100644
--- a/src/include/utils/rel.h
+++ b/src/include/utils/rel.h
@@ -677,6 +677,8 @@ RelationCloseSmgr(Relation relation)
*/
#define RelationIsPopulated(relation) ((relation)->rd_rel->relispopulated)
+#define RelationIsIVM(relation) ((relation)->rd_rel->relisivm)
+
/*
* RelationIsAccessibleInLogicalDecoding
* True if we need to log enough information to have access via
diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out
index 5058be5411..cc5287344d 100644
--- a/src/test/regress/expected/rules.out
+++ b/src/test/regress/expected/rules.out
@@ -1392,6 +1392,7 @@ pg_matviews| SELECT n.nspname AS schemaname,
t.spcname AS tablespace,
c.relhasindex AS hasindexes,
c.relispopulated AS ispopulated,
+ c.relisivm AS isimmv,
pg_get_viewdef(c.oid) AS definition
FROM ((pg_class c
LEFT JOIN pg_namespace n ON ((n.oid = c.relnamespace)))
--
2.25.1
v29-0003-Allow-to-prolong-life-span-of-transition-tables-.patchtext/x-diff; name=v29-0003-Allow-to-prolong-life-span-of-transition-tables-.patchDownload
From 8be5fe4bab148a5ca0203958873769427ab6aa6a Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:09:45 +0900
Subject: [PATCH v29 03/11] Allow to prolong life span of transition tables
until transaction end
Originally, tuplestores of AFTER trigger's transition tables were
freed for each query depth. For our IVM implementation, we would like
to prolong life of the tuplestores because we have to preserve them
for a whole query assuming that some base tables might be changed
in some trigger functions.
---
src/backend/commands/trigger.c | 83 ++++++++++++++++++++++++++++++++--
src/include/commands/trigger.h | 2 +
2 files changed, 81 insertions(+), 4 deletions(-)
diff --git a/src/backend/commands/trigger.c b/src/backend/commands/trigger.c
index 52177759ab..00b20f4b5b 100644
--- a/src/backend/commands/trigger.c
+++ b/src/backend/commands/trigger.c
@@ -3742,6 +3742,10 @@ typedef struct AfterTriggerEventList
* end of the list, so it is relatively easy to discard them. The event
* list chunks themselves are stored in event_cxt.
*
+ * prolonged_tuplestored is a list of transition table tuplestores whose
+ * life are prolonged to the end of the outmost query instead of each nested
+ * query.
+ *
* query_depth is the current depth of nested AfterTriggerBeginQuery calls
* (-1 when the stack is empty).
*
@@ -3807,6 +3811,7 @@ typedef struct AfterTriggersData
SetConstraintState state; /* the active S C state */
AfterTriggerEventList events; /* deferred-event list */
MemoryContext event_cxt; /* memory context for events, if any */
+ List *prolonged_tuplestores; /* list of prolonged tuplestores */
/* per-query-level data: */
AfterTriggersQueryData *query_stack; /* array of structs shown below */
@@ -3842,6 +3847,7 @@ struct AfterTriggersTableData
bool closed; /* true when no longer OK to add tuples */
bool before_trig_done; /* did we already queue BS triggers? */
bool after_trig_done; /* did we already queue AS triggers? */
+ bool prolonged; /* are transition tables prolonged? */
AfterTriggerEventList after_trig_events; /* if so, saved list pointer */
/*
@@ -3891,6 +3897,7 @@ static void TransitionTableAddTuple(EState *estate,
TupleTableSlot *original_insert_tuple,
Tuplestorestate *tuplestore);
static void AfterTriggerFreeQuery(AfterTriggersQueryData *qs);
+static void release_or_prolong_tuplestore(Tuplestorestate *ts, bool prolonged);
static SetConstraintState SetConstraintStateCreate(int numalloc);
static SetConstraintState SetConstraintStateCopy(SetConstraintState origstate);
static SetConstraintState SetConstraintStateAddItem(SetConstraintState state,
@@ -4768,6 +4775,45 @@ afterTriggerInvokeEvents(AfterTriggerEventList *events,
}
+/*
+ * SetTransitionTablePreserved
+ *
+ * Prolong lifespan of transition tables corresponding specified relid and
+ * command type to the end of the outmost query instead of each nested query.
+ * This enables to use nested AFTER trigger's transition tables from outer
+ * query's triggers. Currently, only immediate incremental view maintenance
+ * uses this.
+ */
+void
+SetTransitionTablePreserved(Oid relid, CmdType cmdType)
+{
+ AfterTriggersTableData *table;
+ AfterTriggersQueryData *qs;
+ bool found = false;
+ ListCell *lc;
+
+ /* Check state, like AfterTriggerSaveEvent. */
+ if (afterTriggers.query_depth < 0)
+ elog(ERROR, "SetTransitionTablePreserved() called outside of query");
+
+ qs = &afterTriggers.query_stack[afterTriggers.query_depth];
+
+ foreach(lc, qs->tables)
+ {
+ table = (AfterTriggersTableData *) lfirst(lc);
+ if (table->relid == relid && table->cmdType == cmdType &&
+ table->closed)
+ {
+ table->prolonged = true;
+ found = true;
+ }
+ }
+
+ if (!found)
+ elog(ERROR,"could not find table with OID %d and command type %d", relid, cmdType);
+}
+
+
/*
* GetAfterTriggersTableData
*
@@ -4978,6 +5024,7 @@ AfterTriggerBeginXact(void)
*/
afterTriggers.firing_counter = (CommandId) 1; /* mustn't be 0 */
afterTriggers.query_depth = -1;
+ afterTriggers.prolonged_tuplestores = NIL;
/*
* Verify that there is no leftover state remaining. If these assertions
@@ -5138,19 +5185,19 @@ AfterTriggerFreeQuery(AfterTriggersQueryData *qs)
ts = table->old_upd_tuplestore;
table->old_upd_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->new_upd_tuplestore;
table->new_upd_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->old_del_tuplestore;
table->old_del_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->new_ins_tuplestore;
table->new_ins_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
if (table->storeslot)
{
TupleTableSlot *slot = table->storeslot;
@@ -5167,6 +5214,34 @@ AfterTriggerFreeQuery(AfterTriggersQueryData *qs)
*/
qs->tables = NIL;
list_free_deep(tables);
+
+ /* Release prolonged tuplestores at the end of the outmost query */
+ if (afterTriggers.query_depth == 0)
+ {
+ foreach(lc, afterTriggers.prolonged_tuplestores)
+ {
+ ts = (Tuplestorestate *) lfirst(lc);
+ if (ts)
+ tuplestore_end(ts);
+ }
+ afterTriggers.prolonged_tuplestores = NIL;
+ }
+}
+
+/*
+ * Release the tuplestore, or append it to the prolonged tuplestores list.
+ */
+static void
+release_or_prolong_tuplestore(Tuplestorestate *ts, bool prolonged)
+{
+ if (prolonged && afterTriggers.query_depth > 0)
+ {
+ MemoryContext oldcxt = MemoryContextSwitchTo(CurTransactionContext);
+ afterTriggers.prolonged_tuplestores = lappend(afterTriggers.prolonged_tuplestores, ts);
+ MemoryContextSwitchTo(oldcxt);
+ }
+ else
+ tuplestore_end(ts);
}
diff --git a/src/include/commands/trigger.h b/src/include/commands/trigger.h
index 430e3ca7dd..48a21c4c51 100644
--- a/src/include/commands/trigger.h
+++ b/src/include/commands/trigger.h
@@ -265,6 +265,8 @@ extern void AfterTriggerEndSubXact(bool isCommit);
extern void AfterTriggerSetState(ConstraintsSetStmt *stmt);
extern bool AfterTriggerPendingOnRel(Oid relid);
+extern void SetTransitionTablePreserved(Oid relid, CmdType cmdType);
+
/*
* in utils/adt/ri_triggers.c
--
2.25.1
v29-0004-Add-Incremental-View-Maintenance-support-to-pg_d.patchtext/x-diff; name=v29-0004-Add-Incremental-View-Maintenance-support-to-pg_d.patchDownload
From 8d7896f934938ad2a459cf6e85f0a32cbc6e4a71 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 11 Nov 2020 17:01:25 +0900
Subject: [PATCH v29 04/11] Add Incremental View Maintenance support to pg_dump
Support CREATE INCREMENTAL MATERIALIZED VIEW syntax.
---
src/bin/pg_dump/pg_dump.c | 18 +++++++++++++++---
src/bin/pg_dump/pg_dump.h | 1 +
src/bin/pg_dump/t/002_pg_dump.pl | 15 +++++++++++++++
3 files changed, 31 insertions(+), 3 deletions(-)
diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c
index 65f64c282d..013ead7655 100644
--- a/src/bin/pg_dump/pg_dump.c
+++ b/src/bin/pg_dump/pg_dump.c
@@ -6354,6 +6354,7 @@ getTables(Archive *fout, int *numTables)
int i_relacl;
int i_acldefault;
int i_ispartition;
+ int i_isivm;
/*
* Find all the tables and table-like objects.
@@ -6456,10 +6457,17 @@ getTables(Archive *fout, int *numTables)
if (fout->remoteVersion >= 100000)
appendPQExpBufferStr(query,
- "c.relispartition AS ispartition ");
+ "c.relispartition AS ispartition, ");
else
appendPQExpBufferStr(query,
- "false AS ispartition ");
+ "false AS ispartition, ");
+
+ if (fout->remoteVersion >= 170000)
+ appendPQExpBufferStr(query,
+ "c.relisivm AS isivm ");
+ else
+ appendPQExpBufferStr(query,
+ "false AS isivm ");
/*
* Left join to pg_depend to pick up dependency info linking sequences to
@@ -6568,6 +6576,7 @@ getTables(Archive *fout, int *numTables)
i_relacl = PQfnumber(res, "relacl");
i_acldefault = PQfnumber(res, "acldefault");
i_ispartition = PQfnumber(res, "ispartition");
+ i_isivm = PQfnumber(res, "isivm");
if (dopt->lockWaitTimeout)
{
@@ -6647,6 +6656,7 @@ getTables(Archive *fout, int *numTables)
tblinfo[i].amname = pg_strdup(PQgetvalue(res, i, i_amname));
tblinfo[i].is_identity_sequence = (strcmp(PQgetvalue(res, i, i_is_identity_sequence), "t") == 0);
tblinfo[i].ispartition = (strcmp(PQgetvalue(res, i, i_ispartition), "t") == 0);
+ tblinfo[i].isivm = (strcmp(PQgetvalue(res, i, i_isivm), "t") == 0);
/* other fields were zeroed above */
@@ -15737,9 +15747,11 @@ dumpTableSchema(Archive *fout, const TableInfo *tbinfo)
binary_upgrade_set_pg_class_oids(fout, q,
tbinfo->dobj.catId.oid, false);
- appendPQExpBuffer(q, "CREATE %s%s %s",
+ appendPQExpBuffer(q, "CREATE %s%s%s %s",
tbinfo->relpersistence == RELPERSISTENCE_UNLOGGED ?
"UNLOGGED " : "",
+ tbinfo->relkind == RELKIND_MATVIEW && tbinfo->isivm ?
+ "INCREMENTAL " : "",
reltypename,
qualrelname);
diff --git a/src/bin/pg_dump/pg_dump.h b/src/bin/pg_dump/pg_dump.h
index 9036b13f6a..3705891d25 100644
--- a/src/bin/pg_dump/pg_dump.h
+++ b/src/bin/pg_dump/pg_dump.h
@@ -323,6 +323,7 @@ typedef struct _tableInfo
int numParents; /* number of (immediate) parent tables */
struct _tableInfo **parents; /* TableInfos of immediate parents */
+ bool isivm; /* is incrementally maintainable materialized view? */
/*
* These fields are computed only if we decide the table is interesting
diff --git a/src/bin/pg_dump/t/002_pg_dump.pl b/src/bin/pg_dump/t/002_pg_dump.pl
index 0758fe5ea0..fb2f31e191 100644
--- a/src/bin/pg_dump/t/002_pg_dump.pl
+++ b/src/bin/pg_dump/t/002_pg_dump.pl
@@ -2799,6 +2799,21 @@ my %tests = (
},
},
+ 'CREATE MATERIALIZED VIEW matview_ivm' => {
+ create_order => 21,
+ create_sql => 'CREATE INCREMENTAL MATERIALIZED VIEW dump_test.matview_ivm (col1) AS
+ SELECT col1 FROM dump_test.test_table;',
+ regexp => qr/^
+ \QCREATE INCREMENTAL MATERIALIZED VIEW dump_test.matview_ivm AS\E
+ \n\s+\QSELECT test_table.col1\E
+ \n\s+\QFROM dump_test.test_table\E
+ \n\s+\QWITH NO DATA;\E
+ /xm,
+ like =>
+ { %full_runs, %dump_test_schema_runs, section_pre_data => 1, },
+ unlike => { exclude_dump_test_schema => 1, },
+ },
+
'CREATE POLICY p1 ON test_table' => {
create_order => 22,
create_sql => 'CREATE POLICY p1 ON dump_test.test_table
--
2.25.1
v29-0005-Add-Incremental-View-Maintenance-support-to-psql.patchtext/x-diff; name=v29-0005-Add-Incremental-View-Maintenance-support-to-psql.patchDownload
From 3af494c500ae3c712c0a371eb35e1698c924cc7c Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:21:54 +0900
Subject: [PATCH v29 05/11] Add Incremental View Maintenance support to psql
Add tab completion and meta-command output for IVM.
---
src/bin/psql/describe.c | 32 +++++++++++++++++++++++++++++++-
src/bin/psql/tab-complete.c | 14 +++++++++-----
2 files changed, 40 insertions(+), 6 deletions(-)
diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c
index bac94a338c..f6c7e7163d 100644
--- a/src/bin/psql/describe.c
+++ b/src/bin/psql/describe.c
@@ -1575,6 +1575,7 @@ describeOneTableDetails(const char *schemaname,
char relpersistence;
char relreplident;
char *relam;
+ bool isivm;
} tableinfo;
bool show_column_details = false;
@@ -1587,7 +1588,26 @@ describeOneTableDetails(const char *schemaname,
initPQExpBuffer(&tmpbuf);
/* Get general table info */
- if (pset.sversion >= 120000)
+ if (pset.sversion >= 170000)
+ {
+ printfPQExpBuffer(&buf,
+ "SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
+ "c.relhastriggers, c.relrowsecurity, c.relforcerowsecurity, "
+ "false AS relhasoids, c.relispartition, %s, c.reltablespace, "
+ "CASE WHEN c.reloftype = 0 THEN '' ELSE c.reloftype::pg_catalog.regtype::pg_catalog.text END, "
+ "c.relpersistence, c.relreplident, am.amname, "
+ "c.relisivm\n"
+ "FROM pg_catalog.pg_class c\n "
+ "LEFT JOIN pg_catalog.pg_class tc ON (c.reltoastrelid = tc.oid)\n"
+ "LEFT JOIN pg_catalog.pg_am am ON (c.relam = am.oid)\n"
+ "WHERE c.oid = '%s';",
+ (verbose ?
+ "pg_catalog.array_to_string(c.reloptions || "
+ "array(select 'toast.' || x from pg_catalog.unnest(tc.reloptions) x), ', ')\n"
+ : "''"),
+ oid);
+ }
+ else if (pset.sversion >= 120000)
{
printfPQExpBuffer(&buf,
"SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
@@ -1707,6 +1727,10 @@ describeOneTableDetails(const char *schemaname,
(char *) NULL : pg_strdup(PQgetvalue(res, 0, 14));
else
tableinfo.relam = NULL;
+ if (pset.sversion >= 170000)
+ tableinfo.isivm = strcmp(PQgetvalue(res, 0, 15), "t") == 0;
+ else
+ tableinfo.isivm = false;
PQclear(res);
res = NULL;
@@ -3552,6 +3576,12 @@ describeOneTableDetails(const char *schemaname,
printfPQExpBuffer(&buf, _("Access method: %s"), tableinfo.relam);
printTableAddFooter(&cont, buf.data);
}
+
+ /* Incremental view maintance info */
+ if (verbose && tableinfo.relkind == RELKIND_MATVIEW && tableinfo.isivm)
+ {
+ printTableAddFooter(&cont, _("Incremental view maintenance: yes"));
+ }
}
/* reloptions, if verbose */
diff --git a/src/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c
index 779fdc90cb..9cc79b722f 100644
--- a/src/bin/psql/tab-complete.c
+++ b/src/bin/psql/tab-complete.c
@@ -1244,6 +1244,7 @@ static const pgsql_thing_t words_after_create[] = {
{"FOREIGN TABLE", NULL, NULL, NULL},
{"FUNCTION", NULL, NULL, Query_for_list_of_functions},
{"GROUP", Query_for_list_of_roles},
+ {"INCREMENTAL MATERIALIZED VIEW", NULL, NULL, &Query_for_list_of_matviews, NULL, THING_NO_DROP | THING_NO_ALTER},
{"INDEX", NULL, NULL, &Query_for_list_of_indexes},
{"LANGUAGE", Query_for_list_of_languages},
{"LARGE OBJECT", NULL, NULL, NULL, NULL, THING_NO_CREATE | THING_NO_DROP},
@@ -3217,7 +3218,7 @@ psql_completion(const char *text, int start, int end)
if (HeadMatches("CREATE", "SCHEMA"))
COMPLETE_WITH("TABLE", "SEQUENCE");
else
- COMPLETE_WITH("TABLE", "SEQUENCE", "MATERIALIZED VIEW");
+ COMPLETE_WITH("TABLE", "SEQUENCE", "MATERIALIZED VIEW", "INCREMENTAL MATERIALIZED VIEW");
}
/* Complete PARTITION BY with RANGE ( or LIST ( or ... */
else if (TailMatches("PARTITION", "BY"))
@@ -3535,13 +3536,16 @@ psql_completion(const char *text, int start, int end)
COMPLETE_WITH("SELECT");
/* CREATE MATERIALIZED VIEW */
- else if (Matches("CREATE", "MATERIALIZED"))
+ else if (Matches("CREATE", "MATERIALIZED") ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED"))
COMPLETE_WITH("VIEW");
- /* Complete CREATE MATERIALIZED VIEW <name> with AS */
- else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny))
+ /* Complete CREATE MATERIALIZED VIEW <name> with AS */
+ else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny) ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED", "VIEW", MatchAny))
COMPLETE_WITH("AS");
/* Complete "CREATE MATERIALIZED VIEW <sth> AS with "SELECT" */
- else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny, "AS"))
+ else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny, "AS") ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED", "VIEW", MatchAny, "AS"))
COMPLETE_WITH("SELECT");
/* CREATE EVENT TRIGGER */
--
2.25.1
v29-0006-Add-Incremental-View-Maintenance-support.patchtext/x-diff; name=v29-0006-Add-Incremental-View-Maintenance-support.patchDownload
From ddec5a0afec9b177be3f244d3535dfe7078fb96c Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 18:59:50 +0900
Subject: [PATCH v29 06/11] Add Incremental View Maintenance support
In this implementation, AFTER triggers are used to collect
tuplestores containing transition table contents. When multiple tables
are changed, multiple AFTER triggers are invoked, then the final AFTER
trigger performs actual update of the matview. In addition, BEFORE
triggers are also used to handle global information for view
maintenance.
To calculate view deltas, we need both pre-state and post-state of base
tables. Post-update states are available in AFTER trigger, and pre-update
states can be calculated by removing inserted tuples and appending deleted
tuples. Insterted tuples are filtered using the snapshot taken before
table modiication, and deleted tuples are contained in the old transition
table.
Incrementally Maintainable Materialized Views (IMMV) can contain
duplicated tuples.
This patch also allows self-join, simultaneous updates of more than
one base table, and multiple updates of the same base table.
---
src/backend/access/transam/xact.c | 5 +
src/backend/commands/createas.c | 680 +++++++++++++
src/backend/commands/matview.c | 1466 ++++++++++++++++++++++++++++-
src/include/catalog/pg_proc.dat | 10 +
src/include/commands/createas.h | 4 +
src/include/commands/matview.h | 9 +
6 files changed, 2139 insertions(+), 35 deletions(-)
diff --git a/src/backend/access/transam/xact.c b/src/backend/access/transam/xact.c
index 8daaa535ed..cd280bdffd 100644
--- a/src/backend/access/transam/xact.c
+++ b/src/backend/access/transam/xact.c
@@ -36,6 +36,7 @@
#include "catalog/pg_enum.h"
#include "catalog/storage.h"
#include "commands/async.h"
+#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/trigger.h"
#include "common/pg_prng.h"
@@ -2803,6 +2804,7 @@ AbortTransaction(void)
AtAbort_Notify();
AtEOXact_RelationMap(false, is_parallel_worker);
AtAbort_Twophase();
+ AtAbort_IVM();
/*
* Advertise the fact that we aborted in pg_xact (assuming that we got as
@@ -5080,6 +5082,9 @@ AbortSubTransaction(void)
pgstat_progress_end_command();
UnlockBuffers();
+ /* Clean up hash entries for incremental view maintenance */
+ AtAbort_IVM();
+
/* Reset WAL record construction state */
XLogResetInsertion();
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index e91920ca14..415f110516 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -32,15 +32,26 @@
#include "access/xact.h"
#include "access/xlog.h"
#include "catalog/namespace.h"
+#include "catalog/index.h"
+#include "catalog/pg_constraint.h"
+#include "catalog/pg_inherits.h"
+#include "catalog/pg_trigger.h"
#include "catalog/toasting.h"
#include "commands/createas.h"
+#include "commands/defrem.h"
#include "commands/matview.h"
#include "commands/prepare.h"
#include "commands/tablecmds.h"
+#include "commands/tablespace.h"
+#include "commands/trigger.h"
#include "commands/view.h"
#include "miscadmin.h"
+#include "optimizer/optimizer.h"
+#include "optimizer/prep.h"
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
+#include "parser/parser.h"
+#include "parser/parsetree.h"
#include "parser/parse_clause.h"
#include "rewrite/rewriteHandler.h"
#include "storage/smgr.h"
@@ -73,6 +84,12 @@ static bool intorel_receive(TupleTableSlot *slot, DestReceiver *self);
static void intorel_shutdown(DestReceiver *self);
static void intorel_destroy(DestReceiver *self);
+static void CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid matviewOid,
+ Relids *relids, bool ex_lock);
+static void CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock);
+static void check_ivm_restriction(Node *node);
+static bool check_ivm_restriction_walker(Node *node, void *context);
+static Bitmapset *get_primary_key_attnos_from_query(Query *query, List **constraintList);
/*
* create_ctas_internal
@@ -282,6 +299,18 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
save_nestlevel = NewGUCNestLevel();
}
+ if (is_matview && into->ivm)
+ {
+ /* check if the query is supported in IMMV definition */
+ if (contain_mutable_functions((Node *) query))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("mutable function is not supported on incrementally maintainable materialized view"),
+ errhint("functions must be marked IMMUTABLE")));
+
+ check_ivm_restriction((Node *) query);
+ }
+
if (into->skipData)
{
/*
@@ -358,6 +387,27 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
/* Restore userid and security context */
SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ if (into->ivm)
+ {
+ Oid matviewOid = address.objectId;
+ Relation matviewRel = table_open(matviewOid, NoLock);
+
+ /*
+ * Mark relisivm field, if it's a matview and into->ivm is true.
+ */
+ SetMatViewIVMState(matviewRel, true);
+
+ if (!into->skipData)
+ {
+ /* Create an index on incremental maintainable materialized view, if possible */
+ CreateIndexOnIMMV((Query *) into->viewQuery, matviewRel);
+
+ /* Create triggers on incremental maintainable materialized view */
+ CreateIvmTriggersOnBaseTables((Query *) into->viewQuery, matviewOid);
+ }
+ table_close(matviewRel, NoLock);
+ }
}
return address;
@@ -635,3 +685,633 @@ intorel_destroy(DestReceiver *self)
{
pfree(self);
}
+
+/*
+ * CreateIvmTriggersOnBaseTables -- create IVM triggers on all base tables
+ */
+void
+CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid)
+{
+ Relids relids = NULL;
+ bool ex_lock = false;
+ RangeTblEntry *rte;
+
+ /* Immediately return if we don't have any base tables. */
+ if (list_length(qry->rtable) < 1)
+ return;
+
+ /*
+ * If the view has more than one base tables, we need an exclusive lock
+ * on the view so that the view would be maintained serially to avoid
+ * the inconsistency that occurs when two base tables are modified in
+ * concurrent transactions. However, if the view has only one table,
+ * we can use a weaker lock.
+ *
+ * The type of lock should be determined here, because if we check the
+ * view definition at maintenance time, we need to acquire a weaker lock,
+ * and upgrading the lock level after this increases probability of
+ * deadlock.
+ */
+
+ rte = list_nth(qry->rtable, 0);
+ if (list_length(qry->rtable) > 1 || rte->rtekind != RTE_RELATION)
+ ex_lock = true;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, (Node *)qry, matviewOid, &relids, ex_lock);
+
+ bms_free(relids);
+}
+
+static void
+CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid matviewOid,
+ Relids *relids, bool ex_lock)
+{
+ if (node == NULL)
+ return;
+
+ /* This can recurse, so check for excessive recursion */
+ check_stack_depth();
+
+ switch (nodeTag(node))
+ {
+ case T_Query:
+ {
+ Query *query = (Query *) node;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, (Node *)query->jointree, matviewOid, relids, ex_lock);
+ }
+ break;
+
+ case T_RangeTblRef:
+ {
+ int rti = ((RangeTblRef *) node)->rtindex;
+ RangeTblEntry *rte = rt_fetch(rti, qry->rtable);
+
+ if (rte->rtekind == RTE_RELATION && !bms_is_member(rte->relid, *relids))
+ {
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_INSERT, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_DELETE, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_UPDATE, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_TRUNCATE, TRIGGER_TYPE_BEFORE, true);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_INSERT, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_DELETE, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_UPDATE, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_TRUNCATE, TRIGGER_TYPE_AFTER, true);
+
+ *relids = bms_add_member(*relids, rte->relid);
+ }
+ }
+ break;
+
+ case T_FromExpr:
+ {
+ FromExpr *f = (FromExpr *) node;
+ ListCell *l;
+
+ foreach(l, f->fromlist)
+ CreateIvmTriggersOnBaseTablesRecurse(qry, lfirst(l), matviewOid, relids, ex_lock);
+ }
+ break;
+
+ case T_JoinExpr:
+ {
+ JoinExpr *j = (JoinExpr *) node;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, j->larg, matviewOid, relids, ex_lock);
+ CreateIvmTriggersOnBaseTablesRecurse(qry, j->rarg, matviewOid, relids, ex_lock);
+ }
+ break;
+
+ default:
+ elog(ERROR, "unrecognized node type: %d", (int) nodeTag(node));
+ }
+}
+
+/*
+ * CreateIvmTrigger -- create IVM trigger on a base table
+ */
+static void
+CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock)
+{
+ ObjectAddress refaddr;
+ ObjectAddress address;
+ CreateTrigStmt *ivm_trigger;
+ List *transitionRels = NIL;
+
+ Assert(timing == TRIGGER_TYPE_BEFORE || timing == TRIGGER_TYPE_AFTER);
+
+ refaddr.classId = RelationRelationId;
+ refaddr.objectId = viewOid;
+ refaddr.objectSubId = 0;
+
+ ivm_trigger = makeNode(CreateTrigStmt);
+ ivm_trigger->relation = NULL;
+ ivm_trigger->row = false;
+
+ ivm_trigger->timing = timing;
+ ivm_trigger->events = type;
+
+ switch (type)
+ {
+ case TRIGGER_TYPE_INSERT:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_ins_before" : "IVM_trigger_ins_after");
+ break;
+ case TRIGGER_TYPE_DELETE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_del_before" : "IVM_trigger_del_after");
+ break;
+ case TRIGGER_TYPE_UPDATE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_upd_before" : "IVM_trigger_upd_after");
+ break;
+ case TRIGGER_TYPE_TRUNCATE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_truncate_before" : "IVM_trigger_truncate_after");
+ break;
+ default:
+ elog(ERROR, "unsupported trigger type");
+ }
+
+ if (timing == TRIGGER_TYPE_AFTER)
+ {
+ if (type == TRIGGER_TYPE_INSERT || type == TRIGGER_TYPE_UPDATE)
+ {
+ TriggerTransition *n = makeNode(TriggerTransition);
+ n->name = "__ivm_newtable";
+ n->isNew = true;
+ n->isTable = true;
+
+ transitionRels = lappend(transitionRels, n);
+ }
+ if (type == TRIGGER_TYPE_DELETE || type == TRIGGER_TYPE_UPDATE)
+ {
+ TriggerTransition *n = makeNode(TriggerTransition);
+ n->name = "__ivm_oldtable";
+ n->isNew = false;
+ n->isTable = true;
+
+ transitionRels = lappend(transitionRels, n);
+ }
+ }
+
+ /*
+ * XXX: When using DELETE or UPDATE, we must use exclusive lock for now
+ * because apply_old_delta(_with_count) uses ctid to identify the tuple
+ * to be deleted/deleted, but doesn't work in concurrent situations.
+ *
+ * If the view doesn't have aggregate, distinct, or tuple duplicate,
+ * then it would work even in concurrent situations. However, we don't have
+ * any way to guarantee the view has a unique key before opening the IMMV
+ * at the maintenance time because users may drop the unique index.
+ */
+
+ if (type == TRIGGER_TYPE_DELETE || type == TRIGGER_TYPE_UPDATE)
+ ex_lock = true;
+
+ ivm_trigger->funcname =
+ (timing == TRIGGER_TYPE_BEFORE ? SystemFuncName("IVM_immediate_before") : SystemFuncName("IVM_immediate_maintenance"));
+
+ ivm_trigger->columns = NIL;
+ ivm_trigger->transitionRels = transitionRels;
+ ivm_trigger->whenClause = NULL;
+ ivm_trigger->isconstraint = false;
+ ivm_trigger->deferrable = false;
+ ivm_trigger->initdeferred = false;
+ ivm_trigger->constrrel = NULL;
+ ivm_trigger->args = list_make2(
+ makeString(DatumGetPointer(DirectFunctionCall1(oidout, ObjectIdGetDatum(viewOid)))),
+ makeString(DatumGetPointer(DirectFunctionCall1(boolout, BoolGetDatum(ex_lock))))
+ );
+
+ address = CreateTrigger(ivm_trigger, NULL, relOid, InvalidOid, InvalidOid,
+ InvalidOid, InvalidOid, InvalidOid, NULL, true, false);
+
+ recordDependencyOn(&address, &refaddr, DEPENDENCY_AUTO);
+
+ /* Make changes-so-far visible */
+ CommandCounterIncrement();
+}
+
+/*
+ * check_ivm_restriction --- look for specify nodes in the query tree
+ */
+static void
+check_ivm_restriction(Node *node)
+{
+ check_ivm_restriction_walker(node, NULL);
+}
+
+static bool
+check_ivm_restriction_walker(Node *node, void *context)
+{
+ if (node == NULL)
+ return false;
+
+ /*
+ * We currently don't support Sub-Query.
+ */
+ if (IsA(node, SubPlan) || IsA(node, SubLink))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("subquery is not supported on incrementally maintainable materialized view")));
+
+ /* This can recurse, so check for excessive recursion */
+ check_stack_depth();
+
+ switch (nodeTag(node))
+ {
+ case T_Query:
+ {
+ Query *qry = (Query *)node;
+ ListCell *lc;
+ List *vars;
+
+ /* if contained CTE, return error */
+ if (qry->cteList != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("CTE is not supported on incrementally maintainable materialized view")));
+ if (qry->havingQual != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg(" HAVING clause is not supported on incrementally maintainable materialized view")));
+ if (qry->sortClause != NIL) /* There is a possibility that we don't need to return an error */
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("ORDER BY clause is not supported on incrementally maintainable materialized view")));
+ if (qry->limitOffset != NULL || qry->limitCount != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view")));
+ if (qry->distinctClause)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("DISTINCT is not supported on incrementally maintainable materialized view")));
+ if (qry->hasDistinctOn)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("DISTINCT ON is not supported on incrementally maintainable materialized view")));
+ if (qry->hasWindowFuncs)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("window functions are not supported on incrementally maintainable materialized view")));
+ if (qry->groupingSets != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUPING SETS, ROLLUP, or CUBE clauses is not supported on incrementally maintainable materialized view")));
+ if (qry->setOperations != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("UNION/INTERSECT/EXCEPT statements are not supported on incrementally maintainable materialized view")));
+ if (list_length(qry->targetList) == 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("empty target list is not supported on incrementally maintainable materialized view")));
+ if (qry->rowMarks != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view")));
+
+ /* system column restrictions */
+ vars = pull_vars_of_level((Node *) qry, 0);
+ foreach(lc, vars)
+ {
+ if (IsA(lfirst(lc), Var))
+ {
+ Var *var = (Var *) lfirst(lc);
+ /* if system column, return error */
+ if (var->varattno < 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("system column is not supported on incrementally maintainable materialized view")));
+ }
+ }
+
+ /* restrictions for rtable */
+ foreach(lc, qry->rtable)
+ {
+ RangeTblEntry *rte = (RangeTblEntry *) lfirst(lc);
+
+ if (rte->subquery)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("subquery is not supported on incrementally maintainable materialized view")));
+
+ if (rte->tablesample != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("TABLESAMPLE clause is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitioned table is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_RELATION && has_superclass(rte->relid))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_RELATION && find_inheritance_children(rte->relid, NoLock) != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("inheritance parent is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_FOREIGN_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("foreign table is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_VIEW ||
+ rte->relkind == RELKIND_MATVIEW)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view")));
+
+ if (rte->rtekind == RTE_VALUES)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("VALUES is not supported on incrementally maintainable materialized view")));
+
+ }
+
+ query_tree_walker(qry, check_ivm_restriction_walker, NULL, QTW_IGNORE_RANGE_TABLE);
+
+ break;
+ }
+ case T_TargetEntry:
+ {
+ TargetEntry *tle = (TargetEntry *)node;
+ if (isIvmName(tle->resname))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("column name %s is not supported on incrementally maintainable materialized view", tle->resname)));
+
+ expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ break;
+ }
+ case T_JoinExpr:
+ {
+ JoinExpr *joinexpr = (JoinExpr *)node;
+
+ if (joinexpr->jointype > JOIN_INNER)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("OUTER JOIN is not supported on incrementally maintainable materialized view")));
+
+ expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ }
+ break;
+ case T_Aggref:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function is not supported on incrementally maintainable materialized view")));
+ break;
+ default:
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
+ break;
+ }
+ return false;
+}
+
+/*
+ * CreateIndexOnIMMV
+ *
+ * Create a unique index on incremental maintainable materialized view.
+ * If the view definition query has a GROUP BY clause, the index is created
+ * on the columns of GROUP BY expressions. Otherwise, if the view contains
+ * all primary key attritubes of its base tables in the target list, the index
+ * is created on these attritubes. In other cases, no index is created.
+ */
+void
+CreateIndexOnIMMV(Query *query, Relation matviewRel)
+{
+ ListCell *lc;
+ IndexStmt *index;
+ ObjectAddress address;
+ List *constraintList = NIL;
+ char idxname[NAMEDATALEN];
+ List *indexoidlist = RelationGetIndexList(matviewRel);
+ ListCell *indexoidscan;
+ Bitmapset *key_attnos;
+
+ snprintf(idxname, sizeof(idxname), "%s_index", RelationGetRelationName(matviewRel));
+
+ index = makeNode(IndexStmt);
+
+ index->unique = true;
+ index->primary = false;
+ index->isconstraint = false;
+ index->deferrable = false;
+ index->initdeferred = false;
+ index->idxname = idxname;
+ index->relation =
+ makeRangeVar(get_namespace_name(RelationGetNamespace(matviewRel)),
+ pstrdup(RelationGetRelationName(matviewRel)),
+ -1);
+ index->accessMethod = DEFAULT_INDEX_TYPE;
+ index->options = NIL;
+ index->tableSpace = get_tablespace_name(matviewRel->rd_rel->reltablespace);
+ index->whereClause = NULL;
+ index->indexParams = NIL;
+ index->indexIncludingParams = NIL;
+ index->excludeOpNames = NIL;
+ index->idxcomment = NULL;
+ index->indexOid = InvalidOid;
+ index->oldNumber = InvalidRelFileNumber;
+ index->oldCreateSubid = InvalidSubTransactionId;
+ index->oldFirstRelfilelocatorSubid = InvalidSubTransactionId;
+ index->transformed = true;
+ index->concurrent = false;
+ index->if_not_exists = false;
+
+ /* create index on the base tables' primary key columns */
+ key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
+ if (key_attnos)
+ {
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ }
+ else
+ {
+ /* create no index, just notice that an appropriate index is necessary for efficient IVM */
+ ereport(NOTICE,
+ (errmsg("could not create an index on materialized view \"%s\" automatically",
+ RelationGetRelationName(matviewRel)),
+ errdetail("This target list does not have all the primary key columns. "),
+ errhint("Create an index on the materialized view for efficient incremental maintenance.")));
+ return;
+ }
+
+ /* If we have a compatible index, we don't need to create another. */
+ foreach(indexoidscan, indexoidlist)
+ {
+ Oid indexoid = lfirst_oid(indexoidscan);
+ Relation indexRel;
+ bool hasCompatibleIndex = false;
+
+ indexRel = index_open(indexoid, AccessShareLock);
+
+ if (CheckIndexCompatible(indexRel->rd_id,
+ index->accessMethod,
+ index->indexParams,
+ index->excludeOpNames))
+ hasCompatibleIndex = true;
+
+ index_close(indexRel, AccessShareLock);
+
+ if (hasCompatibleIndex)
+ return;
+ }
+
+ address = DefineIndex(RelationGetRelid(matviewRel),
+ index,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ -1,
+ false, true, false, false, true);
+
+ ereport(NOTICE,
+ (errmsg("created index \"%s\" on materialized view \"%s\"",
+ idxname, RelationGetRelationName(matviewRel))));
+
+ /*
+ * Make dependencies so that the index is dropped if any base tables's
+ * primary key is dropped.
+ */
+ foreach(lc, constraintList)
+ {
+ Oid constraintOid = lfirst_oid(lc);
+ ObjectAddress refaddr;
+
+ refaddr.classId = ConstraintRelationId;
+ refaddr.objectId = constraintOid;
+ refaddr.objectSubId = 0;
+
+ recordDependencyOn(&address, &refaddr, DEPENDENCY_NORMAL);
+ }
+}
+
+
+/*
+ * get_primary_key_attnos_from_query
+ *
+ * Identify the columns in base tables' primary keys in the target list.
+ *
+ * Returns a Bitmapset of the column attnos of the primary key's columns of
+ * tables that used in the query. The attnos are offset by
+ * FirstLowInvalidHeapAttributeNumber as same as get_primary_key_attnos.
+ *
+ * If any table has no primary key or any primary key's columns is not in
+ * the target list, return NULL. We also return NULL if any pkey constraint
+ * is deferrable.
+ *
+ * constraintList is set to a list of the OIDs of the pkey constraints.
+ */
+static Bitmapset *
+get_primary_key_attnos_from_query(Query *query, List **constraintList)
+{
+ List *key_attnos_list = NIL;
+ ListCell *lc;
+ int i;
+ Bitmapset *keys = NULL;
+ Relids rels_in_from;
+
+ /*
+ * Collect primary key attributes from all tables used in query. The key attributes
+ * sets for each table are stored in key_attnos_list in order by RTE index.
+ */
+ foreach(lc, query->rtable)
+ {
+ RangeTblEntry *r = (RangeTblEntry*) lfirst(lc);
+ Bitmapset *key_attnos;
+ bool has_pkey = true;
+
+ /* for tables, call get_primary_key_attnos */
+ if (r->rtekind == RTE_RELATION)
+ {
+ Oid constraintOid;
+ key_attnos = get_primary_key_attnos(r->relid, false, &constraintOid);
+ *constraintList = lappend_oid(*constraintList, constraintOid);
+ has_pkey = (key_attnos != NULL);
+ }
+ /* for other RTEs, store NULL into key_attnos_list */
+ else
+ key_attnos = NULL;
+
+ /*
+ * If any table or subquery has no primary key or its pkey constraint is deferrable,
+ * we cannot get key attributes for this query, so return NULL.
+ */
+ if (!has_pkey)
+ return NULL;
+
+ key_attnos_list = lappend(key_attnos_list, key_attnos);
+ }
+
+ /* Collect key attributes appearing in the target list */
+ i = 1;
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) flatten_join_alias_vars(NULL, query, lfirst(lc));
+
+ if (IsA(tle->expr, Var))
+ {
+ Var *var = (Var*) tle->expr;
+ Bitmapset *key_attnos = list_nth(key_attnos_list, var->varno - 1);
+
+ /* check if this attribute is from a base table's primary key */
+ if (bms_is_member(var->varattno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ /*
+ * Remove found key attributes from key_attnos_list, and add this
+ * to the result list.
+ */
+ key_attnos = bms_del_member(key_attnos, var->varattno - FirstLowInvalidHeapAttributeNumber);
+ if (bms_is_empty(key_attnos))
+ {
+ key_attnos_list = list_delete_nth_cell(key_attnos_list, var->varno - 1);
+ key_attnos_list = list_insert_nth(key_attnos_list, var->varno - 1, NULL);
+ }
+ keys = bms_add_member(keys, i - FirstLowInvalidHeapAttributeNumber);
+ }
+ }
+ i++;
+ }
+
+ /* Collect RTE indexes of relations appearing in the FROM clause */
+ rels_in_from = get_relids_in_jointree((Node *) query->jointree, false, false);
+
+ /*
+ * Check if all key attributes of relations in FROM are appearing in the target
+ * list. If an attribute remains in key_attnos_list in spite of the table is used
+ * in FROM clause, the target is missing this key attribute, so we return NULL.
+ */
+ i = 1;
+ foreach(lc, key_attnos_list)
+ {
+ Bitmapset *bms = (Bitmapset *)lfirst(lc);
+ if (!bms_is_empty(bms) && bms_is_member(i, rels_in_from))
+ return NULL;
+ i++;
+ }
+
+ return keys;
+}
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index ac2e74fa3f..39305f3c49 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -25,26 +25,37 @@
#include "catalog/indexing.h"
#include "catalog/namespace.h"
#include "catalog/pg_am.h"
+#include "catalog/pg_depend.h"
+#include "catalog/pg_trigger.h"
#include "catalog/pg_opclass.h"
#include "catalog/pg_operator.h"
#include "commands/cluster.h"
#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
+#include "commands/createas.h"
#include "executor/executor.h"
#include "executor/spi.h"
+#include "executor/tstoreReceiver.h"
#include "miscadmin.h"
+#include "nodes/makefuncs.h"
+#include "parser/analyze.h"
+#include "parser/parse_clause.h"
+#include "parser/parse_func.h"
#include "parser/parse_relation.h"
#include "pgstat.h"
#include "rewrite/rewriteHandler.h"
+#include "rewrite/rowsecurity.h"
#include "storage/lmgr.h"
#include "storage/smgr.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
+#include "utils/fmgroids.h"
#include "utils/lsyscache.h"
#include "utils/rel.h"
#include "utils/snapmgr.h"
#include "utils/syscache.h"
+#include "utils/typcache.h"
typedef struct
@@ -58,6 +69,52 @@ typedef struct
BulkInsertState bistate; /* bulk insert state */
} DR_transientrel;
+#define MV_INIT_QUERYHASHSIZE 16
+
+/*
+ * MV_TriggerHashEntry
+ *
+ * Hash entry for base tables on which IVM trigger is invoked
+ */
+typedef struct MV_TriggerHashEntry
+{
+ Oid matview_id; /* OID of the materialized view */
+ int before_trig_count; /* count of before triggers invoked */
+ int after_trig_count; /* count of after triggers invoked */
+
+ Snapshot snapshot; /* Snapshot just before table change */
+
+ List *tables; /* List of MV_TriggerTable */
+ bool has_old; /* tuples are deleted from any table? */
+ bool has_new; /* tuples are inserted into any table? */
+} MV_TriggerHashEntry;
+
+/*
+ * MV_TriggerTable
+ *
+ * IVM related data for tables on which the trigger is invoked.
+ */
+typedef struct MV_TriggerTable
+{
+ Oid table_id; /* OID of the modified table */
+ List *old_tuplestores; /* tuplestores for deleted tuples */
+ List *new_tuplestores; /* tuplestores for inserted tuples */
+
+ List *rte_indexes; /* List of RTE index of the modified table */
+ RangeTblEntry *original_rte; /* the original RTE saved before rewriting query */
+
+ Relation rel; /* relation of the modified table */
+ TupleTableSlot *slot; /* for checking visibility in the pre-state table */
+} MV_TriggerTable;
+
+static HTAB *mv_trigger_info = NULL;
+
+static bool in_delta_calculation = false;
+
+/* ENR name for materialized view delta */
+#define NEW_DELTA_ENRNAME "new_delta"
+#define OLD_DELTA_ENRNAME "old_delta"
+
static int matview_maintenance_depth = 0;
static void transientrel_startup(DestReceiver *self, int operation, TupleDesc typeinfo);
@@ -65,7 +122,9 @@ static bool transientrel_receive(TupleTableSlot *slot, DestReceiver *self);
static void transientrel_shutdown(DestReceiver *self);
static void transientrel_destroy(DestReceiver *self);
static uint64 refresh_matview_datafill(DestReceiver *dest, Query *query,
- const char *queryString);
+ QueryEnvironment *queryEnv,
+ TupleDesc *resultTupleDesc,
+ const char *queryString);
static char *make_temptable_name_n(char *tempname, int n);
static void refresh_by_match_merge(Oid matviewOid, Oid tempOid, Oid relowner,
int save_sec_context);
@@ -73,6 +132,37 @@ static void refresh_by_heap_swap(Oid matviewOid, Oid OIDNewHeap, char relpersist
static bool is_usable_unique_index(Relation indexRel);
static void OpenMatViewIncrementalMaintenance(void);
static void CloseMatViewIncrementalMaintenance(void);
+static Query *get_matview_query(Relation matviewRel);
+
+static Query *rewrite_query_for_preupdate_state(Query *query, List *tables,
+ ParseState *pstate, Oid matviewid);
+static void register_delta_ENRs(ParseState *pstate, Query *query, List *tables);
+static char *make_delta_enr_name(const char *prefix, Oid relid, int count);
+static RangeTblEntry *get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *table,
+ QueryEnvironment *queryEnv, Oid matviewid);
+static RangeTblEntry *replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
+ QueryEnvironment *queryEnv);
+static Query *rewrite_query_for_counting(Query *query, ParseState *pstate);
+
+static void calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
+ DestReceiver *dest_old, DestReceiver *dest_new,
+ TupleDesc *tupdesc_old, TupleDesc *tupdesc_new,
+ QueryEnvironment *queryEnv);
+static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte_index);
+
+static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
+ TupleDesc tupdesc_old, TupleDesc tupdesc_new,
+ Query *query);
+static void apply_old_delta(const char *matviewname, const char *deltaname_old,
+ List *keys);
+static void apply_new_delta(const char *matviewname, const char *deltaname_new,
+ StringInfo target_list);
+static char *get_matching_condition_string(List *keys);
+static void generate_equal(StringInfo querybuf, Oid opttype,
+ const char *leftop, const char *rightop);
+
+static void mv_InitHashTables(void);
+static void clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort);
/*
* SetMatViewPopulatedState
@@ -114,6 +204,46 @@ SetMatViewPopulatedState(Relation relation, bool newstate)
CommandCounterIncrement();
}
+/*
+ * SetMatViewIVMState
+ * Mark a materialized view as IVM, or not.
+ *
+ * NOTE: caller must be holding an appropriate lock on the relation.
+ */
+void
+SetMatViewIVMState(Relation relation, bool newstate)
+{
+ Relation pgrel;
+ HeapTuple tuple;
+
+ Assert(relation->rd_rel->relkind == RELKIND_MATVIEW);
+
+ /*
+ * Update relation's pg_class entry. Crucial side-effect: other backends
+ * (and this one too!) are sent SI message to make them rebuild relcache
+ * entries.
+ */
+ pgrel = table_open(RelationRelationId, RowExclusiveLock);
+ tuple = SearchSysCacheCopy1(RELOID,
+ ObjectIdGetDatum(RelationGetRelid(relation)));
+ if (!HeapTupleIsValid(tuple))
+ elog(ERROR, "cache lookup failed for relation %u",
+ RelationGetRelid(relation));
+
+ ((Form_pg_class) GETSTRUCT(tuple))->relisivm = newstate;
+
+ CatalogTupleUpdate(pgrel, &tuple->t_self, tuple);
+
+ heap_freetuple(tuple);
+ table_close(pgrel, RowExclusiveLock);
+
+ /*
+ * Advance command counter to make the updated pg_class row locally
+ * visible.
+ */
+ CommandCounterIncrement();
+}
+
/*
* ExecRefreshMatView -- execute a REFRESH MATERIALIZED VIEW command
*
@@ -140,8 +270,6 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
{
Oid matviewOid;
Relation matviewRel;
- RewriteRule *rule;
- List *actions;
Query *dataQuery;
Oid tableSpace;
Oid relowner;
@@ -155,6 +283,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
int save_sec_context;
int save_nestlevel;
ObjectAddress address;
+ bool oldPopulated;
/* Determine strength of lock needed. */
concurrent = stmt->concurrent;
@@ -178,6 +307,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
SetUserIdAndSecContext(relowner,
save_sec_context | SECURITY_RESTRICTED_OPERATION);
save_nestlevel = NewGUCNestLevel();
+ oldPopulated = RelationIsPopulated(matviewRel);
/* Make sure it is a materialized view. */
if (matviewRel->rd_rel->relkind != RELKIND_MATVIEW)
@@ -199,32 +329,9 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
errmsg("%s and %s options cannot be used together",
"CONCURRENTLY", "WITH NO DATA")));
- /*
- * Check that everything is correct for a refresh. Problems at this point
- * are internal errors, so elog is sufficient.
- */
- if (matviewRel->rd_rel->relhasrules == false ||
- matviewRel->rd_rules->numLocks < 1)
- elog(ERROR,
- "materialized view \"%s\" is missing rewrite information",
- RelationGetRelationName(matviewRel));
-
- if (matviewRel->rd_rules->numLocks > 1)
- elog(ERROR,
- "materialized view \"%s\" has too many rules",
- RelationGetRelationName(matviewRel));
- rule = matviewRel->rd_rules->rules[0];
- if (rule->event != CMD_SELECT || !(rule->isInstead))
- elog(ERROR,
- "the rule for materialized view \"%s\" is not a SELECT INSTEAD OF rule",
- RelationGetRelationName(matviewRel));
+ dataQuery = get_matview_query(matviewRel);
- actions = rule->actions;
- if (list_length(actions) != 1)
- elog(ERROR,
- "the rule for materialized view \"%s\" is not a single action",
- RelationGetRelationName(matviewRel));
/*
* Check that there is a unique index with no WHERE clause on one or more
@@ -259,12 +366,6 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
errhint("Create a unique index with no WHERE clause on one or more columns of the materialized view.")));
}
- /*
- * The stored query was rewritten at the time of the MV definition, but
- * has not been scribbled on by the planner.
- */
- dataQuery = linitial_node(Query, actions);
-
/*
* Check for active uses of the relation in the current transaction, such
* as open scans.
@@ -292,6 +393,74 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
relpersistence = matviewRel->rd_rel->relpersistence;
}
+ /* delete IMMV triggers. */
+ if (RelationIsIVM(matviewRel) && stmt->skipData )
+ {
+ Relation tgRel;
+ Relation depRel;
+ ScanKeyData key;
+ SysScanDesc scan;
+ HeapTuple tup;
+ ObjectAddresses *immv_triggers;
+
+ immv_triggers = new_object_addresses();
+
+ tgRel = table_open(TriggerRelationId, RowExclusiveLock);
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ /* search triggers that depends on IMMV. */
+ ScanKeyInit(&key,
+ Anum_pg_depend_refobjid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(matviewOid));
+ scan = systable_beginscan(depRel, DependReferenceIndexId, true,
+ NULL, 1, &key);
+ while ((tup = systable_getnext(scan)) != NULL)
+ {
+ ObjectAddress obj;
+ Form_pg_depend foundDep = (Form_pg_depend) GETSTRUCT(tup);
+
+ if (foundDep->classid == TriggerRelationId)
+ {
+ HeapTuple tgtup;
+ ScanKeyData tgkey[1];
+ SysScanDesc tgscan;
+ Form_pg_trigger tgform;
+
+ /* Find the trigger name. */
+ ScanKeyInit(&tgkey[0],
+ Anum_pg_trigger_oid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(foundDep->objid));
+
+ tgscan = systable_beginscan(tgRel, TriggerOidIndexId, true,
+ NULL, 1, tgkey);
+ tgtup = systable_getnext(tgscan);
+ if (!HeapTupleIsValid(tgtup))
+ elog(ERROR, "could not find tuple for immv trigger %u", foundDep->objid);
+
+ tgform = (Form_pg_trigger) GETSTRUCT(tgtup);
+
+ /* If trigger is created by IMMV, delete it. */
+ if (strncmp(NameStr(tgform->tgname), "IVM_trigger_", 12) == 0)
+ {
+ obj.classId = foundDep->classid;
+ obj.objectId = foundDep->objid;
+ obj.objectSubId = foundDep->refobjsubid;
+ add_exact_object_address(&obj, immv_triggers);
+ }
+ systable_endscan(tgscan);
+ }
+ }
+ systable_endscan(scan);
+
+ performMultipleDeletions(immv_triggers, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ table_close(depRel, RowExclusiveLock);
+ table_close(tgRel, RowExclusiveLock);
+ free_object_addresses(immv_triggers);
+ }
+
/*
* Create the transient table that will receive the regenerated data. Lock
* it against access by any other process until commit (by which time it
@@ -305,7 +474,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
/* Generate the data, if wanted. */
if (!stmt->skipData)
- processed = refresh_matview_datafill(dest, dataQuery, queryString);
+ processed = refresh_matview_datafill(dest, dataQuery, NULL, NULL, queryString);
/* Make the matview match the newly generated data. */
if (concurrent)
@@ -340,6 +509,12 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
pgstat_count_heap_insert(matviewRel, processed);
}
+ if (!stmt->skipData && RelationIsIVM(matviewRel) && !oldPopulated)
+ {
+ CreateIndexOnIMMV(dataQuery, matviewRel);
+ CreateIvmTriggersOnBaseTables(dataQuery, matviewOid);
+ }
+
table_close(matviewRel, NoLock);
/* Roll back any GUC changes */
@@ -374,6 +549,8 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
*/
static uint64
refresh_matview_datafill(DestReceiver *dest, Query *query,
+ QueryEnvironment *queryEnv,
+ TupleDesc *resultTupleDesc,
const char *queryString)
{
List *rewritten;
@@ -410,7 +587,7 @@ refresh_matview_datafill(DestReceiver *dest, Query *query,
/* Create a QueryDesc, redirecting output to our tuple receiver */
queryDesc = CreateQueryDesc(plan, queryString,
GetActiveSnapshot(), InvalidSnapshot,
- dest, NULL, NULL, 0);
+ dest, NULL, queryEnv ? queryEnv: NULL, 0);
/* call ExecutorStart to prepare the plan for execution */
ExecutorStart(queryDesc, 0);
@@ -420,6 +597,9 @@ refresh_matview_datafill(DestReceiver *dest, Query *query,
processed = queryDesc->estate->es_processed;
+ if (resultTupleDesc)
+ *resultTupleDesc = CreateTupleDescCopy(queryDesc->tupDesc);
+
/* and clean up */
ExecutorFinish(queryDesc);
ExecutorEnd(queryDesc);
@@ -931,3 +1111,1219 @@ CloseMatViewIncrementalMaintenance(void)
matview_maintenance_depth--;
Assert(matview_maintenance_depth >= 0);
}
+
+/*
+ * get_matview_query - get the Query from a matview's _RETURN rule.
+ */
+static Query *
+get_matview_query(Relation matviewRel)
+{
+ RewriteRule *rule;
+ List * actions;
+
+ /*
+ * Check that everything is correct for a refresh. Problems at this point
+ * are internal errors, so elog is sufficient.
+ */
+ if (matviewRel->rd_rel->relhasrules == false ||
+ matviewRel->rd_rules->numLocks < 1)
+ elog(ERROR,
+ "materialized view \"%s\" is missing rewrite information",
+ RelationGetRelationName(matviewRel));
+
+ if (matviewRel->rd_rules->numLocks > 1)
+ elog(ERROR,
+ "materialized view \"%s\" has too many rules",
+ RelationGetRelationName(matviewRel));
+
+ rule = matviewRel->rd_rules->rules[0];
+ if (rule->event != CMD_SELECT || !(rule->isInstead))
+ elog(ERROR,
+ "the rule for materialized view \"%s\" is not a SELECT INSTEAD OF rule",
+ RelationGetRelationName(matviewRel));
+
+ actions = rule->actions;
+ if (list_length(actions) != 1)
+ elog(ERROR,
+ "the rule for materialized view \"%s\" is not a single action",
+ RelationGetRelationName(matviewRel));
+
+ /*
+ * The stored query was rewritten at the time of the MV definition, but
+ * has not been scribbled on by the planner.
+ */
+ return linitial_node(Query, actions);
+}
+
+
+/* ----------------------------------------------------
+ * Incremental View Maintenance routines
+ * ---------------------------------------------------
+ */
+
+/*
+ * IVM_immediate_before
+ *
+ * IVM trigger function invoked before base table is modified. If this is
+ * invoked firstly in the same statement, we save the transaction id and the
+ * command id at that time.
+ */
+Datum
+IVM_immediate_before(PG_FUNCTION_ARGS)
+{
+ TriggerData *trigdata = (TriggerData *) fcinfo->context;
+ char *matviewOid_text = trigdata->tg_trigger->tgargs[0];
+ char *ex_lock_text = trigdata->tg_trigger->tgargs[1];
+ Oid matviewOid;
+ MV_TriggerHashEntry *entry;
+ bool found;
+ bool ex_lock;
+
+ matviewOid = DatumGetObjectId(DirectFunctionCall1(oidin, CStringGetDatum(matviewOid_text)));
+ ex_lock = DatumGetBool(DirectFunctionCall1(boolin, CStringGetDatum(ex_lock_text)));
+
+ /* If the view has more than one tables, we have to use an exclusive lock. */
+ if (ex_lock)
+ {
+ /*
+ * Wait for concurrent transactions which update this materialized view at
+ * READ COMMITED. This is needed to see changes committed in other
+ * transactions. No wait and raise an error at REPEATABLE READ or
+ * SERIALIZABLE to prevent update anomalies of matviews.
+ * XXX: dead-lock is possible here.
+ */
+ if (!IsolationUsesXactSnapshot())
+ LockRelationOid(matviewOid, ExclusiveLock);
+ else if (!ConditionalLockRelationOid(matviewOid, ExclusiveLock))
+ {
+ /* try to throw error by name; relation could be deleted... */
+ char *relname = get_rel_name(matviewOid);
+
+ if (!relname)
+ ereport(ERROR,
+ (errcode(ERRCODE_LOCK_NOT_AVAILABLE),
+ errmsg("could not obtain lock on materialized view during incremental maintenance")));
+
+ ereport(ERROR,
+ (errcode(ERRCODE_LOCK_NOT_AVAILABLE),
+ errmsg("could not obtain lock on materialized view \"%s\" during incremental maintenance",
+ relname)));
+ }
+ }
+ else
+ LockRelationOid(matviewOid, RowExclusiveLock);
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_trigger_info)
+ mv_InitHashTables();
+
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_ENTER, &found);
+
+ /* On the first BEFORE to update the view, initialize trigger data */
+ if (!found)
+ {
+ /*
+ * Get a snapshot just before the table was modified for checking
+ * tuple visibility in the pre-update state of the table.
+ */
+ Snapshot snapshot = GetActiveSnapshot();
+
+ entry->matview_id = matviewOid;
+ entry->before_trig_count = 0;
+ entry->after_trig_count = 0;
+ entry->snapshot = RegisterSnapshot(snapshot);
+ entry->tables = NIL;
+ entry->has_old = false;
+ entry->has_new = false;
+ }
+
+ entry->before_trig_count++;
+
+ return PointerGetDatum(NULL);
+}
+
+/*
+ * IVM_immediate_maintenance
+ *
+ * IVM trigger function invoked after base table is modified.
+ * For each table, tuplestores of transition tables are collected.
+ * and after the last modification
+ */
+Datum
+IVM_immediate_maintenance(PG_FUNCTION_ARGS)
+{
+ TriggerData *trigdata = (TriggerData *) fcinfo->context;
+ Relation rel;
+ Oid relid;
+ Oid matviewOid;
+ Query *query;
+ Query *rewritten = NULL;
+ char *matviewOid_text = trigdata->tg_trigger->tgargs[0];
+ Relation matviewRel;
+ int old_depth = matview_maintenance_depth;
+
+ Oid relowner;
+ Tuplestorestate *old_tuplestore = NULL;
+ Tuplestorestate *new_tuplestore = NULL;
+ DestReceiver *dest_new = NULL, *dest_old = NULL;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ MV_TriggerHashEntry *entry;
+ MV_TriggerTable *table;
+ bool found;
+
+ ParseState *pstate;
+ QueryEnvironment *queryEnv = create_queryEnv();
+ MemoryContext oldcxt;
+ ListCell *lc;
+ int i;
+
+
+ /* Create a ParseState for rewriting the view definition query */
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ rel = trigdata->tg_relation;
+ relid = rel->rd_id;
+
+ matviewOid = DatumGetObjectId(DirectFunctionCall1(oidin, CStringGetDatum(matviewOid_text)));
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_trigger_info)
+ mv_InitHashTables();
+
+ /* get the entry for this materialized view */
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_FIND, &found);
+ Assert (found && entry != NULL);
+ entry->after_trig_count++;
+
+ /* search the entry for the modified table and create new entry if not found */
+ found = false;
+ foreach(lc, entry->tables)
+ {
+ table = (MV_TriggerTable *) lfirst(lc);
+ if (table->table_id == relid)
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ table = (MV_TriggerTable *) palloc0(sizeof(MV_TriggerTable));
+ table->table_id = relid;
+ table->old_tuplestores = NIL;
+ table->new_tuplestores = NIL;
+ table->rte_indexes = NIL;
+ table->slot = MakeSingleTupleTableSlot(RelationGetDescr(rel), table_slot_callbacks(rel));
+ table->rel = table_open(RelationGetRelid(rel), NoLock);
+ entry->tables = lappend(entry->tables, table);
+
+ MemoryContextSwitchTo(oldcxt);
+ }
+
+ /* Save the transition tables and make a request to not free immediately */
+ if (trigdata->tg_oldtable)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+ table->old_tuplestores = lappend(table->old_tuplestores, trigdata->tg_oldtable);
+ entry->has_old = true;
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (trigdata->tg_newtable)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+ table->new_tuplestores = lappend(table->new_tuplestores, trigdata->tg_newtable);
+ entry->has_new = true;
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (entry->has_new || entry->has_old)
+ {
+ CmdType cmd;
+
+ if (TRIGGER_FIRED_BY_INSERT(trigdata->tg_event))
+ cmd = CMD_INSERT;
+ else if (TRIGGER_FIRED_BY_DELETE(trigdata->tg_event))
+ cmd = CMD_DELETE;
+ else if (TRIGGER_FIRED_BY_UPDATE(trigdata->tg_event))
+ cmd = CMD_UPDATE;
+ else
+ elog(ERROR,"unsupported trigger type");
+
+ /* Prolong lifespan of transition tables to the end of the last AFTER trigger */
+ SetTransitionTablePreserved(relid, cmd);
+ }
+
+
+ /* If this is not the last AFTER trigger call, immediately exit. */
+ Assert (entry->before_trig_count >= entry->after_trig_count);
+ if (entry->before_trig_count != entry->after_trig_count)
+ return PointerGetDatum(NULL);
+
+ /*
+ * If this is the last AFTER trigger call, continue and update the view.
+ */
+
+ /*
+ * Advance command counter to make the updated base table row locally
+ * visible.
+ */
+ CommandCounterIncrement();
+
+ matviewRel = table_open(matviewOid, NoLock);
+
+ /* Make sure it is a materialized view. */
+ Assert(matviewRel->rd_rel->relkind == RELKIND_MATVIEW);
+
+ /*
+ * Get and push the latast snapshot to see any changes which is committed
+ * during waiting in other transactions at READ COMMITTED level.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /*
+ * Check for active uses of the relation in the current transaction, such
+ * as open scans.
+ *
+ * NB: We count on this to protect us against problems with refreshing the
+ * data using TABLE_INSERT_FROZEN.
+ */
+ CheckTableNotInUse(matviewRel, "refresh a materialized view incrementally");
+
+ /*
+ * Switch to the owner's userid, so that any functions are run as that
+ * user. Also arrange to make GUC variable changes local to this command.
+ * We will switch modes when we are about to execute user code.
+ */
+ relowner = matviewRel->rd_rel->relowner;
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+
+ /* get view query*/
+ query = get_matview_query(matviewRel);
+
+ /*
+ * When a base table is truncated, the view content will be empty if the
+ * view definition query does not contain an aggregate without a GROUP clause.
+ * Therefore, such views can be truncated.
+ */
+ if (TRIGGER_FIRED_BY_TRUNCATE(trigdata->tg_event))
+ {
+ ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
+ NIL, DROP_RESTRICT, false, false);
+
+ /* Clean up hash entry and delete tuplestores */
+ clean_up_IVM_hash_entry(entry, false);
+
+ /* Pop the original snapshot. */
+ PopActiveSnapshot();
+
+ table_close(matviewRel, NoLock);
+
+ /* Roll back any GUC changes */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ return PointerGetDatum(NULL);
+ }
+
+ /*
+ * rewrite query for calculating deltas
+ */
+
+ rewritten = copyObject(query);
+
+ /* Replace resnames in a target list with materialized view's attnames */
+ i = 0;
+ foreach (lc, rewritten->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
+
+ tle->resname = pstrdup(resname);
+ i++;
+ }
+
+ /* Set all tables in the query to pre-update state */
+ rewritten = rewrite_query_for_preupdate_state(rewritten, entry->tables,
+ pstate, matviewOid);
+ /* Rewrite for counting duplicated tuples */
+ rewritten = rewrite_query_for_counting(rewritten, pstate);
+
+ /* Create tuplestores to store view deltas */
+ if (entry->has_old)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ old_tuplestore = tuplestore_begin_heap(false, false, work_mem);
+ dest_old = CreateDestReceiver(DestTuplestore);
+ SetTuplestoreDestReceiverParams(dest_old,
+ old_tuplestore,
+ TopTransactionContext,
+ false,
+ NULL,
+ NULL);
+
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (entry->has_new)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ new_tuplestore = tuplestore_begin_heap(false, false, work_mem);
+ dest_new = CreateDestReceiver(DestTuplestore);
+ SetTuplestoreDestReceiverParams(dest_new,
+ new_tuplestore,
+ TopTransactionContext,
+ false,
+ NULL,
+ NULL);
+ MemoryContextSwitchTo(oldcxt);
+ }
+
+ /* for all modified tables */
+ foreach(lc, entry->tables)
+ {
+ ListCell *lc2;
+
+ table = (MV_TriggerTable *) lfirst(lc);
+
+ /* loop for self-join */
+ foreach(lc2, table->rte_indexes)
+ {
+ int rte_index = lfirst_int(lc2);
+ TupleDesc tupdesc_old;
+ TupleDesc tupdesc_new;
+
+ /* calculate delta tables */
+ calc_delta(table, rte_index, rewritten, dest_old, dest_new,
+ &tupdesc_old, &tupdesc_new, queryEnv);
+
+ /* Set the table in the query to post-update state */
+ rewritten = rewrite_query_for_postupdate_state(rewritten, table, rte_index);
+
+ PG_TRY();
+ {
+ /* apply the delta tables to the materialized view */
+ apply_delta(matviewOid, old_tuplestore, new_tuplestore,
+ tupdesc_old, tupdesc_new, query);
+ }
+ PG_CATCH();
+ {
+ matview_maintenance_depth = old_depth;
+ PG_RE_THROW();
+ }
+ PG_END_TRY();
+
+ /* clear view delta tuplestores */
+ if (old_tuplestore)
+ tuplestore_clear(old_tuplestore);
+ if (new_tuplestore)
+ tuplestore_clear(new_tuplestore);
+ }
+ }
+
+ /* Clean up hash entry and delete tuplestores */
+ clean_up_IVM_hash_entry(entry, false);
+ if (old_tuplestore)
+ {
+ dest_old->rDestroy(dest_old);
+ tuplestore_end(old_tuplestore);
+ }
+ if (new_tuplestore)
+ {
+ dest_new->rDestroy(dest_new);
+ tuplestore_end(new_tuplestore);
+ }
+
+ /* Pop the original snapshot. */
+ PopActiveSnapshot();
+
+ table_close(matviewRel, NoLock);
+
+ /* Roll back any GUC changes */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ return PointerGetDatum(NULL);
+}
+
+/*
+ * rewrite_query_for_preupdate_state
+ *
+ * Rewrite the query so that base tables' RTEs will represent "pre-update"
+ * state of tables. This is necessary to calculate view delta after multiple
+ * tables are modified.
+ */
+static Query*
+rewrite_query_for_preupdate_state(Query *query, List *tables,
+ ParseState *pstate, Oid matviewid)
+{
+ ListCell *lc;
+ int num_rte = list_length(query->rtable);
+ int i;
+
+
+ /* register delta ENRs */
+ register_delta_ENRs(pstate, query, tables);
+
+ /* XXX: Is necessary? Is this right timing? */
+ AcquireRewriteLocks(query, true, false);
+
+ i = 1;
+ foreach(lc, query->rtable)
+ {
+ RangeTblEntry *r = (RangeTblEntry*) lfirst(lc);
+
+ ListCell *lc2;
+ foreach(lc2, tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc2);
+ /*
+ * if the modified table is found then replace the original RTE with
+ * "pre-state" RTE and append its index to the list.
+ */
+ if (r->relid == table->table_id)
+ {
+ List *securityQuals;
+ List *withCheckOptions;
+ bool hasRowSecurity;
+ bool hasSubLinks;
+
+ RangeTblEntry *rte_pre = get_prestate_rte(r, table, pstate->p_queryEnv, matviewid);
+
+ /*
+ * Set a row security poslicies of the modified table to the subquery RTE which
+ * represents the pre-update state of the table.
+ */
+ get_row_security_policies(query, table->original_rte, i,
+ &securityQuals, &withCheckOptions,
+ &hasRowSecurity, &hasSubLinks);
+
+ if (hasRowSecurity)
+ {
+ query->hasRowSecurity = true;
+ rte_pre->security_barrier = true;
+ }
+ if (hasSubLinks)
+ query->hasSubLinks = true;
+
+ rte_pre->securityQuals = securityQuals;
+ lfirst(lc) = rte_pre;
+
+ table->rte_indexes = lappend_int(table->rte_indexes, i);
+ break;
+ }
+ }
+
+ /* finish the loop if we processed all RTE included in the original query */
+ if (i++ >= num_rte)
+ break;
+ }
+
+ return query;
+}
+
+/*
+ * register_delta_ENRs
+ *
+ * For all modified tables, make ENRs for their transition tables
+ * and register them to the queryEnv. ENR's RTEs are also appended
+ * into the list in query tree.
+ */
+static void
+register_delta_ENRs(ParseState *pstate, Query *query, List *tables)
+{
+ QueryEnvironment *queryEnv = pstate->p_queryEnv;
+ ListCell *lc;
+ RangeTblEntry *rte;
+
+ foreach(lc, tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc);
+ ListCell *lc2;
+ int count;
+
+ count = 0;
+ foreach(lc2, table->old_tuplestores)
+ {
+ Tuplestorestate *oldtable = (Tuplestorestate *) lfirst(lc2);
+ EphemeralNamedRelation enr =
+ palloc(sizeof(EphemeralNamedRelationData));
+ ParseNamespaceItem *nsitem;
+
+ enr->md.name = make_delta_enr_name("old", table->table_id, count);
+ enr->md.reliddesc = table->table_id;
+ enr->md.tupdesc = NULL;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(oldtable);
+ enr->reldata = oldtable;
+ register_ENR(queryEnv, enr);
+
+ nsitem = addRangeTableEntryForENR(pstate, makeRangeVar(NULL, enr->md.name, -1), true);
+ rte = nsitem->p_rte;
+
+ query->rtable = lappend(query->rtable, rte);
+
+ count++;
+ }
+
+ count = 0;
+ foreach(lc2, table->new_tuplestores)
+ {
+ Tuplestorestate *newtable = (Tuplestorestate *) lfirst(lc2);
+ EphemeralNamedRelation enr =
+ palloc(sizeof(EphemeralNamedRelationData));
+ ParseNamespaceItem *nsitem;
+
+ enr->md.name = make_delta_enr_name("new", table->table_id, count);
+ enr->md.reliddesc = table->table_id;
+ enr->md.tupdesc = NULL;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(newtable);
+ enr->reldata = newtable;
+ register_ENR(queryEnv, enr);
+
+ nsitem = addRangeTableEntryForENR(pstate, makeRangeVar(NULL, enr->md.name, -1), true);
+ rte = nsitem->p_rte;
+
+ query->rtable = lappend(query->rtable, rte);
+
+ count++;
+ }
+ }
+}
+
+#define DatumGetItemPointer(X) ((ItemPointer) DatumGetPointer(X))
+#define PG_GETARG_ITEMPOINTER(n) DatumGetItemPointer(PG_GETARG_DATUM(n))
+
+/*
+ * ivm_visible_in_prestate
+ *
+ * Check visibility of a tuple specified by the tableoid and item pointer
+ * using the snapshot taken just before the table was modified.
+ */
+Datum
+ivm_visible_in_prestate(PG_FUNCTION_ARGS)
+{
+ Oid tableoid = PG_GETARG_OID(0);
+ ItemPointer itemPtr = PG_GETARG_ITEMPOINTER(1);
+ Oid matviewOid = PG_GETARG_OID(2);
+ MV_TriggerHashEntry *entry;
+ MV_TriggerTable *table = NULL;
+ ListCell *lc;
+ bool found;
+ bool result;
+
+ if (!in_delta_calculation)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("ivm_visible_in_prestate can be called only in delta calculation")));
+
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_FIND, &found);
+ Assert (found && entry != NULL);
+
+ foreach(lc, entry->tables)
+ {
+ table = (MV_TriggerTable *) lfirst(lc);
+ if (table->table_id == tableoid)
+ break;
+ }
+
+ Assert (table != NULL);
+
+ result = table_tuple_fetch_row_version(table->rel, itemPtr, entry->snapshot, table->slot);
+
+ PG_RETURN_BOOL(result);
+}
+
+/*
+ * get_prestate_rte
+ *
+ * Rewrite RTE of the modified table to a subquery which represents
+ * "pre-state" table. The original RTE is saved in table->rte_original.
+ */
+static RangeTblEntry*
+get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *table,
+ QueryEnvironment *queryEnv, Oid matviewid)
+{
+ StringInfoData str;
+ RawStmt *raw;
+ Query *subquery;
+ Relation rel;
+ ParseState *pstate;
+ char *relname;
+ int i;
+
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ /*
+ * We can use NoLock here since AcquireRewriteLocks should
+ * have locked the relation already.
+ */
+ rel = table_open(table->table_id, NoLock);
+ relname = quote_qualified_identifier(
+ get_namespace_name(RelationGetNamespace(rel)),
+ RelationGetRelationName(rel));
+ table_close(rel, NoLock);
+
+ /*
+ * Filtering inserted row using the snapshot taken before the table
+ * is modified. ctid is required for maintaining outer join views.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str,
+ "SELECT t.* FROM %s t"
+ " WHERE pg_catalog.ivm_visible_in_prestate(t.tableoid, t.ctid ,%d::pg_catalog.oid)",
+ relname, matviewid);
+
+ /*
+ * Append deleted rows contained in old transition tables.
+ */
+ for (i = 0; i < list_length(table->old_tuplestores); i++)
+ {
+ appendStringInfo(&str, " UNION ALL ");
+ appendStringInfo(&str," SELECT * FROM %s",
+ make_delta_enr_name("old", table->table_id, i));
+ }
+
+ /* Get a subquery representing pre-state of the table */
+ raw = (RawStmt*)linitial(raw_parser(str.data, RAW_PARSE_DEFAULT));
+ subquery = transformStmt(pstate, raw->stmt);
+
+ /* save the original RTE */
+ table->original_rte = copyObject(rte);
+
+ rte->rtekind = RTE_SUBQUERY;
+ rte->subquery = subquery;
+ rte->security_barrier = false;
+
+ /* Clear fields that should not be set in a subquery RTE */
+ rte->relid = InvalidOid;
+ rte->relkind = 0;
+ rte->rellockmode = 0;
+ rte->tablesample = NULL;
+ rte->perminfoindex = 0; /* no permission checking for this RTE */
+ rte->inh = false; /* must not be set for a subquery */
+
+ return rte;
+}
+
+/*
+ * make_delta_enr_name
+ *
+ * Make a name for ENR of a transition table from the base table's oid.
+ * prefix will be "new" or "old" depending on its transition table kind..
+ */
+static char*
+make_delta_enr_name(const char *prefix, Oid relid, int count)
+{
+ char buf[NAMEDATALEN];
+ char *name;
+
+ snprintf(buf, NAMEDATALEN, "__ivm_%s_%u_%u", prefix, relid, count);
+ name = pstrdup(buf);
+
+ return name;
+}
+
+/*
+ * replace_rte_with_delta
+ *
+ * Replace RTE of the modified table with a single table delta that combine its
+ * all transition tables.
+ */
+static RangeTblEntry*
+replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
+ QueryEnvironment *queryEnv)
+{
+ Oid relid = table->table_id;
+ StringInfoData str;
+ ParseState *pstate;
+ RawStmt *raw;
+ Query *sub;
+ int num_tuplestores = list_length(is_new ? table->new_tuplestores : table->old_tuplestores);
+ int i;
+
+ /* the previous RTE must be a subquery which represents "pre-state" table */
+ Assert(rte->rtekind == RTE_SUBQUERY);
+
+ /* Create a ParseState for rewriting the view definition query */
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ initStringInfo(&str);
+
+ for (i = 0; i < num_tuplestores; i++)
+ {
+ if (i > 0)
+ appendStringInfo(&str, " UNION ALL ");
+
+ appendStringInfo(&str,
+ " SELECT * FROM %s",
+ make_delta_enr_name(is_new ? "new" : "old", relid, i));
+ }
+
+ raw = (RawStmt*)linitial(raw_parser(str.data, RAW_PARSE_DEFAULT));
+ sub = transformStmt(pstate, raw->stmt);
+
+ /*
+ * Update the subquery so that it represent the combined transition
+ * table. Note that we leave the security_barrier and securityQuals
+ * fields so that the subquery relation can be protected by the RLS
+ * policy as same as the modified table.
+ */
+ rte->rtekind = RTE_SUBQUERY;
+ rte->subquery = sub;
+
+ return rte;
+}
+
+/*
+ * rewrite_query_for_counting
+ *
+ * Rewrite query for counting duplicated tuples.
+ */
+static Query *
+rewrite_query_for_counting(Query *query, ParseState *pstate)
+{
+ TargetEntry *tle_count;
+ FuncCall *fn;
+ Node *node;
+
+ /* Add count(*) for counting distinct tuples in views */
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+ fn->agg_star = true;
+ if (!query->groupClause && !query->hasAggs)
+ query->groupClause = transformDistinctClause(NULL, &query->targetList, query->sortClause, false);
+
+ node = ParseFuncOrColumn(pstate, fn->funcname, NIL, NULL, fn, false, -1);
+
+ tle_count = makeTargetEntry((Expr *) node,
+ list_length(query->targetList) + 1,
+ pstrdup("__ivm_count__"),
+ false);
+ query->targetList = lappend(query->targetList, tle_count);
+ query->hasAggs = true;
+
+ return query;
+}
+
+/*
+ * calc_delta
+ *
+ * Calculate view deltas generated under the modification of a table specified
+ * by the RTE index.
+ */
+static void
+calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
+ DestReceiver *dest_old, DestReceiver *dest_new,
+ TupleDesc *tupdesc_old, TupleDesc *tupdesc_new,
+ QueryEnvironment *queryEnv)
+{
+ ListCell *lc = list_nth_cell(query->rtable, rte_index - 1);
+ RangeTblEntry *rte = (RangeTblEntry *) lfirst(lc);
+
+ in_delta_calculation = true;
+
+ /* Generate old delta */
+ if (list_length(table->old_tuplestores) > 0)
+ {
+ /* Replace the modified table with the old delta table and calculate the old view delta. */
+ replace_rte_with_delta(rte, table, false, queryEnv);
+ refresh_matview_datafill(dest_old, query, queryEnv, tupdesc_old, "");
+ }
+
+ /* Generate new delta */
+ if (list_length(table->new_tuplestores) > 0)
+ {
+ /* Replace the modified table with the new delta table and calculate the new view delta*/
+ replace_rte_with_delta(rte, table, true, queryEnv);
+ refresh_matview_datafill(dest_new, query, queryEnv, tupdesc_new, "");
+ }
+
+ in_delta_calculation = false;
+}
+
+/*
+ * rewrite_query_for_postupdate_state
+ *
+ * Rewrite the query so that the specified base table's RTEs will represent
+ * "post-update" state of tables. This is called after the view delta
+ * calculation due to changes on this table finishes.
+ */
+static Query*
+rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte_index)
+{
+ ListCell *lc = list_nth_cell(query->rtable, rte_index - 1);
+
+ /* Retore the original RTE */
+ lfirst(lc) = table->original_rte;
+
+ return query;
+}
+
+/*
+ * apply_delta
+ *
+ * Apply deltas to the materialized view. In outer join cases, this requires
+ * the view maintenance graph.
+ */
+static void
+apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
+ TupleDesc tupdesc_old, TupleDesc tupdesc_new,
+ Query *query)
+{
+ StringInfoData querybuf;
+ StringInfoData target_list_buf;
+ Relation matviewRel;
+ char *matviewname;
+ ListCell *lc;
+ int i;
+ List *keys = NIL;
+
+
+ /*
+ * get names of the materialized view and delta tables
+ */
+
+ matviewRel = table_open(matviewOid, NoLock);
+ matviewname = quote_qualified_identifier(get_namespace_name(RelationGetNamespace(matviewRel)),
+ RelationGetRelationName(matviewRel));
+
+ /*
+ * Build parts of the maintenance queries
+ */
+
+ initStringInfo(&querybuf);
+ initStringInfo(&target_list_buf);
+
+ /* build string of target list */
+ for (i = 0; i < matviewRel->rd_att->natts; i++)
+ {
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
+
+ if (i != 0)
+ appendStringInfo(&target_list_buf, ", ");
+ appendStringInfo(&target_list_buf, "%s", quote_qualified_identifier(NULL, resname));
+ }
+
+ i = 0;
+ foreach (lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+
+ i++;
+
+ if (tle->resjunk)
+ continue;
+
+ keys = lappend(keys, attr);
+ }
+
+ /* Start maintaining the materialized view. */
+ OpenMatViewIncrementalMaintenance();
+
+ /* Open SPI context. */
+ if (SPI_connect() != SPI_OK_CONNECT)
+ elog(ERROR, "SPI_connect failed");
+
+ /* For tuple deletion */
+ if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
+ {
+ EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ int rc;
+
+ /* convert tuplestores to ENR, and register for SPI */
+ enr->md.name = pstrdup(OLD_DELTA_ENRNAME);
+ enr->md.reliddesc = InvalidOid;
+ enr->md.tupdesc = tupdesc_old;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(old_tuplestores);
+ enr->reldata = old_tuplestores;
+
+ rc = SPI_register_relation(enr);
+ if (rc != SPI_OK_REL_REGISTER)
+ elog(ERROR, "SPI_register failed");
+
+ apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+
+ }
+ /* For tuple insertion */
+ if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
+ {
+ EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ int rc;
+
+ /* convert tuplestores to ENR, and register for SPI */
+ enr->md.name = pstrdup(NEW_DELTA_ENRNAME);
+ enr->md.reliddesc = InvalidOid;
+ enr->md.tupdesc = tupdesc_new;;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(new_tuplestores);
+ enr->reldata = new_tuplestores;
+
+ rc = SPI_register_relation(enr);
+ if (rc != SPI_OK_REL_REGISTER)
+ elog(ERROR, "SPI_register failed");
+
+ /* apply new delta */
+ apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
+ }
+
+ /* We're done maintaining the materialized view. */
+ CloseMatViewIncrementalMaintenance();
+
+ table_close(matviewRel, NoLock);
+
+ /* Close SPI context. */
+ if (SPI_finish() != SPI_OK_FINISH)
+ elog(ERROR, "SPI_finish failed");
+}
+
+/*
+ * apply_old_delta
+ *
+ * Execute a query for applying a delta table given by deltname_old
+ * which contains tuples to be deleted from to a materialized view given by
+ * matviewname. This is used when counting is not required.
+ */
+static void
+apply_old_delta(const char *matviewname, const char *deltaname_old,
+ List *keys)
+{
+ StringInfoData querybuf;
+ StringInfoData keysbuf;
+ char *match_cond;
+ ListCell *lc;
+
+ /* build WHERE condition for searching tuples to be deleted */
+ match_cond = get_matching_condition_string(keys);
+
+ /* build string of keys list */
+ initStringInfo(&keysbuf);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&keysbuf, "%s", quote_qualified_identifier("mv", resname));
+ if (lnext(keys, lc))
+ appendStringInfo(&keysbuf, ", ");
+ }
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "DELETE FROM %s WHERE ctid IN ("
+ "SELECT tid FROM (SELECT pg_catalog.row_number() over (partition by %s) AS \"__ivm_row_number__\","
+ "mv.ctid AS tid,"
+ "diff.\"__ivm_count__\""
+ "FROM %s AS mv, %s AS diff "
+ "WHERE %s) v "
+ "WHERE v.\"__ivm_row_number__\" OPERATOR(pg_catalog.<=) v.\"__ivm_count__\")",
+ matviewname,
+ keysbuf.data,
+ matviewname, deltaname_old,
+ match_cond);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
+/*
+ * apply_new_delta
+ *
+ * Execute a query for applying a delta table given by deltname_new
+ * which contains tuples to be inserted into a materialized view given by
+ * matviewname. This is used when counting is not required.
+ */
+static void
+apply_new_delta(const char *matviewname, const char *deltaname_new,
+ StringInfo target_list)
+{
+ StringInfoData querybuf;
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "INSERT INTO %s (%s) SELECT %s FROM ("
+ "SELECT diff.*, pg_catalog.generate_series(1, diff.\"__ivm_count__\")"
+ " AS __ivm_generate_series__ "
+ "FROM %s AS diff) AS v",
+ matviewname, target_list->data, target_list->data,
+ deltaname_new);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_INSERT)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
+/*
+ * get_matching_condition_string
+ *
+ * Build a predicate string for looking for a tuple with given keys.
+ */
+static char *
+get_matching_condition_string(List *keys)
+{
+ StringInfoData match_cond;
+ ListCell *lc;
+
+ /* If there is no key columns, the condition is always true. */
+ if (keys == NIL)
+ return "true";
+
+ initStringInfo(&match_cond);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ char *mv_resname = quote_qualified_identifier("mv", resname);
+ char *diff_resname = quote_qualified_identifier("diff", resname);
+ Oid typid = attr->atttypid;
+
+ /* Considering NULL values, we can not use simple = operator. */
+ appendStringInfo(&match_cond, "(");
+ generate_equal(&match_cond, typid, mv_resname, diff_resname);
+ appendStringInfo(&match_cond, " OR (%s IS NULL AND %s IS NULL))",
+ mv_resname, diff_resname);
+
+ if (lnext(keys, lc))
+ appendStringInfo(&match_cond, " AND ");
+ }
+
+ return match_cond.data;
+}
+
+/*
+ * generate_equals
+ *
+ * Generate an equality clause using given operands' default equality
+ * operator.
+ */
+static void
+generate_equal(StringInfo querybuf, Oid opttype,
+ const char *leftop, const char *rightop)
+{
+ TypeCacheEntry *typentry;
+
+ typentry = lookup_type_cache(opttype, TYPECACHE_EQ_OPR);
+ if (!OidIsValid(typentry->eq_opr))
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_FUNCTION),
+ errmsg("could not identify an equality operator for type %s",
+ format_type_be_qualified(opttype))));
+
+ generate_operator_clause(querybuf,
+ leftop, opttype,
+ typentry->eq_opr,
+ rightop, opttype);
+}
+
+/*
+ * mv_InitHashTables
+ */
+static void
+mv_InitHashTables(void)
+{
+ HASHCTL ctl;
+
+ memset(&ctl, 0, sizeof(ctl));
+ ctl.keysize = sizeof(Oid);
+ ctl.entrysize = sizeof(MV_TriggerHashEntry);
+ mv_trigger_info = hash_create("MV trigger info",
+ MV_INIT_QUERYHASHSIZE,
+ &ctl, HASH_ELEM | HASH_BLOBS);
+}
+
+/*
+ * AtAbort_IVM
+ *
+ * Clean up hash entries for all materialized views. This is called at
+ * transaction abort.
+ */
+void
+AtAbort_IVM()
+{
+ HASH_SEQ_STATUS seq;
+ MV_TriggerHashEntry *entry;
+
+ if (mv_trigger_info)
+ {
+ hash_seq_init(&seq, mv_trigger_info);
+ while ((entry = hash_seq_search(&seq)) != NULL)
+ clean_up_IVM_hash_entry(entry, true);
+ }
+ in_delta_calculation = false;
+}
+
+/*
+ * clean_up_IVM_hash_entry
+ *
+ * Clean up tuple stores and hash entries for a materialized view after its
+ * maintenance finished.
+ */
+static void
+clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort)
+{
+ bool found;
+ ListCell *lc;
+
+ foreach(lc, entry->tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc);
+
+ list_free(table->old_tuplestores);
+ list_free(table->new_tuplestores);
+ if (!is_abort)
+ {
+ ExecDropSingleTupleTableSlot(table->slot);
+ table_close(table->rel, NoLock);
+ }
+ }
+ list_free(entry->tables);
+
+ if (!is_abort)
+ UnregisterSnapshot(entry->snapshot);
+
+ hash_search(mv_trigger_info, (void *) &entry->matview_id, HASH_REMOVE, &found);
+}
+
+/*
+ * isIvmName
+ *
+ * Check if this is a IVM hidden column from the name.
+ */
+bool
+isIvmName(const char *s)
+{
+ if (s)
+ return (strncmp(s, "__ivm_", 6) == 0);
+ return false;
+}
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index 9805bc6118..f6896d77b4 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -12062,4 +12062,14 @@
proname => 'any_value_transfn', prorettype => 'anyelement',
proargtypes => 'anyelement anyelement', prosrc => 'any_value_transfn' },
+# IVM
+{ oid => '786', descr => 'ivm trigger (before)',
+ proname => 'IVM_immediate_before', provolatile => 'v', prorettype => 'trigger',
+ proargtypes => '', prosrc => 'IVM_immediate_before' },
+{ oid => '787', descr => 'ivm trigger (after)',
+ proname => 'IVM_immediate_maintenance', provolatile => 'v', prorettype => 'trigger',
+ proargtypes => '', prosrc => 'IVM_immediate_maintenance' },
+{ oid => '788', descr => 'ivm filetring ',
+ proname => 'ivm_visible_in_prestate', provolatile => 's', prorettype => 'bool',
+ proargtypes => 'oid tid oid', prosrc => 'ivm_visible_in_prestate' },
]
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 3647f96f73..09a64fa2e5 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -16,6 +16,7 @@
#include "catalog/objectaddress.h"
#include "nodes/params.h"
+#include "nodes/pathnodes.h"
#include "parser/parse_node.h"
#include "tcop/dest.h"
#include "utils/queryenvironment.h"
@@ -25,6 +26,9 @@ extern ObjectAddress ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *st
ParamListInfo params, QueryEnvironment *queryEnv,
QueryCompletion *qc);
+extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
+extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
+
extern int GetIntoRelEFlags(IntoClause *intoClause);
extern DestReceiver *CreateIntoRelDestReceiver(IntoClause *intoClause);
diff --git a/src/include/commands/matview.h b/src/include/commands/matview.h
index 9eaa6212a1..504b83a446 100644
--- a/src/include/commands/matview.h
+++ b/src/include/commands/matview.h
@@ -15,6 +15,7 @@
#define MATVIEW_H
#include "catalog/objectaddress.h"
+#include "fmgr.h"
#include "nodes/params.h"
#include "nodes/parsenodes.h"
#include "tcop/dest.h"
@@ -23,6 +24,8 @@
extern void SetMatViewPopulatedState(Relation relation, bool newstate);
+extern void SetMatViewIVMState(Relation relation, bool newstate);
+
extern ObjectAddress ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
ParamListInfo params, QueryCompletion *qc);
@@ -30,4 +33,10 @@ extern DestReceiver *CreateTransientRelDestReceiver(Oid transientoid);
extern bool MatViewIncrementalMaintenanceIsEnabled(void);
+extern Datum IVM_immediate_before(PG_FUNCTION_ARGS);
+extern Datum IVM_immediate_maintenance(PG_FUNCTION_ARGS);
+extern Datum IVM_visible_in_prestate(PG_FUNCTION_ARGS);
+extern void AtAbort_IVM(void);
+extern bool isIvmName(const char *s);
+
#endif /* MATVIEW_H */
--
2.25.1
v29-0007-Add-DISTINCT-support-for-IVM.patchtext/x-diff; name=v29-0007-Add-DISTINCT-support-for-IVM.patchDownload
From 10e7fcf2213e310443f751df05daab05d36286cd Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 19:08:51 +0900
Subject: [PATCH v29 07/11] Add DISTINCT support for IVM
When IMMV is created with DISTINCT, multiplicity of tuples is
counted and stored in "__ivm_count__" column, which is a hidden
column of IMMV. The value in __ivm_count__ is updated when IMMV
is maintained incrementally. A tuple in IMMV can be removed if
and only if the count becomes zero.
---
src/backend/commands/createas.c | 141 ++++++++++++++++++++------
src/backend/commands/indexcmds.c | 40 ++++++++
src/backend/commands/matview.c | 148 ++++++++++++++++++++++++++--
src/backend/commands/tablecmds.c | 9 ++
src/backend/parser/parse_relation.c | 18 +++-
src/backend/rewrite/rewriteDefine.c | 3 +-
src/include/commands/createas.h | 2 +
src/include/nodes/parsenodes.h | 1 +
8 files changed, 317 insertions(+), 45 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index 415f110516..076f35ee6b 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -53,6 +53,7 @@
#include "parser/parser.h"
#include "parser/parsetree.h"
#include "parser/parse_clause.h"
+#include "parser/parse_func.h"
#include "rewrite/rewriteHandler.h"
#include "storage/smgr.h"
#include "tcop/tcopprot.h"
@@ -309,6 +310,9 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
errhint("functions must be marked IMMUTABLE")));
check_ivm_restriction((Node *) query);
+
+ /* For IMMV, we need to rewrite matview query */
+ query = rewriteQueryForIMMV(query, into->colNames);
}
if (into->skipData)
@@ -413,6 +417,49 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
return address;
}
+/*
+ * rewriteQueryForIMMV -- rewrite view definition query for IMMV
+ *
+ * count(*) is added for counting distinct tuples in views.
+ */
+Query *
+rewriteQueryForIMMV(Query *query, List *colNames)
+{
+ Query *rewritten;
+
+ Node *node;
+ ParseState *pstate = make_parsestate(NULL);
+ FuncCall *fn;
+
+ rewritten = copyObject(query);
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ /*
+ * Convert DISTINCT to GROUP BY and add count(*) for counting distinct
+ * tuples in views.
+ */
+ if (rewritten->distinctClause)
+ {
+ TargetEntry *tle;
+
+ rewritten->groupClause = transformDistinctClause(NULL, &rewritten->targetList, rewritten->sortClause, false);
+
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+ fn->agg_star = true;
+
+ node = ParseFuncOrColumn(pstate, fn->funcname, NIL, NULL, fn, false, -1);
+
+ tle = makeTargetEntry((Expr *) node,
+ list_length(rewritten->targetList) + 1,
+ pstrdup("__ivm_count__"),
+ false);
+ rewritten->targetList = lappend(rewritten->targetList, tle);
+ rewritten->hasAggs = true;
+ }
+
+ return rewritten;
+}
+
/*
* GetIntoRelEFlags --- compute executor flags needed for CREATE TABLE AS
*
@@ -536,7 +583,8 @@ intorel_startup(DestReceiver *self, int operation, TupleDesc typeinfo)
ColumnDef *col;
char *colname;
- if (lc)
+ /* Don't override hidden columns added for IVM */
+ if (lc && !isIvmName(NameStr(attribute->attname)))
{
colname = strVal(lfirst(lc));
lc = lnext(into->colNames, lc);
@@ -940,10 +988,6 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view")));
- if (qry->distinctClause)
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("DISTINCT is not supported on incrementally maintainable materialized view")));
if (qry->hasDistinctOn)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
@@ -1090,12 +1134,18 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
char idxname[NAMEDATALEN];
List *indexoidlist = RelationGetIndexList(matviewRel);
ListCell *indexoidscan;
- Bitmapset *key_attnos;
snprintf(idxname, sizeof(idxname), "%s_index", RelationGetRelationName(matviewRel));
index = makeNode(IndexStmt);
+ /*
+ * We consider null values not distinct to make sure that views with DISTINCT
+ * or GROUP BY don't contain multiple NULL rows when NULL is inserted to
+ * a base table concurrently.
+ */
+ index->nulls_not_distinct = true;
+
index->unique = true;
index->primary = false;
index->isconstraint = false;
@@ -1122,41 +1172,68 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
index->concurrent = false;
index->if_not_exists = false;
- /* create index on the base tables' primary key columns */
- key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
- if (key_attnos)
+ if (query->distinctClause)
{
+ /* create unique constraint on all columns */
foreach(lc, query->targetList)
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
-
- if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
- {
- IndexElem *iparam;
-
- iparam = makeNode(IndexElem);
- iparam->name = pstrdup(NameStr(attr->attname));
- iparam->expr = NULL;
- iparam->indexcolname = NULL;
- iparam->collation = NIL;
- iparam->opclass = NIL;
- iparam->opclassopts = NIL;
- iparam->ordering = SORTBY_DEFAULT;
- iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
- index->indexParams = lappend(index->indexParams, iparam);
- }
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
}
}
else
{
- /* create no index, just notice that an appropriate index is necessary for efficient IVM */
- ereport(NOTICE,
- (errmsg("could not create an index on materialized view \"%s\" automatically",
- RelationGetRelationName(matviewRel)),
- errdetail("This target list does not have all the primary key columns. "),
- errhint("Create an index on the materialized view for efficient incremental maintenance.")));
- return;
+ Bitmapset *key_attnos;
+
+ /* create index on the base tables' primary key columns */
+ key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
+ if (key_attnos)
+ {
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ }
+ else
+ {
+ /* create no index, just notice that an appropriate index is necessary for efficient IVM */
+ ereport(NOTICE,
+ (errmsg("could not create an index on materialized view \"%s\" automatically",
+ RelationGetRelationName(matviewRel)),
+ errdetail("This target list does not have all the primary key columns, "
+ "or this view does not contain DISTINCT clause."),
+ errhint("Create an index on the materialized view for efficient incremental maintenance.")));
+ return;
+ }
}
/* If we have a compatible index, we don't need to create another. */
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index ab8b81b302..4811a1c8df 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -38,6 +38,7 @@
#include "commands/dbcommands.h"
#include "commands/defrem.h"
#include "commands/event_trigger.h"
+#include "commands/matview.h"
#include "commands/progress.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
@@ -1104,6 +1105,45 @@ DefineIndex(Oid tableId,
safe_index = indexInfo->ii_Expressions == NIL &&
indexInfo->ii_Predicate == NIL;
+ /*
+ * We disallow unique indexes on IVM columns of IMMVs.
+ */
+ if (RelationIsIVM(rel) && stmt->unique)
+ {
+ for (int i = 0; i < indexInfo->ii_NumIndexKeyAttrs; i++)
+ {
+ AttrNumber attno = indexInfo->ii_IndexAttrNumbers[i];
+ if (attno > 0)
+ {
+ char *name = NameStr(TupleDescAttr(rel->rd_att, attno - 1)->attname);
+ if (name && isIvmName(name))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("unique index creation on IVM columns is not supported")));
+ }
+ }
+
+ if (indexInfo->ii_Expressions)
+ {
+ Bitmapset *indexattrs = NULL;
+ int varno = -1;
+
+ pull_varattnos((Node *) indexInfo->ii_Expressions, 1, &indexattrs);
+
+ while ((varno = bms_next_member(indexattrs, varno)) >= 0)
+ {
+ int attno = varno + FirstLowInvalidHeapAttributeNumber;
+ char *name = NameStr(TupleDescAttr(rel->rd_att, attno - 1)->attname);
+ if (name && isIvmName(name))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("unique index creation on IVM columns is not supported")));
+ }
+
+ }
+ }
+
+
/*
* Report index creation if appropriate (delay this till after most of the
* error checks)
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index 39305f3c49..aa518f20ef 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -152,11 +152,15 @@ static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *
static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
- Query *query);
+ Query *query, bool use_count, char *count_colname);
static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
+static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
+ List *keys, const char *count_colname);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
+static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
+ List *keys, StringInfo target_list, const char* count_colname);
static char *get_matching_condition_string(List *keys);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
@@ -271,6 +275,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
Oid matviewOid;
Relation matviewRel;
Query *dataQuery;
+ Query *viewQuery;
Oid tableSpace;
Oid relowner;
Oid OIDNewHeap;
@@ -330,8 +335,13 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
"CONCURRENTLY", "WITH NO DATA")));
- dataQuery = get_matview_query(matviewRel);
+ viewQuery = get_matview_query(matviewRel);
+ /* For IMMV, we need to rewrite matview query */
+ if (!stmt->skipData && RelationIsIVM(matviewRel))
+ dataQuery = rewriteQueryForIMMV(viewQuery,NIL);
+ else
+ dataQuery = viewQuery;
/*
* Check that there is a unique index with no WHERE clause on one or more
@@ -511,8 +521,8 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
if (!stmt->skipData && RelationIsIVM(matviewRel) && !oldPopulated)
{
- CreateIndexOnIMMV(dataQuery, matviewRel);
- CreateIvmTriggersOnBaseTables(dataQuery, matviewOid);
+ CreateIndexOnIMMV(viewQuery, matviewRel);
+ CreateIvmTriggersOnBaseTables(viewQuery, matviewOid);
}
table_close(matviewRel, NoLock);
@@ -1512,6 +1522,13 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
int rte_index = lfirst_int(lc2);
TupleDesc tupdesc_old;
TupleDesc tupdesc_new;
+ bool use_count = false;
+ char *count_colname = NULL;
+
+ count_colname = pstrdup("__ivm_count__");
+
+ if (query->distinctClause)
+ use_count = true;
/* calculate delta tables */
calc_delta(table, rte_index, rewritten, dest_old, dest_new,
@@ -1524,7 +1541,8 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
{
/* apply the delta tables to the materialized view */
apply_delta(matviewOid, old_tuplestore, new_tuplestore,
- tupdesc_old, tupdesc_new, query);
+ tupdesc_old, tupdesc_new, query, use_count,
+ count_colname);
}
PG_CATCH();
{
@@ -1997,7 +2015,7 @@ rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte
static void
apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
- Query *query)
+ Query *query, bool use_count, char *count_colname)
{
StringInfoData querybuf;
StringInfoData target_list_buf;
@@ -2073,7 +2091,12 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (rc != SPI_OK_REL_REGISTER)
elog(ERROR, "SPI_register failed");
- apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+ if (use_count)
+ /* apply old delta and get rows to be recalculated */
+ apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
+ keys, count_colname);
+ else
+ apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
}
/* For tuple insertion */
@@ -2095,7 +2118,11 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_register failed");
/* apply new delta */
- apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
+ if (use_count)
+ apply_new_delta_with_count(matviewname, NEW_DELTA_ENRNAME,
+ keys, &target_list_buf, count_colname);
+ else
+ apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
}
/* We're done maintaining the materialized view. */
@@ -2108,6 +2135,51 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_finish failed");
}
+/*
+ * apply_old_delta_with_count
+ *
+ * Execute a query for applying a delta table given by deltname_old
+ * which contains tuples to be deleted from to a materialized view given by
+ * matviewname. This is used when counting is required, that is, the view
+ * has aggregate or distinct.
+ */
+static void
+apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
+ List *keys, const char *count_colname)
+{
+ StringInfoData querybuf;
+ char *match_cond;
+
+ /* build WHERE condition for searching tuples to be deleted */
+ match_cond = get_matching_condition_string(keys);
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "WITH t AS (" /* collecting tid of target tuples in the view */
+ "SELECT diff.%s, " /* count column */
+ "(diff.%s OPERATOR(pg_catalog.=) mv.%s) AS for_dlt, "
+ "mv.ctid "
+ "FROM %s AS mv, %s AS diff "
+ "WHERE %s" /* tuple matching condition */
+ "), updt AS (" /* update a tuple if this is not to be deleted */
+ "UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
+ "FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
+ ")"
+ /* delete a tuple if this is to be deleted */
+ "DELETE FROM %s AS mv USING t "
+ "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
+ count_colname,
+ count_colname, count_colname,
+ matviewname, deltaname_old,
+ match_cond,
+ matviewname, count_colname, count_colname, count_colname,
+ matviewname);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
/*
* apply_old_delta
*
@@ -2157,6 +2229,66 @@ apply_old_delta(const char *matviewname, const char *deltaname_old,
elog(ERROR, "SPI_exec failed: %s", querybuf.data);
}
+/*
+ * apply_new_delta_with_count
+ *
+ * Execute a query for applying a delta table given by deltname_new
+ * which contains tuples to be inserted into a materialized view given by
+ * matviewname. This is used when counting is required, that is, the view
+ * has aggregate or distinct. Also, when a table in EXISTS sub queries
+ * is modified.
+ */
+static void
+apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
+ List *keys, StringInfo target_list, const char* count_colname)
+{
+ StringInfoData querybuf;
+ StringInfoData returning_keys;
+ ListCell *lc;
+ char *match_cond = "";
+
+ /* build WHERE condition for searching tuples to be updated */
+ match_cond = get_matching_condition_string(keys);
+
+ /* build string of keys list */
+ initStringInfo(&returning_keys);
+ if (keys)
+ {
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&returning_keys, "%s", quote_qualified_identifier("mv", resname));
+ if (lnext(keys, lc))
+ appendStringInfo(&returning_keys, ", ");
+ }
+ }
+ else
+ appendStringInfo(&returning_keys, "NULL");
+
+ /* Search for matching tuples from the view and update if found or insert if not. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "WITH updt AS (" /* update a tuple if this exists in the view */
+ "UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.+) diff.%s "
+ "FROM %s AS diff "
+ "WHERE %s " /* tuple matching condition */
+ "RETURNING %s" /* returning keys of updated tuples */
+ ") INSERT INTO %s (%s) " /* insert a new tuple if this doesn't exist */
+ "SELECT %s FROM %s AS diff "
+ "WHERE NOT EXISTS (SELECT 1 FROM updt AS mv WHERE %s);",
+ matviewname, count_colname, count_colname, count_colname,
+ deltaname_new,
+ match_cond,
+ returning_keys.data,
+ matviewname, target_list->data,
+ target_list->data, deltaname_new,
+ match_cond);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_INSERT)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
/*
* apply_new_delta
*
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 47c900445c..adbd768e0d 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -53,6 +53,7 @@
#include "commands/cluster.h"
#include "commands/comment.h"
#include "commands/defrem.h"
+#include "commands/matview.h"
#include "commands/event_trigger.h"
#include "commands/policy.h"
#include "commands/sequence.h"
@@ -3673,6 +3674,14 @@ renameatt_internal(Oid myrelid,
targetrelation = relation_open(myrelid, AccessExclusiveLock);
renameatt_check(myrelid, RelationGetForm(targetrelation), recursing);
+ /*
+ * Don't rename IVM columns.
+ */
+ if (RelationIsIVM(targetrelation) && isIvmName(oldattname))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("IVM column can not be renamed")));
+
/*
* if the 'recurse' flag is set then we are supposed to rename this
* attribute in all classes that inherit from 'relname' (as well as in
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index 864ea9b0d5..c257440414 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -36,6 +36,7 @@
#include "utils/rel.h"
#include "utils/syscache.h"
#include "utils/varlena.h"
+#include "commands/matview.h"
/*
@@ -97,7 +98,7 @@ static void expandTupleDesc(TupleDesc tupdesc, Alias *eref,
int count, int offset,
int rtindex, int sublevels_up,
int location, bool include_dropped,
- List **colnames, List **colvars);
+ List **colnames, List **colvars, bool is_ivm);
static int specialAttNum(const char *attname);
static bool rte_visible_if_lateral(ParseState *pstate, RangeTblEntry *rte);
static bool rte_visible_if_qualified(ParseState *pstate, RangeTblEntry *rte);
@@ -1502,6 +1503,7 @@ addRangeTableEntry(ParseState *pstate,
rte->relid = RelationGetRelid(rel);
rte->relkind = rel->rd_rel->relkind;
rte->rellockmode = lockmode;
+ rte->relisivm = rel->rd_rel->relisivm;
/*
* Build the list of effective column names using user-supplied aliases
@@ -1587,6 +1589,7 @@ addRangeTableEntryForRelation(ParseState *pstate,
rte->relid = RelationGetRelid(rel);
rte->relkind = rel->rd_rel->relkind;
rte->rellockmode = lockmode;
+ rte->relisivm = rel->rd_rel->relisivm;
/*
* Build the list of effective column names using user-supplied aliases
@@ -2758,7 +2761,7 @@ expandRTE(RangeTblEntry *rte, int rtindex, int sublevels_up,
expandTupleDesc(tupdesc, rte->eref,
rtfunc->funccolcount, atts_done,
rtindex, sublevels_up, location,
- include_dropped, colnames, colvars);
+ include_dropped, colnames, colvars, false);
}
else if (functypclass == TYPEFUNC_SCALAR)
{
@@ -3026,7 +3029,7 @@ expandRelation(Oid relid, Alias *eref, int rtindex, int sublevels_up,
expandTupleDesc(rel->rd_att, eref, rel->rd_att->natts, 0,
rtindex, sublevels_up,
location, include_dropped,
- colnames, colvars);
+ colnames, colvars, RelationIsIVM(rel));
relation_close(rel, AccessShareLock);
}
@@ -3043,7 +3046,7 @@ static void
expandTupleDesc(TupleDesc tupdesc, Alias *eref, int count, int offset,
int rtindex, int sublevels_up,
int location, bool include_dropped,
- List **colnames, List **colvars)
+ List **colnames, List **colvars, bool is_ivm)
{
ListCell *aliascell;
int varattno;
@@ -3056,6 +3059,9 @@ expandTupleDesc(TupleDesc tupdesc, Alias *eref, int count, int offset,
{
Form_pg_attribute attr = TupleDescAttr(tupdesc, varattno);
+ if (is_ivm && isIvmName(NameStr(attr->attname)) && !MatViewIncrementalMaintenanceIsEnabled())
+ continue;
+
if (attr->attisdropped)
{
if (include_dropped)
@@ -3218,6 +3224,10 @@ expandNSItemAttrs(ParseState *pstate, ParseNamespaceItem *nsitem,
Var *varnode = (Var *) lfirst(var);
TargetEntry *te;
+ /* if transform * into columnlist with IMMV, remove IVM columns */
+ if (rte->relisivm && isIvmName(label) && !MatViewIncrementalMaintenanceIsEnabled())
+ continue;
+
te = makeTargetEntry((Expr *) varnode,
(AttrNumber) pstate->p_next_resno++,
label,
diff --git a/src/backend/rewrite/rewriteDefine.c b/src/backend/rewrite/rewriteDefine.c
index e36fc72e1e..f6dc7ba202 100644
--- a/src/backend/rewrite/rewriteDefine.c
+++ b/src/backend/rewrite/rewriteDefine.c
@@ -621,7 +621,8 @@ checkRuleResultList(List *targetList, TupleDesc resultDesc, bool isSelect,
attr->atttypmod))));
}
- if (i != resultDesc->natts)
+ /* No check for materialized views since this could have special columns for IVM */
+ if ((!isSelect || requireColumnNameMatch) && i != resultDesc->natts)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
isSelect ?
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 09a64fa2e5..76a7873ebf 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -29,6 +29,8 @@ extern ObjectAddress ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *st
extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
+extern Query *rewriteQueryForIMMV(Query *query, List *colNames);
+
extern int GetIntoRelEFlags(IntoClause *intoClause);
extern DestReceiver *CreateIntoRelDestReceiver(IntoClause *intoClause);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index fef4c714b8..1a2b8fa09e 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1073,6 +1073,7 @@ typedef struct RangeTblEntry
int rellockmode; /* lock level that query requires on the rel */
struct TableSampleClause *tablesample; /* sampling info, or NULL */
Index perminfoindex;
+ bool relisivm;
/*
* Fields valid for a subquery RTE (else NULL):
--
2.25.1
v29-0008-Add-aggregates-support-in-IVM.patchtext/x-diff; name=v29-0008-Add-aggregates-support-in-IVM.patchDownload
From e631c43c5a5d7d6b58fcf655d8f69a61a976647f Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 20:46:32 +0900
Subject: [PATCH v29 08/11] Add aggregates support in IVM
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit
count, sum, adn avg are supported.
As a restriction, expressions specified in GROUP BY must appear in
the target list because tuples to be updated in IMMV are identified
by using this group key. However, in the case of aggregates without
GROUP BY, there is only one tuple in the view, so keys are not uses
to identify tuples.
When creating a IMMV, in addition to __ivm_count column, some hidden
columns for each aggregate are added to the target list. For example,
names of these hidden columns are ivm_count_avg and ivm_sum_avg for
the average function, and so on.
When a base table is modified, the aggregated values and related
hidden columns are also updated as well as __ivm_count__. The
way of update depends the kind of aggregate function. Specifically,
sum and count are updated by simply adding or subtracting delta value
calculated from delta tables. avg is updated by using values of sum
and count stored in views as hidden columns and deltas calculated
from delta tables.
About aggregate functions except "count()" (sum and avg), NULLs in input
values are ignored, and the result of aggegate should be NULL when no
rows are selected. To support this specification, the numbers of non-NULL
input values are counted and stored in hidden columns. In the case of
count(), count(x) returns zero when no rows are selected, but count(*)
doesn't ignore NULL input.
---
src/backend/commands/createas.c | 264 +++++++++++++++++--
src/backend/commands/matview.c | 433 ++++++++++++++++++++++++++++++--
src/include/commands/createas.h | 1 +
3 files changed, 661 insertions(+), 37 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index 076f35ee6b..c8aa558f2e 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -54,14 +54,19 @@
#include "parser/parsetree.h"
#include "parser/parse_clause.h"
#include "parser/parse_func.h"
+#include "parser/parse_type.h"
#include "rewrite/rewriteHandler.h"
+#include "rewrite/rewriteManip.h"
#include "storage/smgr.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
#include "utils/lsyscache.h"
+#include "utils/regproc.h"
+#include "utils/fmgroids.h"
#include "utils/rel.h"
#include "utils/rls.h"
#include "utils/snapmgr.h"
+#include "utils/syscache.h"
typedef struct
{
@@ -75,6 +80,11 @@ typedef struct
BulkInsertState bistate; /* bulk insert state */
} DR_intorel;
+typedef struct
+{
+ bool has_agg;
+} check_ivm_restriction_context;
+
/* utility functions for CTAS definition creation */
static ObjectAddress create_ctas_internal(List *attrList, IntoClause *into);
static ObjectAddress create_ctas_nodata(List *tlist, IntoClause *into);
@@ -89,8 +99,9 @@ static void CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid mat
Relids *relids, bool ex_lock);
static void CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock);
static void check_ivm_restriction(Node *node);
-static bool check_ivm_restriction_walker(Node *node, void *context);
+static bool check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context);
static Bitmapset *get_primary_key_attnos_from_query(Query *query, List **constraintList);
+static bool check_aggregate_supports_ivm(Oid aggfnoid);
/*
* create_ctas_internal
@@ -421,6 +432,7 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
* rewriteQueryForIMMV -- rewrite view definition query for IMMV
*
* count(*) is added for counting distinct tuples in views.
+ * Also, additional hidden columns are added for aggregate values.
*/
Query *
rewriteQueryForIMMV(Query *query, List *colNames)
@@ -434,16 +446,49 @@ rewriteQueryForIMMV(Query *query, List *colNames)
rewritten = copyObject(query);
pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
- /*
- * Convert DISTINCT to GROUP BY and add count(*) for counting distinct
- * tuples in views.
- */
- if (rewritten->distinctClause)
+ /* group keys must be in targetlist */
+ if (rewritten->groupClause)
{
- TargetEntry *tle;
+ ListCell *lc;
+ foreach(lc, rewritten->groupClause)
+ {
+ SortGroupClause *scl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(scl, rewritten->targetList);
+ if (tle->resjunk)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUP BY expression not appearing in select list is not supported on incrementally maintainable materialized view")));
+ }
+ }
+ /* Convert DISTINCT to GROUP BY. count(*) will be added afterward. */
+ else if (!rewritten->hasAggs && rewritten->distinctClause)
rewritten->groupClause = transformDistinctClause(NULL, &rewritten->targetList, rewritten->sortClause, false);
+ /* Add additional columns for aggregate values */
+ if (rewritten->hasAggs)
+ {
+ ListCell *lc;
+ List *aggs = NIL;
+ AttrNumber next_resno = list_length(rewritten->targetList) + 1;
+
+ foreach(lc, rewritten->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ char *resname = (colNames == NIL || foreach_current_index(lc) >= list_length(colNames) ?
+ tle->resname : strVal(list_nth(colNames, tle->resno - 1)));
+
+ if (IsA(tle->expr, Aggref))
+ makeIvmAggColumn(pstate, (Aggref *) tle->expr, resname, &next_resno, &aggs);
+ }
+ rewritten->targetList = list_concat(rewritten->targetList, aggs);
+ }
+
+ /* Add count(*) for counting distinct tuples in views */
+ if (rewritten->distinctClause || rewritten->hasAggs)
+ {
+ TargetEntry *tle;
+
fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
fn->agg_star = true;
@@ -460,6 +505,91 @@ rewriteQueryForIMMV(Query *query, List *colNames)
return rewritten;
}
+/*
+ * makeIvmAggColumn -- make additional aggregate columns for IVM
+ *
+ * For an aggregate column specified by aggref, additional aggregate columns
+ * are added, which are used to calculate the new aggregate value in IMMV.
+ * An additional aggregate columns has a name based on resname
+ * (ex. ivm_count_resname), and resno specified by next_resno. The created
+ * columns are returned to aggs, and the resno for the next column is also
+ * returned to next_resno.
+ *
+ * Currently, an additional count() is created for aggref other than count.
+ * In addition, sum() is created for avg aggregate column.
+ */
+void
+makeIvmAggColumn(ParseState *pstate, Aggref *aggref, char *resname, AttrNumber *next_resno, List **aggs)
+{
+ TargetEntry *tle_count;
+ Node *node;
+ FuncCall *fn;
+ Const *dmy_arg = makeConst(INT4OID,
+ -1,
+ InvalidOid,
+ sizeof(int32),
+ Int32GetDatum(1),
+ false,
+ true); /* pass by value */
+ const char *aggname = get_func_name(aggref->aggfnoid);
+
+ /*
+ * For aggregate functions except count, add count() func with the same arg parameters.
+ * This count result is used for determining if the aggregate value should be NULL or not.
+ * Also, add sum() func for avg because we need to calculate an average value as sum/count.
+ *
+ * XXX: If there are same expressions explicitly in the target list, we can use this instead
+ * of adding new duplicated one.
+ */
+ if (strcmp(aggname, "count") != 0)
+ {
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+
+ /* Make a Func with a dummy arg, and then override this by the original agg's args. */
+ node = ParseFuncOrColumn(pstate, fn->funcname, list_make1(dmy_arg), NULL, fn, false, -1);
+ ((Aggref *)node)->args = aggref->args;
+
+ tle_count = makeTargetEntry((Expr *) node,
+ *next_resno,
+ pstrdup(makeObjectName("__ivm_count",resname, "_")),
+ false);
+ *aggs = lappend(*aggs, tle_count);
+ (*next_resno)++;
+ }
+ if (strcmp(aggname, "avg") == 0)
+ {
+ List *dmy_args = NIL;
+ ListCell *lc;
+ foreach(lc, aggref->aggargtypes)
+ {
+ Oid typeid = lfirst_oid(lc);
+ Type type = typeidType(typeid);
+
+ Const *con = makeConst(typeid,
+ -1,
+ typeTypeCollation(type),
+ typeLen(type),
+ (Datum) 0,
+ true,
+ typeByVal(type));
+ dmy_args = lappend(dmy_args, con);
+ ReleaseSysCache(type);
+ }
+ fn = makeFuncCall(SystemFuncName("sum"), NIL, COERCE_EXPLICIT_CALL, -1);
+
+ /* Make a Func with dummy args, and then override this by the original agg's args. */
+ node = ParseFuncOrColumn(pstate, fn->funcname, dmy_args, NULL, fn, false, -1);
+ ((Aggref *)node)->args = aggref->args;
+
+ tle_count = makeTargetEntry((Expr *) node,
+ *next_resno,
+ pstrdup(makeObjectName("__ivm_sum",resname, "_")),
+ false);
+ *aggs = lappend(*aggs, tle_count);
+ (*next_resno)++;
+ }
+}
+
/*
* GetIntoRelEFlags --- compute executor flags needed for CREATE TABLE AS
*
@@ -943,11 +1073,13 @@ CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock
static void
check_ivm_restriction(Node *node)
{
- check_ivm_restriction_walker(node, NULL);
+ check_ivm_restriction_context context = {false};
+
+ check_ivm_restriction_walker(node, &context);
}
static bool
-check_ivm_restriction_walker(Node *node, void *context)
+check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context)
{
if (node == NULL)
return false;
@@ -976,6 +1108,10 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("CTE is not supported on incrementally maintainable materialized view")));
+ if (qry->groupClause != NIL && !qry->hasAggs)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUP BY clause without aggregate is not supported on incrementally maintainable materialized view")));
if (qry->havingQual != NULL)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
@@ -1028,6 +1164,8 @@ check_ivm_restriction_walker(Node *node, void *context)
}
}
+ context->has_agg |= qry->hasAggs;
+
/* restrictions for rtable */
foreach(lc, qry->rtable)
{
@@ -1076,7 +1214,7 @@ check_ivm_restriction_walker(Node *node, void *context)
}
- query_tree_walker(qry, check_ivm_restriction_walker, NULL, QTW_IGNORE_RANGE_TABLE);
+ query_tree_walker(qry, check_ivm_restriction_walker, (void *) context, QTW_IGNORE_RANGE_TABLE);
break;
}
@@ -1087,8 +1225,12 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("column name %s is not supported on incrementally maintainable materialized view", tle->resname)));
+ if (context->has_agg && !IsA(tle->expr, Aggref) && contain_aggs_of_level((Node *) tle->expr, 0))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("expression containing an aggregate in it is not supported on incrementally maintainable materialized view")));
- expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
break;
}
case T_JoinExpr:
@@ -1100,14 +1242,36 @@ check_ivm_restriction_walker(Node *node, void *context)
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("OUTER JOIN is not supported on incrementally maintainable materialized view")));
- expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
+ break;
}
- break;
case T_Aggref:
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("aggregate function is not supported on incrementally maintainable materialized view")));
- break;
+ {
+ /* Check if this supports IVM */
+ Aggref *aggref = (Aggref *) node;
+ const char *aggname = format_procedure(aggref->aggfnoid);
+
+ if (aggref->aggfilter != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with FILTER clause is not supported on incrementally maintainable materialized view")));
+
+ if (aggref->aggdistinct != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with DISTINCT arguments is not supported on incrementally maintainable materialized view")));
+
+ if (aggref->aggorder != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with ORDER clause is not supported on incrementally maintainable materialized view")));
+
+ if (!check_aggregate_supports_ivm(aggref->aggfnoid))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function %s is not supported on incrementally maintainable materialized view", aggname)));
+ break;
+ }
default:
expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
break;
@@ -1115,6 +1279,46 @@ check_ivm_restriction_walker(Node *node, void *context)
return false;
}
+/*
+ * check_aggregate_supports_ivm
+ *
+ * Check if the given aggregate function is supporting IVM
+ */
+static bool
+check_aggregate_supports_ivm(Oid aggfnoid)
+{
+ switch (aggfnoid)
+ {
+ /* count */
+ case F_COUNT_ANY:
+ case F_COUNT_:
+
+ /* sum */
+ case F_SUM_INT8:
+ case F_SUM_INT4:
+ case F_SUM_INT2:
+ case F_SUM_FLOAT4:
+ case F_SUM_FLOAT8:
+ case F_SUM_MONEY:
+ case F_SUM_INTERVAL:
+ case F_SUM_NUMERIC:
+
+ /* avg */
+ case F_AVG_INT8:
+ case F_AVG_INT4:
+ case F_AVG_INT2:
+ case F_AVG_NUMERIC:
+ case F_AVG_FLOAT4:
+ case F_AVG_FLOAT8:
+ case F_AVG_INTERVAL:
+
+ return true;
+
+ default:
+ return false;
+ }
+}
+
/*
* CreateIndexOnIMMV
*
@@ -1172,7 +1376,29 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
index->concurrent = false;
index->if_not_exists = false;
- if (query->distinctClause)
+ if (query->groupClause)
+ {
+ /* create unique constraint on GROUP BY expression columns */
+ foreach(lc, query->groupClause)
+ {
+ SortGroupClause *scl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(scl, query->targetList);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ else if (query->distinctClause)
{
/* create unique constraint on all columns */
foreach(lc, query->targetList)
@@ -1230,7 +1456,7 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
(errmsg("could not create an index on materialized view \"%s\" automatically",
RelationGetRelationName(matviewRel)),
errdetail("This target list does not have all the primary key columns, "
- "or this view does not contain DISTINCT clause."),
+ "or this view does not contain GROUP BY or DISTINCT clause."),
errhint("Create an index on the materialized view for efficient incremental maintenance.")));
return;
}
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index aa518f20ef..ee41f0007d 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -30,6 +30,7 @@
#include "catalog/pg_opclass.h"
#include "catalog/pg_operator.h"
#include "commands/cluster.h"
+#include "commands/defrem.h"
#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
@@ -39,6 +40,7 @@
#include "executor/tstoreReceiver.h"
#include "miscadmin.h"
#include "nodes/makefuncs.h"
+#include "optimizer/optimizer.h"
#include "parser/analyze.h"
#include "parser/parse_clause.h"
#include "parser/parse_func.h"
@@ -111,6 +113,13 @@ static HTAB *mv_trigger_info = NULL;
static bool in_delta_calculation = false;
+/* kind of IVM operation for the view */
+typedef enum
+{
+ IVM_ADD,
+ IVM_SUB
+} IvmOp;
+
/* ENR name for materialized view delta */
#define NEW_DELTA_ENRNAME "new_delta"
#define OLD_DELTA_ENRNAME "old_delta"
@@ -142,7 +151,7 @@ static RangeTblEntry *get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *tabl
QueryEnvironment *queryEnv, Oid matviewid);
static RangeTblEntry *replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
QueryEnvironment *queryEnv);
-static Query *rewrite_query_for_counting(Query *query, ParseState *pstate);
+static Query *rewrite_query_for_counting_and_aggregates(Query *query, ParseState *pstate);
static void calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
DestReceiver *dest_old, DestReceiver *dest_new,
@@ -153,14 +162,27 @@ static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *
static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
Query *query, bool use_count, char *count_colname);
+static void append_set_clause_for_count(const char *resname, StringInfo buf_old,
+ StringInfo buf_new,StringInfo aggs_list);
+static void append_set_clause_for_sum(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list);
+static void append_set_clause_for_avg(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ const char *aggtype);
+static char *get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
+ const char* count_col, const char *castType);
+static char *get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
+ const char* count_col);
static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
- List *keys, const char *count_colname);
+ List *keys, StringInfo aggs_list, StringInfo aggs_set,
+ const char *count_colname);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
- List *keys, StringInfo target_list, const char* count_colname);
+ List *keys, StringInfo target_list, StringInfo aggs_set,
+ const char* count_colname);
static char *get_matching_condition_string(List *keys);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
@@ -1431,11 +1453,44 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
* When a base table is truncated, the view content will be empty if the
* view definition query does not contain an aggregate without a GROUP clause.
* Therefore, such views can be truncated.
+ *
+ * Aggregate views without a GROUP clause always have one row. Therefore,
+ * if a base table is truncated, the view will not be empty and will contain
+ * a row with NULL value (or 0 for count()). So, in this case, we refresh the
+ * view instead of truncating it.
*/
if (TRIGGER_FIRED_BY_TRUNCATE(trigdata->tg_event))
{
- ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
- NIL, DROP_RESTRICT, false, false);
+ if (!(query->hasAggs && query->groupClause == NIL))
+ ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
+ NIL, DROP_RESTRICT, false, false);
+ else
+ {
+ Oid OIDNewHeap;
+ DestReceiver *dest;
+ uint64 processed = 0;
+ Query *dataQuery = rewriteQueryForIMMV(query, NIL);
+ char relpersistence = matviewRel->rd_rel->relpersistence;
+
+ /*
+ * Create the transient table that will receive the regenerated data. Lock
+ * it against access by any other process until commit (by which time it
+ * will be gone).
+ */
+ OIDNewHeap = make_new_heap(matviewOid, matviewRel->rd_rel->reltablespace,
+ matviewRel->rd_rel->relam,
+ relpersistence, ExclusiveLock);
+ LockRelationOid(OIDNewHeap, AccessExclusiveLock);
+ dest = CreateTransientRelDestReceiver(OIDNewHeap);
+
+ /* Generate the data */
+ processed = refresh_matview_datafill(dest, dataQuery, NULL, NULL, "");
+ refresh_by_heap_swap(matviewOid, OIDNewHeap, relpersistence);
+
+ /* Inform cumulative stats system about our activity */
+ pgstat_count_truncate(matviewRel);
+ pgstat_count_heap_insert(matviewRel, processed);
+ }
/* Clean up hash entry and delete tuplestores */
clean_up_IVM_hash_entry(entry, false);
@@ -1475,8 +1530,8 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
/* Set all tables in the query to pre-update state */
rewritten = rewrite_query_for_preupdate_state(rewritten, entry->tables,
pstate, matviewOid);
- /* Rewrite for counting duplicated tuples */
- rewritten = rewrite_query_for_counting(rewritten, pstate);
+ /* Rewrite for counting duplicated tuples and aggregates functions*/
+ rewritten = rewrite_query_for_counting_and_aggregates(rewritten, pstate);
/* Create tuplestores to store view deltas */
if (entry->has_old)
@@ -1527,7 +1582,7 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
count_colname = pstrdup("__ivm_count__");
- if (query->distinctClause)
+ if (query->hasAggs || query->distinctClause)
use_count = true;
/* calculate delta tables */
@@ -1923,17 +1978,34 @@ replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
}
/*
- * rewrite_query_for_counting
+ * rewrite_query_for_counting_and_aggregates
*
- * Rewrite query for counting duplicated tuples.
+ * Rewrite query for counting duplicated tuples and aggregate functions.
*/
static Query *
-rewrite_query_for_counting(Query *query, ParseState *pstate)
+rewrite_query_for_counting_and_aggregates(Query *query, ParseState *pstate)
{
TargetEntry *tle_count;
FuncCall *fn;
Node *node;
+ /* For aggregate views */
+ if (query->hasAggs)
+ {
+ ListCell *lc;
+ List *aggs = NIL;
+ AttrNumber next_resno = list_length(query->targetList) + 1;
+
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+
+ if (IsA(tle->expr, Aggref))
+ makeIvmAggColumn(pstate, (Aggref *)tle->expr, tle->resname, &next_resno, &aggs);
+ }
+ query->targetList = list_concat(query->targetList, aggs);
+ }
+
/* Add count(*) for counting distinct tuples in views */
fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
fn->agg_star = true;
@@ -2006,6 +2078,8 @@ rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte
return query;
}
+#define IVM_colname(type, col) makeObjectName("__ivm_" type, col, "_")
+
/*
* apply_delta
*
@@ -2019,6 +2093,9 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
{
StringInfoData querybuf;
StringInfoData target_list_buf;
+ StringInfo aggs_list_buf = NULL;
+ StringInfo aggs_set_old = NULL;
+ StringInfo aggs_set_new = NULL;
Relation matviewRel;
char *matviewname;
ListCell *lc;
@@ -2041,6 +2118,15 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
initStringInfo(&querybuf);
initStringInfo(&target_list_buf);
+ if (query->hasAggs)
+ {
+ if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
+ aggs_set_old = makeStringInfo();
+ if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
+ aggs_set_new = makeStringInfo();
+ aggs_list_buf = makeStringInfo();
+ }
+
/* build string of target list */
for (i = 0; i < matviewRel->rd_att->natts; i++)
{
@@ -2057,13 +2143,61 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
i++;
if (tle->resjunk)
continue;
- keys = lappend(keys, attr);
+ /*
+ * For views without aggregates, all attributes are used as keys to identify a
+ * tuple in a view.
+ */
+ if (!query->hasAggs)
+ keys = lappend(keys, attr);
+
+ /* For views with aggregates, we need to build SET clause for updating aggregate
+ * values. */
+ if (query->hasAggs && IsA(tle->expr, Aggref))
+ {
+ Aggref *aggref = (Aggref *) tle->expr;
+ const char *aggname = get_func_name(aggref->aggfnoid);
+
+ /*
+ * We can use function names here because it is already checked if these
+ * can be used in IMMV by its OID at the definition time.
+ */
+
+ /* count */
+ if (!strcmp(aggname, "count"))
+ append_set_clause_for_count(resname, aggs_set_old, aggs_set_new, aggs_list_buf);
+
+ /* sum */
+ else if (!strcmp(aggname, "sum"))
+ append_set_clause_for_sum(resname, aggs_set_old, aggs_set_new, aggs_list_buf);
+
+ /* avg */
+ else if (!strcmp(aggname, "avg"))
+ append_set_clause_for_avg(resname, aggs_set_old, aggs_set_new, aggs_list_buf,
+ format_type_be(aggref->aggtype));
+
+ else
+ elog(ERROR, "unsupported aggregate function: %s", aggname);
+ }
+ }
+
+ /* If we have GROUP BY clause, we use its entries as keys. */
+ if (query->hasAggs && query->groupClause)
+ {
+ foreach (lc, query->groupClause)
+ {
+ SortGroupClause *sgcl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(sgcl, query->targetList);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ keys = lappend(keys, attr);
+ }
}
/* Start maintaining the materialized view. */
@@ -2094,7 +2228,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (use_count)
/* apply old delta and get rows to be recalculated */
apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
- keys, count_colname);
+ keys, aggs_list_buf, aggs_set_old,
+ count_colname);
else
apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
@@ -2120,7 +2255,7 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
/* apply new delta */
if (use_count)
apply_new_delta_with_count(matviewname, NEW_DELTA_ENRNAME,
- keys, &target_list_buf, count_colname);
+ keys, aggs_set_new, &target_list_buf, count_colname);
else
apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
}
@@ -2135,6 +2270,250 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_finish failed");
}
+/*
+ * append_set_clause_for_count
+ *
+ * Append SET clause string for count aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_count(const char *resname, StringInfo buf_old,
+ StringInfo buf_new,StringInfo aggs_list)
+{
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* resname = mv.resname - t.resname */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, resname, "mv", "t", NULL, NULL));
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* resname = mv.resname + diff.resname */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, resname, "mv", "diff", NULL, NULL));
+ }
+
+ appendStringInfo(aggs_list, ", %s",
+ quote_qualified_identifier("diff", resname)
+ );
+}
+
+/*
+ * append_set_clause_for_sum
+ *
+ * Append SET clause string for sum aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_sum(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list)
+{
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* sum = mv.sum - t.sum */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, resname, "mv", "t", count_col, NULL)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* sum = mv.sum + diff.sum */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, resname, "mv", "diff", count_col, NULL)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
+/*
+ * append_set_clause_for_avg
+ *
+ * Append SET clause string for avg aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_avg(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ const char *aggtype)
+{
+ char *sum_col = IVM_colname("sum", resname);
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* avg = (mv.sum - t.sum)::aggtype / (mv.count - t.count) */
+ appendStringInfo(buf_old,
+ ", %s = %s OPERATOR(pg_catalog./) %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, sum_col, "mv", "t", count_col, aggtype),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ /* sum = mv.sum - t.sum */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, sum_col),
+ get_operation_string(IVM_SUB, sum_col, "mv", "t", count_col, NULL)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* avg = (mv.sum + diff.sum)::aggtype / (mv.count + diff.count) */
+ appendStringInfo(buf_new,
+ ", %s = %s OPERATOR(pg_catalog./) %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, sum_col, "mv", "diff", count_col, aggtype),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ /* sum = mv.sum + diff.sum */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, sum_col),
+ get_operation_string(IVM_ADD, sum_col, "mv", "diff", count_col, NULL)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("sum", resname)),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
+/*
+ * get_operation_string
+ *
+ * Build a string to calculate the new aggregate values.
+ */
+static char *
+get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
+ const char* count_col, const char *castType)
+{
+ StringInfoData buf;
+ StringInfoData castString;
+ char *col1 = quote_qualified_identifier(arg1, col);
+ char *col2 = quote_qualified_identifier(arg2, col);
+ char op_char = (op == IVM_SUB ? '-' : '+');
+
+ initStringInfo(&buf);
+ initStringInfo(&castString);
+
+ if (castType)
+ appendStringInfo(&castString, "::%s", castType);
+
+ if (!count_col)
+ {
+ /*
+ * If the attributes don't have count columns then calc the result
+ * by using the operator simply.
+ */
+ appendStringInfo(&buf, "(%s OPERATOR(pg_catalog.%c) %s)%s",
+ col1, op_char, col2, castString.data);
+ }
+ else
+ {
+ /*
+ * If the attributes have count columns then consider the condition
+ * where the result becomes NULL.
+ */
+ char *null_cond = get_null_condition_string(op, arg1, arg2, count_col);
+
+ appendStringInfo(&buf,
+ "(CASE WHEN %s THEN NULL "
+ "WHEN %s IS NULL THEN %s "
+ "WHEN %s IS NULL THEN %s "
+ "ELSE (%s OPERATOR(pg_catalog.%c) %s)%s END)",
+ null_cond,
+ col1, col2,
+ col2, col1,
+ col1, op_char, col2, castString.data
+ );
+ }
+
+ return buf.data;
+}
+
+/*
+ * get_null_condition_string
+ *
+ * Build a predicate string for CASE clause to check if an aggregate value
+ * will became NULL after the given operation is applied.
+ */
+static char *
+get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
+ const char* count_col)
+{
+ StringInfoData null_cond;
+ initStringInfo(&null_cond);
+
+ switch (op)
+ {
+ case IVM_ADD:
+ appendStringInfo(&null_cond,
+ "%s OPERATOR(pg_catalog.=) 0 AND %s OPERATOR(pg_catalog.=) 0",
+ quote_qualified_identifier(arg1, count_col),
+ quote_qualified_identifier(arg2, count_col)
+ );
+ break;
+ case IVM_SUB:
+ appendStringInfo(&null_cond,
+ "%s OPERATOR(pg_catalog.=) %s",
+ quote_qualified_identifier(arg1, count_col),
+ quote_qualified_identifier(arg2, count_col)
+ );
+ break;
+ default:
+ elog(ERROR,"unknown operation");
+ }
+
+ return null_cond.data;
+}
+
+
/*
* apply_old_delta_with_count
*
@@ -2142,13 +2521,20 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
* which contains tuples to be deleted from to a materialized view given by
* matviewname. This is used when counting is required, that is, the view
* has aggregate or distinct.
+ *
+ * If the view desn't have aggregates or has GROUP BY, this requires a keys
+ * list to identify a tuple in the view. If the view has aggregates, this
+ * requires strings representing resnames of aggregates and SET clause for
+ * updating aggregate values.
*/
static void
apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
- List *keys, const char *count_colname)
+ List *keys, StringInfo aggs_list, StringInfo aggs_set,
+ const char *count_colname)
{
StringInfoData querybuf;
char *match_cond;
+ bool agg_without_groupby = (list_length(keys) == 0);
/* build WHERE condition for searching tuples to be deleted */
match_cond = get_matching_condition_string(keys);
@@ -2158,22 +2544,26 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
appendStringInfo(&querybuf,
"WITH t AS (" /* collecting tid of target tuples in the view */
"SELECT diff.%s, " /* count column */
- "(diff.%s OPERATOR(pg_catalog.=) mv.%s) AS for_dlt, "
+ "(diff.%s OPERATOR(pg_catalog.=) mv.%s AND %s) AS for_dlt, "
"mv.ctid "
+ "%s " /* aggregate columns */
"FROM %s AS mv, %s AS diff "
"WHERE %s" /* tuple matching condition */
"), updt AS (" /* update a tuple if this is not to be deleted */
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
+ "%s" /* SET clauses for aggregates */
"FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
")"
/* delete a tuple if this is to be deleted */
"DELETE FROM %s AS mv USING t "
"WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
count_colname,
- count_colname, count_colname,
+ count_colname, count_colname, (agg_without_groupby ? "false" : "true"),
+ (aggs_list != NULL ? aggs_list->data : ""),
matviewname, deltaname_old,
match_cond,
matviewname, count_colname, count_colname, count_colname,
+ (aggs_set != NULL ? aggs_set->data : ""),
matviewname);
if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
@@ -2237,10 +2627,15 @@ apply_old_delta(const char *matviewname, const char *deltaname_old,
* matviewname. This is used when counting is required, that is, the view
* has aggregate or distinct. Also, when a table in EXISTS sub queries
* is modified.
+ *
+ * If the view desn't have aggregates or has GROUP BY, this requires a keys
+ * list to identify a tuple in the view. If the view has aggregates, this
+ * requires strings representing SET clause for updating aggregate values.
*/
static void
apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
- List *keys, StringInfo target_list, const char* count_colname)
+ List *keys, StringInfo aggs_set, StringInfo target_list,
+ const char* count_colname)
{
StringInfoData querybuf;
StringInfoData returning_keys;
@@ -2271,6 +2666,7 @@ apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
appendStringInfo(&querybuf,
"WITH updt AS (" /* update a tuple if this exists in the view */
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.+) diff.%s "
+ "%s " /* SET clauses for aggregates */
"FROM %s AS diff "
"WHERE %s " /* tuple matching condition */
"RETURNING %s" /* returning keys of updated tuples */
@@ -2278,6 +2674,7 @@ apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
"SELECT %s FROM %s AS diff "
"WHERE NOT EXISTS (SELECT 1 FROM updt AS mv WHERE %s);",
matviewname, count_colname, count_colname, count_colname,
+ (aggs_set != NULL ? aggs_set->data : ""),
deltaname_new,
match_cond,
returning_keys.data,
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 76a7873ebf..599bae3b5a 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -30,6 +30,7 @@ extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
extern Query *rewriteQueryForIMMV(Query *query, List *colNames);
+extern void makeIvmAggColumn(ParseState *pstate, Aggref *aggref, char *resname, AttrNumber *next_resno, List **aggs);
extern int GetIntoRelEFlags(IntoClause *intoClause);
--
2.25.1
v29-0009-Add-support-for-min-max-aggregates-for-IVM.patchtext/x-diff; name=v29-0009-Add-support-for-min-max-aggregates-for-IVM.patchDownload
From f43b5204477c73073989e3fb60fe6167e9f6551e Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 20:58:25 +0900
Subject: [PATCH v29 09/11] Add support for min/max aggregates for IVM
Supporting min and max is more complicated than count, sum, or avg.
For an example of min, when tuples are inserted, the current min value
in the view and the min value in the inseteted tuples are compared,
then the smaller one is used as the latest min value. On the other
hand, when tuples are deleted, if the current min value in the view
equals to the min in the deleted tuples, we need re-computation the
latest min value from base tables. Otherwise, the current value in
the view remains.
---
src/backend/commands/createas.c | 45 +++
src/backend/commands/matview.c | 644 +++++++++++++++++++++++++++++++-
2 files changed, 680 insertions(+), 9 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index c8aa558f2e..c40ea6b2bc 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -1312,6 +1312,51 @@ check_aggregate_supports_ivm(Oid aggfnoid)
case F_AVG_FLOAT8:
case F_AVG_INTERVAL:
+ /* min */
+ case F_MIN_ANYARRAY:
+ case F_MIN_INT8:
+ case F_MIN_INT4:
+ case F_MIN_INT2:
+ case F_MIN_OID:
+ case F_MIN_FLOAT4:
+ case F_MIN_FLOAT8:
+ case F_MIN_DATE:
+ case F_MIN_TIME:
+ case F_MIN_TIMETZ:
+ case F_MIN_MONEY:
+ case F_MIN_TIMESTAMP:
+ case F_MIN_TIMESTAMPTZ:
+ case F_MIN_INTERVAL:
+ case F_MIN_TEXT:
+ case F_MIN_NUMERIC:
+ case F_MIN_BPCHAR:
+ case F_MIN_TID:
+ case F_MIN_ANYENUM:
+ case F_MIN_INET:
+ case F_MIN_PG_LSN:
+
+ /* max */
+ case F_MAX_ANYARRAY:
+ case F_MAX_INT8:
+ case F_MAX_INT4:
+ case F_MAX_INT2:
+ case F_MAX_OID:
+ case F_MAX_FLOAT4:
+ case F_MAX_FLOAT8:
+ case F_MAX_DATE:
+ case F_MAX_TIME:
+ case F_MAX_TIMETZ:
+ case F_MAX_MONEY:
+ case F_MAX_TIMESTAMP:
+ case F_MAX_TIMESTAMPTZ:
+ case F_MAX_INTERVAL:
+ case F_MAX_TEXT:
+ case F_MAX_NUMERIC:
+ case F_MAX_BPCHAR:
+ case F_MAX_TID:
+ case F_MAX_ANYENUM:
+ case F_MAX_INET:
+ case F_MAX_PG_LSN:
return true;
default:
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index ee41f0007d..eff512d40c 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -73,6 +73,34 @@ typedef struct
#define MV_INIT_QUERYHASHSIZE 16
+/* MV query type codes */
+#define MV_PLAN_RECALC 1
+#define MV_PLAN_SET_VALUE 2
+
+/*
+ * MI_QueryKey
+ *
+ * The key identifying a prepared SPI plan in our query hashtable
+ */
+typedef struct MV_QueryKey
+{
+ Oid matview_id; /* OID of materialized view */
+ int32 query_type; /* query type ID, see MV_PLAN_XXX above */
+} MV_QueryKey;
+
+/*
+ * MV_QueryHashEntry
+ *
+ * Hash entry for cached plans used to maintain materialized views.
+ */
+typedef struct MV_QueryHashEntry
+{
+ MV_QueryKey key;
+ SPIPlanPtr plan;
+ SearchPathMatcher *search_path; /* search_path used for parsing
+ * and planning */
+} MV_QueryHashEntry;
+
/*
* MV_TriggerHashEntry
*
@@ -109,6 +137,7 @@ typedef struct MV_TriggerTable
TupleTableSlot *slot; /* for checking visibility in the pre-state table */
} MV_TriggerTable;
+static HTAB *mv_query_cache = NULL;
static HTAB *mv_trigger_info = NULL;
static bool in_delta_calculation = false;
@@ -169,6 +198,9 @@ static void append_set_clause_for_sum(const char *resname, StringInfo buf_old,
static void append_set_clause_for_avg(const char *resname, StringInfo buf_old,
StringInfo buf_new, StringInfo aggs_list,
const char *aggtype);
+static void append_set_clause_for_minmax(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ bool is_min);
static char *get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
const char* count_col, const char *castType);
static char *get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
@@ -177,17 +209,30 @@ static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
List *keys, StringInfo aggs_list, StringInfo aggs_set,
- const char *count_colname);
+ List *minmax_list, List *is_min_list,
+ const char *count_colname,
+ SPITupleTable **tuptable_recalc, uint64 *num_recalc);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
List *keys, StringInfo target_list, StringInfo aggs_set,
const char* count_colname);
static char *get_matching_condition_string(List *keys);
+static char *get_returning_string(List *minmax_list, List *is_min_list, List *keys);
+static char *get_minmax_recalc_condition_string(List *minmax_list, List *is_min_list);
+static char *get_select_for_recalc_string(List *keys);
+static void recalc_and_set_values(SPITupleTable *tuptable_recalc, int64 num_tuples,
+ List *namelist, List *keys, Relation matviewRel);
+static SPIPlanPtr get_plan_for_recalc(Oid matviewOid, List *namelist, List *keys, Oid *keyTypes);
+static SPIPlanPtr get_plan_for_set_values(Oid matviewOid, char *matviewname, List *namelist,
+ Oid *valTypes);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
static void mv_InitHashTables(void);
+static SPIPlanPtr mv_FetchPreparedPlan(MV_QueryKey *key);
+static void mv_HashPreparedPlan(MV_QueryKey *key, SPIPlanPtr plan);
+static void mv_BuildQueryKey(MV_QueryKey *key, Oid matview_id, int32 query_type);
static void clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort);
/*
@@ -2101,6 +2146,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
ListCell *lc;
int i;
List *keys = NIL;
+ List *minmax_list = NIL;
+ List *is_min_list = NIL;
/*
@@ -2182,6 +2229,17 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
append_set_clause_for_avg(resname, aggs_set_old, aggs_set_new, aggs_list_buf,
format_type_be(aggref->aggtype));
+ /* min/max */
+ else if (!strcmp(aggname, "min") || !strcmp(aggname, "max"))
+ {
+ bool is_min = (!strcmp(aggname, "min"));
+
+ append_set_clause_for_minmax(resname, aggs_set_old, aggs_set_new, aggs_list_buf, is_min);
+
+ /* make a resname list of min and max aggregates */
+ minmax_list = lappend(minmax_list, resname);
+ is_min_list = lappend_int(is_min_list, is_min);
+ }
else
elog(ERROR, "unsupported aggregate function: %s", aggname);
}
@@ -2211,6 +2269,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
{
EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ SPITupleTable *tuptable_recalc = NULL;
+ uint64 num_recalc;
int rc;
/* convert tuplestores to ENR, and register for SPI */
@@ -2229,10 +2289,18 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
/* apply old delta and get rows to be recalculated */
apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
keys, aggs_list_buf, aggs_set_old,
- count_colname);
+ minmax_list, is_min_list,
+ count_colname, &tuptable_recalc, &num_recalc);
else
apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+ /*
+ * If we have min or max, we might have to recalculate aggregate values from base tables
+ * on some tuples. TIDs and keys such tuples are returned as a result of the above query.
+ */
+ if (minmax_list && tuptable_recalc)
+ recalc_and_set_values(tuptable_recalc, num_recalc, minmax_list, keys, matviewRel);
+
}
/* For tuple insertion */
if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
@@ -2424,6 +2492,70 @@ append_set_clause_for_avg(const char *resname, StringInfo buf_old,
);
}
+/*
+ * append_set_clause_for_minmax
+ *
+ * Append SET clause string for min or max aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ * is_min is true if this is min, false if not.
+ */
+static void
+append_set_clause_for_minmax(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ bool is_min)
+{
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /*
+ * If the new value doesn't became NULL then use the value remaining
+ * in the view although this will be recomputated afterwords.
+ */
+ appendStringInfo(buf_old,
+ ", %s = CASE WHEN %s THEN NULL ELSE %s END",
+ quote_qualified_identifier(NULL, resname),
+ get_null_condition_string(IVM_SUB, "mv", "t", count_col),
+ quote_qualified_identifier("mv", resname)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /*
+ * min = LEAST(mv.min, diff.min)
+ * max = GREATEST(mv.max, diff.max)
+ */
+ appendStringInfo(buf_new,
+ ", %s = CASE WHEN %s THEN NULL ELSE %s(%s,%s) END",
+ quote_qualified_identifier(NULL, resname),
+ get_null_condition_string(IVM_ADD, "mv", "diff", count_col),
+
+ is_min ? "LEAST" : "GREATEST",
+ quote_qualified_identifier("mv", resname),
+ quote_qualified_identifier("diff", resname)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
/*
* get_operation_string
*
@@ -2526,19 +2658,44 @@ get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
* list to identify a tuple in the view. If the view has aggregates, this
* requires strings representing resnames of aggregates and SET clause for
* updating aggregate values.
+ *
+ * If the view has min or max aggregate, this requires a list of resnames of
+ * min/max aggregates and a list of boolean which represents which entries in
+ * minmax_list is min. These are necessary to check if we need to recalculate
+ * min or max aggregate values. In this case, this query returns TID and keys
+ * of tuples which need to be recalculated. This result and the number of rows
+ * are stored in tuptables and num_recalc repectedly.
+ *
*/
static void
apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
List *keys, StringInfo aggs_list, StringInfo aggs_set,
- const char *count_colname)
+ List *minmax_list, List *is_min_list,
+ const char *count_colname,
+ SPITupleTable **tuptable_recalc, uint64 *num_recalc)
{
StringInfoData querybuf;
char *match_cond;
+ char *updt_returning = "";
+ char *select_for_recalc = "SELECT";
bool agg_without_groupby = (list_length(keys) == 0);
+ Assert(tuptable_recalc != NULL);
+ Assert(num_recalc != NULL);
+
/* build WHERE condition for searching tuples to be deleted */
match_cond = get_matching_condition_string(keys);
+ /*
+ * We need a special RETURNING clause and SELECT statement for min/max to
+ * check which tuple needs re-calculation from base tables.
+ */
+ if (minmax_list)
+ {
+ updt_returning = get_returning_string(minmax_list, is_min_list, keys);
+ select_for_recalc = get_select_for_recalc_string(keys);
+ }
+
/* Search for matching tuples from the view and update or delete if found. */
initStringInfo(&querybuf);
appendStringInfo(&querybuf,
@@ -2553,10 +2710,11 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
"%s" /* SET clauses for aggregates */
"FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
- ")"
- /* delete a tuple if this is to be deleted */
- "DELETE FROM %s AS mv USING t "
- "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
+ "%s" /* RETURNING clause for recalc infomation */
+ "), dlt AS (" /* delete a tuple if this is to be deleted */
+ "DELETE FROM %s AS mv USING t "
+ "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt"
+ ") %s", /* SELECT returning which tuples need to be recalculated */
count_colname,
count_colname, count_colname, (agg_without_groupby ? "false" : "true"),
(aggs_list != NULL ? aggs_list->data : ""),
@@ -2564,10 +2722,25 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
match_cond,
matviewname, count_colname, count_colname, count_colname,
(aggs_set != NULL ? aggs_set->data : ""),
- matviewname);
+ updt_returning,
+ matviewname,
+ select_for_recalc);
- if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_SELECT)
elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+
+
+ /* Return tuples to be recalculated. */
+ if (minmax_list)
+ {
+ *tuptable_recalc = SPI_tuptable;
+ *num_recalc = SPI_processed;
+ }
+ else
+ {
+ *tuptable_recalc = NULL;
+ *num_recalc = 0;
+ }
}
/*
@@ -2750,6 +2923,349 @@ get_matching_condition_string(List *keys)
return match_cond.data;
}
+/*
+ * get_returning_string
+ *
+ * Build a string for RETURNING clause of UPDATE used in apply_old_delta_with_count.
+ * This clause returns ctid and a boolean value that indicates if we need to
+ * recalculate min or max value, for each updated row.
+ */
+static char *
+get_returning_string(List *minmax_list, List *is_min_list, List *keys)
+{
+ StringInfoData returning;
+ char *recalc_cond;
+ ListCell *lc;
+
+ Assert(minmax_list != NIL && is_min_list != NIL);
+ recalc_cond = get_minmax_recalc_condition_string(minmax_list, is_min_list);
+
+ initStringInfo(&returning);
+
+ appendStringInfo(&returning, "RETURNING mv.ctid AS tid, (%s) AS recalc", recalc_cond);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&returning, ", %s", quote_qualified_identifier("mv", resname));
+ }
+
+ return returning.data;
+}
+
+/*
+ * get_minmax_recalc_condition_string
+ *
+ * Build a predicate string for checking if any min/max aggregate
+ * value needs to be recalculated.
+ */
+static char *
+get_minmax_recalc_condition_string(List *minmax_list, List *is_min_list)
+{
+ StringInfoData recalc_cond;
+ ListCell *lc1, *lc2;
+
+ initStringInfo(&recalc_cond);
+
+ Assert (list_length(minmax_list) == list_length(is_min_list));
+
+ forboth (lc1, minmax_list, lc2, is_min_list)
+ {
+ char *resname = (char *) lfirst(lc1);
+ bool is_min = (bool) lfirst_int(lc2);
+ char *op_str = (is_min ? ">=" : "<=");
+
+ appendStringInfo(&recalc_cond, "%s OPERATOR(pg_catalog.%s) %s",
+ quote_qualified_identifier("mv", resname),
+ op_str,
+ quote_qualified_identifier("t", resname)
+ );
+
+ if (lnext(minmax_list, lc1))
+ appendStringInfo(&recalc_cond, " OR ");
+ }
+
+ return recalc_cond.data;
+}
+
+/*
+ * get_select_for_recalc_string
+ *
+ * Build a query to return tid and keys of tuples which need
+ * recalculation. This is used as the result of the query
+ * built by apply_old_delta.
+ */
+static char *
+get_select_for_recalc_string(List *keys)
+{
+ StringInfoData qry;
+ ListCell *lc;
+
+ initStringInfo(&qry);
+
+ appendStringInfo(&qry, "SELECT tid");
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ appendStringInfo(&qry, ", %s", NameStr(attr->attname));
+ }
+
+ appendStringInfo(&qry, " FROM updt WHERE recalc");
+
+ return qry.data;
+}
+
+/*
+ * recalc_and_set_values
+ *
+ * Recalculate tuples in a materialized from base tables and update these.
+ * The tuples which needs recalculation are specified by keys, and resnames
+ * of columns to be updated are specified by namelist. TIDs and key values
+ * are given by tuples in tuptable_recalc. Its first attribute must be TID
+ * and key values must be following this.
+ */
+static void
+recalc_and_set_values(SPITupleTable *tuptable_recalc, int64 num_tuples,
+ List *namelist, List *keys, Relation matviewRel)
+{
+ TupleDesc tupdesc_recalc = tuptable_recalc->tupdesc;
+ Oid *keyTypes = NULL, *types = NULL;
+ char *keyNulls = NULL, *nulls = NULL;
+ Datum *keyVals = NULL, *vals = NULL;
+ int num_vals = list_length(namelist);
+ int num_keys = list_length(keys);
+ uint64 i;
+ Oid matviewOid;
+ char *matviewname;
+
+ matviewOid = RelationGetRelid(matviewRel);
+ matviewname = quote_qualified_identifier(get_namespace_name(RelationGetNamespace(matviewRel)),
+ RelationGetRelationName(matviewRel));
+
+ /* If we have keys, initialize arrays for them. */
+ if (keys)
+ {
+ keyTypes = palloc(sizeof(Oid) * num_keys);
+ keyNulls = palloc(sizeof(char) * num_keys);
+ keyVals = palloc(sizeof(Datum) * num_keys);
+ /* a tuple contains keys to be recalculated and ctid to be updated*/
+ Assert(tupdesc_recalc->natts == num_keys + 1);
+
+ /* Types of key attributes */
+ for (i = 0; i < num_keys; i++)
+ keyTypes[i] = TupleDescAttr(tupdesc_recalc, i + 1)->atttypid;
+ }
+
+ /* allocate memory for all attribute names and tid */
+ types = palloc(sizeof(Oid) * (num_vals + 1));
+ nulls = palloc(sizeof(char) * (num_vals + 1));
+ vals = palloc(sizeof(Datum) * (num_vals + 1));
+
+ /* For each tuple which needs recalculation */
+ for (i = 0; i < num_tuples; i++)
+ {
+ int j;
+ bool isnull;
+ SPIPlanPtr plan;
+ SPITupleTable *tuptable_newvals;
+ TupleDesc tupdesc_newvals;
+
+ /* Set group key values as parameters if needed. */
+ if (keys)
+ {
+ for (j = 0; j < num_keys; j++)
+ {
+ keyVals[j] = SPI_getbinval(tuptable_recalc->vals[i], tupdesc_recalc, j + 2, &isnull);
+ if (isnull)
+ keyNulls[j] = 'n';
+ else
+ keyNulls[j] = ' ';
+ }
+ }
+
+ /*
+ * Get recalculated values from base tables. The result must be
+ * only one tuple thich contains the new values for specified keys.
+ */
+ plan = get_plan_for_recalc(matviewOid, namelist, keys, keyTypes);
+ if (SPI_execute_plan(plan, keyVals, keyNulls, false, 0) != SPI_OK_SELECT)
+ elog(ERROR, "SPI_execute_plan");
+ if (SPI_processed != 1)
+ elog(ERROR, "SPI_execute_plan returned zero or more than one rows");
+
+ tuptable_newvals = SPI_tuptable;
+ tupdesc_newvals = tuptable_newvals->tupdesc;
+
+ Assert(tupdesc_newvals->natts == num_vals);
+
+ /* Set the new values as parameters */
+ for (j = 0; j < tupdesc_newvals->natts; j++)
+ {
+ if (i == 0)
+ types[j] = TupleDescAttr(tupdesc_newvals, j)->atttypid;
+
+ vals[j] = SPI_getbinval(tuptable_newvals->vals[0], tupdesc_newvals, j + 1, &isnull);
+ if (isnull)
+ nulls[j] = 'n';
+ else
+ nulls[j] = ' ';
+ }
+ /* Set TID of the view tuple to be updated as a parameter */
+ types[j] = TIDOID;
+ vals[j] = SPI_getbinval(tuptable_recalc->vals[i], tupdesc_recalc, 1, &isnull);
+ nulls[j] = ' ';
+
+ /* Update the view tuple to the new values */
+ plan = get_plan_for_set_values(matviewOid, matviewname, namelist, types);
+ if (SPI_execute_plan(plan, vals, nulls, false, 0) != SPI_OK_UPDATE)
+ elog(ERROR, "SPI_execute_plan");
+ }
+}
+
+
+/*
+ * get_plan_for_recalc
+ *
+ * Create or fetch a plan for recalculating value in the view's target list
+ * from base tables using the definition query of materialized view specified
+ * by matviewOid. namelist is a list of resnames of values to be recalculated.
+ *
+ * keys is a list of keys to identify tuples to be recalculated if this is not
+ * empty. KeyTypes is an array of types of keys.
+ */
+static SPIPlanPtr
+get_plan_for_recalc(Oid matviewOid, List *namelist, List *keys, Oid *keyTypes)
+{
+ MV_QueryKey hash_key;
+ SPIPlanPtr plan;
+
+ /* Fetch or prepare a saved plan for the recalculation */
+ mv_BuildQueryKey(&hash_key, matviewOid, MV_PLAN_RECALC);
+ if ((plan = mv_FetchPreparedPlan(&hash_key)) == NULL)
+ {
+ ListCell *lc;
+ StringInfoData str;
+ char *viewdef;
+
+ /* get view definition of matview */
+ viewdef = text_to_cstring((text *) DatumGetPointer(
+ DirectFunctionCall1(pg_get_viewdef, ObjectIdGetDatum(matviewOid))));
+ /* get rid of trailing semi-colon */
+ viewdef[strlen(viewdef)-1] = '\0';
+
+ /*
+ * Build a query string for recalculating values. This is like
+ *
+ * SELECT x1, x2, x3, ... FROM ( ... view definition query ...) mv
+ * WHERE (key1, key2, ...) = ($1, $2, ...);
+ */
+
+ initStringInfo(&str);
+ appendStringInfo(&str, "SELECT ");
+ foreach (lc, namelist)
+ {
+ appendStringInfo(&str, "%s", (char *) lfirst(lc));
+ if (lnext(namelist, lc))
+ appendStringInfoString(&str, ", ");
+ }
+ appendStringInfo(&str, " FROM (%s) mv", viewdef);
+
+ if (keys)
+ {
+ int i = 1;
+ char paramname[16];
+
+ appendStringInfo(&str, " WHERE (");
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ Oid typid = attr->atttypid;
+
+ sprintf(paramname, "$%d", i);
+ appendStringInfo(&str, "(");
+ generate_equal(&str, typid, resname, paramname);
+ appendStringInfo(&str, " OR (%s IS NULL AND %s IS NULL))",
+ resname, paramname);
+
+ if (lnext(keys, lc))
+ appendStringInfoString(&str, " AND ");
+ i++;
+ }
+ appendStringInfo(&str, ")");
+ }
+ else
+ keyTypes = NULL;
+
+ plan = SPI_prepare(str.data, list_length(keys), keyTypes);
+ if (plan == NULL)
+ elog(ERROR, "SPI_prepare returned %s for %s", SPI_result_code_string(SPI_result), str.data);
+
+ SPI_keepplan(plan);
+ mv_HashPreparedPlan(&hash_key, plan);
+ }
+
+ return plan;
+}
+
+/*
+ * get_plan_for_set_values
+ *
+ * Create or fetch a plan for applying new values calculated by
+ * get_plan_for_recalc to a materialized view specified by matviewOid.
+ * matviewname is the name of the view. namelist is a list of resnames
+ * of attributes to be updated, and valTypes is an array of types of the
+ * values.
+ */
+static SPIPlanPtr
+get_plan_for_set_values(Oid matviewOid, char *matviewname, List *namelist,
+ Oid *valTypes)
+{
+ MV_QueryKey key;
+ SPIPlanPtr plan;
+
+ /* Fetch or prepare a saved plan for the real check */
+ mv_BuildQueryKey(&key, matviewOid, MV_PLAN_SET_VALUE);
+ if ((plan = mv_FetchPreparedPlan(&key)) == NULL)
+ {
+ ListCell *lc;
+ StringInfoData str;
+ int i;
+
+ /*
+ * Build a query string for applying min/max values. This is like
+ *
+ * UPDATE matviewname AS mv
+ * SET (x1, x2, x3, x4) = ($1, $2, $3, $4)
+ * WHERE ctid = $5;
+ */
+
+ initStringInfo(&str);
+ appendStringInfo(&str, "UPDATE %s AS mv SET (", matviewname);
+ foreach (lc, namelist)
+ {
+ appendStringInfo(&str, "%s", (char *) lfirst(lc));
+ if (lnext(namelist, lc))
+ appendStringInfoString(&str, ", ");
+ }
+ appendStringInfo(&str, ") = ROW(");
+
+ for (i = 1; i <= list_length(namelist); i++)
+ appendStringInfo(&str, "%s$%d", (i==1 ? "" : ", "), i);
+
+ appendStringInfo(&str, ") WHERE ctid OPERATOR(pg_catalog.=) $%d", i);
+
+ plan = SPI_prepare(str.data, list_length(namelist) + 1, valTypes);
+ if (plan == NULL)
+ elog(ERROR, "SPI_prepare returned %s for %s", SPI_result_code_string(SPI_result), str.data);
+
+ SPI_keepplan(plan);
+ mv_HashPreparedPlan(&key, plan);
+ }
+
+ return plan;
+}
+
/*
* generate_equals
*
@@ -2783,6 +3299,13 @@ mv_InitHashTables(void)
{
HASHCTL ctl;
+ memset(&ctl, 0, sizeof(ctl));
+ ctl.keysize = sizeof(MV_QueryKey);
+ ctl.entrysize = sizeof(MV_QueryHashEntry);
+ mv_query_cache = hash_create("MV query cache",
+ MV_INIT_QUERYHASHSIZE,
+ &ctl, HASH_ELEM | HASH_BLOBS);
+
memset(&ctl, 0, sizeof(ctl));
ctl.keysize = sizeof(Oid);
ctl.entrysize = sizeof(MV_TriggerHashEntry);
@@ -2791,6 +3314,109 @@ mv_InitHashTables(void)
&ctl, HASH_ELEM | HASH_BLOBS);
}
+/*
+ * mv_FetchPreparedPlan
+ */
+static SPIPlanPtr
+mv_FetchPreparedPlan(MV_QueryKey *key)
+{
+ MV_QueryHashEntry *entry;
+ SPIPlanPtr plan;
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_query_cache)
+ mv_InitHashTables();
+
+ /*
+ * Lookup for the key
+ */
+ entry = (MV_QueryHashEntry *) hash_search(mv_query_cache,
+ (void *) key,
+ HASH_FIND, NULL);
+ if (entry == NULL)
+ return NULL;
+
+ /*
+ * Check whether the plan is still valid. If it isn't, we don't want to
+ * simply rely on plancache.c to regenerate it; rather we should start
+ * from scratch and rebuild the query text too. This is to cover cases
+ * such as table/column renames. We depend on the plancache machinery to
+ * detect possible invalidations, though.
+ *
+ * CAUTION: this check is only trustworthy if the caller has already
+ * locked both materialized views and base tables.
+ *
+ * Also, check whether the search_path is still the same as when we made it.
+ * If it isn't, we need to rebuild the query text because the result of
+ * pg_ivm_get_viewdef() will change.
+ */
+ plan = entry->plan;
+ if (plan && SPI_plan_is_valid(plan) &&
+ SearchPathMatchesCurrentEnvironment(entry->search_path))
+ return plan;
+
+ /*
+ * Otherwise we might as well flush the cached plan now, to free a little
+ * memory space before we make a new one.
+ */
+ if (plan)
+ SPI_freeplan(plan);
+ if (entry->search_path)
+ pfree(entry->search_path);
+
+ entry->plan = NULL;
+ entry->search_path = NULL;
+
+ return NULL;
+}
+
+/*
+ * mv_HashPreparedPlan
+ *
+ * Add another plan to our private SPI query plan hashtable.
+ */
+static void
+mv_HashPreparedPlan(MV_QueryKey *key, SPIPlanPtr plan)
+{
+ MV_QueryHashEntry *entry;
+ bool found;
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_query_cache)
+ mv_InitHashTables();
+
+ /*
+ * Add the new plan. We might be overwriting an entry previously found
+ * invalid by mv_FetchPreparedPlan.
+ */
+ entry = (MV_QueryHashEntry *) hash_search(mv_query_cache,
+ (void *) key,
+ HASH_ENTER, &found);
+ Assert(!found || entry->plan == NULL);
+ entry->plan = plan;
+ entry->search_path = GetSearchPathMatcher(TopMemoryContext);
+}
+
+/*
+ * mv_BuildQueryKey
+ *
+ * Construct a hashtable key for a prepared SPI plan for IVM.
+ */
+static void
+mv_BuildQueryKey(MV_QueryKey *key, Oid matview_id, int32 query_type)
+{
+ /*
+ * We assume struct MV_QueryKey contains no padding bytes, else we'd need
+ * to use memset to clear them.
+ */
+ key->matview_id = matview_id;
+ key->query_type = query_type;
+}
+
/*
* AtAbort_IVM
*
--
2.25.1
v29-0010-Add-regression-tests-for-Incremental-View-Mainte.patchtext/x-diff; name=v29-0010-Add-regression-tests-for-Incremental-View-Mainte.patchDownload
From 9cd5a7b31c21475f81c99c8a586abde03d8e00cf Mon Sep 17 00:00:00 2001
From: Takuma Hoshiai <takuma.hoshiai@gmail.com>
Date: Wed, 10 Mar 2021 11:11:13 +0900
Subject: [PATCH v29 10/11] Add regression tests for Incremental View
Maintenance
---
src/bin/pg_dump/pg_dump.h | 1 +
.../regress/expected/incremental_matview.out | 1030 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/incremental_matview.sql | 533 +++++++++
4 files changed, 1565 insertions(+), 1 deletion(-)
create mode 100644 src/test/regress/expected/incremental_matview.out
create mode 100644 src/test/regress/sql/incremental_matview.sql
diff --git a/src/bin/pg_dump/pg_dump.h b/src/bin/pg_dump/pg_dump.h
index 3705891d25..71ea246abd 100644
--- a/src/bin/pg_dump/pg_dump.h
+++ b/src/bin/pg_dump/pg_dump.h
@@ -323,6 +323,7 @@ typedef struct _tableInfo
int numParents; /* number of (immediate) parent tables */
struct _tableInfo **parents; /* TableInfos of immediate parents */
+
bool isivm; /* is incrementally maintainable materialized view? */
/*
diff --git a/src/test/regress/expected/incremental_matview.out b/src/test/regress/expected/incremental_matview.out
new file mode 100644
index 0000000000..8946d09f5d
--- /dev/null
+++ b/src/test/regress/expected/incremental_matview.out
@@ -0,0 +1,1030 @@
+-- create a table to use as a basis for views and materialized views in various combinations
+CREATE TABLE mv_base_a (i int, j int);
+INSERT INTO mv_base_a VALUES
+ (1,10),
+ (2,20),
+ (3,30),
+ (4,40),
+ (5,50);
+CREATE TABLE mv_base_b (i int, k int);
+INSERT INTO mv_base_b VALUES
+ (1,101),
+ (2,102),
+ (3,103),
+ (4,104);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_1 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) WITH NO DATA;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ERROR: materialized view "mv_ivm_1" has not been populated
+HINT: Use the REFRESH MATERIALIZED VIEW command.
+REFRESH MATERIALIZED VIEW mv_ivm_1;
+NOTICE: could not create an index on materialized view "mv_ivm_1" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+-- REFRESH WITH NO DATA
+BEGIN;
+CREATE FUNCTION dummy_ivm_trigger_func() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+CREATE CONSTRAINT TRIGGER dummy_ivm_trigger AFTER INSERT
+ON mv_base_a FROM mv_ivm_1 FOR EACH ROW
+EXECUTE PROCEDURE dummy_ivm_trigger_func();
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ count
+-------
+ 17
+(1 row)
+
+REFRESH MATERIALIZED VIEW mv_ivm_1 WITH NO DATA;
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+-- immediate maintenance
+BEGIN;
+INSERT INTO mv_base_b VALUES(5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+ 5 | 50 | 105
+(5 rows)
+
+UPDATE mv_base_a SET j = 0 WHERE i = 1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 0 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+ 5 | 50 | 105
+(5 rows)
+
+DELETE FROM mv_base_b WHERE (i,k) = (5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 0 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+ROLLBACK;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+-- rename of IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS SELECT DISTINCT * FROM mv_base_a;
+NOTICE: created index "mv_ivm_rename_index" on materialized view "mv_ivm_rename"
+ALTER MATERIALIZED VIEW mv_ivm_rename RENAME COLUMN __ivm_count__ TO xxx;
+ERROR: IVM column can not be renamed
+DROP MATERIALIZED VIEW mv_ivm_rename;
+-- unique index on IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_unique AS SELECT DISTINCT * FROM mv_base_a;
+NOTICE: created index "mv_ivm_unique_index" on materialized view "mv_ivm_unique"
+CREATE UNIQUE INDEX ON mv_ivm_unique(__ivm_count__);
+ERROR: unique index creation on IVM columns is not supported
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__));
+ERROR: unique index creation on IVM columns is not supported
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__ + 1));
+ERROR: unique index creation on IVM columns is not supported
+DROP MATERIALIZED VIEW mv_ivm_unique;
+-- TRUNCATE a base table in join views
+BEGIN;
+TRUNCATE mv_base_a;
+SELECT * FROM mv_ivm_1;
+ i | j | k
+---+---+---
+(0 rows)
+
+ROLLBACK;
+BEGIN;
+TRUNCATE mv_base_b;
+SELECT * FROM mv_ivm_1;
+ i | j | k
+---+---+---
+(0 rows)
+
+ROLLBACK;
+-- some query syntax
+BEGIN;
+CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql'
+ AS 'SELECT 1' IMMUTABLE;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_func AS SELECT * FROM ivm_func();
+NOTICE: could not create an index on materialized view "mv_ivm_func" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_no_tbl AS SELECT 1;
+NOTICE: could not create an index on materialized view "mv_ivm_no_tbl" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+ROLLBACK;
+-- result of materialized view have DISTINCT clause or the duplicate result.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_duplicate AS SELECT j FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_duplicate" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_distinct AS SELECT DISTINCT j FROM mv_base_a;
+NOTICE: created index "mv_ivm_distinct_index" on materialized view "mv_ivm_distinct"
+INSERT INTO mv_base_a VALUES(6,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 20
+ 30
+ 40
+ 50
+(6 rows)
+
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+ROLLBACK;
+-- support SUM(), COUNT() and AVG() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 120 | 2 | 60.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+UPDATE mv_base_a SET j = 200 WHERE (i,j) = (2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+----------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 220 | 2 | 110.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (2,200);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+ROLLBACK;
+-- support COUNT(*) aggregate function
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ i | sum | count
+---+-----+-------
+ 1 | 10 | 1
+ 2 | 20 | 1
+ 3 | 30 | 1
+ 4 | 40 | 1
+ 5 | 50 | 1
+(5 rows)
+
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ i | sum | count
+---+-----+-------
+ 1 | 10 | 1
+ 2 | 120 | 2
+ 3 | 30 | 1
+ 4 | 40 | 1
+ 5 | 50 | 1
+(5 rows)
+
+ROLLBACK;
+-- TRUNCATE a base table in aggregate views
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+TRUNCATE mv_base_a;
+SELECT sum, count FROM mv_ivm_agg;
+ sum | count
+-----+-------
+(0 rows)
+
+SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+ i | sum | count
+---+-----+-------
+(0 rows)
+
+ROLLBACK;
+-- support aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_group" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+---------------------
+ 150 | 5 | 30.0000000000000000
+(1 row)
+
+INSERT INTO mv_base_a VALUES(6,60);
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+---------------------
+ 210 | 6 | 35.0000000000000000
+(1 row)
+
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+ROLLBACK;
+-- TRUNCATE a base table in aggregate views without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_group" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+TRUNCATE mv_base_a;
+SELECT sum, count, avg FROM mv_ivm_group;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+ROLLBACK;
+-- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_avg_bug AS SELECT i, SUM(j), COUNT(j), AVG(j) FROM mv_base_A GROUP BY i;
+NOTICE: created index "mv_ivm_avg_bug_index" on materialized view "mv_ivm_avg_bug"
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+INSERT INTO mv_base_a VALUES
+ (1,0),
+ (1,0),
+ (2,30),
+ (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 3 | 3.3333333333333333
+ 2 | 80 | 3 | 26.6666666666666667
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (1,0);
+DELETE FROM mv_base_a WHERE (i,j) = (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+ROLLBACK;
+-- support MIN(), MAX() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_min_max_index" on materialized view "mv_ivm_min_max"
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 10 | 10
+ 2 | 20 | 20
+ 3 | 30 | 30
+ 4 | 40 | 40
+ 5 | 50 | 50
+(5 rows)
+
+INSERT INTO mv_base_a VALUES
+ (1,11), (1,12),
+ (2,21), (2,22),
+ (3,31), (3,32),
+ (4,41), (4,42),
+ (5,51), (5,52);
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 10 | 12
+ 2 | 20 | 22
+ 3 | 30 | 32
+ 4 | 40 | 42
+ 5 | 50 | 52
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) IN ((1,10), (2,21), (3,32));
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 11 | 12
+ 2 | 20 | 22
+ 3 | 30 | 31
+ 4 | 40 | 42
+ 5 | 50 | 52
+(5 rows)
+
+ROLLBACK;
+-- support MIN(), MAX() aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT MIN(j), MAX(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_min_max" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 10 | 50
+(1 row)
+
+INSERT INTO mv_base_a VALUES
+ (0,0), (6,60), (7,70);
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 0 | 70
+(1 row)
+
+DELETE FROM mv_base_a WHERE (i,j) IN ((0,0), (7,70));
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 10 | 60
+(1 row)
+
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ |
+(1 row)
+
+ROLLBACK;
+-- Test MIN/MAX after search_path change
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min AS SELECT MIN(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_min" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 10
+(1 row)
+
+CREATE SCHEMA myschema;
+GRANT ALL ON SCHEMA myschema TO public;
+CREATE TABLE myschema.mv_base_a (j int);
+INSERT INTO myschema.mv_base_a VALUES (1);
+DELETE FROM mv_base_a WHERE (i,j) = (1,10);
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 20
+(1 row)
+
+SET search_path TO myschema,public,pg_catalog;
+DELETE FROM public.mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 30
+(1 row)
+
+ROLLBACK;
+-- aggregate views with column names specified
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ a | sum
+---+------
+ 1 | 110
+ 2 | 2200
+ 3 | 300
+ 4 | 40
+ 5 | 50
+(5 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ a | b
+---+------
+ 1 | 110
+ 2 | 2200
+ 3 | 300
+ 4 | 40
+ 5 | 50
+(5 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b,c) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+ERROR: too many column names were specified
+ROLLBACK;
+-- support self join view and multiple change on the same table
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_self(v1, v2) AS
+ SELECT t1.v, t2.v FROM base_t AS t1 JOIN base_t AS t2 ON t1.i = t2.i;
+NOTICE: could not create an index on materialized view "mv_self" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+----+----
+ 10 | 10
+ 20 | 20
+ 30 | 30
+(3 rows)
+
+INSERT INTO base_t VALUES (4,40);
+DELETE FROM base_t WHERE i = 1;
+UPDATE base_t SET v = v*10 WHERE i=2;
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+-----+-----
+ 30 | 30
+ 40 | 40
+ 200 | 200
+(3 rows)
+
+WITH
+ ins_t1 AS (INSERT INTO base_t VALUES (5,50) RETURNING 1),
+ ins_t2 AS (INSERT INTO base_t VALUES (6,60) RETURNING 1),
+ upd_t AS (UPDATE base_t SET v = v + 100 RETURNING 1),
+ dlt_t AS (DELETE FROM base_t WHERE i IN (4,5) RETURNING 1)
+SELECT NULL;
+ ?column?
+----------
+
+(1 row)
+
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+-----+-----
+ 50 | 50
+ 60 | 60
+ 130 | 130
+ 300 | 300
+(4 rows)
+
+--- with sub-transactions
+SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,70);
+RELEASE SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,77);
+SELECT * FROM mv_self ORDER BY v1, v2;
+ v1 | v2
+-----+-----
+ 50 | 50
+ 60 | 60
+ 70 | 70
+ 70 | 77
+ 77 | 70
+ 77 | 77
+ 130 | 130
+ 300 | 300
+(8 rows)
+
+ROLLBACK;
+-- support simultaneous table changes
+BEGIN;
+CREATE TABLE base_r (i int, v int);
+CREATE TABLE base_s (i int, v int);
+INSERT INTO base_r VALUES (1, 10), (2, 20), (3, 30);
+INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300);
+CREATE INCREMENTAL MATERIALIZED VIEW mv(v1, v2) AS
+ SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i);
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY v1;
+ v1 | v2
+----+-----
+ 10 | 100
+ 20 | 200
+ 30 | 300
+(3 rows)
+
+WITH
+ ins_r AS (INSERT INTO base_r VALUES (1,11) RETURNING 1),
+ ins_r2 AS (INSERT INTO base_r VALUES (3,33) RETURNING 1),
+ ins_s AS (INSERT INTO base_s VALUES (2,222) RETURNING 1),
+ upd_r AS (UPDATE base_r SET v = v + 1000 WHERE i = 2 RETURNING 1),
+ dlt_s AS (DELETE FROM base_s WHERE i = 3 RETURNING 1)
+SELECT NULL;
+ ?column?
+----------
+
+(1 row)
+
+SELECT * FROM mv ORDER BY v1;
+ v1 | v2
+------+-----
+ 10 | 100
+ 11 | 100
+ 1020 | 200
+ 1020 | 222
+(4 rows)
+
+ROLLBACK;
+-- support foreign reference constraints
+BEGIN;
+CREATE TABLE ri1 (i int PRIMARY KEY);
+CREATE TABLE ri2 (i int PRIMARY KEY REFERENCES ri1(i) ON UPDATE CASCADE ON DELETE CASCADE, v int);
+INSERT INTO ri1 VALUES (1),(2),(3);
+INSERT INTO ri2 VALUES (1),(2),(3);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ri(i1, i2) AS
+ SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i);
+NOTICE: created index "mv_ri_index" on materialized view "mv_ri"
+SELECT * FROM mv_ri ORDER BY i1;
+ i1 | i2
+----+----
+ 1 | 1
+ 2 | 2
+ 3 | 3
+(3 rows)
+
+UPDATE ri1 SET i=10 where i=1;
+DELETE FROM ri1 WHERE i=2;
+SELECT * FROM mv_ri ORDER BY i2;
+ i1 | i2
+----+----
+ 3 | 3
+ 10 | 10
+(2 rows)
+
+ROLLBACK;
+-- views including NULL
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1,10),(2, NULL);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY i;
+ i | v
+---+----
+ 1 | 10
+ 2 |
+(2 rows)
+
+UPDATE base_t SET v = 20 WHERE i = 2;
+SELECT * FROM mv ORDER BY i;
+ i | v
+---+----
+ 1 | 10
+ 2 | 20
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY i;
+ i
+---
+(0 rows)
+
+INSERT INTO base_t VALUES (1),(NULL);
+SELECT * FROM mv ORDER BY i;
+ i
+---
+ 1
+
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, sum(v) FROM base_t GROUP BY i;
+NOTICE: created index "mv_index" on materialized view "mv"
+SELECT * FROM mv ORDER BY i;
+ i | sum
+---+-----
+ 1 | 30
+ | 3
+(2 rows)
+
+UPDATE base_t SET v = v * 10;
+SELECT * FROM mv ORDER BY i;
+ i | sum
+---+-----
+ 1 | 300
+ | 30
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, min(v), max(v) FROM base_t GROUP BY i;
+NOTICE: created index "mv_index" on materialized view "mv"
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 1 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 1;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 3;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 5;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 4
+(1 row)
+
+ROLLBACK;
+-- IMMV containing user defined type
+BEGIN;
+CREATE TYPE mytype;
+CREATE FUNCTION mytype_in(cstring)
+ RETURNS mytype AS 'int4in'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+NOTICE: return type mytype is only a shell
+CREATE FUNCTION mytype_out(mytype)
+ RETURNS cstring AS 'int4out'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+NOTICE: argument type mytype is only a shell
+CREATE TYPE mytype (
+ LIKE = int4,
+ INPUT = mytype_in,
+ OUTPUT = mytype_out
+);
+CREATE FUNCTION mytype_eq(mytype, mytype)
+ RETURNS bool AS 'int4eq'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_lt(mytype, mytype)
+ RETURNS bool AS 'int4lt'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_cmp(mytype, mytype)
+ RETURNS integer AS 'btint4cmp'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE OPERATOR = (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_eq);
+CREATE OPERATOR < (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_lt);
+CREATE OPERATOR CLASS mytype_ops
+ DEFAULT FOR TYPE mytype USING btree AS
+ OPERATOR 1 <,
+ OPERATOR 3 = ,
+ FUNCTION 1 mytype_cmp(mytype,mytype);
+CREATE TABLE t_mytype (x mytype);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_mytype AS
+ SELECT * FROM t_mytype;
+NOTICE: could not create an index on materialized view "mv_mytype" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+INSERT INTO t_mytype VALUES ('1'::mytype);
+SELECT * FROM mv_mytype;
+ x
+---
+ 1
+(1 row)
+
+ROLLBACK;
+-- outer join is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv(a,b) AS SELECT a.i, b.i FROM mv_base_a a LEFT JOIN mv_base_b b ON a.i=b.i;
+ERROR: OUTER JOIN is not supported on incrementally maintainable materialized view
+-- CTE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS
+ WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i;
+ERROR: CTE is not supported on incrementally maintainable materialized view
+-- contain system column
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm01 AS SELECT i,j,xmin FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT i,j,xmin::text AS x_min FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm06 AS SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+-- contain subquery
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm03 AS SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 );
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT * FROM mv_base_b) b WHERE a.i = b.i;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm05 AS SELECT i,j, (SELECT k FROM mv_base_b b WHERE a.i = b.i) FROM mv_base_a a;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+-- contain ORDER BY
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) ORDER BY i,j,k;
+ERROR: ORDER BY clause is not supported on incrementally maintainable materialized view
+-- contain HAVING
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) GROUP BY i,j,k HAVING SUM(i) > 5;
+ERROR: HAVING clause is not supported on incrementally maintainable materialized view
+-- contain view or materialized view
+CREATE VIEW b_view AS SELECT i,k FROM mv_base_b;
+CREATE MATERIALIZED VIEW b_mview AS SELECT i,k FROM mv_base_b;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT a.i,a.j FROM mv_base_a a,b_view b WHERE a.i = b.i;
+ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT a.i,a.j FROM mv_base_a a,b_mview b WHERE a.i = b.i;
+ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm09 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) b WHERE a.i = b.i;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm10 AS SELECT a.i,a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) OR a.i > 5;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+-- contain mutable functions
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+ERROR: mutable function is not supported on incrementally maintainable materialized view
+HINT: functions must be marked IMMUTABLE
+-- LIMIT/OFFSET is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm13 AS SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5;
+ERROR: LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view
+-- DISTINCT ON is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm14 AS SELECT DISTINCT ON(i) i, j FROM mv_base_a;
+ERROR: DISTINCT ON is not supported on incrementally maintainable materialized view
+-- TABLESAMPLE clause is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm15 AS SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50);
+ERROR: TABLESAMPLE clause is not supported on incrementally maintainable materialized view
+-- window functions are not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm16 AS SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a;
+ERROR: window functions are not supported on incrementally maintainable materialized view
+-- aggregate function with some options is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm17 AS SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a;
+ERROR: aggregate function with FILTER clause is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm18 AS SELECT COUNT(DISTINCT i) FROM mv_base_a;
+ERROR: aggregate function with DISTINCT arguments is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm19 AS SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a;
+ERROR: aggregate function with ORDER clause is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm20 AS SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),());
+ERROR: GROUPING SETS, ROLLUP, or CUBE clauses is not supported on incrementally maintainable materialized view
+-- inheritance parent is not supported
+BEGIN;
+CREATE TABLE parent (i int, v int);
+CREATE TABLE child_a(options text) INHERITS(parent);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm21 AS SELECT * FROM parent;
+ERROR: inheritance parent is not supported on incrementally maintainable materialized view
+ROLLBACK;
+-- UNION statement is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm22 AS SELECT i,j FROM mv_base_a UNION ALL SELECT i,k FROM mv_base_b;;
+ERROR: UNION/INTERSECT/EXCEPT statements are not supported on incrementally maintainable materialized view
+-- empty target list is not allowed with IVM
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm25 AS SELECT FROM mv_base_a;
+ERROR: empty target list is not supported on incrementally maintainable materialized view
+-- FOR UPDATE/SHARE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm26 AS SELECT i,j FROM mv_base_a FOR UPDATE;
+ERROR: FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view
+-- tartget list cannot contain ivm column that start with '__ivm'
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm28 AS SELECT i AS "__ivm_count__" FROM mv_base_a;
+ERROR: column name __ivm_count__ is not supported on incrementally maintainable materialized view
+-- expressions specified in GROUP BY must appear in the target list.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm29 AS SELECT COUNT(i) FROM mv_base_a GROUP BY i;
+ERROR: GROUP BY expression not appearing in select list is not supported on incrementally maintainable materialized view
+-- experssions containing an aggregate is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm30 AS SELECT sum(i)*0.5 FROM mv_base_a;
+ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm31 AS SELECT sum(i)/sum(j) FROM mv_base_a;
+ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view
+-- VALUES is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_only_values1 AS values(1);
+ERROR: VALUES is not supported on incrementally maintainable materialized view
+-- views containing base tables with Row Level Security
+DROP USER IF EXISTS ivm_admin;
+NOTICE: role "ivm_admin" does not exist, skipping
+DROP USER IF EXISTS ivm_user;
+NOTICE: role "ivm_user" does not exist, skipping
+CREATE USER ivm_admin;
+CREATE USER ivm_user;
+--- create a table with RLS
+SET SESSION AUTHORIZATION ivm_admin;
+CREATE TABLE rls_tbl(id int, data text, owner name);
+INSERT INTO rls_tbl VALUES
+ (1,'foo','ivm_user'),
+ (2,'bar','postgres');
+CREATE TABLE num_tbl(id int, num text);
+INSERT INTO num_tbl VALUES
+ (1,'one'),
+ (2,'two'),
+ (3,'three'),
+ (4,'four'),
+ (5,'five'),
+ (6,'six');
+--- Users can access only their own rows
+CREATE POLICY rls_tbl_policy ON rls_tbl FOR SELECT TO PUBLIC USING(owner = current_user);
+ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
+GRANT ALL on rls_tbl TO PUBLIC;
+GRANT ALL on num_tbl TO PUBLIC;
+--- create a view owned by ivm_user
+SET SESSION AUTHORIZATION ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls AS SELECT * FROM rls_tbl;
+NOTICE: could not create an index on materialized view "ivm_rls" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+------+----------
+ 1 | foo | ivm_user
+(1 row)
+
+RESET SESSION AUTHORIZATION;
+--- inserts rows owned by different users
+INSERT INTO rls_tbl VALUES
+ (3,'baz','ivm_user'),
+ (4,'qux','postgres');
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+------+----------
+ 1 | foo | ivm_user
+ 3 | baz | ivm_user
+(2 rows)
+
+--- combination of diffent kinds of commands
+WITH
+ i AS (INSERT INTO rls_tbl VALUES(5,'quux','postgres'), (6,'corge','ivm_user')),
+ u AS (UPDATE rls_tbl SET owner = 'postgres' WHERE id = 1),
+ u2 AS (UPDATE rls_tbl SET owner = 'ivm_user' WHERE id = 2)
+SELECT;
+--
+(1 row)
+
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+-------+----------
+ 2 | bar | ivm_user
+ 3 | baz | ivm_user
+ 6 | corge | ivm_user
+(3 rows)
+
+---
+SET SESSION AUTHORIZATION ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls2 AS SELECT * FROM rls_tbl JOIN num_tbl USING(id);
+NOTICE: could not create an index on materialized view "ivm_rls2" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+RESET SESSION AUTHORIZATION;
+WITH
+ x AS (UPDATE rls_tbl SET data = data || '_2' where id in (3,4)),
+ y AS (UPDATE num_tbl SET num = num || '_2' where id in (3,4))
+SELECT;
+--
+(1 row)
+
+SELECT * FROM ivm_rls2 ORDER BY 1,2,3;
+ id | data | owner | num
+----+-------+----------+---------
+ 2 | bar | ivm_user | two
+ 3 | baz_2 | ivm_user | three_2
+ 6 | corge | ivm_user | six
+(3 rows)
+
+-- automatic index creation
+CREATE TABLE base_a (i int primary key, j int);
+CREATE TABLE base_b (i int primary key, j int);
+--- group by: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx1 AS SELECT i, sum(j) FROM base_a GROUP BY i;
+NOTICE: created index "mv_idx1_index" on materialized view "mv_idx1"
+--- distinct: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx2 AS SELECT DISTINCT j FROM base_a;
+NOTICE: created index "mv_idx2_index" on materialized view "mv_idx2"
+--- with all pkey columns: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx3(i_a, i_b) AS SELECT a.i, b.i FROM base_a a, base_b b;
+NOTICE: created index "mv_idx3_index" on materialized view "mv_idx3"
+--- missing some pkey columns: no index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx4 AS SELECT j FROM base_a;
+NOTICE: could not create an index on materialized view "mv_idx4" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx5 AS SELECT a.i, b.j FROM base_a a, base_b b;
+NOTICE: could not create an index on materialized view "mv_idx5" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+-- cleanup
+DROP TABLE rls_tbl CASCADE;
+NOTICE: drop cascades to 2 other objects
+DETAIL: drop cascades to materialized view ivm_rls
+drop cascades to materialized view ivm_rls2
+DROP TABLE num_tbl CASCADE;
+DROP USER ivm_user;
+DROP USER ivm_admin;
+DROP TABLE mv_base_b CASCADE;
+NOTICE: drop cascades to 3 other objects
+DETAIL: drop cascades to materialized view mv_ivm_1
+drop cascades to view b_view
+drop cascades to materialized view b_mview
+DROP TABLE mv_base_a CASCADE;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 4df9d8503b..21f7247a07 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -78,7 +78,7 @@ test: brin_bloom brin_multi
# psql depends on create_am
# amutils depends on geometry, create_index_spgist, hash_index, brin
# ----------
-test: create_table_like alter_generic alter_operator misc async dbsize merge misc_functions sysviews tsrf tid tidscan tidrangescan collate.icu.utf8 incremental_sort create_role
+test: create_table_like alter_generic alter_operator misc async dbsize merge misc_functions sysviews tsrf tid tidscan tidrangescan collate.icu.utf8 incremental_sort create_role incremental_matview
# collate.*.utf8 tests cannot be run in parallel with each other
test: rules psql psql_crosstab amutils stats_ext collate.linux.utf8 collate.windows.win1252
diff --git a/src/test/regress/sql/incremental_matview.sql b/src/test/regress/sql/incremental_matview.sql
new file mode 100644
index 0000000000..82686f9324
--- /dev/null
+++ b/src/test/regress/sql/incremental_matview.sql
@@ -0,0 +1,533 @@
+-- create a table to use as a basis for views and materialized views in various combinations
+CREATE TABLE mv_base_a (i int, j int);
+INSERT INTO mv_base_a VALUES
+ (1,10),
+ (2,20),
+ (3,30),
+ (4,40),
+ (5,50);
+CREATE TABLE mv_base_b (i int, k int);
+INSERT INTO mv_base_b VALUES
+ (1,101),
+ (2,102),
+ (3,103),
+ (4,104);
+
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_1 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) WITH NO DATA;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+REFRESH MATERIALIZED VIEW mv_ivm_1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+
+-- REFRESH WITH NO DATA
+BEGIN;
+CREATE FUNCTION dummy_ivm_trigger_func() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+
+CREATE CONSTRAINT TRIGGER dummy_ivm_trigger AFTER INSERT
+ON mv_base_a FROM mv_ivm_1 FOR EACH ROW
+EXECUTE PROCEDURE dummy_ivm_trigger_func();
+
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+
+REFRESH MATERIALIZED VIEW mv_ivm_1 WITH NO DATA;
+
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ROLLBACK;
+
+-- immediate maintenance
+BEGIN;
+INSERT INTO mv_base_b VALUES(5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+UPDATE mv_base_a SET j = 0 WHERE i = 1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+DELETE FROM mv_base_b WHERE (i,k) = (5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ROLLBACK;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+
+-- rename of IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS SELECT DISTINCT * FROM mv_base_a;
+ALTER MATERIALIZED VIEW mv_ivm_rename RENAME COLUMN __ivm_count__ TO xxx;
+DROP MATERIALIZED VIEW mv_ivm_rename;
+
+-- unique index on IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_unique AS SELECT DISTINCT * FROM mv_base_a;
+CREATE UNIQUE INDEX ON mv_ivm_unique(__ivm_count__);
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__));
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__ + 1));
+DROP MATERIALIZED VIEW mv_ivm_unique;
+
+-- TRUNCATE a base table in join views
+BEGIN;
+TRUNCATE mv_base_a;
+SELECT * FROM mv_ivm_1;
+ROLLBACK;
+
+BEGIN;
+TRUNCATE mv_base_b;
+SELECT * FROM mv_ivm_1;
+ROLLBACK;
+
+-- some query syntax
+BEGIN;
+CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql'
+ AS 'SELECT 1' IMMUTABLE;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_func AS SELECT * FROM ivm_func();
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_no_tbl AS SELECT 1;
+ROLLBACK;
+
+-- result of materialized view have DISTINCT clause or the duplicate result.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_duplicate AS SELECT j FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_distinct AS SELECT DISTINCT j FROM mv_base_a;
+INSERT INTO mv_base_a VALUES(6,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+DELETE FROM mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ROLLBACK;
+
+-- support SUM(), COUNT() and AVG() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+UPDATE mv_base_a SET j = 200 WHERE (i,j) = (2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+DELETE FROM mv_base_a WHERE (i,j) = (2,200);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ROLLBACK;
+
+-- support COUNT(*) aggregate function
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ROLLBACK;
+
+-- TRUNCATE a base table in aggregate views
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+TRUNCATE mv_base_a;
+SELECT sum, count FROM mv_ivm_agg;
+SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+ROLLBACK;
+
+-- support aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+INSERT INTO mv_base_a VALUES(6,60);
+SELECT * FROM mv_ivm_group ORDER BY 1;
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ROLLBACK;
+
+-- TRUNCATE a base table in aggregate views without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+TRUNCATE mv_base_a;
+SELECT sum, count, avg FROM mv_ivm_group;
+SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+ROLLBACK;
+
+-- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_avg_bug AS SELECT i, SUM(j), COUNT(j), AVG(j) FROM mv_base_A GROUP BY i;
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES
+ (1,0),
+ (1,0),
+ (2,30),
+ (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+DELETE FROM mv_base_a WHERE (i,j) = (1,0);
+DELETE FROM mv_base_a WHERE (i,j) = (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ROLLBACK;
+
+-- support MIN(), MAX() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES
+ (1,11), (1,12),
+ (2,21), (2,22),
+ (3,31), (3,32),
+ (4,41), (4,42),
+ (5,51), (5,52);
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+DELETE FROM mv_base_a WHERE (i,j) IN ((1,10), (2,21), (3,32));
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ROLLBACK;
+
+-- support MIN(), MAX() aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT MIN(j), MAX(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+INSERT INTO mv_base_a VALUES
+ (0,0), (6,60), (7,70);
+SELECT * FROM mv_ivm_min_max;
+DELETE FROM mv_base_a WHERE (i,j) IN ((0,0), (7,70));
+SELECT * FROM mv_ivm_min_max;
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+ROLLBACK;
+
+-- Test MIN/MAX after search_path change
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min AS SELECT MIN(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_min;
+
+CREATE SCHEMA myschema;
+GRANT ALL ON SCHEMA myschema TO public;
+CREATE TABLE myschema.mv_base_a (j int);
+INSERT INTO myschema.mv_base_a VALUES (1);
+
+DELETE FROM mv_base_a WHERE (i,j) = (1,10);
+SELECT * FROM mv_ivm_min;
+
+SET search_path TO myschema,public,pg_catalog;
+DELETE FROM public.mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_min;
+ROLLBACK;
+
+-- aggregate views with column names specified
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b,c) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+ROLLBACK;
+
+-- support self join view and multiple change on the same table
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_self(v1, v2) AS
+ SELECT t1.v, t2.v FROM base_t AS t1 JOIN base_t AS t2 ON t1.i = t2.i;
+SELECT * FROM mv_self ORDER BY v1;
+INSERT INTO base_t VALUES (4,40);
+DELETE FROM base_t WHERE i = 1;
+UPDATE base_t SET v = v*10 WHERE i=2;
+SELECT * FROM mv_self ORDER BY v1;
+WITH
+ ins_t1 AS (INSERT INTO base_t VALUES (5,50) RETURNING 1),
+ ins_t2 AS (INSERT INTO base_t VALUES (6,60) RETURNING 1),
+ upd_t AS (UPDATE base_t SET v = v + 100 RETURNING 1),
+ dlt_t AS (DELETE FROM base_t WHERE i IN (4,5) RETURNING 1)
+SELECT NULL;
+SELECT * FROM mv_self ORDER BY v1;
+
+--- with sub-transactions
+SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,70);
+RELEASE SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,77);
+SELECT * FROM mv_self ORDER BY v1, v2;
+
+ROLLBACK;
+
+-- support simultaneous table changes
+BEGIN;
+CREATE TABLE base_r (i int, v int);
+CREATE TABLE base_s (i int, v int);
+INSERT INTO base_r VALUES (1, 10), (2, 20), (3, 30);
+INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300);
+CREATE INCREMENTAL MATERIALIZED VIEW mv(v1, v2) AS
+ SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i);
+SELECT * FROM mv ORDER BY v1;
+WITH
+ ins_r AS (INSERT INTO base_r VALUES (1,11) RETURNING 1),
+ ins_r2 AS (INSERT INTO base_r VALUES (3,33) RETURNING 1),
+ ins_s AS (INSERT INTO base_s VALUES (2,222) RETURNING 1),
+ upd_r AS (UPDATE base_r SET v = v + 1000 WHERE i = 2 RETURNING 1),
+ dlt_s AS (DELETE FROM base_s WHERE i = 3 RETURNING 1)
+SELECT NULL;
+SELECT * FROM mv ORDER BY v1;
+ROLLBACK;
+
+-- support foreign reference constraints
+BEGIN;
+CREATE TABLE ri1 (i int PRIMARY KEY);
+CREATE TABLE ri2 (i int PRIMARY KEY REFERENCES ri1(i) ON UPDATE CASCADE ON DELETE CASCADE, v int);
+INSERT INTO ri1 VALUES (1),(2),(3);
+INSERT INTO ri2 VALUES (1),(2),(3);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ri(i1, i2) AS
+ SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i);
+SELECT * FROM mv_ri ORDER BY i1;
+UPDATE ri1 SET i=10 where i=1;
+DELETE FROM ri1 WHERE i=2;
+SELECT * FROM mv_ri ORDER BY i2;
+ROLLBACK;
+
+-- views including NULL
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1,10),(2, NULL);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+SELECT * FROM mv ORDER BY i;
+UPDATE base_t SET v = 20 WHERE i = 2;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+SELECT * FROM mv ORDER BY i;
+INSERT INTO base_t VALUES (1),(NULL);
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, sum(v) FROM base_t GROUP BY i;
+SELECT * FROM mv ORDER BY i;
+UPDATE base_t SET v = v * 10;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, min(v), max(v) FROM base_t GROUP BY i;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 1;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 3;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 5;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+-- IMMV containing user defined type
+BEGIN;
+
+CREATE TYPE mytype;
+CREATE FUNCTION mytype_in(cstring)
+ RETURNS mytype AS 'int4in'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_out(mytype)
+ RETURNS cstring AS 'int4out'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE TYPE mytype (
+ LIKE = int4,
+ INPUT = mytype_in,
+ OUTPUT = mytype_out
+);
+
+CREATE FUNCTION mytype_eq(mytype, mytype)
+ RETURNS bool AS 'int4eq'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_lt(mytype, mytype)
+ RETURNS bool AS 'int4lt'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_cmp(mytype, mytype)
+ RETURNS integer AS 'btint4cmp'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+
+CREATE OPERATOR = (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_eq);
+CREATE OPERATOR < (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_lt);
+
+CREATE OPERATOR CLASS mytype_ops
+ DEFAULT FOR TYPE mytype USING btree AS
+ OPERATOR 1 <,
+ OPERATOR 3 = ,
+ FUNCTION 1 mytype_cmp(mytype,mytype);
+
+CREATE TABLE t_mytype (x mytype);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_mytype AS
+ SELECT * FROM t_mytype;
+INSERT INTO t_mytype VALUES ('1'::mytype);
+SELECT * FROM mv_mytype;
+
+ROLLBACK;
+
+-- outer join is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv(a,b) AS SELECT a.i, b.i FROM mv_base_a a LEFT JOIN mv_base_b b ON a.i=b.i;
+-- CTE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS
+ WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i;
+-- contain system column
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm01 AS SELECT i,j,xmin FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT i,j,xmin::text AS x_min FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm06 AS SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a;
+-- contain subquery
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm03 AS SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 );
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT * FROM mv_base_b) b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm05 AS SELECT i,j, (SELECT k FROM mv_base_b b WHERE a.i = b.i) FROM mv_base_a a;
+-- contain ORDER BY
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) ORDER BY i,j,k;
+-- contain HAVING
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) GROUP BY i,j,k HAVING SUM(i) > 5;
+
+-- contain view or materialized view
+CREATE VIEW b_view AS SELECT i,k FROM mv_base_b;
+CREATE MATERIALIZED VIEW b_mview AS SELECT i,k FROM mv_base_b;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT a.i,a.j FROM mv_base_a a,b_view b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT a.i,a.j FROM mv_base_a a,b_mview b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm09 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm10 AS SELECT a.i,a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) OR a.i > 5;
+
+-- contain mutable functions
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+
+-- LIMIT/OFFSET is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm13 AS SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5;
+
+-- DISTINCT ON is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm14 AS SELECT DISTINCT ON(i) i, j FROM mv_base_a;
+
+-- TABLESAMPLE clause is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm15 AS SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50);
+
+-- window functions are not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm16 AS SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a;
+
+-- aggregate function with some options is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm17 AS SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm18 AS SELECT COUNT(DISTINCT i) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm19 AS SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm20 AS SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),());
+
+-- inheritance parent is not supported
+BEGIN;
+CREATE TABLE parent (i int, v int);
+CREATE TABLE child_a(options text) INHERITS(parent);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm21 AS SELECT * FROM parent;
+ROLLBACK;
+
+-- UNION statement is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm22 AS SELECT i,j FROM mv_base_a UNION ALL SELECT i,k FROM mv_base_b;;
+
+-- empty target list is not allowed with IVM
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm25 AS SELECT FROM mv_base_a;
+
+-- FOR UPDATE/SHARE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm26 AS SELECT i,j FROM mv_base_a FOR UPDATE;
+
+-- tartget list cannot contain ivm column that start with '__ivm'
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm28 AS SELECT i AS "__ivm_count__" FROM mv_base_a;
+
+-- expressions specified in GROUP BY must appear in the target list.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm29 AS SELECT COUNT(i) FROM mv_base_a GROUP BY i;
+
+-- experssions containing an aggregate is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm30 AS SELECT sum(i)*0.5 FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm31 AS SELECT sum(i)/sum(j) FROM mv_base_a;
+
+-- VALUES is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_only_values1 AS values(1);
+
+-- views containing base tables with Row Level Security
+DROP USER IF EXISTS ivm_admin;
+DROP USER IF EXISTS ivm_user;
+CREATE USER ivm_admin;
+CREATE USER ivm_user;
+
+--- create a table with RLS
+SET SESSION AUTHORIZATION ivm_admin;
+CREATE TABLE rls_tbl(id int, data text, owner name);
+INSERT INTO rls_tbl VALUES
+ (1,'foo','ivm_user'),
+ (2,'bar','postgres');
+CREATE TABLE num_tbl(id int, num text);
+INSERT INTO num_tbl VALUES
+ (1,'one'),
+ (2,'two'),
+ (3,'three'),
+ (4,'four'),
+ (5,'five'),
+ (6,'six');
+
+--- Users can access only their own rows
+CREATE POLICY rls_tbl_policy ON rls_tbl FOR SELECT TO PUBLIC USING(owner = current_user);
+ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
+GRANT ALL on rls_tbl TO PUBLIC;
+GRANT ALL on num_tbl TO PUBLIC;
+
+--- create a view owned by ivm_user
+SET SESSION AUTHORIZATION ivm_user;
+
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls AS SELECT * FROM rls_tbl;
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+RESET SESSION AUTHORIZATION;
+
+--- inserts rows owned by different users
+INSERT INTO rls_tbl VALUES
+ (3,'baz','ivm_user'),
+ (4,'qux','postgres');
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+
+--- combination of diffent kinds of commands
+WITH
+ i AS (INSERT INTO rls_tbl VALUES(5,'quux','postgres'), (6,'corge','ivm_user')),
+ u AS (UPDATE rls_tbl SET owner = 'postgres' WHERE id = 1),
+ u2 AS (UPDATE rls_tbl SET owner = 'ivm_user' WHERE id = 2)
+SELECT;
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+
+---
+SET SESSION AUTHORIZATION ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls2 AS SELECT * FROM rls_tbl JOIN num_tbl USING(id);
+RESET SESSION AUTHORIZATION;
+
+WITH
+ x AS (UPDATE rls_tbl SET data = data || '_2' where id in (3,4)),
+ y AS (UPDATE num_tbl SET num = num || '_2' where id in (3,4))
+SELECT;
+SELECT * FROM ivm_rls2 ORDER BY 1,2,3;
+
+-- automatic index creation
+CREATE TABLE base_a (i int primary key, j int);
+CREATE TABLE base_b (i int primary key, j int);
+
+--- group by: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx1 AS SELECT i, sum(j) FROM base_a GROUP BY i;
+
+--- distinct: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx2 AS SELECT DISTINCT j FROM base_a;
+
+--- with all pkey columns: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx3(i_a, i_b) AS SELECT a.i, b.i FROM base_a a, base_b b;
+
+--- missing some pkey columns: no index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx4 AS SELECT j FROM base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx5 AS SELECT a.i, b.j FROM base_a a, base_b b;
+
+-- cleanup
+
+DROP TABLE rls_tbl CASCADE;
+DROP TABLE num_tbl CASCADE;
+DROP USER ivm_user;
+DROP USER ivm_admin;
+
+DROP TABLE mv_base_b CASCADE;
+DROP TABLE mv_base_a CASCADE;
--
2.25.1
v29-0011-Add-documentations-about-Incremental-View-Mainte.patchtext/x-diff; name=v29-0011-Add-documentations-about-Incremental-View-Mainte.patchDownload
From d256ff90302143288896010ad941b1aa45e1aec3 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:25:34 +0900
Subject: [PATCH v29 11/11] Add documentations about Incremental View
Maintenance
---
doc/src/sgml/catalogs.sgml | 9 +
.../sgml/ref/create_materialized_view.sgml | 124 ++++-
.../sgml/ref/refresh_materialized_view.sgml | 8 +-
doc/src/sgml/rules.sgml | 437 ++++++++++++++++++
doc/src/sgml/system-views.sgml | 9 +
5 files changed, 583 insertions(+), 4 deletions(-)
diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index d17ff51e28..3de3303cac 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -2224,6 +2224,15 @@ SCRAM-SHA-256$<replaceable><iteration count></replaceable>:<replaceable>&l
</para></entry>
</row>
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>relisivm</structfield> <type>bool</type>
+ </para>
+ <para>
+ True if relation is incrementally maintainable materialized view
+ </para></entry>
+ </row>
+
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>relrewrite</structfield> <type>oid</type>
diff --git a/doc/src/sgml/ref/create_materialized_view.sgml b/doc/src/sgml/ref/create_materialized_view.sgml
index 0d2fea2b97..8c574062db 100644
--- a/doc/src/sgml/ref/create_materialized_view.sgml
+++ b/doc/src/sgml/ref/create_materialized_view.sgml
@@ -21,7 +21,7 @@ PostgreSQL documentation
<refsynopsisdiv>
<synopsis>
-CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
+CREATE [ INCREMENTAL ] MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
[ (<replaceable>column_name</replaceable> [, ...] ) ]
[ USING <replaceable class="parameter">method</replaceable> ]
[ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
@@ -60,6 +60,125 @@ CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
<title>Parameters</title>
<variablelist>
+ <varlistentry>
+ <term><literal>INCREMENTAL</literal></term>
+ <listitem>
+ <para>
+ If specified, some triggers are automatically created so that the rows
+ of the materialized view are immediately updated when base tables of the
+ materialized view are updated. In general, this allows faster update of
+ the materialized view at a price of slower update of the base tables
+ because the triggers will be invoked. We call this form of materialized
+ view as "Incrementally Maintainable Materialized View" (IMMV).
+ </para>
+ <para>
+ When <acronym>IMMV</acronym> is defined without using <command>WITH NO DATA</command>,
+ a unique index is created on the view automatically if possible. If the view
+ definition query has a GROUP BY clause, a unique index is created on the columns
+ of GROUP BY expressions. Also, if the view has DISTINCT clause, a unique index
+ is created on all columns in the target list. Otherwise, if the view contains all
+ primary key attritubes of its base tables in the target list, a unique index is
+ created on these attritubes. In other cases, no index is created.
+ </para>
+ <para>
+ There are restrictions of query definitions allowed to use this
+ option. The following are supported in query definitions for IMMV:
+ <itemizedlist>
+
+ <listitem>
+ <para>
+ Inner joins (including self-joins).
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Some built-in aggregate functions (count, sum, avg, min, max) without a HAVING
+ clause.
+ </para>
+ </listitem>
+ </itemizedlist>
+
+ Unsupported queries with this option include the following:
+
+ <itemizedlist>
+ <listitem>
+ <para>
+ Outer joins.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Sub-queries.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Aggregate functions other than built-in count, sum, avg, min and max.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ Aggregate functions with a HAVING clause.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ DISTINCT ON, WINDOW, VALUES, LIMIT and OFFSET clause.
+ </para>
+ </listitem>
+ </itemizedlist>
+
+ Other restrictions include:
+ <itemizedlist>
+
+ <listitem>
+ <para>
+ IMMVs must be based on simple base tables. It's not supported to
+ create them on top of views or materialized views.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ It is not supported to include system columns in an IMMV.
+ <programlisting>
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+ERROR: system column is not supported with IVM
+ </programlisting>
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Non-immutable functions are not supported.
+ <programlisting>
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+ERROR: functions in IMMV must be marked IMMUTABLE
+ </programlisting>
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ IMMVs do not support expressions that contains aggregates
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Logical replication does not support IMMVs.
+ </para>
+ </listitem>
+
+ </itemizedlist>
+
+ </para>
+ </listitem>
+ </varlistentry>
+
<varlistentry>
<term><literal>IF NOT EXISTS</literal></term>
<listitem>
@@ -155,7 +274,8 @@ CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
This clause specifies whether or not the materialized view should be
populated at creation time. If not, the materialized view will be
flagged as unscannable and cannot be queried until <command>REFRESH
- MATERIALIZED VIEW</command> is used.
+ MATERIALIZED VIEW</command> is used. Also, if the view is IMMV,
+ triggers for maintaining the view are not created.
</para>
</listitem>
</varlistentry>
diff --git a/doc/src/sgml/ref/refresh_materialized_view.sgml b/doc/src/sgml/ref/refresh_materialized_view.sgml
index 675d6090f3..c29cfc19b6 100644
--- a/doc/src/sgml/ref/refresh_materialized_view.sgml
+++ b/doc/src/sgml/ref/refresh_materialized_view.sgml
@@ -35,9 +35,13 @@ REFRESH MATERIALIZED VIEW [ CONCURRENTLY ] <replaceable class="parameter">name</
owner of the materialized view. The old contents are discarded. If
<literal>WITH DATA</literal> is specified (or defaults) the backing query
is executed to provide the new data, and the materialized view is left in a
- scannable state. If <literal>WITH NO DATA</literal> is specified no new
+ scannable state. If the view is an incrementally maintainable materialized
+ view (IMMV) and was 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 <literal>WITH NO DATA</literal> is specified no new
data is generated and the materialized view is left in an unscannable
- state.
+ state. If the view is IMMV, the triggers are dropped.
</para>
<para>
<literal>CONCURRENTLY</literal> and <literal>WITH NO DATA</literal> may not
diff --git a/doc/src/sgml/rules.sgml b/doc/src/sgml/rules.sgml
index d229b94d39..22e4cad103 100644
--- a/doc/src/sgml/rules.sgml
+++ b/doc/src/sgml/rules.sgml
@@ -1096,6 +1096,443 @@ SELECT word FROM words ORDER BY word <-> 'caterpiler' LIMIT 10;
</sect1>
+<sect1 id="rules-ivm">
+<title>Incremental View Maintenance</title>
+
+<indexterm zone="rules-ivm">
+ <primary>incremental view maintenance</primary>
+</indexterm>
+
+<indexterm zone="rules-ivm">
+ <primary>materialized view</primary>
+ <secondary>incremental view maintenance</secondary>
+</indexterm>
+
+<indexterm zone="rules-ivm">
+ <primary>view</primary>
+ <secondary>incremental view maintenance</secondary>
+</indexterm>
+
+<sect2 id="rules-ivm-overview">
+<title>Overview</title>
+
+<para>
+ Incremental View Maintenance (<acronym>IVM</acronym>) is a way to make
+ materialized views up-to-date in which only incremental changes are computed
+ and applied on views rather than recomputing the contents from scratch as
+ <command>REFRESH MATERIALIZED VIEW</command> does. <acronym>IVM</acronym>
+ can update materialized views more efficiently than recomputation when only
+ small parts of the view are changed.
+</para>
+
+<para>
+ There are two approaches with regard to timing of view maintenance:
+ immediate and deferred. In immediate maintenance, views are updated in the
+ same transaction that its base table is modified. In deferred maintenance,
+ views are updated after the transaction is committed, for example, when the
+ view is accessed, as a response to user command like <command>REFRESH
+ MATERIALIZED VIEW</command>, or periodically in background, and so on.
+ <productname>PostgreSQL</productname> currently implements only a kind of
+ immediate maintenance, in which materialized views are updated immediately
+ in AFTER triggers when a base table is modified.
+</para>
+
+<para>
+ To create materialized views supporting <acronym>IVM</acronym>, use the
+ <command>CREATE INCREMENTAL MATERIALIZED VIEW</command>, for example:
+<programlisting>
+CREATE <emphasis>INCREMENTAL</emphasis> MATERIALIZED VIEW mymatview AS SELECT * FROM mytab;
+</programlisting>
+ When a materialized view is created with the <literal>INCREMENTAL</literal>
+ keyword, some triggers are automatically created so that the view's contents are
+ immediately updated when its base tables are modified. We call this form
+ of materialized view an Incrementally Maintainable Materialized View
+ (<acronym>IMMV</acronym>).
+<programlisting>
+postgres=# CREATE INCREMENTAL MATERIALIZED VIEW m AS SELECT * FROM t0;
+NOTICE: could not create an index on materialized view "m" automatically
+HINT: Create an index on the materialized view for effcient incremental maintenance.
+SELECT 3
+postgres=# SELECT * FROM m;
+ i
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+postgres=# INSERT INTO t0 VALUES (4);
+INSERT 0 1
+postgres=# SELECT * FROM m; -- automatically updated
+ i
+---
+ 1
+ 2
+ 3
+ 4
+(4 rows)
+</programlisting>
+</para>
+
+<para>
+ Some <acronym>IMMV</acronym>s have hidden columns which are added
+ automatically when a materialized view is created. Their name starts
+ with <literal>__ivm_</literal> and they contain information required
+ for maintaining the <acronym>IMMV</acronym>. Such columns are not visible
+ when the <acronym>IMMV</acronym> is accessed by <literal>SELECT *</literal>
+ but are visible if the column name is explicitly specified in the target
+ list. We can also see the hidden columns in <literal>\d</literal>
+ meta-commands of <command>psql</command> commands.
+</para>
+
+<para>
+ In general, <acronym>IMMV</acronym>s allow faster updates of materialized
+ views at the price of slower updates to their base tables. Updates of
+ <acronym>IMMV</acronym> is slower because triggers will be invoked and the
+ view is updated in triggers per modification statement.
+</para>
+
+<para>
+ For example, suppose a normal materialized view defined as below:
+
+<programlisting>
+test=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm AS
+ SELECT a.aid, b.bid, a.abalance, b.bbalance
+ FROM pgbench_accounts a JOIN pgbench_branches b USING(bid);
+SELECT 10000000
+
+</programlisting>
+
+ Updating a tuple in a base table of this materialized view is rapid but the
+ <command>REFRESH MATERIALIZED VIEW</command> command on this view takes a long time:
+
+<programlisting>
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 0.990 ms
+
+test=# REFRESH MATERIALIZED VIEW mv_normal ;
+REFRESH MATERIALIZED VIEW
+Time: 33533.952 ms (00:33.534)
+</programlisting>
+</para>
+
+<para>
+ On the other hand, after creating <acronym>IMMV</acronym> with the same view
+ definition as below:
+
+<programlisting>
+test=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm AS
+ SELECT a.aid, b.bid, a.abalance, b.bbalance
+ FROM pgbench_accounts a JOIN pgbench_branches b USING(bid);
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+NOTICE: created index "mv_ivm_index" on materialized view "mv_ivm"
+</programlisting>
+
+ updating a tuple in a base table takes more than the normal view,
+ but its content is updated automatically and this is faster than the
+ <command>REFRESH MATERIALIZED VIEW</command> command.
+
+<programlisting>
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 13.068 ms
+</programlisting>
+
+</para>
+
+<para>
+ Appropriate indexes on <acronym>IMMV</acronym>s are necessary for
+ efficient <acronym>IVM</acronym> because it looks for tuples to be
+ updated in <acronym>IMMV</acronym>. If there are no indexes, it
+ will take a long time.
+</para>
+
+<para>
+ Therefore, when <acronym>IMMV</acronym> is defined, a unique index is created on the view
+ automatically if possible. If the view definition query has a GROUP BY clause, a unique
+ index is created on the columns of GROUP BY expressions. Also, if the view has DISTINCT
+ clause, a unique index is created on all columns in the target list. Otherwise, if the
+ view contains all primary key attritubes of its base tables in the target list, a unique
+ index is created on these attritubes. In other cases, no index is created.
+</para>
+
+<para>
+ In the previous example, a unique index "mv_ivm_index" is created on aid and bid
+ columns of materialized view "mv_ivm", and this enables the rapid update of the view.
+ Dropping this index make updating the view take a loger time.
+<programlisting>
+test=# DROP INDEX mv_ivm_index;
+DROP INDEX
+Time: 67.081 ms
+
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 16386.245 ms (00:16.386)
+</programlisting>
+
+</para>
+
+<para>
+ <acronym>IVM</acronym> is effective when we want to keep a materialized
+ view up-to-date and small fraction of a base table is modified
+ infrequently. Due to the overhead of immediate maintenance, <acronym>IVM</acronym>
+ 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, <acronym>IVM</acronym> is not effective and the cost of
+ maintenance can be larger than the <command>REFRESH MATERIALIZED VIEW</command>
+ command. In such situation, we can use <command>REFRESH MATERIALIZED VIEW</command>
+ and specify <literal>WITH NO DATA</literal> to disable immediate
+ maintenance before modifying a base table. After a base table modification,
+ execute the <command>REFRESH MATERIALIZED VIEW</command> (with <literal>WITH DATA</literal>)
+ command to refresh the view data and enable immediate maintenance.
+</para>
+
+</sect2>
+
+<sect2 id="rules-ivm-support">
+<title>Supported View Definitions and Restrictions</title>
+
+<para>
+ Currently, we can create <acronym>IMMV</acronym>s using inner joins, and some
+ aggregates. However, several restrictions apply to the definition of IMMV.
+</para>
+
+<sect3 id="rules-ivm-support-joins">
+<title>Joins</title>
+<para>
+ Inner joins including self-join are supported. Outer joins are not supported.
+</para>
+</sect3>
+
+<sect3 id="rules-ivm-support-aggregates">
+<title>Aggregates</title>
+<para>
+ Supported aggregate functions are <function>count</function>, <function>sum</function>,
+ <function>avg</function>, <function>min</function>, and <function>max</function>.
+ Currently, only built-in aggregate functions are supported and user defined
+ aggregates cannot be used. When a base table is modified, the new aggregated
+ values are incrementally calculated using the old aggregated values and values
+ of related hidden columns stored in <acronym>IMMV</acronym>.
+</para>
+
+<para>
+ Note that for <function>min</function> or <function>max</function>, the new values
+ could be re-calculated from base tables with regard to the affected groups when a
+ tuple containing the current minimal or maximal values are deleted from a base table.
+ Therefore, it can takes a long time to update an <acronym>IMMV</acronym> containing
+ these functions.
+</para>
+
+<para>
+ Also note that using <function>sum</function> or <function>avg</function> on
+ <type>real</type> (<type>float4</type>) type or <type>double precision</type>
+ (<type>float8</type>) type in <acronym>IMMV</acronym> is unsafe. This is
+ because aggregated values in <acronym>IMMV</acronym> can become different from
+ results calculated from base tables due to the limited precision of these types.
+ To avoid this problem, use the <type>numeric</type> type instead.
+</para>
+
+ <sect4 id="rules-ivm-restrictions-aggregates">
+ <title>Restrictions on Aggregates</title>
+ <para>
+ There are the following restrictions:
+ <itemizedlist>
+ <listitem>
+ <para>
+ If we have a <literal>GROUP BY</literal> clause, expressions specified in
+ <literal>GROUP BY</literal> must appear in the target list. This is
+ how tuples to be updated in the <acronym>IMMV</acronym> are identified.
+ These attributes are used as scan keys for searching tuples in the
+ <acronym>IMMV</acronym>, so indexes on them are required for efficient
+ <acronym>IVM</acronym>.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <literal>HAVING</literal> clause cannot be used.
+ </para>
+ </listitem>
+ </itemizedlist>
+ </para>
+ </sect4>
+</sect3>
+
+<sect3 id="rules-ivm-general-restricitons">
+<title>Other General Restrictions</title>
+<para>
+ There are other restrictions which generally apply to <acronym>IMMV</acronym>:
+ <itemizedlist>
+ <listitem>
+ <para>
+ Sub-queries cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ CTEs cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Window functions cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s must be based on simple base tables. It's not
+ supported to create them on top of views, materialized views, foreign tables, inhe.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ LIMIT and OFFSET clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s cannot contain system columns.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s cannot contain non-immutable functions.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ UNION/INTERSECT/EXCEPT clauses cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ DISTINCT ON clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ TABLESAMPLE parameter cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ inheritance parent tables cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ VALUES clause cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <literal>GROUPING SETS</literal> and <literal>FILTER</literal> clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ FOR UPDATE/SHARE cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ targetlist cannot contain columns whose name start with <literal>__ivm_</literal>.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ targetlist cannot contain expressions which contain an aggregate in it.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Logical replication is not supported, that is, even when a base table
+ at a publisher node is modified, <acronym>IMMV</acronym>s at subscriber
+ nodes are not updated.
+ </para>
+ </listitem>
+
+ </itemizedlist>
+</para>
+</sect3>
+
+</sect2>
+
+<sect2 id="rules-ivm-distinct">
+<title><literal>DISTINCT</literal></title>
+
+<para>
+ <productname>PostgreSQL</productname> supports <acronym>IMMV</acronym> with
+ <literal>DISTINCT</literal>. For example, suppose a <acronym>IMMV</acronym>
+ defined with <literal>DISTINCT</literal> on a base table containing duplicate
+ tuples. When tuples are deleted from the base table, a tuple in the view is
+ deleted if and only if the multiplicity of the tuple becomes zero. Moreover,
+ when tuples are inserted into the base table, a tuple is inserted into the
+ view only if the same tuple doesn't already exist in it.
+</para>
+
+<para>
+ Physically, an <acronym>IMMV</acronym> defined with <literal>DISTINCT</literal>
+ contains tuples after eliminating duplicates, and the multiplicity of each tuple
+ is stored in a hidden column named <literal>__ivm_count__</literal>.
+</para>
+</sect2>
+
+<sect2 id="rules-ivm-concurrent-transactions">
+<title>Concurrent Transactions</title>
+<para>
+ Suppose an <acronym>IMMV</acronym> is defined on two base tables and each
+ table was modified in different a concurrent transaction simultaneously.
+ In the transaction which was committed first, <acronym>IMMV</acronym> can
+ be updated considering only the change which happened in this transaction.
+ On the other hand, in order to update the view correctly in the transaction
+ which was committed later, we need to know the changes occurred in
+ both transactions. For this reason, <literal>ExclusiveLock</literal>
+ is held on an <acronym>IMMV</acronym> immediately after a base table is
+ modified in <literal>READ COMMITTED</literal> mode to make sure that
+ the <acronym>IMMV</acronym> is updated in the latter transaction after
+ the former transaction is committed. In <literal>REPEATABLE READ</literal>
+ or <literal>SERIALIZABLE</literal> mode, an error is raised immediately
+ if lock acquisition fails because any changes which occurred in
+ other transactions are not be visible in these modes and
+ <acronym>IMMV</acronym> cannot be updated correctly in such situations.
+ However, as an exception if the view has only one base table and
+ <command>INSERT</command> is performed on the table,
+ the lock held on thew view is <literal>RowExclusiveLock</literal>.
+</para>
+</sect2>
+
+<sect2 id="rules-ivm-rls">
+<title>Row Level Security</title>
+<para>
+ If some base tables have row level security policy, rows that are not visible
+ to the materialized view's owner are excluded from the result. In addition, such
+ rows are excluded as well when views are incrementally maintained. However, if a
+ new policy is defined or policies are changed after the materialized view was created,
+ the new policy will not be applied to the view contents. To apply the new policy,
+ you need to refresh materialized views.
+</para>
+</sect2>
+
+</sect1>
+
<sect1 id="rules-update">
<title>Rules on <command>INSERT</command>, <command>UPDATE</command>, and <command>DELETE</command></title>
diff --git a/doc/src/sgml/system-views.sgml b/doc/src/sgml/system-views.sgml
index 2b35c2f91b..5366f707eb 100644
--- a/doc/src/sgml/system-views.sgml
+++ b/doc/src/sgml/system-views.sgml
@@ -1787,6 +1787,15 @@ SELECT * FROM pg_locks pl LEFT JOIN pg_prepared_xacts ppx
</para></entry>
</row>
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>isimmv</structfield> <type>bool</type>
+ </para>
+ <para>
+ True if materialized view is incrementally maintainable
+ </para></entry>
+ </row>
+
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>definition</structfield> <type>text</type>
--
2.25.1
On Mon, 28 Aug 2023 11:52:52 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:
On Mon, 28 Aug 2023 02:49:08 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:On Sun, 2 Jul 2023 10:38:20 +0800
jian he <jian.universality@gmail.com> wrote:I attahed the patches v29 updated to comments from jian he.
The changes from the previous includes:- errors in documentations is fixed.
- remove unnecessary BEGIN from the test
- add isimmv column to pg_matviews system view
- fix a typo
- rebase to the master branch
I found pg_dump test was broken, so attached the fixed version.
Regards,
Yugo Nagata
ok. Now I really found a small bug.
this works as intended:
BEGIN;
CREATE INCREMENTAL MATERIALIZED VIEW test_ivm AS SELECT i, MIN(j) as
min_j FROM mv_base_a group by 1;
INSERT INTO mv_base_a select 1,-2 where false;
rollback;however the following one:
BEGIN;
CREATE INCREMENTAL MATERIALIZED VIEW test_ivm1 AS SELECT MIN(j) as
min_j FROM mv_base_a;
INSERT INTO mv_base_a select 1, -2 where false;
rollback;will evaluate
tuplestore_tuple_count(new_tuplestores) to 1, it will walk through
IVM_immediate_maintenance function to apply_delta.
but should it be zero?This is not a bug because an aggregate without GROUP BY always
results one row whose value is NULL.The contents of test_imv1 would be always same as " SELECT MIN(j) as min_j
FROM mv_base_a;", isn't it?Regards,
Yugo Nagata--
Yugo NAGATA <nagata@sraoss.co.jp>--
Yugo NAGATA <nagata@sraoss.co.jp>
--
Yugo NAGATA <nagata@sraoss.co.jp>
Attachments:
v29-0001-Add-a-syntax-to-create-Incrementally-Maintainabl.patchtext/x-diff; name=v29-0001-Add-a-syntax-to-create-Incrementally-Maintainabl.patchDownload
From 2f52a958a3c4e36be3eb7cb23eb11f13bf9092a6 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:05:02 +0900
Subject: [PATCH v29 01/11] Add a syntax to create Incrementally Maintainable
Materialized Views
Allow to create Incrementally Maintainable Materialized View (IMMV)
by using INCREMENTAL option in CREATE MATERIALIZED VIEW command
as follow:
CREATE [INCREMANTAL] MATERIALIZED VIEW xxxxx AS SELECT ....;
---
src/backend/parser/gram.y | 32 +++++++++++++++++++++-----------
src/include/nodes/primnodes.h | 1 +
src/include/parser/kwlist.h | 1 +
3 files changed, 23 insertions(+), 11 deletions(-)
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 7d2032885e..33c647b0c7 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -465,6 +465,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <range> OptTempTableName
%type <into> into_clause create_as_target create_mv_target
+%type <boolean> incremental
%type <defelt> createfunc_opt_item common_func_opt_item dostmt_opt_item
%type <fun_param> func_arg func_arg_with_default table_func_column aggr_arg
@@ -718,7 +719,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
HANDLER HAVING HEADER_P HOLD HOUR_P
IDENTITY_P IF_P ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IMPORT_P IN_P INCLUDE
- INCLUDING INCREMENT INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
+ INCLUDING INCREMENT INCREMENTAL INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
@@ -4652,32 +4653,34 @@ opt_with_data:
*****************************************************************************/
CreateMatViewStmt:
- CREATE OptNoLog MATERIALIZED VIEW create_mv_target AS SelectStmt opt_with_data
+ CREATE OptNoLog incremental MATERIALIZED VIEW create_mv_target AS SelectStmt opt_with_data
{
CreateTableAsStmt *ctas = makeNode(CreateTableAsStmt);
- ctas->query = $7;
- ctas->into = $5;
+ ctas->query = $8;
+ ctas->into = $6;
ctas->objtype = OBJECT_MATVIEW;
ctas->is_select_into = false;
ctas->if_not_exists = false;
/* cram additional flags into the IntoClause */
- $5->rel->relpersistence = $2;
- $5->skipData = !($8);
+ $6->rel->relpersistence = $2;
+ $6->skipData = !($9);
+ $6->ivm = $3;
$$ = (Node *) ctas;
}
- | CREATE OptNoLog MATERIALIZED VIEW IF_P NOT EXISTS create_mv_target AS SelectStmt opt_with_data
+ | CREATE OptNoLog incremental MATERIALIZED VIEW IF_P NOT EXISTS create_mv_target AS SelectStmt opt_with_data
{
CreateTableAsStmt *ctas = makeNode(CreateTableAsStmt);
- ctas->query = $10;
- ctas->into = $8;
+ ctas->query = $11;
+ ctas->into = $9;
ctas->objtype = OBJECT_MATVIEW;
ctas->is_select_into = false;
ctas->if_not_exists = true;
/* cram additional flags into the IntoClause */
- $8->rel->relpersistence = $2;
- $8->skipData = !($11);
+ $9->rel->relpersistence = $2;
+ $9->skipData = !($12);
+ $9->ivm = $3;
$$ = (Node *) ctas;
}
;
@@ -4694,9 +4697,14 @@ create_mv_target:
$$->tableSpaceName = $5;
$$->viewQuery = NULL; /* filled at analysis time */
$$->skipData = false; /* might get changed later */
+ $$->ivm = false;
}
;
+incremental: INCREMENTAL { $$ = true; }
+ | /*EMPTY*/ { $$ = false; }
+ ;
+
OptNoLog: UNLOGGED { $$ = RELPERSISTENCE_UNLOGGED; }
| /*EMPTY*/ { $$ = RELPERSISTENCE_PERMANENT; }
;
@@ -17141,6 +17149,7 @@ unreserved_keyword:
| INCLUDE
| INCLUDING
| INCREMENT
+ | INCREMENTAL
| INDENT
| INDEX
| INDEXES
@@ -17709,6 +17718,7 @@ bare_label_keyword:
| INCLUDE
| INCLUDING
| INCREMENT
+ | INCREMENTAL
| INDENT
| INDEX
| INDEXES
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 60d72a876b..cecb968b36 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -146,6 +146,7 @@ typedef struct IntoClause
/* materialized view's SELECT query */
Node *viewQuery pg_node_attr(query_jumble_ignore);
bool skipData; /* true for WITH NO DATA */
+ bool ivm; /* true for WITH IVM */
} IntoClause;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 5984dcfa4b..d60eb98d65 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -207,6 +207,7 @@ PG_KEYWORD("in", IN_P, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("include", INCLUDE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("including", INCLUDING, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("increment", INCREMENT, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("incremental", INCREMENTAL, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("indent", INDENT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("index", INDEX, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("indexes", INDEXES, UNRESERVED_KEYWORD, BARE_LABEL)
--
2.25.1
v29-0002-Add-relisivm-column-to-pg_class-system-catalog.patchtext/x-diff; name=v29-0002-Add-relisivm-column-to-pg_class-system-catalog.patchDownload
From 2a6a9670bf78f8a18366bf29c23488f929928982 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:07:23 +0900
Subject: [PATCH v29 02/11] Add relisivm column to pg_class system catalog
If this boolean column is true, a relations is Incrementally Maintainable
Materialized View (IMMV). This is set when IMMV is created.
Also, isimmv columns is added to pg_matviews system view.
isimmv
---
src/backend/catalog/heap.c | 1 +
src/backend/catalog/index.c | 1 +
src/backend/catalog/system_views.sql | 1 +
src/backend/utils/cache/lsyscache.c | 24 ++++++++++++++++++++++++
src/backend/utils/cache/relcache.c | 2 ++
src/include/catalog/pg_class.h | 3 +++
src/include/utils/lsyscache.h | 1 +
src/include/utils/rel.h | 2 ++
src/test/regress/expected/rules.out | 1 +
9 files changed, 36 insertions(+)
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index b534da7d80..d9eac41463 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -924,6 +924,7 @@ InsertPgClassTuple(Relation pg_class_desc,
values[Anum_pg_class_relrewrite - 1] = ObjectIdGetDatum(rd_rel->relrewrite);
values[Anum_pg_class_relfrozenxid - 1] = TransactionIdGetDatum(rd_rel->relfrozenxid);
values[Anum_pg_class_relminmxid - 1] = MultiXactIdGetDatum(rd_rel->relminmxid);
+ values[Anum_pg_class_relisivm - 1] = BoolGetDatum(rd_rel->relisivm);
if (relacl != (Datum) 0)
values[Anum_pg_class_relacl - 1] = relacl;
else
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index fd09378848..e4b52fdd21 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -993,6 +993,7 @@ index_create(Relation heapRelation,
indexRelation->rd_rel->relowner = heapRelation->rd_rel->relowner;
indexRelation->rd_rel->relam = accessMethodId;
indexRelation->rd_rel->relispartition = OidIsValid(parentIndexRelid);
+ indexRelation->rd_rel->relisivm = false;
/*
* store index's pg_class entry
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index 77b06e2a7a..2b60ed9e52 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -146,6 +146,7 @@ CREATE VIEW pg_matviews AS
T.spcname AS tablespace,
C.relhasindex AS hasindexes,
C.relispopulated AS ispopulated,
+ C.relisivm AS isimmv,
pg_get_viewdef(C.oid) AS definition
FROM pg_class C LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
LEFT JOIN pg_tablespace T ON (T.oid = C.reltablespace)
diff --git a/src/backend/utils/cache/lsyscache.c b/src/backend/utils/cache/lsyscache.c
index fc6d267e44..2b29ab4409 100644
--- a/src/backend/utils/cache/lsyscache.c
+++ b/src/backend/utils/cache/lsyscache.c
@@ -2046,6 +2046,30 @@ get_rel_relispartition(Oid relid)
return false;
}
+/*
+ * get_rel_relisivm
+ *
+ * Returns the relisivm flag associated with a given relation.
+ */
+bool
+get_rel_relisivm(Oid relid)
+{
+ HeapTuple tp;
+
+ tp = SearchSysCache1(RELOID, ObjectIdGetDatum(relid));
+ if (HeapTupleIsValid(tp))
+ {
+ Form_pg_class reltup = (Form_pg_class) GETSTRUCT(tp);
+ bool result;
+
+ result = reltup->relisivm;
+ ReleaseSysCache(tp);
+ return result;
+ }
+ else
+ return false;
+}
+
/*
* get_rel_tablespace
*
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 7234cb3da6..96cd510780 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -1924,6 +1924,8 @@ formrdesc(const char *relationName, Oid relationReltype,
/* ... and they're always populated, too */
relation->rd_rel->relispopulated = true;
+ /* ... and they're always no ivm, too */
+ relation->rd_rel->relisivm = false;
relation->rd_rel->relreplident = REPLICA_IDENTITY_NOTHING;
relation->rd_rel->relpages = 0;
diff --git a/src/include/catalog/pg_class.h b/src/include/catalog/pg_class.h
index 2d1bb7af3a..62b9c0e5cb 100644
--- a/src/include/catalog/pg_class.h
+++ b/src/include/catalog/pg_class.h
@@ -119,6 +119,9 @@ CATALOG(pg_class,1259,RelationRelationId) BKI_BOOTSTRAP BKI_ROWTYPE_OID(83,Relat
/* is relation a partition? */
bool relispartition BKI_DEFAULT(f);
+ /* is relation a matview with ivm? */
+ bool relisivm BKI_DEFAULT(f);
+
/* link to original rel during table rewrite; otherwise 0 */
Oid relrewrite BKI_DEFAULT(0) BKI_LOOKUP_OPT(pg_class);
diff --git a/src/include/utils/lsyscache.h b/src/include/utils/lsyscache.h
index f5fdbfe116..7b433749f5 100644
--- a/src/include/utils/lsyscache.h
+++ b/src/include/utils/lsyscache.h
@@ -138,6 +138,7 @@ extern Oid get_rel_namespace(Oid relid);
extern Oid get_rel_type_id(Oid relid);
extern char get_rel_relkind(Oid relid);
extern bool get_rel_relispartition(Oid relid);
+extern bool get_rel_relisivm(Oid relid);
extern Oid get_rel_tablespace(Oid relid);
extern char get_rel_persistence(Oid relid);
extern Oid get_transform_fromsql(Oid typid, Oid langid, List *trftypes);
diff --git a/src/include/utils/rel.h b/src/include/utils/rel.h
index 1426a353cd..b8961176bb 100644
--- a/src/include/utils/rel.h
+++ b/src/include/utils/rel.h
@@ -677,6 +677,8 @@ RelationCloseSmgr(Relation relation)
*/
#define RelationIsPopulated(relation) ((relation)->rd_rel->relispopulated)
+#define RelationIsIVM(relation) ((relation)->rd_rel->relisivm)
+
/*
* RelationIsAccessibleInLogicalDecoding
* True if we need to log enough information to have access via
diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out
index 5058be5411..cc5287344d 100644
--- a/src/test/regress/expected/rules.out
+++ b/src/test/regress/expected/rules.out
@@ -1392,6 +1392,7 @@ pg_matviews| SELECT n.nspname AS schemaname,
t.spcname AS tablespace,
c.relhasindex AS hasindexes,
c.relispopulated AS ispopulated,
+ c.relisivm AS isimmv,
pg_get_viewdef(c.oid) AS definition
FROM ((pg_class c
LEFT JOIN pg_namespace n ON ((n.oid = c.relnamespace)))
--
2.25.1
v29-0003-Allow-to-prolong-life-span-of-transition-tables-.patchtext/x-diff; name=v29-0003-Allow-to-prolong-life-span-of-transition-tables-.patchDownload
From 93da379a3df6e0f4acda7e1ed0fdb6daa56ede71 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:09:45 +0900
Subject: [PATCH v29 03/11] Allow to prolong life span of transition tables
until transaction end
Originally, tuplestores of AFTER trigger's transition tables were
freed for each query depth. For our IVM implementation, we would like
to prolong life of the tuplestores because we have to preserve them
for a whole query assuming that some base tables might be changed
in some trigger functions.
---
src/backend/commands/trigger.c | 83 ++++++++++++++++++++++++++++++++--
src/include/commands/trigger.h | 2 +
2 files changed, 81 insertions(+), 4 deletions(-)
diff --git a/src/backend/commands/trigger.c b/src/backend/commands/trigger.c
index 52177759ab..00b20f4b5b 100644
--- a/src/backend/commands/trigger.c
+++ b/src/backend/commands/trigger.c
@@ -3742,6 +3742,10 @@ typedef struct AfterTriggerEventList
* end of the list, so it is relatively easy to discard them. The event
* list chunks themselves are stored in event_cxt.
*
+ * prolonged_tuplestored is a list of transition table tuplestores whose
+ * life are prolonged to the end of the outmost query instead of each nested
+ * query.
+ *
* query_depth is the current depth of nested AfterTriggerBeginQuery calls
* (-1 when the stack is empty).
*
@@ -3807,6 +3811,7 @@ typedef struct AfterTriggersData
SetConstraintState state; /* the active S C state */
AfterTriggerEventList events; /* deferred-event list */
MemoryContext event_cxt; /* memory context for events, if any */
+ List *prolonged_tuplestores; /* list of prolonged tuplestores */
/* per-query-level data: */
AfterTriggersQueryData *query_stack; /* array of structs shown below */
@@ -3842,6 +3847,7 @@ struct AfterTriggersTableData
bool closed; /* true when no longer OK to add tuples */
bool before_trig_done; /* did we already queue BS triggers? */
bool after_trig_done; /* did we already queue AS triggers? */
+ bool prolonged; /* are transition tables prolonged? */
AfterTriggerEventList after_trig_events; /* if so, saved list pointer */
/*
@@ -3891,6 +3897,7 @@ static void TransitionTableAddTuple(EState *estate,
TupleTableSlot *original_insert_tuple,
Tuplestorestate *tuplestore);
static void AfterTriggerFreeQuery(AfterTriggersQueryData *qs);
+static void release_or_prolong_tuplestore(Tuplestorestate *ts, bool prolonged);
static SetConstraintState SetConstraintStateCreate(int numalloc);
static SetConstraintState SetConstraintStateCopy(SetConstraintState origstate);
static SetConstraintState SetConstraintStateAddItem(SetConstraintState state,
@@ -4768,6 +4775,45 @@ afterTriggerInvokeEvents(AfterTriggerEventList *events,
}
+/*
+ * SetTransitionTablePreserved
+ *
+ * Prolong lifespan of transition tables corresponding specified relid and
+ * command type to the end of the outmost query instead of each nested query.
+ * This enables to use nested AFTER trigger's transition tables from outer
+ * query's triggers. Currently, only immediate incremental view maintenance
+ * uses this.
+ */
+void
+SetTransitionTablePreserved(Oid relid, CmdType cmdType)
+{
+ AfterTriggersTableData *table;
+ AfterTriggersQueryData *qs;
+ bool found = false;
+ ListCell *lc;
+
+ /* Check state, like AfterTriggerSaveEvent. */
+ if (afterTriggers.query_depth < 0)
+ elog(ERROR, "SetTransitionTablePreserved() called outside of query");
+
+ qs = &afterTriggers.query_stack[afterTriggers.query_depth];
+
+ foreach(lc, qs->tables)
+ {
+ table = (AfterTriggersTableData *) lfirst(lc);
+ if (table->relid == relid && table->cmdType == cmdType &&
+ table->closed)
+ {
+ table->prolonged = true;
+ found = true;
+ }
+ }
+
+ if (!found)
+ elog(ERROR,"could not find table with OID %d and command type %d", relid, cmdType);
+}
+
+
/*
* GetAfterTriggersTableData
*
@@ -4978,6 +5024,7 @@ AfterTriggerBeginXact(void)
*/
afterTriggers.firing_counter = (CommandId) 1; /* mustn't be 0 */
afterTriggers.query_depth = -1;
+ afterTriggers.prolonged_tuplestores = NIL;
/*
* Verify that there is no leftover state remaining. If these assertions
@@ -5138,19 +5185,19 @@ AfterTriggerFreeQuery(AfterTriggersQueryData *qs)
ts = table->old_upd_tuplestore;
table->old_upd_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->new_upd_tuplestore;
table->new_upd_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->old_del_tuplestore;
table->old_del_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->new_ins_tuplestore;
table->new_ins_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
if (table->storeslot)
{
TupleTableSlot *slot = table->storeslot;
@@ -5167,6 +5214,34 @@ AfterTriggerFreeQuery(AfterTriggersQueryData *qs)
*/
qs->tables = NIL;
list_free_deep(tables);
+
+ /* Release prolonged tuplestores at the end of the outmost query */
+ if (afterTriggers.query_depth == 0)
+ {
+ foreach(lc, afterTriggers.prolonged_tuplestores)
+ {
+ ts = (Tuplestorestate *) lfirst(lc);
+ if (ts)
+ tuplestore_end(ts);
+ }
+ afterTriggers.prolonged_tuplestores = NIL;
+ }
+}
+
+/*
+ * Release the tuplestore, or append it to the prolonged tuplestores list.
+ */
+static void
+release_or_prolong_tuplestore(Tuplestorestate *ts, bool prolonged)
+{
+ if (prolonged && afterTriggers.query_depth > 0)
+ {
+ MemoryContext oldcxt = MemoryContextSwitchTo(CurTransactionContext);
+ afterTriggers.prolonged_tuplestores = lappend(afterTriggers.prolonged_tuplestores, ts);
+ MemoryContextSwitchTo(oldcxt);
+ }
+ else
+ tuplestore_end(ts);
}
diff --git a/src/include/commands/trigger.h b/src/include/commands/trigger.h
index 430e3ca7dd..48a21c4c51 100644
--- a/src/include/commands/trigger.h
+++ b/src/include/commands/trigger.h
@@ -265,6 +265,8 @@ extern void AfterTriggerEndSubXact(bool isCommit);
extern void AfterTriggerSetState(ConstraintsSetStmt *stmt);
extern bool AfterTriggerPendingOnRel(Oid relid);
+extern void SetTransitionTablePreserved(Oid relid, CmdType cmdType);
+
/*
* in utils/adt/ri_triggers.c
--
2.25.1
v29-0004-Add-Incremental-View-Maintenance-support-to-pg_d.patchtext/x-diff; name=v29-0004-Add-Incremental-View-Maintenance-support-to-pg_d.patchDownload
From 52122e921c381f697284d779d34685405098f392 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 11 Nov 2020 17:01:25 +0900
Subject: [PATCH v29 04/11] Add Incremental View Maintenance support to pg_dump
Support CREATE INCREMENTAL MATERIALIZED VIEW syntax.
---
src/bin/pg_dump/pg_dump.c | 18 +++++++++++++++---
src/bin/pg_dump/pg_dump.h | 2 ++
src/bin/pg_dump/t/002_pg_dump.pl | 18 ++++++++++++++++++
3 files changed, 35 insertions(+), 3 deletions(-)
diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c
index 65f64c282d..013ead7655 100644
--- a/src/bin/pg_dump/pg_dump.c
+++ b/src/bin/pg_dump/pg_dump.c
@@ -6354,6 +6354,7 @@ getTables(Archive *fout, int *numTables)
int i_relacl;
int i_acldefault;
int i_ispartition;
+ int i_isivm;
/*
* Find all the tables and table-like objects.
@@ -6456,10 +6457,17 @@ getTables(Archive *fout, int *numTables)
if (fout->remoteVersion >= 100000)
appendPQExpBufferStr(query,
- "c.relispartition AS ispartition ");
+ "c.relispartition AS ispartition, ");
else
appendPQExpBufferStr(query,
- "false AS ispartition ");
+ "false AS ispartition, ");
+
+ if (fout->remoteVersion >= 170000)
+ appendPQExpBufferStr(query,
+ "c.relisivm AS isivm ");
+ else
+ appendPQExpBufferStr(query,
+ "false AS isivm ");
/*
* Left join to pg_depend to pick up dependency info linking sequences to
@@ -6568,6 +6576,7 @@ getTables(Archive *fout, int *numTables)
i_relacl = PQfnumber(res, "relacl");
i_acldefault = PQfnumber(res, "acldefault");
i_ispartition = PQfnumber(res, "ispartition");
+ i_isivm = PQfnumber(res, "isivm");
if (dopt->lockWaitTimeout)
{
@@ -6647,6 +6656,7 @@ getTables(Archive *fout, int *numTables)
tblinfo[i].amname = pg_strdup(PQgetvalue(res, i, i_amname));
tblinfo[i].is_identity_sequence = (strcmp(PQgetvalue(res, i, i_is_identity_sequence), "t") == 0);
tblinfo[i].ispartition = (strcmp(PQgetvalue(res, i, i_ispartition), "t") == 0);
+ tblinfo[i].isivm = (strcmp(PQgetvalue(res, i, i_isivm), "t") == 0);
/* other fields were zeroed above */
@@ -15737,9 +15747,11 @@ dumpTableSchema(Archive *fout, const TableInfo *tbinfo)
binary_upgrade_set_pg_class_oids(fout, q,
tbinfo->dobj.catId.oid, false);
- appendPQExpBuffer(q, "CREATE %s%s %s",
+ appendPQExpBuffer(q, "CREATE %s%s%s %s",
tbinfo->relpersistence == RELPERSISTENCE_UNLOGGED ?
"UNLOGGED " : "",
+ tbinfo->relkind == RELKIND_MATVIEW && tbinfo->isivm ?
+ "INCREMENTAL " : "",
reltypename,
qualrelname);
diff --git a/src/bin/pg_dump/pg_dump.h b/src/bin/pg_dump/pg_dump.h
index 9036b13f6a..71ea246abd 100644
--- a/src/bin/pg_dump/pg_dump.h
+++ b/src/bin/pg_dump/pg_dump.h
@@ -324,6 +324,8 @@ typedef struct _tableInfo
int numParents; /* number of (immediate) parent tables */
struct _tableInfo **parents; /* TableInfos of immediate parents */
+ bool isivm; /* is incrementally maintainable materialized view? */
+
/*
* These fields are computed only if we decide the table is interesting
* (it's either a table to dump, or a direct parent of a dumpable table).
diff --git a/src/bin/pg_dump/t/002_pg_dump.pl b/src/bin/pg_dump/t/002_pg_dump.pl
index 0758fe5ea0..f83c317268 100644
--- a/src/bin/pg_dump/t/002_pg_dump.pl
+++ b/src/bin/pg_dump/t/002_pg_dump.pl
@@ -2799,6 +2799,24 @@ my %tests = (
},
},
+ 'CREATE MATERIALIZED VIEW matview_ivm' => {
+ create_order => 21,
+ create_sql => 'CREATE INCREMENTAL MATERIALIZED VIEW dump_test.matview_ivm (col1) AS
+ SELECT col1 FROM dump_test.test_table;',
+ regexp => qr/^
+ \QCREATE INCREMENTAL MATERIALIZED VIEW dump_test.matview_ivm AS\E
+ \n\s+\QSELECT col1\E
+ \n\s+\QFROM dump_test.test_table\E
+ \n\s+\QWITH NO DATA;\E
+ /xm,
+ like =>
+ { %full_runs, %dump_test_schema_runs, section_pre_data => 1, },
+ unlike => {
+ exclude_dump_test_schema => 1,
+ only_dump_measurement => 1,
+ },
+ },
+
'CREATE POLICY p1 ON test_table' => {
create_order => 22,
create_sql => 'CREATE POLICY p1 ON dump_test.test_table
--
2.25.1
v29-0005-Add-Incremental-View-Maintenance-support-to-psql.patchtext/x-diff; name=v29-0005-Add-Incremental-View-Maintenance-support-to-psql.patchDownload
From 81cb185a3303d564440240ec13ae532d5158f628 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:21:54 +0900
Subject: [PATCH v29 05/11] Add Incremental View Maintenance support to psql
Add tab completion and meta-command output for IVM.
---
src/bin/psql/describe.c | 32 +++++++++++++++++++++++++++++++-
src/bin/psql/tab-complete.c | 14 +++++++++-----
2 files changed, 40 insertions(+), 6 deletions(-)
diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c
index bac94a338c..f6c7e7163d 100644
--- a/src/bin/psql/describe.c
+++ b/src/bin/psql/describe.c
@@ -1575,6 +1575,7 @@ describeOneTableDetails(const char *schemaname,
char relpersistence;
char relreplident;
char *relam;
+ bool isivm;
} tableinfo;
bool show_column_details = false;
@@ -1587,7 +1588,26 @@ describeOneTableDetails(const char *schemaname,
initPQExpBuffer(&tmpbuf);
/* Get general table info */
- if (pset.sversion >= 120000)
+ if (pset.sversion >= 170000)
+ {
+ printfPQExpBuffer(&buf,
+ "SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
+ "c.relhastriggers, c.relrowsecurity, c.relforcerowsecurity, "
+ "false AS relhasoids, c.relispartition, %s, c.reltablespace, "
+ "CASE WHEN c.reloftype = 0 THEN '' ELSE c.reloftype::pg_catalog.regtype::pg_catalog.text END, "
+ "c.relpersistence, c.relreplident, am.amname, "
+ "c.relisivm\n"
+ "FROM pg_catalog.pg_class c\n "
+ "LEFT JOIN pg_catalog.pg_class tc ON (c.reltoastrelid = tc.oid)\n"
+ "LEFT JOIN pg_catalog.pg_am am ON (c.relam = am.oid)\n"
+ "WHERE c.oid = '%s';",
+ (verbose ?
+ "pg_catalog.array_to_string(c.reloptions || "
+ "array(select 'toast.' || x from pg_catalog.unnest(tc.reloptions) x), ', ')\n"
+ : "''"),
+ oid);
+ }
+ else if (pset.sversion >= 120000)
{
printfPQExpBuffer(&buf,
"SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
@@ -1707,6 +1727,10 @@ describeOneTableDetails(const char *schemaname,
(char *) NULL : pg_strdup(PQgetvalue(res, 0, 14));
else
tableinfo.relam = NULL;
+ if (pset.sversion >= 170000)
+ tableinfo.isivm = strcmp(PQgetvalue(res, 0, 15), "t") == 0;
+ else
+ tableinfo.isivm = false;
PQclear(res);
res = NULL;
@@ -3552,6 +3576,12 @@ describeOneTableDetails(const char *schemaname,
printfPQExpBuffer(&buf, _("Access method: %s"), tableinfo.relam);
printTableAddFooter(&cont, buf.data);
}
+
+ /* Incremental view maintance info */
+ if (verbose && tableinfo.relkind == RELKIND_MATVIEW && tableinfo.isivm)
+ {
+ printTableAddFooter(&cont, _("Incremental view maintenance: yes"));
+ }
}
/* reloptions, if verbose */
diff --git a/src/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c
index 779fdc90cb..9cc79b722f 100644
--- a/src/bin/psql/tab-complete.c
+++ b/src/bin/psql/tab-complete.c
@@ -1244,6 +1244,7 @@ static const pgsql_thing_t words_after_create[] = {
{"FOREIGN TABLE", NULL, NULL, NULL},
{"FUNCTION", NULL, NULL, Query_for_list_of_functions},
{"GROUP", Query_for_list_of_roles},
+ {"INCREMENTAL MATERIALIZED VIEW", NULL, NULL, &Query_for_list_of_matviews, NULL, THING_NO_DROP | THING_NO_ALTER},
{"INDEX", NULL, NULL, &Query_for_list_of_indexes},
{"LANGUAGE", Query_for_list_of_languages},
{"LARGE OBJECT", NULL, NULL, NULL, NULL, THING_NO_CREATE | THING_NO_DROP},
@@ -3217,7 +3218,7 @@ psql_completion(const char *text, int start, int end)
if (HeadMatches("CREATE", "SCHEMA"))
COMPLETE_WITH("TABLE", "SEQUENCE");
else
- COMPLETE_WITH("TABLE", "SEQUENCE", "MATERIALIZED VIEW");
+ COMPLETE_WITH("TABLE", "SEQUENCE", "MATERIALIZED VIEW", "INCREMENTAL MATERIALIZED VIEW");
}
/* Complete PARTITION BY with RANGE ( or LIST ( or ... */
else if (TailMatches("PARTITION", "BY"))
@@ -3535,13 +3536,16 @@ psql_completion(const char *text, int start, int end)
COMPLETE_WITH("SELECT");
/* CREATE MATERIALIZED VIEW */
- else if (Matches("CREATE", "MATERIALIZED"))
+ else if (Matches("CREATE", "MATERIALIZED") ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED"))
COMPLETE_WITH("VIEW");
- /* Complete CREATE MATERIALIZED VIEW <name> with AS */
- else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny))
+ /* Complete CREATE MATERIALIZED VIEW <name> with AS */
+ else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny) ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED", "VIEW", MatchAny))
COMPLETE_WITH("AS");
/* Complete "CREATE MATERIALIZED VIEW <sth> AS with "SELECT" */
- else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny, "AS"))
+ else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny, "AS") ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED", "VIEW", MatchAny, "AS"))
COMPLETE_WITH("SELECT");
/* CREATE EVENT TRIGGER */
--
2.25.1
v29-0006-Add-Incremental-View-Maintenance-support.patchtext/x-diff; name=v29-0006-Add-Incremental-View-Maintenance-support.patchDownload
From 714f9575c8a4c9bebecac115fe628ec9b7f797d6 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 18:59:50 +0900
Subject: [PATCH v29 06/11] Add Incremental View Maintenance support
In this implementation, AFTER triggers are used to collect
tuplestores containing transition table contents. When multiple tables
are changed, multiple AFTER triggers are invoked, then the final AFTER
trigger performs actual update of the matview. In addition, BEFORE
triggers are also used to handle global information for view
maintenance.
To calculate view deltas, we need both pre-state and post-state of base
tables. Post-update states are available in AFTER trigger, and pre-update
states can be calculated by removing inserted tuples and appending deleted
tuples. Insterted tuples are filtered using the snapshot taken before
table modiication, and deleted tuples are contained in the old transition
table.
Incrementally Maintainable Materialized Views (IMMV) can contain
duplicated tuples.
This patch also allows self-join, simultaneous updates of more than
one base table, and multiple updates of the same base table.
---
src/backend/access/transam/xact.c | 5 +
src/backend/commands/createas.c | 680 +++++++++++++
src/backend/commands/matview.c | 1466 ++++++++++++++++++++++++++++-
src/include/catalog/pg_proc.dat | 10 +
src/include/commands/createas.h | 4 +
src/include/commands/matview.h | 9 +
6 files changed, 2139 insertions(+), 35 deletions(-)
diff --git a/src/backend/access/transam/xact.c b/src/backend/access/transam/xact.c
index 8daaa535ed..cd280bdffd 100644
--- a/src/backend/access/transam/xact.c
+++ b/src/backend/access/transam/xact.c
@@ -36,6 +36,7 @@
#include "catalog/pg_enum.h"
#include "catalog/storage.h"
#include "commands/async.h"
+#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/trigger.h"
#include "common/pg_prng.h"
@@ -2803,6 +2804,7 @@ AbortTransaction(void)
AtAbort_Notify();
AtEOXact_RelationMap(false, is_parallel_worker);
AtAbort_Twophase();
+ AtAbort_IVM();
/*
* Advertise the fact that we aborted in pg_xact (assuming that we got as
@@ -5080,6 +5082,9 @@ AbortSubTransaction(void)
pgstat_progress_end_command();
UnlockBuffers();
+ /* Clean up hash entries for incremental view maintenance */
+ AtAbort_IVM();
+
/* Reset WAL record construction state */
XLogResetInsertion();
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index e91920ca14..415f110516 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -32,15 +32,26 @@
#include "access/xact.h"
#include "access/xlog.h"
#include "catalog/namespace.h"
+#include "catalog/index.h"
+#include "catalog/pg_constraint.h"
+#include "catalog/pg_inherits.h"
+#include "catalog/pg_trigger.h"
#include "catalog/toasting.h"
#include "commands/createas.h"
+#include "commands/defrem.h"
#include "commands/matview.h"
#include "commands/prepare.h"
#include "commands/tablecmds.h"
+#include "commands/tablespace.h"
+#include "commands/trigger.h"
#include "commands/view.h"
#include "miscadmin.h"
+#include "optimizer/optimizer.h"
+#include "optimizer/prep.h"
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
+#include "parser/parser.h"
+#include "parser/parsetree.h"
#include "parser/parse_clause.h"
#include "rewrite/rewriteHandler.h"
#include "storage/smgr.h"
@@ -73,6 +84,12 @@ static bool intorel_receive(TupleTableSlot *slot, DestReceiver *self);
static void intorel_shutdown(DestReceiver *self);
static void intorel_destroy(DestReceiver *self);
+static void CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid matviewOid,
+ Relids *relids, bool ex_lock);
+static void CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock);
+static void check_ivm_restriction(Node *node);
+static bool check_ivm_restriction_walker(Node *node, void *context);
+static Bitmapset *get_primary_key_attnos_from_query(Query *query, List **constraintList);
/*
* create_ctas_internal
@@ -282,6 +299,18 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
save_nestlevel = NewGUCNestLevel();
}
+ if (is_matview && into->ivm)
+ {
+ /* check if the query is supported in IMMV definition */
+ if (contain_mutable_functions((Node *) query))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("mutable function is not supported on incrementally maintainable materialized view"),
+ errhint("functions must be marked IMMUTABLE")));
+
+ check_ivm_restriction((Node *) query);
+ }
+
if (into->skipData)
{
/*
@@ -358,6 +387,27 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
/* Restore userid and security context */
SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ if (into->ivm)
+ {
+ Oid matviewOid = address.objectId;
+ Relation matviewRel = table_open(matviewOid, NoLock);
+
+ /*
+ * Mark relisivm field, if it's a matview and into->ivm is true.
+ */
+ SetMatViewIVMState(matviewRel, true);
+
+ if (!into->skipData)
+ {
+ /* Create an index on incremental maintainable materialized view, if possible */
+ CreateIndexOnIMMV((Query *) into->viewQuery, matviewRel);
+
+ /* Create triggers on incremental maintainable materialized view */
+ CreateIvmTriggersOnBaseTables((Query *) into->viewQuery, matviewOid);
+ }
+ table_close(matviewRel, NoLock);
+ }
}
return address;
@@ -635,3 +685,633 @@ intorel_destroy(DestReceiver *self)
{
pfree(self);
}
+
+/*
+ * CreateIvmTriggersOnBaseTables -- create IVM triggers on all base tables
+ */
+void
+CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid)
+{
+ Relids relids = NULL;
+ bool ex_lock = false;
+ RangeTblEntry *rte;
+
+ /* Immediately return if we don't have any base tables. */
+ if (list_length(qry->rtable) < 1)
+ return;
+
+ /*
+ * If the view has more than one base tables, we need an exclusive lock
+ * on the view so that the view would be maintained serially to avoid
+ * the inconsistency that occurs when two base tables are modified in
+ * concurrent transactions. However, if the view has only one table,
+ * we can use a weaker lock.
+ *
+ * The type of lock should be determined here, because if we check the
+ * view definition at maintenance time, we need to acquire a weaker lock,
+ * and upgrading the lock level after this increases probability of
+ * deadlock.
+ */
+
+ rte = list_nth(qry->rtable, 0);
+ if (list_length(qry->rtable) > 1 || rte->rtekind != RTE_RELATION)
+ ex_lock = true;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, (Node *)qry, matviewOid, &relids, ex_lock);
+
+ bms_free(relids);
+}
+
+static void
+CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid matviewOid,
+ Relids *relids, bool ex_lock)
+{
+ if (node == NULL)
+ return;
+
+ /* This can recurse, so check for excessive recursion */
+ check_stack_depth();
+
+ switch (nodeTag(node))
+ {
+ case T_Query:
+ {
+ Query *query = (Query *) node;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, (Node *)query->jointree, matviewOid, relids, ex_lock);
+ }
+ break;
+
+ case T_RangeTblRef:
+ {
+ int rti = ((RangeTblRef *) node)->rtindex;
+ RangeTblEntry *rte = rt_fetch(rti, qry->rtable);
+
+ if (rte->rtekind == RTE_RELATION && !bms_is_member(rte->relid, *relids))
+ {
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_INSERT, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_DELETE, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_UPDATE, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_TRUNCATE, TRIGGER_TYPE_BEFORE, true);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_INSERT, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_DELETE, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_UPDATE, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_TRUNCATE, TRIGGER_TYPE_AFTER, true);
+
+ *relids = bms_add_member(*relids, rte->relid);
+ }
+ }
+ break;
+
+ case T_FromExpr:
+ {
+ FromExpr *f = (FromExpr *) node;
+ ListCell *l;
+
+ foreach(l, f->fromlist)
+ CreateIvmTriggersOnBaseTablesRecurse(qry, lfirst(l), matviewOid, relids, ex_lock);
+ }
+ break;
+
+ case T_JoinExpr:
+ {
+ JoinExpr *j = (JoinExpr *) node;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, j->larg, matviewOid, relids, ex_lock);
+ CreateIvmTriggersOnBaseTablesRecurse(qry, j->rarg, matviewOid, relids, ex_lock);
+ }
+ break;
+
+ default:
+ elog(ERROR, "unrecognized node type: %d", (int) nodeTag(node));
+ }
+}
+
+/*
+ * CreateIvmTrigger -- create IVM trigger on a base table
+ */
+static void
+CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock)
+{
+ ObjectAddress refaddr;
+ ObjectAddress address;
+ CreateTrigStmt *ivm_trigger;
+ List *transitionRels = NIL;
+
+ Assert(timing == TRIGGER_TYPE_BEFORE || timing == TRIGGER_TYPE_AFTER);
+
+ refaddr.classId = RelationRelationId;
+ refaddr.objectId = viewOid;
+ refaddr.objectSubId = 0;
+
+ ivm_trigger = makeNode(CreateTrigStmt);
+ ivm_trigger->relation = NULL;
+ ivm_trigger->row = false;
+
+ ivm_trigger->timing = timing;
+ ivm_trigger->events = type;
+
+ switch (type)
+ {
+ case TRIGGER_TYPE_INSERT:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_ins_before" : "IVM_trigger_ins_after");
+ break;
+ case TRIGGER_TYPE_DELETE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_del_before" : "IVM_trigger_del_after");
+ break;
+ case TRIGGER_TYPE_UPDATE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_upd_before" : "IVM_trigger_upd_after");
+ break;
+ case TRIGGER_TYPE_TRUNCATE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_truncate_before" : "IVM_trigger_truncate_after");
+ break;
+ default:
+ elog(ERROR, "unsupported trigger type");
+ }
+
+ if (timing == TRIGGER_TYPE_AFTER)
+ {
+ if (type == TRIGGER_TYPE_INSERT || type == TRIGGER_TYPE_UPDATE)
+ {
+ TriggerTransition *n = makeNode(TriggerTransition);
+ n->name = "__ivm_newtable";
+ n->isNew = true;
+ n->isTable = true;
+
+ transitionRels = lappend(transitionRels, n);
+ }
+ if (type == TRIGGER_TYPE_DELETE || type == TRIGGER_TYPE_UPDATE)
+ {
+ TriggerTransition *n = makeNode(TriggerTransition);
+ n->name = "__ivm_oldtable";
+ n->isNew = false;
+ n->isTable = true;
+
+ transitionRels = lappend(transitionRels, n);
+ }
+ }
+
+ /*
+ * XXX: When using DELETE or UPDATE, we must use exclusive lock for now
+ * because apply_old_delta(_with_count) uses ctid to identify the tuple
+ * to be deleted/deleted, but doesn't work in concurrent situations.
+ *
+ * If the view doesn't have aggregate, distinct, or tuple duplicate,
+ * then it would work even in concurrent situations. However, we don't have
+ * any way to guarantee the view has a unique key before opening the IMMV
+ * at the maintenance time because users may drop the unique index.
+ */
+
+ if (type == TRIGGER_TYPE_DELETE || type == TRIGGER_TYPE_UPDATE)
+ ex_lock = true;
+
+ ivm_trigger->funcname =
+ (timing == TRIGGER_TYPE_BEFORE ? SystemFuncName("IVM_immediate_before") : SystemFuncName("IVM_immediate_maintenance"));
+
+ ivm_trigger->columns = NIL;
+ ivm_trigger->transitionRels = transitionRels;
+ ivm_trigger->whenClause = NULL;
+ ivm_trigger->isconstraint = false;
+ ivm_trigger->deferrable = false;
+ ivm_trigger->initdeferred = false;
+ ivm_trigger->constrrel = NULL;
+ ivm_trigger->args = list_make2(
+ makeString(DatumGetPointer(DirectFunctionCall1(oidout, ObjectIdGetDatum(viewOid)))),
+ makeString(DatumGetPointer(DirectFunctionCall1(boolout, BoolGetDatum(ex_lock))))
+ );
+
+ address = CreateTrigger(ivm_trigger, NULL, relOid, InvalidOid, InvalidOid,
+ InvalidOid, InvalidOid, InvalidOid, NULL, true, false);
+
+ recordDependencyOn(&address, &refaddr, DEPENDENCY_AUTO);
+
+ /* Make changes-so-far visible */
+ CommandCounterIncrement();
+}
+
+/*
+ * check_ivm_restriction --- look for specify nodes in the query tree
+ */
+static void
+check_ivm_restriction(Node *node)
+{
+ check_ivm_restriction_walker(node, NULL);
+}
+
+static bool
+check_ivm_restriction_walker(Node *node, void *context)
+{
+ if (node == NULL)
+ return false;
+
+ /*
+ * We currently don't support Sub-Query.
+ */
+ if (IsA(node, SubPlan) || IsA(node, SubLink))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("subquery is not supported on incrementally maintainable materialized view")));
+
+ /* This can recurse, so check for excessive recursion */
+ check_stack_depth();
+
+ switch (nodeTag(node))
+ {
+ case T_Query:
+ {
+ Query *qry = (Query *)node;
+ ListCell *lc;
+ List *vars;
+
+ /* if contained CTE, return error */
+ if (qry->cteList != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("CTE is not supported on incrementally maintainable materialized view")));
+ if (qry->havingQual != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg(" HAVING clause is not supported on incrementally maintainable materialized view")));
+ if (qry->sortClause != NIL) /* There is a possibility that we don't need to return an error */
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("ORDER BY clause is not supported on incrementally maintainable materialized view")));
+ if (qry->limitOffset != NULL || qry->limitCount != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view")));
+ if (qry->distinctClause)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("DISTINCT is not supported on incrementally maintainable materialized view")));
+ if (qry->hasDistinctOn)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("DISTINCT ON is not supported on incrementally maintainable materialized view")));
+ if (qry->hasWindowFuncs)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("window functions are not supported on incrementally maintainable materialized view")));
+ if (qry->groupingSets != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUPING SETS, ROLLUP, or CUBE clauses is not supported on incrementally maintainable materialized view")));
+ if (qry->setOperations != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("UNION/INTERSECT/EXCEPT statements are not supported on incrementally maintainable materialized view")));
+ if (list_length(qry->targetList) == 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("empty target list is not supported on incrementally maintainable materialized view")));
+ if (qry->rowMarks != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view")));
+
+ /* system column restrictions */
+ vars = pull_vars_of_level((Node *) qry, 0);
+ foreach(lc, vars)
+ {
+ if (IsA(lfirst(lc), Var))
+ {
+ Var *var = (Var *) lfirst(lc);
+ /* if system column, return error */
+ if (var->varattno < 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("system column is not supported on incrementally maintainable materialized view")));
+ }
+ }
+
+ /* restrictions for rtable */
+ foreach(lc, qry->rtable)
+ {
+ RangeTblEntry *rte = (RangeTblEntry *) lfirst(lc);
+
+ if (rte->subquery)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("subquery is not supported on incrementally maintainable materialized view")));
+
+ if (rte->tablesample != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("TABLESAMPLE clause is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitioned table is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_RELATION && has_superclass(rte->relid))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_RELATION && find_inheritance_children(rte->relid, NoLock) != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("inheritance parent is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_FOREIGN_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("foreign table is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_VIEW ||
+ rte->relkind == RELKIND_MATVIEW)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view")));
+
+ if (rte->rtekind == RTE_VALUES)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("VALUES is not supported on incrementally maintainable materialized view")));
+
+ }
+
+ query_tree_walker(qry, check_ivm_restriction_walker, NULL, QTW_IGNORE_RANGE_TABLE);
+
+ break;
+ }
+ case T_TargetEntry:
+ {
+ TargetEntry *tle = (TargetEntry *)node;
+ if (isIvmName(tle->resname))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("column name %s is not supported on incrementally maintainable materialized view", tle->resname)));
+
+ expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ break;
+ }
+ case T_JoinExpr:
+ {
+ JoinExpr *joinexpr = (JoinExpr *)node;
+
+ if (joinexpr->jointype > JOIN_INNER)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("OUTER JOIN is not supported on incrementally maintainable materialized view")));
+
+ expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ }
+ break;
+ case T_Aggref:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function is not supported on incrementally maintainable materialized view")));
+ break;
+ default:
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
+ break;
+ }
+ return false;
+}
+
+/*
+ * CreateIndexOnIMMV
+ *
+ * Create a unique index on incremental maintainable materialized view.
+ * If the view definition query has a GROUP BY clause, the index is created
+ * on the columns of GROUP BY expressions. Otherwise, if the view contains
+ * all primary key attritubes of its base tables in the target list, the index
+ * is created on these attritubes. In other cases, no index is created.
+ */
+void
+CreateIndexOnIMMV(Query *query, Relation matviewRel)
+{
+ ListCell *lc;
+ IndexStmt *index;
+ ObjectAddress address;
+ List *constraintList = NIL;
+ char idxname[NAMEDATALEN];
+ List *indexoidlist = RelationGetIndexList(matviewRel);
+ ListCell *indexoidscan;
+ Bitmapset *key_attnos;
+
+ snprintf(idxname, sizeof(idxname), "%s_index", RelationGetRelationName(matviewRel));
+
+ index = makeNode(IndexStmt);
+
+ index->unique = true;
+ index->primary = false;
+ index->isconstraint = false;
+ index->deferrable = false;
+ index->initdeferred = false;
+ index->idxname = idxname;
+ index->relation =
+ makeRangeVar(get_namespace_name(RelationGetNamespace(matviewRel)),
+ pstrdup(RelationGetRelationName(matviewRel)),
+ -1);
+ index->accessMethod = DEFAULT_INDEX_TYPE;
+ index->options = NIL;
+ index->tableSpace = get_tablespace_name(matviewRel->rd_rel->reltablespace);
+ index->whereClause = NULL;
+ index->indexParams = NIL;
+ index->indexIncludingParams = NIL;
+ index->excludeOpNames = NIL;
+ index->idxcomment = NULL;
+ index->indexOid = InvalidOid;
+ index->oldNumber = InvalidRelFileNumber;
+ index->oldCreateSubid = InvalidSubTransactionId;
+ index->oldFirstRelfilelocatorSubid = InvalidSubTransactionId;
+ index->transformed = true;
+ index->concurrent = false;
+ index->if_not_exists = false;
+
+ /* create index on the base tables' primary key columns */
+ key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
+ if (key_attnos)
+ {
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ }
+ else
+ {
+ /* create no index, just notice that an appropriate index is necessary for efficient IVM */
+ ereport(NOTICE,
+ (errmsg("could not create an index on materialized view \"%s\" automatically",
+ RelationGetRelationName(matviewRel)),
+ errdetail("This target list does not have all the primary key columns. "),
+ errhint("Create an index on the materialized view for efficient incremental maintenance.")));
+ return;
+ }
+
+ /* If we have a compatible index, we don't need to create another. */
+ foreach(indexoidscan, indexoidlist)
+ {
+ Oid indexoid = lfirst_oid(indexoidscan);
+ Relation indexRel;
+ bool hasCompatibleIndex = false;
+
+ indexRel = index_open(indexoid, AccessShareLock);
+
+ if (CheckIndexCompatible(indexRel->rd_id,
+ index->accessMethod,
+ index->indexParams,
+ index->excludeOpNames))
+ hasCompatibleIndex = true;
+
+ index_close(indexRel, AccessShareLock);
+
+ if (hasCompatibleIndex)
+ return;
+ }
+
+ address = DefineIndex(RelationGetRelid(matviewRel),
+ index,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ -1,
+ false, true, false, false, true);
+
+ ereport(NOTICE,
+ (errmsg("created index \"%s\" on materialized view \"%s\"",
+ idxname, RelationGetRelationName(matviewRel))));
+
+ /*
+ * Make dependencies so that the index is dropped if any base tables's
+ * primary key is dropped.
+ */
+ foreach(lc, constraintList)
+ {
+ Oid constraintOid = lfirst_oid(lc);
+ ObjectAddress refaddr;
+
+ refaddr.classId = ConstraintRelationId;
+ refaddr.objectId = constraintOid;
+ refaddr.objectSubId = 0;
+
+ recordDependencyOn(&address, &refaddr, DEPENDENCY_NORMAL);
+ }
+}
+
+
+/*
+ * get_primary_key_attnos_from_query
+ *
+ * Identify the columns in base tables' primary keys in the target list.
+ *
+ * Returns a Bitmapset of the column attnos of the primary key's columns of
+ * tables that used in the query. The attnos are offset by
+ * FirstLowInvalidHeapAttributeNumber as same as get_primary_key_attnos.
+ *
+ * If any table has no primary key or any primary key's columns is not in
+ * the target list, return NULL. We also return NULL if any pkey constraint
+ * is deferrable.
+ *
+ * constraintList is set to a list of the OIDs of the pkey constraints.
+ */
+static Bitmapset *
+get_primary_key_attnos_from_query(Query *query, List **constraintList)
+{
+ List *key_attnos_list = NIL;
+ ListCell *lc;
+ int i;
+ Bitmapset *keys = NULL;
+ Relids rels_in_from;
+
+ /*
+ * Collect primary key attributes from all tables used in query. The key attributes
+ * sets for each table are stored in key_attnos_list in order by RTE index.
+ */
+ foreach(lc, query->rtable)
+ {
+ RangeTblEntry *r = (RangeTblEntry*) lfirst(lc);
+ Bitmapset *key_attnos;
+ bool has_pkey = true;
+
+ /* for tables, call get_primary_key_attnos */
+ if (r->rtekind == RTE_RELATION)
+ {
+ Oid constraintOid;
+ key_attnos = get_primary_key_attnos(r->relid, false, &constraintOid);
+ *constraintList = lappend_oid(*constraintList, constraintOid);
+ has_pkey = (key_attnos != NULL);
+ }
+ /* for other RTEs, store NULL into key_attnos_list */
+ else
+ key_attnos = NULL;
+
+ /*
+ * If any table or subquery has no primary key or its pkey constraint is deferrable,
+ * we cannot get key attributes for this query, so return NULL.
+ */
+ if (!has_pkey)
+ return NULL;
+
+ key_attnos_list = lappend(key_attnos_list, key_attnos);
+ }
+
+ /* Collect key attributes appearing in the target list */
+ i = 1;
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) flatten_join_alias_vars(NULL, query, lfirst(lc));
+
+ if (IsA(tle->expr, Var))
+ {
+ Var *var = (Var*) tle->expr;
+ Bitmapset *key_attnos = list_nth(key_attnos_list, var->varno - 1);
+
+ /* check if this attribute is from a base table's primary key */
+ if (bms_is_member(var->varattno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ /*
+ * Remove found key attributes from key_attnos_list, and add this
+ * to the result list.
+ */
+ key_attnos = bms_del_member(key_attnos, var->varattno - FirstLowInvalidHeapAttributeNumber);
+ if (bms_is_empty(key_attnos))
+ {
+ key_attnos_list = list_delete_nth_cell(key_attnos_list, var->varno - 1);
+ key_attnos_list = list_insert_nth(key_attnos_list, var->varno - 1, NULL);
+ }
+ keys = bms_add_member(keys, i - FirstLowInvalidHeapAttributeNumber);
+ }
+ }
+ i++;
+ }
+
+ /* Collect RTE indexes of relations appearing in the FROM clause */
+ rels_in_from = get_relids_in_jointree((Node *) query->jointree, false, false);
+
+ /*
+ * Check if all key attributes of relations in FROM are appearing in the target
+ * list. If an attribute remains in key_attnos_list in spite of the table is used
+ * in FROM clause, the target is missing this key attribute, so we return NULL.
+ */
+ i = 1;
+ foreach(lc, key_attnos_list)
+ {
+ Bitmapset *bms = (Bitmapset *)lfirst(lc);
+ if (!bms_is_empty(bms) && bms_is_member(i, rels_in_from))
+ return NULL;
+ i++;
+ }
+
+ return keys;
+}
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index ac2e74fa3f..39305f3c49 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -25,26 +25,37 @@
#include "catalog/indexing.h"
#include "catalog/namespace.h"
#include "catalog/pg_am.h"
+#include "catalog/pg_depend.h"
+#include "catalog/pg_trigger.h"
#include "catalog/pg_opclass.h"
#include "catalog/pg_operator.h"
#include "commands/cluster.h"
#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
+#include "commands/createas.h"
#include "executor/executor.h"
#include "executor/spi.h"
+#include "executor/tstoreReceiver.h"
#include "miscadmin.h"
+#include "nodes/makefuncs.h"
+#include "parser/analyze.h"
+#include "parser/parse_clause.h"
+#include "parser/parse_func.h"
#include "parser/parse_relation.h"
#include "pgstat.h"
#include "rewrite/rewriteHandler.h"
+#include "rewrite/rowsecurity.h"
#include "storage/lmgr.h"
#include "storage/smgr.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
+#include "utils/fmgroids.h"
#include "utils/lsyscache.h"
#include "utils/rel.h"
#include "utils/snapmgr.h"
#include "utils/syscache.h"
+#include "utils/typcache.h"
typedef struct
@@ -58,6 +69,52 @@ typedef struct
BulkInsertState bistate; /* bulk insert state */
} DR_transientrel;
+#define MV_INIT_QUERYHASHSIZE 16
+
+/*
+ * MV_TriggerHashEntry
+ *
+ * Hash entry for base tables on which IVM trigger is invoked
+ */
+typedef struct MV_TriggerHashEntry
+{
+ Oid matview_id; /* OID of the materialized view */
+ int before_trig_count; /* count of before triggers invoked */
+ int after_trig_count; /* count of after triggers invoked */
+
+ Snapshot snapshot; /* Snapshot just before table change */
+
+ List *tables; /* List of MV_TriggerTable */
+ bool has_old; /* tuples are deleted from any table? */
+ bool has_new; /* tuples are inserted into any table? */
+} MV_TriggerHashEntry;
+
+/*
+ * MV_TriggerTable
+ *
+ * IVM related data for tables on which the trigger is invoked.
+ */
+typedef struct MV_TriggerTable
+{
+ Oid table_id; /* OID of the modified table */
+ List *old_tuplestores; /* tuplestores for deleted tuples */
+ List *new_tuplestores; /* tuplestores for inserted tuples */
+
+ List *rte_indexes; /* List of RTE index of the modified table */
+ RangeTblEntry *original_rte; /* the original RTE saved before rewriting query */
+
+ Relation rel; /* relation of the modified table */
+ TupleTableSlot *slot; /* for checking visibility in the pre-state table */
+} MV_TriggerTable;
+
+static HTAB *mv_trigger_info = NULL;
+
+static bool in_delta_calculation = false;
+
+/* ENR name for materialized view delta */
+#define NEW_DELTA_ENRNAME "new_delta"
+#define OLD_DELTA_ENRNAME "old_delta"
+
static int matview_maintenance_depth = 0;
static void transientrel_startup(DestReceiver *self, int operation, TupleDesc typeinfo);
@@ -65,7 +122,9 @@ static bool transientrel_receive(TupleTableSlot *slot, DestReceiver *self);
static void transientrel_shutdown(DestReceiver *self);
static void transientrel_destroy(DestReceiver *self);
static uint64 refresh_matview_datafill(DestReceiver *dest, Query *query,
- const char *queryString);
+ QueryEnvironment *queryEnv,
+ TupleDesc *resultTupleDesc,
+ const char *queryString);
static char *make_temptable_name_n(char *tempname, int n);
static void refresh_by_match_merge(Oid matviewOid, Oid tempOid, Oid relowner,
int save_sec_context);
@@ -73,6 +132,37 @@ static void refresh_by_heap_swap(Oid matviewOid, Oid OIDNewHeap, char relpersist
static bool is_usable_unique_index(Relation indexRel);
static void OpenMatViewIncrementalMaintenance(void);
static void CloseMatViewIncrementalMaintenance(void);
+static Query *get_matview_query(Relation matviewRel);
+
+static Query *rewrite_query_for_preupdate_state(Query *query, List *tables,
+ ParseState *pstate, Oid matviewid);
+static void register_delta_ENRs(ParseState *pstate, Query *query, List *tables);
+static char *make_delta_enr_name(const char *prefix, Oid relid, int count);
+static RangeTblEntry *get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *table,
+ QueryEnvironment *queryEnv, Oid matviewid);
+static RangeTblEntry *replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
+ QueryEnvironment *queryEnv);
+static Query *rewrite_query_for_counting(Query *query, ParseState *pstate);
+
+static void calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
+ DestReceiver *dest_old, DestReceiver *dest_new,
+ TupleDesc *tupdesc_old, TupleDesc *tupdesc_new,
+ QueryEnvironment *queryEnv);
+static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte_index);
+
+static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
+ TupleDesc tupdesc_old, TupleDesc tupdesc_new,
+ Query *query);
+static void apply_old_delta(const char *matviewname, const char *deltaname_old,
+ List *keys);
+static void apply_new_delta(const char *matviewname, const char *deltaname_new,
+ StringInfo target_list);
+static char *get_matching_condition_string(List *keys);
+static void generate_equal(StringInfo querybuf, Oid opttype,
+ const char *leftop, const char *rightop);
+
+static void mv_InitHashTables(void);
+static void clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort);
/*
* SetMatViewPopulatedState
@@ -114,6 +204,46 @@ SetMatViewPopulatedState(Relation relation, bool newstate)
CommandCounterIncrement();
}
+/*
+ * SetMatViewIVMState
+ * Mark a materialized view as IVM, or not.
+ *
+ * NOTE: caller must be holding an appropriate lock on the relation.
+ */
+void
+SetMatViewIVMState(Relation relation, bool newstate)
+{
+ Relation pgrel;
+ HeapTuple tuple;
+
+ Assert(relation->rd_rel->relkind == RELKIND_MATVIEW);
+
+ /*
+ * Update relation's pg_class entry. Crucial side-effect: other backends
+ * (and this one too!) are sent SI message to make them rebuild relcache
+ * entries.
+ */
+ pgrel = table_open(RelationRelationId, RowExclusiveLock);
+ tuple = SearchSysCacheCopy1(RELOID,
+ ObjectIdGetDatum(RelationGetRelid(relation)));
+ if (!HeapTupleIsValid(tuple))
+ elog(ERROR, "cache lookup failed for relation %u",
+ RelationGetRelid(relation));
+
+ ((Form_pg_class) GETSTRUCT(tuple))->relisivm = newstate;
+
+ CatalogTupleUpdate(pgrel, &tuple->t_self, tuple);
+
+ heap_freetuple(tuple);
+ table_close(pgrel, RowExclusiveLock);
+
+ /*
+ * Advance command counter to make the updated pg_class row locally
+ * visible.
+ */
+ CommandCounterIncrement();
+}
+
/*
* ExecRefreshMatView -- execute a REFRESH MATERIALIZED VIEW command
*
@@ -140,8 +270,6 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
{
Oid matviewOid;
Relation matviewRel;
- RewriteRule *rule;
- List *actions;
Query *dataQuery;
Oid tableSpace;
Oid relowner;
@@ -155,6 +283,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
int save_sec_context;
int save_nestlevel;
ObjectAddress address;
+ bool oldPopulated;
/* Determine strength of lock needed. */
concurrent = stmt->concurrent;
@@ -178,6 +307,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
SetUserIdAndSecContext(relowner,
save_sec_context | SECURITY_RESTRICTED_OPERATION);
save_nestlevel = NewGUCNestLevel();
+ oldPopulated = RelationIsPopulated(matviewRel);
/* Make sure it is a materialized view. */
if (matviewRel->rd_rel->relkind != RELKIND_MATVIEW)
@@ -199,32 +329,9 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
errmsg("%s and %s options cannot be used together",
"CONCURRENTLY", "WITH NO DATA")));
- /*
- * Check that everything is correct for a refresh. Problems at this point
- * are internal errors, so elog is sufficient.
- */
- if (matviewRel->rd_rel->relhasrules == false ||
- matviewRel->rd_rules->numLocks < 1)
- elog(ERROR,
- "materialized view \"%s\" is missing rewrite information",
- RelationGetRelationName(matviewRel));
-
- if (matviewRel->rd_rules->numLocks > 1)
- elog(ERROR,
- "materialized view \"%s\" has too many rules",
- RelationGetRelationName(matviewRel));
- rule = matviewRel->rd_rules->rules[0];
- if (rule->event != CMD_SELECT || !(rule->isInstead))
- elog(ERROR,
- "the rule for materialized view \"%s\" is not a SELECT INSTEAD OF rule",
- RelationGetRelationName(matviewRel));
+ dataQuery = get_matview_query(matviewRel);
- actions = rule->actions;
- if (list_length(actions) != 1)
- elog(ERROR,
- "the rule for materialized view \"%s\" is not a single action",
- RelationGetRelationName(matviewRel));
/*
* Check that there is a unique index with no WHERE clause on one or more
@@ -259,12 +366,6 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
errhint("Create a unique index with no WHERE clause on one or more columns of the materialized view.")));
}
- /*
- * The stored query was rewritten at the time of the MV definition, but
- * has not been scribbled on by the planner.
- */
- dataQuery = linitial_node(Query, actions);
-
/*
* Check for active uses of the relation in the current transaction, such
* as open scans.
@@ -292,6 +393,74 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
relpersistence = matviewRel->rd_rel->relpersistence;
}
+ /* delete IMMV triggers. */
+ if (RelationIsIVM(matviewRel) && stmt->skipData )
+ {
+ Relation tgRel;
+ Relation depRel;
+ ScanKeyData key;
+ SysScanDesc scan;
+ HeapTuple tup;
+ ObjectAddresses *immv_triggers;
+
+ immv_triggers = new_object_addresses();
+
+ tgRel = table_open(TriggerRelationId, RowExclusiveLock);
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ /* search triggers that depends on IMMV. */
+ ScanKeyInit(&key,
+ Anum_pg_depend_refobjid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(matviewOid));
+ scan = systable_beginscan(depRel, DependReferenceIndexId, true,
+ NULL, 1, &key);
+ while ((tup = systable_getnext(scan)) != NULL)
+ {
+ ObjectAddress obj;
+ Form_pg_depend foundDep = (Form_pg_depend) GETSTRUCT(tup);
+
+ if (foundDep->classid == TriggerRelationId)
+ {
+ HeapTuple tgtup;
+ ScanKeyData tgkey[1];
+ SysScanDesc tgscan;
+ Form_pg_trigger tgform;
+
+ /* Find the trigger name. */
+ ScanKeyInit(&tgkey[0],
+ Anum_pg_trigger_oid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(foundDep->objid));
+
+ tgscan = systable_beginscan(tgRel, TriggerOidIndexId, true,
+ NULL, 1, tgkey);
+ tgtup = systable_getnext(tgscan);
+ if (!HeapTupleIsValid(tgtup))
+ elog(ERROR, "could not find tuple for immv trigger %u", foundDep->objid);
+
+ tgform = (Form_pg_trigger) GETSTRUCT(tgtup);
+
+ /* If trigger is created by IMMV, delete it. */
+ if (strncmp(NameStr(tgform->tgname), "IVM_trigger_", 12) == 0)
+ {
+ obj.classId = foundDep->classid;
+ obj.objectId = foundDep->objid;
+ obj.objectSubId = foundDep->refobjsubid;
+ add_exact_object_address(&obj, immv_triggers);
+ }
+ systable_endscan(tgscan);
+ }
+ }
+ systable_endscan(scan);
+
+ performMultipleDeletions(immv_triggers, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ table_close(depRel, RowExclusiveLock);
+ table_close(tgRel, RowExclusiveLock);
+ free_object_addresses(immv_triggers);
+ }
+
/*
* Create the transient table that will receive the regenerated data. Lock
* it against access by any other process until commit (by which time it
@@ -305,7 +474,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
/* Generate the data, if wanted. */
if (!stmt->skipData)
- processed = refresh_matview_datafill(dest, dataQuery, queryString);
+ processed = refresh_matview_datafill(dest, dataQuery, NULL, NULL, queryString);
/* Make the matview match the newly generated data. */
if (concurrent)
@@ -340,6 +509,12 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
pgstat_count_heap_insert(matviewRel, processed);
}
+ if (!stmt->skipData && RelationIsIVM(matviewRel) && !oldPopulated)
+ {
+ CreateIndexOnIMMV(dataQuery, matviewRel);
+ CreateIvmTriggersOnBaseTables(dataQuery, matviewOid);
+ }
+
table_close(matviewRel, NoLock);
/* Roll back any GUC changes */
@@ -374,6 +549,8 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
*/
static uint64
refresh_matview_datafill(DestReceiver *dest, Query *query,
+ QueryEnvironment *queryEnv,
+ TupleDesc *resultTupleDesc,
const char *queryString)
{
List *rewritten;
@@ -410,7 +587,7 @@ refresh_matview_datafill(DestReceiver *dest, Query *query,
/* Create a QueryDesc, redirecting output to our tuple receiver */
queryDesc = CreateQueryDesc(plan, queryString,
GetActiveSnapshot(), InvalidSnapshot,
- dest, NULL, NULL, 0);
+ dest, NULL, queryEnv ? queryEnv: NULL, 0);
/* call ExecutorStart to prepare the plan for execution */
ExecutorStart(queryDesc, 0);
@@ -420,6 +597,9 @@ refresh_matview_datafill(DestReceiver *dest, Query *query,
processed = queryDesc->estate->es_processed;
+ if (resultTupleDesc)
+ *resultTupleDesc = CreateTupleDescCopy(queryDesc->tupDesc);
+
/* and clean up */
ExecutorFinish(queryDesc);
ExecutorEnd(queryDesc);
@@ -931,3 +1111,1219 @@ CloseMatViewIncrementalMaintenance(void)
matview_maintenance_depth--;
Assert(matview_maintenance_depth >= 0);
}
+
+/*
+ * get_matview_query - get the Query from a matview's _RETURN rule.
+ */
+static Query *
+get_matview_query(Relation matviewRel)
+{
+ RewriteRule *rule;
+ List * actions;
+
+ /*
+ * Check that everything is correct for a refresh. Problems at this point
+ * are internal errors, so elog is sufficient.
+ */
+ if (matviewRel->rd_rel->relhasrules == false ||
+ matviewRel->rd_rules->numLocks < 1)
+ elog(ERROR,
+ "materialized view \"%s\" is missing rewrite information",
+ RelationGetRelationName(matviewRel));
+
+ if (matviewRel->rd_rules->numLocks > 1)
+ elog(ERROR,
+ "materialized view \"%s\" has too many rules",
+ RelationGetRelationName(matviewRel));
+
+ rule = matviewRel->rd_rules->rules[0];
+ if (rule->event != CMD_SELECT || !(rule->isInstead))
+ elog(ERROR,
+ "the rule for materialized view \"%s\" is not a SELECT INSTEAD OF rule",
+ RelationGetRelationName(matviewRel));
+
+ actions = rule->actions;
+ if (list_length(actions) != 1)
+ elog(ERROR,
+ "the rule for materialized view \"%s\" is not a single action",
+ RelationGetRelationName(matviewRel));
+
+ /*
+ * The stored query was rewritten at the time of the MV definition, but
+ * has not been scribbled on by the planner.
+ */
+ return linitial_node(Query, actions);
+}
+
+
+/* ----------------------------------------------------
+ * Incremental View Maintenance routines
+ * ---------------------------------------------------
+ */
+
+/*
+ * IVM_immediate_before
+ *
+ * IVM trigger function invoked before base table is modified. If this is
+ * invoked firstly in the same statement, we save the transaction id and the
+ * command id at that time.
+ */
+Datum
+IVM_immediate_before(PG_FUNCTION_ARGS)
+{
+ TriggerData *trigdata = (TriggerData *) fcinfo->context;
+ char *matviewOid_text = trigdata->tg_trigger->tgargs[0];
+ char *ex_lock_text = trigdata->tg_trigger->tgargs[1];
+ Oid matviewOid;
+ MV_TriggerHashEntry *entry;
+ bool found;
+ bool ex_lock;
+
+ matviewOid = DatumGetObjectId(DirectFunctionCall1(oidin, CStringGetDatum(matviewOid_text)));
+ ex_lock = DatumGetBool(DirectFunctionCall1(boolin, CStringGetDatum(ex_lock_text)));
+
+ /* If the view has more than one tables, we have to use an exclusive lock. */
+ if (ex_lock)
+ {
+ /*
+ * Wait for concurrent transactions which update this materialized view at
+ * READ COMMITED. This is needed to see changes committed in other
+ * transactions. No wait and raise an error at REPEATABLE READ or
+ * SERIALIZABLE to prevent update anomalies of matviews.
+ * XXX: dead-lock is possible here.
+ */
+ if (!IsolationUsesXactSnapshot())
+ LockRelationOid(matviewOid, ExclusiveLock);
+ else if (!ConditionalLockRelationOid(matviewOid, ExclusiveLock))
+ {
+ /* try to throw error by name; relation could be deleted... */
+ char *relname = get_rel_name(matviewOid);
+
+ if (!relname)
+ ereport(ERROR,
+ (errcode(ERRCODE_LOCK_NOT_AVAILABLE),
+ errmsg("could not obtain lock on materialized view during incremental maintenance")));
+
+ ereport(ERROR,
+ (errcode(ERRCODE_LOCK_NOT_AVAILABLE),
+ errmsg("could not obtain lock on materialized view \"%s\" during incremental maintenance",
+ relname)));
+ }
+ }
+ else
+ LockRelationOid(matviewOid, RowExclusiveLock);
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_trigger_info)
+ mv_InitHashTables();
+
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_ENTER, &found);
+
+ /* On the first BEFORE to update the view, initialize trigger data */
+ if (!found)
+ {
+ /*
+ * Get a snapshot just before the table was modified for checking
+ * tuple visibility in the pre-update state of the table.
+ */
+ Snapshot snapshot = GetActiveSnapshot();
+
+ entry->matview_id = matviewOid;
+ entry->before_trig_count = 0;
+ entry->after_trig_count = 0;
+ entry->snapshot = RegisterSnapshot(snapshot);
+ entry->tables = NIL;
+ entry->has_old = false;
+ entry->has_new = false;
+ }
+
+ entry->before_trig_count++;
+
+ return PointerGetDatum(NULL);
+}
+
+/*
+ * IVM_immediate_maintenance
+ *
+ * IVM trigger function invoked after base table is modified.
+ * For each table, tuplestores of transition tables are collected.
+ * and after the last modification
+ */
+Datum
+IVM_immediate_maintenance(PG_FUNCTION_ARGS)
+{
+ TriggerData *trigdata = (TriggerData *) fcinfo->context;
+ Relation rel;
+ Oid relid;
+ Oid matviewOid;
+ Query *query;
+ Query *rewritten = NULL;
+ char *matviewOid_text = trigdata->tg_trigger->tgargs[0];
+ Relation matviewRel;
+ int old_depth = matview_maintenance_depth;
+
+ Oid relowner;
+ Tuplestorestate *old_tuplestore = NULL;
+ Tuplestorestate *new_tuplestore = NULL;
+ DestReceiver *dest_new = NULL, *dest_old = NULL;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ MV_TriggerHashEntry *entry;
+ MV_TriggerTable *table;
+ bool found;
+
+ ParseState *pstate;
+ QueryEnvironment *queryEnv = create_queryEnv();
+ MemoryContext oldcxt;
+ ListCell *lc;
+ int i;
+
+
+ /* Create a ParseState for rewriting the view definition query */
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ rel = trigdata->tg_relation;
+ relid = rel->rd_id;
+
+ matviewOid = DatumGetObjectId(DirectFunctionCall1(oidin, CStringGetDatum(matviewOid_text)));
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_trigger_info)
+ mv_InitHashTables();
+
+ /* get the entry for this materialized view */
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_FIND, &found);
+ Assert (found && entry != NULL);
+ entry->after_trig_count++;
+
+ /* search the entry for the modified table and create new entry if not found */
+ found = false;
+ foreach(lc, entry->tables)
+ {
+ table = (MV_TriggerTable *) lfirst(lc);
+ if (table->table_id == relid)
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ table = (MV_TriggerTable *) palloc0(sizeof(MV_TriggerTable));
+ table->table_id = relid;
+ table->old_tuplestores = NIL;
+ table->new_tuplestores = NIL;
+ table->rte_indexes = NIL;
+ table->slot = MakeSingleTupleTableSlot(RelationGetDescr(rel), table_slot_callbacks(rel));
+ table->rel = table_open(RelationGetRelid(rel), NoLock);
+ entry->tables = lappend(entry->tables, table);
+
+ MemoryContextSwitchTo(oldcxt);
+ }
+
+ /* Save the transition tables and make a request to not free immediately */
+ if (trigdata->tg_oldtable)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+ table->old_tuplestores = lappend(table->old_tuplestores, trigdata->tg_oldtable);
+ entry->has_old = true;
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (trigdata->tg_newtable)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+ table->new_tuplestores = lappend(table->new_tuplestores, trigdata->tg_newtable);
+ entry->has_new = true;
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (entry->has_new || entry->has_old)
+ {
+ CmdType cmd;
+
+ if (TRIGGER_FIRED_BY_INSERT(trigdata->tg_event))
+ cmd = CMD_INSERT;
+ else if (TRIGGER_FIRED_BY_DELETE(trigdata->tg_event))
+ cmd = CMD_DELETE;
+ else if (TRIGGER_FIRED_BY_UPDATE(trigdata->tg_event))
+ cmd = CMD_UPDATE;
+ else
+ elog(ERROR,"unsupported trigger type");
+
+ /* Prolong lifespan of transition tables to the end of the last AFTER trigger */
+ SetTransitionTablePreserved(relid, cmd);
+ }
+
+
+ /* If this is not the last AFTER trigger call, immediately exit. */
+ Assert (entry->before_trig_count >= entry->after_trig_count);
+ if (entry->before_trig_count != entry->after_trig_count)
+ return PointerGetDatum(NULL);
+
+ /*
+ * If this is the last AFTER trigger call, continue and update the view.
+ */
+
+ /*
+ * Advance command counter to make the updated base table row locally
+ * visible.
+ */
+ CommandCounterIncrement();
+
+ matviewRel = table_open(matviewOid, NoLock);
+
+ /* Make sure it is a materialized view. */
+ Assert(matviewRel->rd_rel->relkind == RELKIND_MATVIEW);
+
+ /*
+ * Get and push the latast snapshot to see any changes which is committed
+ * during waiting in other transactions at READ COMMITTED level.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /*
+ * Check for active uses of the relation in the current transaction, such
+ * as open scans.
+ *
+ * NB: We count on this to protect us against problems with refreshing the
+ * data using TABLE_INSERT_FROZEN.
+ */
+ CheckTableNotInUse(matviewRel, "refresh a materialized view incrementally");
+
+ /*
+ * Switch to the owner's userid, so that any functions are run as that
+ * user. Also arrange to make GUC variable changes local to this command.
+ * We will switch modes when we are about to execute user code.
+ */
+ relowner = matviewRel->rd_rel->relowner;
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+
+ /* get view query*/
+ query = get_matview_query(matviewRel);
+
+ /*
+ * When a base table is truncated, the view content will be empty if the
+ * view definition query does not contain an aggregate without a GROUP clause.
+ * Therefore, such views can be truncated.
+ */
+ if (TRIGGER_FIRED_BY_TRUNCATE(trigdata->tg_event))
+ {
+ ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
+ NIL, DROP_RESTRICT, false, false);
+
+ /* Clean up hash entry and delete tuplestores */
+ clean_up_IVM_hash_entry(entry, false);
+
+ /* Pop the original snapshot. */
+ PopActiveSnapshot();
+
+ table_close(matviewRel, NoLock);
+
+ /* Roll back any GUC changes */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ return PointerGetDatum(NULL);
+ }
+
+ /*
+ * rewrite query for calculating deltas
+ */
+
+ rewritten = copyObject(query);
+
+ /* Replace resnames in a target list with materialized view's attnames */
+ i = 0;
+ foreach (lc, rewritten->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
+
+ tle->resname = pstrdup(resname);
+ i++;
+ }
+
+ /* Set all tables in the query to pre-update state */
+ rewritten = rewrite_query_for_preupdate_state(rewritten, entry->tables,
+ pstate, matviewOid);
+ /* Rewrite for counting duplicated tuples */
+ rewritten = rewrite_query_for_counting(rewritten, pstate);
+
+ /* Create tuplestores to store view deltas */
+ if (entry->has_old)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ old_tuplestore = tuplestore_begin_heap(false, false, work_mem);
+ dest_old = CreateDestReceiver(DestTuplestore);
+ SetTuplestoreDestReceiverParams(dest_old,
+ old_tuplestore,
+ TopTransactionContext,
+ false,
+ NULL,
+ NULL);
+
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (entry->has_new)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ new_tuplestore = tuplestore_begin_heap(false, false, work_mem);
+ dest_new = CreateDestReceiver(DestTuplestore);
+ SetTuplestoreDestReceiverParams(dest_new,
+ new_tuplestore,
+ TopTransactionContext,
+ false,
+ NULL,
+ NULL);
+ MemoryContextSwitchTo(oldcxt);
+ }
+
+ /* for all modified tables */
+ foreach(lc, entry->tables)
+ {
+ ListCell *lc2;
+
+ table = (MV_TriggerTable *) lfirst(lc);
+
+ /* loop for self-join */
+ foreach(lc2, table->rte_indexes)
+ {
+ int rte_index = lfirst_int(lc2);
+ TupleDesc tupdesc_old;
+ TupleDesc tupdesc_new;
+
+ /* calculate delta tables */
+ calc_delta(table, rte_index, rewritten, dest_old, dest_new,
+ &tupdesc_old, &tupdesc_new, queryEnv);
+
+ /* Set the table in the query to post-update state */
+ rewritten = rewrite_query_for_postupdate_state(rewritten, table, rte_index);
+
+ PG_TRY();
+ {
+ /* apply the delta tables to the materialized view */
+ apply_delta(matviewOid, old_tuplestore, new_tuplestore,
+ tupdesc_old, tupdesc_new, query);
+ }
+ PG_CATCH();
+ {
+ matview_maintenance_depth = old_depth;
+ PG_RE_THROW();
+ }
+ PG_END_TRY();
+
+ /* clear view delta tuplestores */
+ if (old_tuplestore)
+ tuplestore_clear(old_tuplestore);
+ if (new_tuplestore)
+ tuplestore_clear(new_tuplestore);
+ }
+ }
+
+ /* Clean up hash entry and delete tuplestores */
+ clean_up_IVM_hash_entry(entry, false);
+ if (old_tuplestore)
+ {
+ dest_old->rDestroy(dest_old);
+ tuplestore_end(old_tuplestore);
+ }
+ if (new_tuplestore)
+ {
+ dest_new->rDestroy(dest_new);
+ tuplestore_end(new_tuplestore);
+ }
+
+ /* Pop the original snapshot. */
+ PopActiveSnapshot();
+
+ table_close(matviewRel, NoLock);
+
+ /* Roll back any GUC changes */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ return PointerGetDatum(NULL);
+}
+
+/*
+ * rewrite_query_for_preupdate_state
+ *
+ * Rewrite the query so that base tables' RTEs will represent "pre-update"
+ * state of tables. This is necessary to calculate view delta after multiple
+ * tables are modified.
+ */
+static Query*
+rewrite_query_for_preupdate_state(Query *query, List *tables,
+ ParseState *pstate, Oid matviewid)
+{
+ ListCell *lc;
+ int num_rte = list_length(query->rtable);
+ int i;
+
+
+ /* register delta ENRs */
+ register_delta_ENRs(pstate, query, tables);
+
+ /* XXX: Is necessary? Is this right timing? */
+ AcquireRewriteLocks(query, true, false);
+
+ i = 1;
+ foreach(lc, query->rtable)
+ {
+ RangeTblEntry *r = (RangeTblEntry*) lfirst(lc);
+
+ ListCell *lc2;
+ foreach(lc2, tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc2);
+ /*
+ * if the modified table is found then replace the original RTE with
+ * "pre-state" RTE and append its index to the list.
+ */
+ if (r->relid == table->table_id)
+ {
+ List *securityQuals;
+ List *withCheckOptions;
+ bool hasRowSecurity;
+ bool hasSubLinks;
+
+ RangeTblEntry *rte_pre = get_prestate_rte(r, table, pstate->p_queryEnv, matviewid);
+
+ /*
+ * Set a row security poslicies of the modified table to the subquery RTE which
+ * represents the pre-update state of the table.
+ */
+ get_row_security_policies(query, table->original_rte, i,
+ &securityQuals, &withCheckOptions,
+ &hasRowSecurity, &hasSubLinks);
+
+ if (hasRowSecurity)
+ {
+ query->hasRowSecurity = true;
+ rte_pre->security_barrier = true;
+ }
+ if (hasSubLinks)
+ query->hasSubLinks = true;
+
+ rte_pre->securityQuals = securityQuals;
+ lfirst(lc) = rte_pre;
+
+ table->rte_indexes = lappend_int(table->rte_indexes, i);
+ break;
+ }
+ }
+
+ /* finish the loop if we processed all RTE included in the original query */
+ if (i++ >= num_rte)
+ break;
+ }
+
+ return query;
+}
+
+/*
+ * register_delta_ENRs
+ *
+ * For all modified tables, make ENRs for their transition tables
+ * and register them to the queryEnv. ENR's RTEs are also appended
+ * into the list in query tree.
+ */
+static void
+register_delta_ENRs(ParseState *pstate, Query *query, List *tables)
+{
+ QueryEnvironment *queryEnv = pstate->p_queryEnv;
+ ListCell *lc;
+ RangeTblEntry *rte;
+
+ foreach(lc, tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc);
+ ListCell *lc2;
+ int count;
+
+ count = 0;
+ foreach(lc2, table->old_tuplestores)
+ {
+ Tuplestorestate *oldtable = (Tuplestorestate *) lfirst(lc2);
+ EphemeralNamedRelation enr =
+ palloc(sizeof(EphemeralNamedRelationData));
+ ParseNamespaceItem *nsitem;
+
+ enr->md.name = make_delta_enr_name("old", table->table_id, count);
+ enr->md.reliddesc = table->table_id;
+ enr->md.tupdesc = NULL;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(oldtable);
+ enr->reldata = oldtable;
+ register_ENR(queryEnv, enr);
+
+ nsitem = addRangeTableEntryForENR(pstate, makeRangeVar(NULL, enr->md.name, -1), true);
+ rte = nsitem->p_rte;
+
+ query->rtable = lappend(query->rtable, rte);
+
+ count++;
+ }
+
+ count = 0;
+ foreach(lc2, table->new_tuplestores)
+ {
+ Tuplestorestate *newtable = (Tuplestorestate *) lfirst(lc2);
+ EphemeralNamedRelation enr =
+ palloc(sizeof(EphemeralNamedRelationData));
+ ParseNamespaceItem *nsitem;
+
+ enr->md.name = make_delta_enr_name("new", table->table_id, count);
+ enr->md.reliddesc = table->table_id;
+ enr->md.tupdesc = NULL;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(newtable);
+ enr->reldata = newtable;
+ register_ENR(queryEnv, enr);
+
+ nsitem = addRangeTableEntryForENR(pstate, makeRangeVar(NULL, enr->md.name, -1), true);
+ rte = nsitem->p_rte;
+
+ query->rtable = lappend(query->rtable, rte);
+
+ count++;
+ }
+ }
+}
+
+#define DatumGetItemPointer(X) ((ItemPointer) DatumGetPointer(X))
+#define PG_GETARG_ITEMPOINTER(n) DatumGetItemPointer(PG_GETARG_DATUM(n))
+
+/*
+ * ivm_visible_in_prestate
+ *
+ * Check visibility of a tuple specified by the tableoid and item pointer
+ * using the snapshot taken just before the table was modified.
+ */
+Datum
+ivm_visible_in_prestate(PG_FUNCTION_ARGS)
+{
+ Oid tableoid = PG_GETARG_OID(0);
+ ItemPointer itemPtr = PG_GETARG_ITEMPOINTER(1);
+ Oid matviewOid = PG_GETARG_OID(2);
+ MV_TriggerHashEntry *entry;
+ MV_TriggerTable *table = NULL;
+ ListCell *lc;
+ bool found;
+ bool result;
+
+ if (!in_delta_calculation)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("ivm_visible_in_prestate can be called only in delta calculation")));
+
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_FIND, &found);
+ Assert (found && entry != NULL);
+
+ foreach(lc, entry->tables)
+ {
+ table = (MV_TriggerTable *) lfirst(lc);
+ if (table->table_id == tableoid)
+ break;
+ }
+
+ Assert (table != NULL);
+
+ result = table_tuple_fetch_row_version(table->rel, itemPtr, entry->snapshot, table->slot);
+
+ PG_RETURN_BOOL(result);
+}
+
+/*
+ * get_prestate_rte
+ *
+ * Rewrite RTE of the modified table to a subquery which represents
+ * "pre-state" table. The original RTE is saved in table->rte_original.
+ */
+static RangeTblEntry*
+get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *table,
+ QueryEnvironment *queryEnv, Oid matviewid)
+{
+ StringInfoData str;
+ RawStmt *raw;
+ Query *subquery;
+ Relation rel;
+ ParseState *pstate;
+ char *relname;
+ int i;
+
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ /*
+ * We can use NoLock here since AcquireRewriteLocks should
+ * have locked the relation already.
+ */
+ rel = table_open(table->table_id, NoLock);
+ relname = quote_qualified_identifier(
+ get_namespace_name(RelationGetNamespace(rel)),
+ RelationGetRelationName(rel));
+ table_close(rel, NoLock);
+
+ /*
+ * Filtering inserted row using the snapshot taken before the table
+ * is modified. ctid is required for maintaining outer join views.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str,
+ "SELECT t.* FROM %s t"
+ " WHERE pg_catalog.ivm_visible_in_prestate(t.tableoid, t.ctid ,%d::pg_catalog.oid)",
+ relname, matviewid);
+
+ /*
+ * Append deleted rows contained in old transition tables.
+ */
+ for (i = 0; i < list_length(table->old_tuplestores); i++)
+ {
+ appendStringInfo(&str, " UNION ALL ");
+ appendStringInfo(&str," SELECT * FROM %s",
+ make_delta_enr_name("old", table->table_id, i));
+ }
+
+ /* Get a subquery representing pre-state of the table */
+ raw = (RawStmt*)linitial(raw_parser(str.data, RAW_PARSE_DEFAULT));
+ subquery = transformStmt(pstate, raw->stmt);
+
+ /* save the original RTE */
+ table->original_rte = copyObject(rte);
+
+ rte->rtekind = RTE_SUBQUERY;
+ rte->subquery = subquery;
+ rte->security_barrier = false;
+
+ /* Clear fields that should not be set in a subquery RTE */
+ rte->relid = InvalidOid;
+ rte->relkind = 0;
+ rte->rellockmode = 0;
+ rte->tablesample = NULL;
+ rte->perminfoindex = 0; /* no permission checking for this RTE */
+ rte->inh = false; /* must not be set for a subquery */
+
+ return rte;
+}
+
+/*
+ * make_delta_enr_name
+ *
+ * Make a name for ENR of a transition table from the base table's oid.
+ * prefix will be "new" or "old" depending on its transition table kind..
+ */
+static char*
+make_delta_enr_name(const char *prefix, Oid relid, int count)
+{
+ char buf[NAMEDATALEN];
+ char *name;
+
+ snprintf(buf, NAMEDATALEN, "__ivm_%s_%u_%u", prefix, relid, count);
+ name = pstrdup(buf);
+
+ return name;
+}
+
+/*
+ * replace_rte_with_delta
+ *
+ * Replace RTE of the modified table with a single table delta that combine its
+ * all transition tables.
+ */
+static RangeTblEntry*
+replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
+ QueryEnvironment *queryEnv)
+{
+ Oid relid = table->table_id;
+ StringInfoData str;
+ ParseState *pstate;
+ RawStmt *raw;
+ Query *sub;
+ int num_tuplestores = list_length(is_new ? table->new_tuplestores : table->old_tuplestores);
+ int i;
+
+ /* the previous RTE must be a subquery which represents "pre-state" table */
+ Assert(rte->rtekind == RTE_SUBQUERY);
+
+ /* Create a ParseState for rewriting the view definition query */
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ initStringInfo(&str);
+
+ for (i = 0; i < num_tuplestores; i++)
+ {
+ if (i > 0)
+ appendStringInfo(&str, " UNION ALL ");
+
+ appendStringInfo(&str,
+ " SELECT * FROM %s",
+ make_delta_enr_name(is_new ? "new" : "old", relid, i));
+ }
+
+ raw = (RawStmt*)linitial(raw_parser(str.data, RAW_PARSE_DEFAULT));
+ sub = transformStmt(pstate, raw->stmt);
+
+ /*
+ * Update the subquery so that it represent the combined transition
+ * table. Note that we leave the security_barrier and securityQuals
+ * fields so that the subquery relation can be protected by the RLS
+ * policy as same as the modified table.
+ */
+ rte->rtekind = RTE_SUBQUERY;
+ rte->subquery = sub;
+
+ return rte;
+}
+
+/*
+ * rewrite_query_for_counting
+ *
+ * Rewrite query for counting duplicated tuples.
+ */
+static Query *
+rewrite_query_for_counting(Query *query, ParseState *pstate)
+{
+ TargetEntry *tle_count;
+ FuncCall *fn;
+ Node *node;
+
+ /* Add count(*) for counting distinct tuples in views */
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+ fn->agg_star = true;
+ if (!query->groupClause && !query->hasAggs)
+ query->groupClause = transformDistinctClause(NULL, &query->targetList, query->sortClause, false);
+
+ node = ParseFuncOrColumn(pstate, fn->funcname, NIL, NULL, fn, false, -1);
+
+ tle_count = makeTargetEntry((Expr *) node,
+ list_length(query->targetList) + 1,
+ pstrdup("__ivm_count__"),
+ false);
+ query->targetList = lappend(query->targetList, tle_count);
+ query->hasAggs = true;
+
+ return query;
+}
+
+/*
+ * calc_delta
+ *
+ * Calculate view deltas generated under the modification of a table specified
+ * by the RTE index.
+ */
+static void
+calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
+ DestReceiver *dest_old, DestReceiver *dest_new,
+ TupleDesc *tupdesc_old, TupleDesc *tupdesc_new,
+ QueryEnvironment *queryEnv)
+{
+ ListCell *lc = list_nth_cell(query->rtable, rte_index - 1);
+ RangeTblEntry *rte = (RangeTblEntry *) lfirst(lc);
+
+ in_delta_calculation = true;
+
+ /* Generate old delta */
+ if (list_length(table->old_tuplestores) > 0)
+ {
+ /* Replace the modified table with the old delta table and calculate the old view delta. */
+ replace_rte_with_delta(rte, table, false, queryEnv);
+ refresh_matview_datafill(dest_old, query, queryEnv, tupdesc_old, "");
+ }
+
+ /* Generate new delta */
+ if (list_length(table->new_tuplestores) > 0)
+ {
+ /* Replace the modified table with the new delta table and calculate the new view delta*/
+ replace_rte_with_delta(rte, table, true, queryEnv);
+ refresh_matview_datafill(dest_new, query, queryEnv, tupdesc_new, "");
+ }
+
+ in_delta_calculation = false;
+}
+
+/*
+ * rewrite_query_for_postupdate_state
+ *
+ * Rewrite the query so that the specified base table's RTEs will represent
+ * "post-update" state of tables. This is called after the view delta
+ * calculation due to changes on this table finishes.
+ */
+static Query*
+rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte_index)
+{
+ ListCell *lc = list_nth_cell(query->rtable, rte_index - 1);
+
+ /* Retore the original RTE */
+ lfirst(lc) = table->original_rte;
+
+ return query;
+}
+
+/*
+ * apply_delta
+ *
+ * Apply deltas to the materialized view. In outer join cases, this requires
+ * the view maintenance graph.
+ */
+static void
+apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
+ TupleDesc tupdesc_old, TupleDesc tupdesc_new,
+ Query *query)
+{
+ StringInfoData querybuf;
+ StringInfoData target_list_buf;
+ Relation matviewRel;
+ char *matviewname;
+ ListCell *lc;
+ int i;
+ List *keys = NIL;
+
+
+ /*
+ * get names of the materialized view and delta tables
+ */
+
+ matviewRel = table_open(matviewOid, NoLock);
+ matviewname = quote_qualified_identifier(get_namespace_name(RelationGetNamespace(matviewRel)),
+ RelationGetRelationName(matviewRel));
+
+ /*
+ * Build parts of the maintenance queries
+ */
+
+ initStringInfo(&querybuf);
+ initStringInfo(&target_list_buf);
+
+ /* build string of target list */
+ for (i = 0; i < matviewRel->rd_att->natts; i++)
+ {
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
+
+ if (i != 0)
+ appendStringInfo(&target_list_buf, ", ");
+ appendStringInfo(&target_list_buf, "%s", quote_qualified_identifier(NULL, resname));
+ }
+
+ i = 0;
+ foreach (lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+
+ i++;
+
+ if (tle->resjunk)
+ continue;
+
+ keys = lappend(keys, attr);
+ }
+
+ /* Start maintaining the materialized view. */
+ OpenMatViewIncrementalMaintenance();
+
+ /* Open SPI context. */
+ if (SPI_connect() != SPI_OK_CONNECT)
+ elog(ERROR, "SPI_connect failed");
+
+ /* For tuple deletion */
+ if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
+ {
+ EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ int rc;
+
+ /* convert tuplestores to ENR, and register for SPI */
+ enr->md.name = pstrdup(OLD_DELTA_ENRNAME);
+ enr->md.reliddesc = InvalidOid;
+ enr->md.tupdesc = tupdesc_old;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(old_tuplestores);
+ enr->reldata = old_tuplestores;
+
+ rc = SPI_register_relation(enr);
+ if (rc != SPI_OK_REL_REGISTER)
+ elog(ERROR, "SPI_register failed");
+
+ apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+
+ }
+ /* For tuple insertion */
+ if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
+ {
+ EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ int rc;
+
+ /* convert tuplestores to ENR, and register for SPI */
+ enr->md.name = pstrdup(NEW_DELTA_ENRNAME);
+ enr->md.reliddesc = InvalidOid;
+ enr->md.tupdesc = tupdesc_new;;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(new_tuplestores);
+ enr->reldata = new_tuplestores;
+
+ rc = SPI_register_relation(enr);
+ if (rc != SPI_OK_REL_REGISTER)
+ elog(ERROR, "SPI_register failed");
+
+ /* apply new delta */
+ apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
+ }
+
+ /* We're done maintaining the materialized view. */
+ CloseMatViewIncrementalMaintenance();
+
+ table_close(matviewRel, NoLock);
+
+ /* Close SPI context. */
+ if (SPI_finish() != SPI_OK_FINISH)
+ elog(ERROR, "SPI_finish failed");
+}
+
+/*
+ * apply_old_delta
+ *
+ * Execute a query for applying a delta table given by deltname_old
+ * which contains tuples to be deleted from to a materialized view given by
+ * matviewname. This is used when counting is not required.
+ */
+static void
+apply_old_delta(const char *matviewname, const char *deltaname_old,
+ List *keys)
+{
+ StringInfoData querybuf;
+ StringInfoData keysbuf;
+ char *match_cond;
+ ListCell *lc;
+
+ /* build WHERE condition for searching tuples to be deleted */
+ match_cond = get_matching_condition_string(keys);
+
+ /* build string of keys list */
+ initStringInfo(&keysbuf);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&keysbuf, "%s", quote_qualified_identifier("mv", resname));
+ if (lnext(keys, lc))
+ appendStringInfo(&keysbuf, ", ");
+ }
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "DELETE FROM %s WHERE ctid IN ("
+ "SELECT tid FROM (SELECT pg_catalog.row_number() over (partition by %s) AS \"__ivm_row_number__\","
+ "mv.ctid AS tid,"
+ "diff.\"__ivm_count__\""
+ "FROM %s AS mv, %s AS diff "
+ "WHERE %s) v "
+ "WHERE v.\"__ivm_row_number__\" OPERATOR(pg_catalog.<=) v.\"__ivm_count__\")",
+ matviewname,
+ keysbuf.data,
+ matviewname, deltaname_old,
+ match_cond);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
+/*
+ * apply_new_delta
+ *
+ * Execute a query for applying a delta table given by deltname_new
+ * which contains tuples to be inserted into a materialized view given by
+ * matviewname. This is used when counting is not required.
+ */
+static void
+apply_new_delta(const char *matviewname, const char *deltaname_new,
+ StringInfo target_list)
+{
+ StringInfoData querybuf;
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "INSERT INTO %s (%s) SELECT %s FROM ("
+ "SELECT diff.*, pg_catalog.generate_series(1, diff.\"__ivm_count__\")"
+ " AS __ivm_generate_series__ "
+ "FROM %s AS diff) AS v",
+ matviewname, target_list->data, target_list->data,
+ deltaname_new);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_INSERT)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
+/*
+ * get_matching_condition_string
+ *
+ * Build a predicate string for looking for a tuple with given keys.
+ */
+static char *
+get_matching_condition_string(List *keys)
+{
+ StringInfoData match_cond;
+ ListCell *lc;
+
+ /* If there is no key columns, the condition is always true. */
+ if (keys == NIL)
+ return "true";
+
+ initStringInfo(&match_cond);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ char *mv_resname = quote_qualified_identifier("mv", resname);
+ char *diff_resname = quote_qualified_identifier("diff", resname);
+ Oid typid = attr->atttypid;
+
+ /* Considering NULL values, we can not use simple = operator. */
+ appendStringInfo(&match_cond, "(");
+ generate_equal(&match_cond, typid, mv_resname, diff_resname);
+ appendStringInfo(&match_cond, " OR (%s IS NULL AND %s IS NULL))",
+ mv_resname, diff_resname);
+
+ if (lnext(keys, lc))
+ appendStringInfo(&match_cond, " AND ");
+ }
+
+ return match_cond.data;
+}
+
+/*
+ * generate_equals
+ *
+ * Generate an equality clause using given operands' default equality
+ * operator.
+ */
+static void
+generate_equal(StringInfo querybuf, Oid opttype,
+ const char *leftop, const char *rightop)
+{
+ TypeCacheEntry *typentry;
+
+ typentry = lookup_type_cache(opttype, TYPECACHE_EQ_OPR);
+ if (!OidIsValid(typentry->eq_opr))
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_FUNCTION),
+ errmsg("could not identify an equality operator for type %s",
+ format_type_be_qualified(opttype))));
+
+ generate_operator_clause(querybuf,
+ leftop, opttype,
+ typentry->eq_opr,
+ rightop, opttype);
+}
+
+/*
+ * mv_InitHashTables
+ */
+static void
+mv_InitHashTables(void)
+{
+ HASHCTL ctl;
+
+ memset(&ctl, 0, sizeof(ctl));
+ ctl.keysize = sizeof(Oid);
+ ctl.entrysize = sizeof(MV_TriggerHashEntry);
+ mv_trigger_info = hash_create("MV trigger info",
+ MV_INIT_QUERYHASHSIZE,
+ &ctl, HASH_ELEM | HASH_BLOBS);
+}
+
+/*
+ * AtAbort_IVM
+ *
+ * Clean up hash entries for all materialized views. This is called at
+ * transaction abort.
+ */
+void
+AtAbort_IVM()
+{
+ HASH_SEQ_STATUS seq;
+ MV_TriggerHashEntry *entry;
+
+ if (mv_trigger_info)
+ {
+ hash_seq_init(&seq, mv_trigger_info);
+ while ((entry = hash_seq_search(&seq)) != NULL)
+ clean_up_IVM_hash_entry(entry, true);
+ }
+ in_delta_calculation = false;
+}
+
+/*
+ * clean_up_IVM_hash_entry
+ *
+ * Clean up tuple stores and hash entries for a materialized view after its
+ * maintenance finished.
+ */
+static void
+clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort)
+{
+ bool found;
+ ListCell *lc;
+
+ foreach(lc, entry->tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc);
+
+ list_free(table->old_tuplestores);
+ list_free(table->new_tuplestores);
+ if (!is_abort)
+ {
+ ExecDropSingleTupleTableSlot(table->slot);
+ table_close(table->rel, NoLock);
+ }
+ }
+ list_free(entry->tables);
+
+ if (!is_abort)
+ UnregisterSnapshot(entry->snapshot);
+
+ hash_search(mv_trigger_info, (void *) &entry->matview_id, HASH_REMOVE, &found);
+}
+
+/*
+ * isIvmName
+ *
+ * Check if this is a IVM hidden column from the name.
+ */
+bool
+isIvmName(const char *s)
+{
+ if (s)
+ return (strncmp(s, "__ivm_", 6) == 0);
+ return false;
+}
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index 9805bc6118..f6896d77b4 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -12062,4 +12062,14 @@
proname => 'any_value_transfn', prorettype => 'anyelement',
proargtypes => 'anyelement anyelement', prosrc => 'any_value_transfn' },
+# IVM
+{ oid => '786', descr => 'ivm trigger (before)',
+ proname => 'IVM_immediate_before', provolatile => 'v', prorettype => 'trigger',
+ proargtypes => '', prosrc => 'IVM_immediate_before' },
+{ oid => '787', descr => 'ivm trigger (after)',
+ proname => 'IVM_immediate_maintenance', provolatile => 'v', prorettype => 'trigger',
+ proargtypes => '', prosrc => 'IVM_immediate_maintenance' },
+{ oid => '788', descr => 'ivm filetring ',
+ proname => 'ivm_visible_in_prestate', provolatile => 's', prorettype => 'bool',
+ proargtypes => 'oid tid oid', prosrc => 'ivm_visible_in_prestate' },
]
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 3647f96f73..09a64fa2e5 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -16,6 +16,7 @@
#include "catalog/objectaddress.h"
#include "nodes/params.h"
+#include "nodes/pathnodes.h"
#include "parser/parse_node.h"
#include "tcop/dest.h"
#include "utils/queryenvironment.h"
@@ -25,6 +26,9 @@ extern ObjectAddress ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *st
ParamListInfo params, QueryEnvironment *queryEnv,
QueryCompletion *qc);
+extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
+extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
+
extern int GetIntoRelEFlags(IntoClause *intoClause);
extern DestReceiver *CreateIntoRelDestReceiver(IntoClause *intoClause);
diff --git a/src/include/commands/matview.h b/src/include/commands/matview.h
index 9eaa6212a1..504b83a446 100644
--- a/src/include/commands/matview.h
+++ b/src/include/commands/matview.h
@@ -15,6 +15,7 @@
#define MATVIEW_H
#include "catalog/objectaddress.h"
+#include "fmgr.h"
#include "nodes/params.h"
#include "nodes/parsenodes.h"
#include "tcop/dest.h"
@@ -23,6 +24,8 @@
extern void SetMatViewPopulatedState(Relation relation, bool newstate);
+extern void SetMatViewIVMState(Relation relation, bool newstate);
+
extern ObjectAddress ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
ParamListInfo params, QueryCompletion *qc);
@@ -30,4 +33,10 @@ extern DestReceiver *CreateTransientRelDestReceiver(Oid transientoid);
extern bool MatViewIncrementalMaintenanceIsEnabled(void);
+extern Datum IVM_immediate_before(PG_FUNCTION_ARGS);
+extern Datum IVM_immediate_maintenance(PG_FUNCTION_ARGS);
+extern Datum IVM_visible_in_prestate(PG_FUNCTION_ARGS);
+extern void AtAbort_IVM(void);
+extern bool isIvmName(const char *s);
+
#endif /* MATVIEW_H */
--
2.25.1
v29-0007-Add-DISTINCT-support-for-IVM.patchtext/x-diff; name=v29-0007-Add-DISTINCT-support-for-IVM.patchDownload
From b793929595683e09d8c1c2eee78c284497663ad3 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 19:08:51 +0900
Subject: [PATCH v29 07/11] Add DISTINCT support for IVM
When IMMV is created with DISTINCT, multiplicity of tuples is
counted and stored in "__ivm_count__" column, which is a hidden
column of IMMV. The value in __ivm_count__ is updated when IMMV
is maintained incrementally. A tuple in IMMV can be removed if
and only if the count becomes zero.
---
src/backend/commands/createas.c | 141 ++++++++++++++++++++------
src/backend/commands/indexcmds.c | 40 ++++++++
src/backend/commands/matview.c | 148 ++++++++++++++++++++++++++--
src/backend/commands/tablecmds.c | 9 ++
src/backend/parser/parse_relation.c | 18 +++-
src/backend/rewrite/rewriteDefine.c | 3 +-
src/include/commands/createas.h | 2 +
src/include/nodes/parsenodes.h | 1 +
8 files changed, 317 insertions(+), 45 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index 415f110516..076f35ee6b 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -53,6 +53,7 @@
#include "parser/parser.h"
#include "parser/parsetree.h"
#include "parser/parse_clause.h"
+#include "parser/parse_func.h"
#include "rewrite/rewriteHandler.h"
#include "storage/smgr.h"
#include "tcop/tcopprot.h"
@@ -309,6 +310,9 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
errhint("functions must be marked IMMUTABLE")));
check_ivm_restriction((Node *) query);
+
+ /* For IMMV, we need to rewrite matview query */
+ query = rewriteQueryForIMMV(query, into->colNames);
}
if (into->skipData)
@@ -413,6 +417,49 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
return address;
}
+/*
+ * rewriteQueryForIMMV -- rewrite view definition query for IMMV
+ *
+ * count(*) is added for counting distinct tuples in views.
+ */
+Query *
+rewriteQueryForIMMV(Query *query, List *colNames)
+{
+ Query *rewritten;
+
+ Node *node;
+ ParseState *pstate = make_parsestate(NULL);
+ FuncCall *fn;
+
+ rewritten = copyObject(query);
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ /*
+ * Convert DISTINCT to GROUP BY and add count(*) for counting distinct
+ * tuples in views.
+ */
+ if (rewritten->distinctClause)
+ {
+ TargetEntry *tle;
+
+ rewritten->groupClause = transformDistinctClause(NULL, &rewritten->targetList, rewritten->sortClause, false);
+
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+ fn->agg_star = true;
+
+ node = ParseFuncOrColumn(pstate, fn->funcname, NIL, NULL, fn, false, -1);
+
+ tle = makeTargetEntry((Expr *) node,
+ list_length(rewritten->targetList) + 1,
+ pstrdup("__ivm_count__"),
+ false);
+ rewritten->targetList = lappend(rewritten->targetList, tle);
+ rewritten->hasAggs = true;
+ }
+
+ return rewritten;
+}
+
/*
* GetIntoRelEFlags --- compute executor flags needed for CREATE TABLE AS
*
@@ -536,7 +583,8 @@ intorel_startup(DestReceiver *self, int operation, TupleDesc typeinfo)
ColumnDef *col;
char *colname;
- if (lc)
+ /* Don't override hidden columns added for IVM */
+ if (lc && !isIvmName(NameStr(attribute->attname)))
{
colname = strVal(lfirst(lc));
lc = lnext(into->colNames, lc);
@@ -940,10 +988,6 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view")));
- if (qry->distinctClause)
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("DISTINCT is not supported on incrementally maintainable materialized view")));
if (qry->hasDistinctOn)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
@@ -1090,12 +1134,18 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
char idxname[NAMEDATALEN];
List *indexoidlist = RelationGetIndexList(matviewRel);
ListCell *indexoidscan;
- Bitmapset *key_attnos;
snprintf(idxname, sizeof(idxname), "%s_index", RelationGetRelationName(matviewRel));
index = makeNode(IndexStmt);
+ /*
+ * We consider null values not distinct to make sure that views with DISTINCT
+ * or GROUP BY don't contain multiple NULL rows when NULL is inserted to
+ * a base table concurrently.
+ */
+ index->nulls_not_distinct = true;
+
index->unique = true;
index->primary = false;
index->isconstraint = false;
@@ -1122,41 +1172,68 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
index->concurrent = false;
index->if_not_exists = false;
- /* create index on the base tables' primary key columns */
- key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
- if (key_attnos)
+ if (query->distinctClause)
{
+ /* create unique constraint on all columns */
foreach(lc, query->targetList)
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
-
- if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
- {
- IndexElem *iparam;
-
- iparam = makeNode(IndexElem);
- iparam->name = pstrdup(NameStr(attr->attname));
- iparam->expr = NULL;
- iparam->indexcolname = NULL;
- iparam->collation = NIL;
- iparam->opclass = NIL;
- iparam->opclassopts = NIL;
- iparam->ordering = SORTBY_DEFAULT;
- iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
- index->indexParams = lappend(index->indexParams, iparam);
- }
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
}
}
else
{
- /* create no index, just notice that an appropriate index is necessary for efficient IVM */
- ereport(NOTICE,
- (errmsg("could not create an index on materialized view \"%s\" automatically",
- RelationGetRelationName(matviewRel)),
- errdetail("This target list does not have all the primary key columns. "),
- errhint("Create an index on the materialized view for efficient incremental maintenance.")));
- return;
+ Bitmapset *key_attnos;
+
+ /* create index on the base tables' primary key columns */
+ key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
+ if (key_attnos)
+ {
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ }
+ else
+ {
+ /* create no index, just notice that an appropriate index is necessary for efficient IVM */
+ ereport(NOTICE,
+ (errmsg("could not create an index on materialized view \"%s\" automatically",
+ RelationGetRelationName(matviewRel)),
+ errdetail("This target list does not have all the primary key columns, "
+ "or this view does not contain DISTINCT clause."),
+ errhint("Create an index on the materialized view for efficient incremental maintenance.")));
+ return;
+ }
}
/* If we have a compatible index, we don't need to create another. */
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index ab8b81b302..4811a1c8df 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -38,6 +38,7 @@
#include "commands/dbcommands.h"
#include "commands/defrem.h"
#include "commands/event_trigger.h"
+#include "commands/matview.h"
#include "commands/progress.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
@@ -1104,6 +1105,45 @@ DefineIndex(Oid tableId,
safe_index = indexInfo->ii_Expressions == NIL &&
indexInfo->ii_Predicate == NIL;
+ /*
+ * We disallow unique indexes on IVM columns of IMMVs.
+ */
+ if (RelationIsIVM(rel) && stmt->unique)
+ {
+ for (int i = 0; i < indexInfo->ii_NumIndexKeyAttrs; i++)
+ {
+ AttrNumber attno = indexInfo->ii_IndexAttrNumbers[i];
+ if (attno > 0)
+ {
+ char *name = NameStr(TupleDescAttr(rel->rd_att, attno - 1)->attname);
+ if (name && isIvmName(name))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("unique index creation on IVM columns is not supported")));
+ }
+ }
+
+ if (indexInfo->ii_Expressions)
+ {
+ Bitmapset *indexattrs = NULL;
+ int varno = -1;
+
+ pull_varattnos((Node *) indexInfo->ii_Expressions, 1, &indexattrs);
+
+ while ((varno = bms_next_member(indexattrs, varno)) >= 0)
+ {
+ int attno = varno + FirstLowInvalidHeapAttributeNumber;
+ char *name = NameStr(TupleDescAttr(rel->rd_att, attno - 1)->attname);
+ if (name && isIvmName(name))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("unique index creation on IVM columns is not supported")));
+ }
+
+ }
+ }
+
+
/*
* Report index creation if appropriate (delay this till after most of the
* error checks)
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index 39305f3c49..aa518f20ef 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -152,11 +152,15 @@ static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *
static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
- Query *query);
+ Query *query, bool use_count, char *count_colname);
static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
+static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
+ List *keys, const char *count_colname);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
+static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
+ List *keys, StringInfo target_list, const char* count_colname);
static char *get_matching_condition_string(List *keys);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
@@ -271,6 +275,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
Oid matviewOid;
Relation matviewRel;
Query *dataQuery;
+ Query *viewQuery;
Oid tableSpace;
Oid relowner;
Oid OIDNewHeap;
@@ -330,8 +335,13 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
"CONCURRENTLY", "WITH NO DATA")));
- dataQuery = get_matview_query(matviewRel);
+ viewQuery = get_matview_query(matviewRel);
+ /* For IMMV, we need to rewrite matview query */
+ if (!stmt->skipData && RelationIsIVM(matviewRel))
+ dataQuery = rewriteQueryForIMMV(viewQuery,NIL);
+ else
+ dataQuery = viewQuery;
/*
* Check that there is a unique index with no WHERE clause on one or more
@@ -511,8 +521,8 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
if (!stmt->skipData && RelationIsIVM(matviewRel) && !oldPopulated)
{
- CreateIndexOnIMMV(dataQuery, matviewRel);
- CreateIvmTriggersOnBaseTables(dataQuery, matviewOid);
+ CreateIndexOnIMMV(viewQuery, matviewRel);
+ CreateIvmTriggersOnBaseTables(viewQuery, matviewOid);
}
table_close(matviewRel, NoLock);
@@ -1512,6 +1522,13 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
int rte_index = lfirst_int(lc2);
TupleDesc tupdesc_old;
TupleDesc tupdesc_new;
+ bool use_count = false;
+ char *count_colname = NULL;
+
+ count_colname = pstrdup("__ivm_count__");
+
+ if (query->distinctClause)
+ use_count = true;
/* calculate delta tables */
calc_delta(table, rte_index, rewritten, dest_old, dest_new,
@@ -1524,7 +1541,8 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
{
/* apply the delta tables to the materialized view */
apply_delta(matviewOid, old_tuplestore, new_tuplestore,
- tupdesc_old, tupdesc_new, query);
+ tupdesc_old, tupdesc_new, query, use_count,
+ count_colname);
}
PG_CATCH();
{
@@ -1997,7 +2015,7 @@ rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte
static void
apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
- Query *query)
+ Query *query, bool use_count, char *count_colname)
{
StringInfoData querybuf;
StringInfoData target_list_buf;
@@ -2073,7 +2091,12 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (rc != SPI_OK_REL_REGISTER)
elog(ERROR, "SPI_register failed");
- apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+ if (use_count)
+ /* apply old delta and get rows to be recalculated */
+ apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
+ keys, count_colname);
+ else
+ apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
}
/* For tuple insertion */
@@ -2095,7 +2118,11 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_register failed");
/* apply new delta */
- apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
+ if (use_count)
+ apply_new_delta_with_count(matviewname, NEW_DELTA_ENRNAME,
+ keys, &target_list_buf, count_colname);
+ else
+ apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
}
/* We're done maintaining the materialized view. */
@@ -2108,6 +2135,51 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_finish failed");
}
+/*
+ * apply_old_delta_with_count
+ *
+ * Execute a query for applying a delta table given by deltname_old
+ * which contains tuples to be deleted from to a materialized view given by
+ * matviewname. This is used when counting is required, that is, the view
+ * has aggregate or distinct.
+ */
+static void
+apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
+ List *keys, const char *count_colname)
+{
+ StringInfoData querybuf;
+ char *match_cond;
+
+ /* build WHERE condition for searching tuples to be deleted */
+ match_cond = get_matching_condition_string(keys);
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "WITH t AS (" /* collecting tid of target tuples in the view */
+ "SELECT diff.%s, " /* count column */
+ "(diff.%s OPERATOR(pg_catalog.=) mv.%s) AS for_dlt, "
+ "mv.ctid "
+ "FROM %s AS mv, %s AS diff "
+ "WHERE %s" /* tuple matching condition */
+ "), updt AS (" /* update a tuple if this is not to be deleted */
+ "UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
+ "FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
+ ")"
+ /* delete a tuple if this is to be deleted */
+ "DELETE FROM %s AS mv USING t "
+ "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
+ count_colname,
+ count_colname, count_colname,
+ matviewname, deltaname_old,
+ match_cond,
+ matviewname, count_colname, count_colname, count_colname,
+ matviewname);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
/*
* apply_old_delta
*
@@ -2157,6 +2229,66 @@ apply_old_delta(const char *matviewname, const char *deltaname_old,
elog(ERROR, "SPI_exec failed: %s", querybuf.data);
}
+/*
+ * apply_new_delta_with_count
+ *
+ * Execute a query for applying a delta table given by deltname_new
+ * which contains tuples to be inserted into a materialized view given by
+ * matviewname. This is used when counting is required, that is, the view
+ * has aggregate or distinct. Also, when a table in EXISTS sub queries
+ * is modified.
+ */
+static void
+apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
+ List *keys, StringInfo target_list, const char* count_colname)
+{
+ StringInfoData querybuf;
+ StringInfoData returning_keys;
+ ListCell *lc;
+ char *match_cond = "";
+
+ /* build WHERE condition for searching tuples to be updated */
+ match_cond = get_matching_condition_string(keys);
+
+ /* build string of keys list */
+ initStringInfo(&returning_keys);
+ if (keys)
+ {
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&returning_keys, "%s", quote_qualified_identifier("mv", resname));
+ if (lnext(keys, lc))
+ appendStringInfo(&returning_keys, ", ");
+ }
+ }
+ else
+ appendStringInfo(&returning_keys, "NULL");
+
+ /* Search for matching tuples from the view and update if found or insert if not. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "WITH updt AS (" /* update a tuple if this exists in the view */
+ "UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.+) diff.%s "
+ "FROM %s AS diff "
+ "WHERE %s " /* tuple matching condition */
+ "RETURNING %s" /* returning keys of updated tuples */
+ ") INSERT INTO %s (%s) " /* insert a new tuple if this doesn't exist */
+ "SELECT %s FROM %s AS diff "
+ "WHERE NOT EXISTS (SELECT 1 FROM updt AS mv WHERE %s);",
+ matviewname, count_colname, count_colname, count_colname,
+ deltaname_new,
+ match_cond,
+ returning_keys.data,
+ matviewname, target_list->data,
+ target_list->data, deltaname_new,
+ match_cond);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_INSERT)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
/*
* apply_new_delta
*
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 47c900445c..adbd768e0d 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -53,6 +53,7 @@
#include "commands/cluster.h"
#include "commands/comment.h"
#include "commands/defrem.h"
+#include "commands/matview.h"
#include "commands/event_trigger.h"
#include "commands/policy.h"
#include "commands/sequence.h"
@@ -3673,6 +3674,14 @@ renameatt_internal(Oid myrelid,
targetrelation = relation_open(myrelid, AccessExclusiveLock);
renameatt_check(myrelid, RelationGetForm(targetrelation), recursing);
+ /*
+ * Don't rename IVM columns.
+ */
+ if (RelationIsIVM(targetrelation) && isIvmName(oldattname))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("IVM column can not be renamed")));
+
/*
* if the 'recurse' flag is set then we are supposed to rename this
* attribute in all classes that inherit from 'relname' (as well as in
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index 864ea9b0d5..c257440414 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -36,6 +36,7 @@
#include "utils/rel.h"
#include "utils/syscache.h"
#include "utils/varlena.h"
+#include "commands/matview.h"
/*
@@ -97,7 +98,7 @@ static void expandTupleDesc(TupleDesc tupdesc, Alias *eref,
int count, int offset,
int rtindex, int sublevels_up,
int location, bool include_dropped,
- List **colnames, List **colvars);
+ List **colnames, List **colvars, bool is_ivm);
static int specialAttNum(const char *attname);
static bool rte_visible_if_lateral(ParseState *pstate, RangeTblEntry *rte);
static bool rte_visible_if_qualified(ParseState *pstate, RangeTblEntry *rte);
@@ -1502,6 +1503,7 @@ addRangeTableEntry(ParseState *pstate,
rte->relid = RelationGetRelid(rel);
rte->relkind = rel->rd_rel->relkind;
rte->rellockmode = lockmode;
+ rte->relisivm = rel->rd_rel->relisivm;
/*
* Build the list of effective column names using user-supplied aliases
@@ -1587,6 +1589,7 @@ addRangeTableEntryForRelation(ParseState *pstate,
rte->relid = RelationGetRelid(rel);
rte->relkind = rel->rd_rel->relkind;
rte->rellockmode = lockmode;
+ rte->relisivm = rel->rd_rel->relisivm;
/*
* Build the list of effective column names using user-supplied aliases
@@ -2758,7 +2761,7 @@ expandRTE(RangeTblEntry *rte, int rtindex, int sublevels_up,
expandTupleDesc(tupdesc, rte->eref,
rtfunc->funccolcount, atts_done,
rtindex, sublevels_up, location,
- include_dropped, colnames, colvars);
+ include_dropped, colnames, colvars, false);
}
else if (functypclass == TYPEFUNC_SCALAR)
{
@@ -3026,7 +3029,7 @@ expandRelation(Oid relid, Alias *eref, int rtindex, int sublevels_up,
expandTupleDesc(rel->rd_att, eref, rel->rd_att->natts, 0,
rtindex, sublevels_up,
location, include_dropped,
- colnames, colvars);
+ colnames, colvars, RelationIsIVM(rel));
relation_close(rel, AccessShareLock);
}
@@ -3043,7 +3046,7 @@ static void
expandTupleDesc(TupleDesc tupdesc, Alias *eref, int count, int offset,
int rtindex, int sublevels_up,
int location, bool include_dropped,
- List **colnames, List **colvars)
+ List **colnames, List **colvars, bool is_ivm)
{
ListCell *aliascell;
int varattno;
@@ -3056,6 +3059,9 @@ expandTupleDesc(TupleDesc tupdesc, Alias *eref, int count, int offset,
{
Form_pg_attribute attr = TupleDescAttr(tupdesc, varattno);
+ if (is_ivm && isIvmName(NameStr(attr->attname)) && !MatViewIncrementalMaintenanceIsEnabled())
+ continue;
+
if (attr->attisdropped)
{
if (include_dropped)
@@ -3218,6 +3224,10 @@ expandNSItemAttrs(ParseState *pstate, ParseNamespaceItem *nsitem,
Var *varnode = (Var *) lfirst(var);
TargetEntry *te;
+ /* if transform * into columnlist with IMMV, remove IVM columns */
+ if (rte->relisivm && isIvmName(label) && !MatViewIncrementalMaintenanceIsEnabled())
+ continue;
+
te = makeTargetEntry((Expr *) varnode,
(AttrNumber) pstate->p_next_resno++,
label,
diff --git a/src/backend/rewrite/rewriteDefine.c b/src/backend/rewrite/rewriteDefine.c
index e36fc72e1e..f6dc7ba202 100644
--- a/src/backend/rewrite/rewriteDefine.c
+++ b/src/backend/rewrite/rewriteDefine.c
@@ -621,7 +621,8 @@ checkRuleResultList(List *targetList, TupleDesc resultDesc, bool isSelect,
attr->atttypmod))));
}
- if (i != resultDesc->natts)
+ /* No check for materialized views since this could have special columns for IVM */
+ if ((!isSelect || requireColumnNameMatch) && i != resultDesc->natts)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
isSelect ?
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 09a64fa2e5..76a7873ebf 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -29,6 +29,8 @@ extern ObjectAddress ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *st
extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
+extern Query *rewriteQueryForIMMV(Query *query, List *colNames);
+
extern int GetIntoRelEFlags(IntoClause *intoClause);
extern DestReceiver *CreateIntoRelDestReceiver(IntoClause *intoClause);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index fef4c714b8..1a2b8fa09e 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1073,6 +1073,7 @@ typedef struct RangeTblEntry
int rellockmode; /* lock level that query requires on the rel */
struct TableSampleClause *tablesample; /* sampling info, or NULL */
Index perminfoindex;
+ bool relisivm;
/*
* Fields valid for a subquery RTE (else NULL):
--
2.25.1
v29-0008-Add-aggregates-support-in-IVM.patchtext/x-diff; name=v29-0008-Add-aggregates-support-in-IVM.patchDownload
From 7e9f4983e2db94c62a3bb1b97e32632adfb69094 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 20:46:32 +0900
Subject: [PATCH v29 08/11] Add aggregates support in IVM
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit
count, sum, adn avg are supported.
As a restriction, expressions specified in GROUP BY must appear in
the target list because tuples to be updated in IMMV are identified
by using this group key. However, in the case of aggregates without
GROUP BY, there is only one tuple in the view, so keys are not uses
to identify tuples.
When creating a IMMV, in addition to __ivm_count column, some hidden
columns for each aggregate are added to the target list. For example,
names of these hidden columns are ivm_count_avg and ivm_sum_avg for
the average function, and so on.
When a base table is modified, the aggregated values and related
hidden columns are also updated as well as __ivm_count__. The
way of update depends the kind of aggregate function. Specifically,
sum and count are updated by simply adding or subtracting delta value
calculated from delta tables. avg is updated by using values of sum
and count stored in views as hidden columns and deltas calculated
from delta tables.
About aggregate functions except "count()" (sum and avg), NULLs in input
values are ignored, and the result of aggegate should be NULL when no
rows are selected. To support this specification, the numbers of non-NULL
input values are counted and stored in hidden columns. In the case of
count(), count(x) returns zero when no rows are selected, but count(*)
doesn't ignore NULL input.
---
src/backend/commands/createas.c | 264 +++++++++++++++++--
src/backend/commands/matview.c | 433 ++++++++++++++++++++++++++++++--
src/include/commands/createas.h | 1 +
3 files changed, 661 insertions(+), 37 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index 076f35ee6b..c8aa558f2e 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -54,14 +54,19 @@
#include "parser/parsetree.h"
#include "parser/parse_clause.h"
#include "parser/parse_func.h"
+#include "parser/parse_type.h"
#include "rewrite/rewriteHandler.h"
+#include "rewrite/rewriteManip.h"
#include "storage/smgr.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
#include "utils/lsyscache.h"
+#include "utils/regproc.h"
+#include "utils/fmgroids.h"
#include "utils/rel.h"
#include "utils/rls.h"
#include "utils/snapmgr.h"
+#include "utils/syscache.h"
typedef struct
{
@@ -75,6 +80,11 @@ typedef struct
BulkInsertState bistate; /* bulk insert state */
} DR_intorel;
+typedef struct
+{
+ bool has_agg;
+} check_ivm_restriction_context;
+
/* utility functions for CTAS definition creation */
static ObjectAddress create_ctas_internal(List *attrList, IntoClause *into);
static ObjectAddress create_ctas_nodata(List *tlist, IntoClause *into);
@@ -89,8 +99,9 @@ static void CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid mat
Relids *relids, bool ex_lock);
static void CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock);
static void check_ivm_restriction(Node *node);
-static bool check_ivm_restriction_walker(Node *node, void *context);
+static bool check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context);
static Bitmapset *get_primary_key_attnos_from_query(Query *query, List **constraintList);
+static bool check_aggregate_supports_ivm(Oid aggfnoid);
/*
* create_ctas_internal
@@ -421,6 +432,7 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
* rewriteQueryForIMMV -- rewrite view definition query for IMMV
*
* count(*) is added for counting distinct tuples in views.
+ * Also, additional hidden columns are added for aggregate values.
*/
Query *
rewriteQueryForIMMV(Query *query, List *colNames)
@@ -434,16 +446,49 @@ rewriteQueryForIMMV(Query *query, List *colNames)
rewritten = copyObject(query);
pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
- /*
- * Convert DISTINCT to GROUP BY and add count(*) for counting distinct
- * tuples in views.
- */
- if (rewritten->distinctClause)
+ /* group keys must be in targetlist */
+ if (rewritten->groupClause)
{
- TargetEntry *tle;
+ ListCell *lc;
+ foreach(lc, rewritten->groupClause)
+ {
+ SortGroupClause *scl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(scl, rewritten->targetList);
+ if (tle->resjunk)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUP BY expression not appearing in select list is not supported on incrementally maintainable materialized view")));
+ }
+ }
+ /* Convert DISTINCT to GROUP BY. count(*) will be added afterward. */
+ else if (!rewritten->hasAggs && rewritten->distinctClause)
rewritten->groupClause = transformDistinctClause(NULL, &rewritten->targetList, rewritten->sortClause, false);
+ /* Add additional columns for aggregate values */
+ if (rewritten->hasAggs)
+ {
+ ListCell *lc;
+ List *aggs = NIL;
+ AttrNumber next_resno = list_length(rewritten->targetList) + 1;
+
+ foreach(lc, rewritten->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ char *resname = (colNames == NIL || foreach_current_index(lc) >= list_length(colNames) ?
+ tle->resname : strVal(list_nth(colNames, tle->resno - 1)));
+
+ if (IsA(tle->expr, Aggref))
+ makeIvmAggColumn(pstate, (Aggref *) tle->expr, resname, &next_resno, &aggs);
+ }
+ rewritten->targetList = list_concat(rewritten->targetList, aggs);
+ }
+
+ /* Add count(*) for counting distinct tuples in views */
+ if (rewritten->distinctClause || rewritten->hasAggs)
+ {
+ TargetEntry *tle;
+
fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
fn->agg_star = true;
@@ -460,6 +505,91 @@ rewriteQueryForIMMV(Query *query, List *colNames)
return rewritten;
}
+/*
+ * makeIvmAggColumn -- make additional aggregate columns for IVM
+ *
+ * For an aggregate column specified by aggref, additional aggregate columns
+ * are added, which are used to calculate the new aggregate value in IMMV.
+ * An additional aggregate columns has a name based on resname
+ * (ex. ivm_count_resname), and resno specified by next_resno. The created
+ * columns are returned to aggs, and the resno for the next column is also
+ * returned to next_resno.
+ *
+ * Currently, an additional count() is created for aggref other than count.
+ * In addition, sum() is created for avg aggregate column.
+ */
+void
+makeIvmAggColumn(ParseState *pstate, Aggref *aggref, char *resname, AttrNumber *next_resno, List **aggs)
+{
+ TargetEntry *tle_count;
+ Node *node;
+ FuncCall *fn;
+ Const *dmy_arg = makeConst(INT4OID,
+ -1,
+ InvalidOid,
+ sizeof(int32),
+ Int32GetDatum(1),
+ false,
+ true); /* pass by value */
+ const char *aggname = get_func_name(aggref->aggfnoid);
+
+ /*
+ * For aggregate functions except count, add count() func with the same arg parameters.
+ * This count result is used for determining if the aggregate value should be NULL or not.
+ * Also, add sum() func for avg because we need to calculate an average value as sum/count.
+ *
+ * XXX: If there are same expressions explicitly in the target list, we can use this instead
+ * of adding new duplicated one.
+ */
+ if (strcmp(aggname, "count") != 0)
+ {
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+
+ /* Make a Func with a dummy arg, and then override this by the original agg's args. */
+ node = ParseFuncOrColumn(pstate, fn->funcname, list_make1(dmy_arg), NULL, fn, false, -1);
+ ((Aggref *)node)->args = aggref->args;
+
+ tle_count = makeTargetEntry((Expr *) node,
+ *next_resno,
+ pstrdup(makeObjectName("__ivm_count",resname, "_")),
+ false);
+ *aggs = lappend(*aggs, tle_count);
+ (*next_resno)++;
+ }
+ if (strcmp(aggname, "avg") == 0)
+ {
+ List *dmy_args = NIL;
+ ListCell *lc;
+ foreach(lc, aggref->aggargtypes)
+ {
+ Oid typeid = lfirst_oid(lc);
+ Type type = typeidType(typeid);
+
+ Const *con = makeConst(typeid,
+ -1,
+ typeTypeCollation(type),
+ typeLen(type),
+ (Datum) 0,
+ true,
+ typeByVal(type));
+ dmy_args = lappend(dmy_args, con);
+ ReleaseSysCache(type);
+ }
+ fn = makeFuncCall(SystemFuncName("sum"), NIL, COERCE_EXPLICIT_CALL, -1);
+
+ /* Make a Func with dummy args, and then override this by the original agg's args. */
+ node = ParseFuncOrColumn(pstate, fn->funcname, dmy_args, NULL, fn, false, -1);
+ ((Aggref *)node)->args = aggref->args;
+
+ tle_count = makeTargetEntry((Expr *) node,
+ *next_resno,
+ pstrdup(makeObjectName("__ivm_sum",resname, "_")),
+ false);
+ *aggs = lappend(*aggs, tle_count);
+ (*next_resno)++;
+ }
+}
+
/*
* GetIntoRelEFlags --- compute executor flags needed for CREATE TABLE AS
*
@@ -943,11 +1073,13 @@ CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock
static void
check_ivm_restriction(Node *node)
{
- check_ivm_restriction_walker(node, NULL);
+ check_ivm_restriction_context context = {false};
+
+ check_ivm_restriction_walker(node, &context);
}
static bool
-check_ivm_restriction_walker(Node *node, void *context)
+check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context)
{
if (node == NULL)
return false;
@@ -976,6 +1108,10 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("CTE is not supported on incrementally maintainable materialized view")));
+ if (qry->groupClause != NIL && !qry->hasAggs)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUP BY clause without aggregate is not supported on incrementally maintainable materialized view")));
if (qry->havingQual != NULL)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
@@ -1028,6 +1164,8 @@ check_ivm_restriction_walker(Node *node, void *context)
}
}
+ context->has_agg |= qry->hasAggs;
+
/* restrictions for rtable */
foreach(lc, qry->rtable)
{
@@ -1076,7 +1214,7 @@ check_ivm_restriction_walker(Node *node, void *context)
}
- query_tree_walker(qry, check_ivm_restriction_walker, NULL, QTW_IGNORE_RANGE_TABLE);
+ query_tree_walker(qry, check_ivm_restriction_walker, (void *) context, QTW_IGNORE_RANGE_TABLE);
break;
}
@@ -1087,8 +1225,12 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("column name %s is not supported on incrementally maintainable materialized view", tle->resname)));
+ if (context->has_agg && !IsA(tle->expr, Aggref) && contain_aggs_of_level((Node *) tle->expr, 0))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("expression containing an aggregate in it is not supported on incrementally maintainable materialized view")));
- expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
break;
}
case T_JoinExpr:
@@ -1100,14 +1242,36 @@ check_ivm_restriction_walker(Node *node, void *context)
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("OUTER JOIN is not supported on incrementally maintainable materialized view")));
- expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
+ break;
}
- break;
case T_Aggref:
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("aggregate function is not supported on incrementally maintainable materialized view")));
- break;
+ {
+ /* Check if this supports IVM */
+ Aggref *aggref = (Aggref *) node;
+ const char *aggname = format_procedure(aggref->aggfnoid);
+
+ if (aggref->aggfilter != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with FILTER clause is not supported on incrementally maintainable materialized view")));
+
+ if (aggref->aggdistinct != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with DISTINCT arguments is not supported on incrementally maintainable materialized view")));
+
+ if (aggref->aggorder != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with ORDER clause is not supported on incrementally maintainable materialized view")));
+
+ if (!check_aggregate_supports_ivm(aggref->aggfnoid))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function %s is not supported on incrementally maintainable materialized view", aggname)));
+ break;
+ }
default:
expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
break;
@@ -1115,6 +1279,46 @@ check_ivm_restriction_walker(Node *node, void *context)
return false;
}
+/*
+ * check_aggregate_supports_ivm
+ *
+ * Check if the given aggregate function is supporting IVM
+ */
+static bool
+check_aggregate_supports_ivm(Oid aggfnoid)
+{
+ switch (aggfnoid)
+ {
+ /* count */
+ case F_COUNT_ANY:
+ case F_COUNT_:
+
+ /* sum */
+ case F_SUM_INT8:
+ case F_SUM_INT4:
+ case F_SUM_INT2:
+ case F_SUM_FLOAT4:
+ case F_SUM_FLOAT8:
+ case F_SUM_MONEY:
+ case F_SUM_INTERVAL:
+ case F_SUM_NUMERIC:
+
+ /* avg */
+ case F_AVG_INT8:
+ case F_AVG_INT4:
+ case F_AVG_INT2:
+ case F_AVG_NUMERIC:
+ case F_AVG_FLOAT4:
+ case F_AVG_FLOAT8:
+ case F_AVG_INTERVAL:
+
+ return true;
+
+ default:
+ return false;
+ }
+}
+
/*
* CreateIndexOnIMMV
*
@@ -1172,7 +1376,29 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
index->concurrent = false;
index->if_not_exists = false;
- if (query->distinctClause)
+ if (query->groupClause)
+ {
+ /* create unique constraint on GROUP BY expression columns */
+ foreach(lc, query->groupClause)
+ {
+ SortGroupClause *scl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(scl, query->targetList);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ else if (query->distinctClause)
{
/* create unique constraint on all columns */
foreach(lc, query->targetList)
@@ -1230,7 +1456,7 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
(errmsg("could not create an index on materialized view \"%s\" automatically",
RelationGetRelationName(matviewRel)),
errdetail("This target list does not have all the primary key columns, "
- "or this view does not contain DISTINCT clause."),
+ "or this view does not contain GROUP BY or DISTINCT clause."),
errhint("Create an index on the materialized view for efficient incremental maintenance.")));
return;
}
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index aa518f20ef..ee41f0007d 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -30,6 +30,7 @@
#include "catalog/pg_opclass.h"
#include "catalog/pg_operator.h"
#include "commands/cluster.h"
+#include "commands/defrem.h"
#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
@@ -39,6 +40,7 @@
#include "executor/tstoreReceiver.h"
#include "miscadmin.h"
#include "nodes/makefuncs.h"
+#include "optimizer/optimizer.h"
#include "parser/analyze.h"
#include "parser/parse_clause.h"
#include "parser/parse_func.h"
@@ -111,6 +113,13 @@ static HTAB *mv_trigger_info = NULL;
static bool in_delta_calculation = false;
+/* kind of IVM operation for the view */
+typedef enum
+{
+ IVM_ADD,
+ IVM_SUB
+} IvmOp;
+
/* ENR name for materialized view delta */
#define NEW_DELTA_ENRNAME "new_delta"
#define OLD_DELTA_ENRNAME "old_delta"
@@ -142,7 +151,7 @@ static RangeTblEntry *get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *tabl
QueryEnvironment *queryEnv, Oid matviewid);
static RangeTblEntry *replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
QueryEnvironment *queryEnv);
-static Query *rewrite_query_for_counting(Query *query, ParseState *pstate);
+static Query *rewrite_query_for_counting_and_aggregates(Query *query, ParseState *pstate);
static void calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
DestReceiver *dest_old, DestReceiver *dest_new,
@@ -153,14 +162,27 @@ static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *
static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
Query *query, bool use_count, char *count_colname);
+static void append_set_clause_for_count(const char *resname, StringInfo buf_old,
+ StringInfo buf_new,StringInfo aggs_list);
+static void append_set_clause_for_sum(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list);
+static void append_set_clause_for_avg(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ const char *aggtype);
+static char *get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
+ const char* count_col, const char *castType);
+static char *get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
+ const char* count_col);
static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
- List *keys, const char *count_colname);
+ List *keys, StringInfo aggs_list, StringInfo aggs_set,
+ const char *count_colname);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
- List *keys, StringInfo target_list, const char* count_colname);
+ List *keys, StringInfo target_list, StringInfo aggs_set,
+ const char* count_colname);
static char *get_matching_condition_string(List *keys);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
@@ -1431,11 +1453,44 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
* When a base table is truncated, the view content will be empty if the
* view definition query does not contain an aggregate without a GROUP clause.
* Therefore, such views can be truncated.
+ *
+ * Aggregate views without a GROUP clause always have one row. Therefore,
+ * if a base table is truncated, the view will not be empty and will contain
+ * a row with NULL value (or 0 for count()). So, in this case, we refresh the
+ * view instead of truncating it.
*/
if (TRIGGER_FIRED_BY_TRUNCATE(trigdata->tg_event))
{
- ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
- NIL, DROP_RESTRICT, false, false);
+ if (!(query->hasAggs && query->groupClause == NIL))
+ ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
+ NIL, DROP_RESTRICT, false, false);
+ else
+ {
+ Oid OIDNewHeap;
+ DestReceiver *dest;
+ uint64 processed = 0;
+ Query *dataQuery = rewriteQueryForIMMV(query, NIL);
+ char relpersistence = matviewRel->rd_rel->relpersistence;
+
+ /*
+ * Create the transient table that will receive the regenerated data. Lock
+ * it against access by any other process until commit (by which time it
+ * will be gone).
+ */
+ OIDNewHeap = make_new_heap(matviewOid, matviewRel->rd_rel->reltablespace,
+ matviewRel->rd_rel->relam,
+ relpersistence, ExclusiveLock);
+ LockRelationOid(OIDNewHeap, AccessExclusiveLock);
+ dest = CreateTransientRelDestReceiver(OIDNewHeap);
+
+ /* Generate the data */
+ processed = refresh_matview_datafill(dest, dataQuery, NULL, NULL, "");
+ refresh_by_heap_swap(matviewOid, OIDNewHeap, relpersistence);
+
+ /* Inform cumulative stats system about our activity */
+ pgstat_count_truncate(matviewRel);
+ pgstat_count_heap_insert(matviewRel, processed);
+ }
/* Clean up hash entry and delete tuplestores */
clean_up_IVM_hash_entry(entry, false);
@@ -1475,8 +1530,8 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
/* Set all tables in the query to pre-update state */
rewritten = rewrite_query_for_preupdate_state(rewritten, entry->tables,
pstate, matviewOid);
- /* Rewrite for counting duplicated tuples */
- rewritten = rewrite_query_for_counting(rewritten, pstate);
+ /* Rewrite for counting duplicated tuples and aggregates functions*/
+ rewritten = rewrite_query_for_counting_and_aggregates(rewritten, pstate);
/* Create tuplestores to store view deltas */
if (entry->has_old)
@@ -1527,7 +1582,7 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
count_colname = pstrdup("__ivm_count__");
- if (query->distinctClause)
+ if (query->hasAggs || query->distinctClause)
use_count = true;
/* calculate delta tables */
@@ -1923,17 +1978,34 @@ replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
}
/*
- * rewrite_query_for_counting
+ * rewrite_query_for_counting_and_aggregates
*
- * Rewrite query for counting duplicated tuples.
+ * Rewrite query for counting duplicated tuples and aggregate functions.
*/
static Query *
-rewrite_query_for_counting(Query *query, ParseState *pstate)
+rewrite_query_for_counting_and_aggregates(Query *query, ParseState *pstate)
{
TargetEntry *tle_count;
FuncCall *fn;
Node *node;
+ /* For aggregate views */
+ if (query->hasAggs)
+ {
+ ListCell *lc;
+ List *aggs = NIL;
+ AttrNumber next_resno = list_length(query->targetList) + 1;
+
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+
+ if (IsA(tle->expr, Aggref))
+ makeIvmAggColumn(pstate, (Aggref *)tle->expr, tle->resname, &next_resno, &aggs);
+ }
+ query->targetList = list_concat(query->targetList, aggs);
+ }
+
/* Add count(*) for counting distinct tuples in views */
fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
fn->agg_star = true;
@@ -2006,6 +2078,8 @@ rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte
return query;
}
+#define IVM_colname(type, col) makeObjectName("__ivm_" type, col, "_")
+
/*
* apply_delta
*
@@ -2019,6 +2093,9 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
{
StringInfoData querybuf;
StringInfoData target_list_buf;
+ StringInfo aggs_list_buf = NULL;
+ StringInfo aggs_set_old = NULL;
+ StringInfo aggs_set_new = NULL;
Relation matviewRel;
char *matviewname;
ListCell *lc;
@@ -2041,6 +2118,15 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
initStringInfo(&querybuf);
initStringInfo(&target_list_buf);
+ if (query->hasAggs)
+ {
+ if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
+ aggs_set_old = makeStringInfo();
+ if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
+ aggs_set_new = makeStringInfo();
+ aggs_list_buf = makeStringInfo();
+ }
+
/* build string of target list */
for (i = 0; i < matviewRel->rd_att->natts; i++)
{
@@ -2057,13 +2143,61 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
i++;
if (tle->resjunk)
continue;
- keys = lappend(keys, attr);
+ /*
+ * For views without aggregates, all attributes are used as keys to identify a
+ * tuple in a view.
+ */
+ if (!query->hasAggs)
+ keys = lappend(keys, attr);
+
+ /* For views with aggregates, we need to build SET clause for updating aggregate
+ * values. */
+ if (query->hasAggs && IsA(tle->expr, Aggref))
+ {
+ Aggref *aggref = (Aggref *) tle->expr;
+ const char *aggname = get_func_name(aggref->aggfnoid);
+
+ /*
+ * We can use function names here because it is already checked if these
+ * can be used in IMMV by its OID at the definition time.
+ */
+
+ /* count */
+ if (!strcmp(aggname, "count"))
+ append_set_clause_for_count(resname, aggs_set_old, aggs_set_new, aggs_list_buf);
+
+ /* sum */
+ else if (!strcmp(aggname, "sum"))
+ append_set_clause_for_sum(resname, aggs_set_old, aggs_set_new, aggs_list_buf);
+
+ /* avg */
+ else if (!strcmp(aggname, "avg"))
+ append_set_clause_for_avg(resname, aggs_set_old, aggs_set_new, aggs_list_buf,
+ format_type_be(aggref->aggtype));
+
+ else
+ elog(ERROR, "unsupported aggregate function: %s", aggname);
+ }
+ }
+
+ /* If we have GROUP BY clause, we use its entries as keys. */
+ if (query->hasAggs && query->groupClause)
+ {
+ foreach (lc, query->groupClause)
+ {
+ SortGroupClause *sgcl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(sgcl, query->targetList);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ keys = lappend(keys, attr);
+ }
}
/* Start maintaining the materialized view. */
@@ -2094,7 +2228,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (use_count)
/* apply old delta and get rows to be recalculated */
apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
- keys, count_colname);
+ keys, aggs_list_buf, aggs_set_old,
+ count_colname);
else
apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
@@ -2120,7 +2255,7 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
/* apply new delta */
if (use_count)
apply_new_delta_with_count(matviewname, NEW_DELTA_ENRNAME,
- keys, &target_list_buf, count_colname);
+ keys, aggs_set_new, &target_list_buf, count_colname);
else
apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
}
@@ -2135,6 +2270,250 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_finish failed");
}
+/*
+ * append_set_clause_for_count
+ *
+ * Append SET clause string for count aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_count(const char *resname, StringInfo buf_old,
+ StringInfo buf_new,StringInfo aggs_list)
+{
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* resname = mv.resname - t.resname */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, resname, "mv", "t", NULL, NULL));
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* resname = mv.resname + diff.resname */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, resname, "mv", "diff", NULL, NULL));
+ }
+
+ appendStringInfo(aggs_list, ", %s",
+ quote_qualified_identifier("diff", resname)
+ );
+}
+
+/*
+ * append_set_clause_for_sum
+ *
+ * Append SET clause string for sum aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_sum(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list)
+{
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* sum = mv.sum - t.sum */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, resname, "mv", "t", count_col, NULL)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* sum = mv.sum + diff.sum */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, resname, "mv", "diff", count_col, NULL)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
+/*
+ * append_set_clause_for_avg
+ *
+ * Append SET clause string for avg aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_avg(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ const char *aggtype)
+{
+ char *sum_col = IVM_colname("sum", resname);
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* avg = (mv.sum - t.sum)::aggtype / (mv.count - t.count) */
+ appendStringInfo(buf_old,
+ ", %s = %s OPERATOR(pg_catalog./) %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, sum_col, "mv", "t", count_col, aggtype),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ /* sum = mv.sum - t.sum */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, sum_col),
+ get_operation_string(IVM_SUB, sum_col, "mv", "t", count_col, NULL)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* avg = (mv.sum + diff.sum)::aggtype / (mv.count + diff.count) */
+ appendStringInfo(buf_new,
+ ", %s = %s OPERATOR(pg_catalog./) %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, sum_col, "mv", "diff", count_col, aggtype),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ /* sum = mv.sum + diff.sum */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, sum_col),
+ get_operation_string(IVM_ADD, sum_col, "mv", "diff", count_col, NULL)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("sum", resname)),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
+/*
+ * get_operation_string
+ *
+ * Build a string to calculate the new aggregate values.
+ */
+static char *
+get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
+ const char* count_col, const char *castType)
+{
+ StringInfoData buf;
+ StringInfoData castString;
+ char *col1 = quote_qualified_identifier(arg1, col);
+ char *col2 = quote_qualified_identifier(arg2, col);
+ char op_char = (op == IVM_SUB ? '-' : '+');
+
+ initStringInfo(&buf);
+ initStringInfo(&castString);
+
+ if (castType)
+ appendStringInfo(&castString, "::%s", castType);
+
+ if (!count_col)
+ {
+ /*
+ * If the attributes don't have count columns then calc the result
+ * by using the operator simply.
+ */
+ appendStringInfo(&buf, "(%s OPERATOR(pg_catalog.%c) %s)%s",
+ col1, op_char, col2, castString.data);
+ }
+ else
+ {
+ /*
+ * If the attributes have count columns then consider the condition
+ * where the result becomes NULL.
+ */
+ char *null_cond = get_null_condition_string(op, arg1, arg2, count_col);
+
+ appendStringInfo(&buf,
+ "(CASE WHEN %s THEN NULL "
+ "WHEN %s IS NULL THEN %s "
+ "WHEN %s IS NULL THEN %s "
+ "ELSE (%s OPERATOR(pg_catalog.%c) %s)%s END)",
+ null_cond,
+ col1, col2,
+ col2, col1,
+ col1, op_char, col2, castString.data
+ );
+ }
+
+ return buf.data;
+}
+
+/*
+ * get_null_condition_string
+ *
+ * Build a predicate string for CASE clause to check if an aggregate value
+ * will became NULL after the given operation is applied.
+ */
+static char *
+get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
+ const char* count_col)
+{
+ StringInfoData null_cond;
+ initStringInfo(&null_cond);
+
+ switch (op)
+ {
+ case IVM_ADD:
+ appendStringInfo(&null_cond,
+ "%s OPERATOR(pg_catalog.=) 0 AND %s OPERATOR(pg_catalog.=) 0",
+ quote_qualified_identifier(arg1, count_col),
+ quote_qualified_identifier(arg2, count_col)
+ );
+ break;
+ case IVM_SUB:
+ appendStringInfo(&null_cond,
+ "%s OPERATOR(pg_catalog.=) %s",
+ quote_qualified_identifier(arg1, count_col),
+ quote_qualified_identifier(arg2, count_col)
+ );
+ break;
+ default:
+ elog(ERROR,"unknown operation");
+ }
+
+ return null_cond.data;
+}
+
+
/*
* apply_old_delta_with_count
*
@@ -2142,13 +2521,20 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
* which contains tuples to be deleted from to a materialized view given by
* matviewname. This is used when counting is required, that is, the view
* has aggregate or distinct.
+ *
+ * If the view desn't have aggregates or has GROUP BY, this requires a keys
+ * list to identify a tuple in the view. If the view has aggregates, this
+ * requires strings representing resnames of aggregates and SET clause for
+ * updating aggregate values.
*/
static void
apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
- List *keys, const char *count_colname)
+ List *keys, StringInfo aggs_list, StringInfo aggs_set,
+ const char *count_colname)
{
StringInfoData querybuf;
char *match_cond;
+ bool agg_without_groupby = (list_length(keys) == 0);
/* build WHERE condition for searching tuples to be deleted */
match_cond = get_matching_condition_string(keys);
@@ -2158,22 +2544,26 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
appendStringInfo(&querybuf,
"WITH t AS (" /* collecting tid of target tuples in the view */
"SELECT diff.%s, " /* count column */
- "(diff.%s OPERATOR(pg_catalog.=) mv.%s) AS for_dlt, "
+ "(diff.%s OPERATOR(pg_catalog.=) mv.%s AND %s) AS for_dlt, "
"mv.ctid "
+ "%s " /* aggregate columns */
"FROM %s AS mv, %s AS diff "
"WHERE %s" /* tuple matching condition */
"), updt AS (" /* update a tuple if this is not to be deleted */
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
+ "%s" /* SET clauses for aggregates */
"FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
")"
/* delete a tuple if this is to be deleted */
"DELETE FROM %s AS mv USING t "
"WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
count_colname,
- count_colname, count_colname,
+ count_colname, count_colname, (agg_without_groupby ? "false" : "true"),
+ (aggs_list != NULL ? aggs_list->data : ""),
matviewname, deltaname_old,
match_cond,
matviewname, count_colname, count_colname, count_colname,
+ (aggs_set != NULL ? aggs_set->data : ""),
matviewname);
if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
@@ -2237,10 +2627,15 @@ apply_old_delta(const char *matviewname, const char *deltaname_old,
* matviewname. This is used when counting is required, that is, the view
* has aggregate or distinct. Also, when a table in EXISTS sub queries
* is modified.
+ *
+ * If the view desn't have aggregates or has GROUP BY, this requires a keys
+ * list to identify a tuple in the view. If the view has aggregates, this
+ * requires strings representing SET clause for updating aggregate values.
*/
static void
apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
- List *keys, StringInfo target_list, const char* count_colname)
+ List *keys, StringInfo aggs_set, StringInfo target_list,
+ const char* count_colname)
{
StringInfoData querybuf;
StringInfoData returning_keys;
@@ -2271,6 +2666,7 @@ apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
appendStringInfo(&querybuf,
"WITH updt AS (" /* update a tuple if this exists in the view */
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.+) diff.%s "
+ "%s " /* SET clauses for aggregates */
"FROM %s AS diff "
"WHERE %s " /* tuple matching condition */
"RETURNING %s" /* returning keys of updated tuples */
@@ -2278,6 +2674,7 @@ apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
"SELECT %s FROM %s AS diff "
"WHERE NOT EXISTS (SELECT 1 FROM updt AS mv WHERE %s);",
matviewname, count_colname, count_colname, count_colname,
+ (aggs_set != NULL ? aggs_set->data : ""),
deltaname_new,
match_cond,
returning_keys.data,
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 76a7873ebf..599bae3b5a 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -30,6 +30,7 @@ extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
extern Query *rewriteQueryForIMMV(Query *query, List *colNames);
+extern void makeIvmAggColumn(ParseState *pstate, Aggref *aggref, char *resname, AttrNumber *next_resno, List **aggs);
extern int GetIntoRelEFlags(IntoClause *intoClause);
--
2.25.1
v29-0009-Add-support-for-min-max-aggregates-for-IVM.patchtext/x-diff; name=v29-0009-Add-support-for-min-max-aggregates-for-IVM.patchDownload
From 181eb5fcd7d1f7127786db203ccddfa69bc1a4f5 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 20:58:25 +0900
Subject: [PATCH v29 09/11] Add support for min/max aggregates for IVM
Supporting min and max is more complicated than count, sum, or avg.
For an example of min, when tuples are inserted, the current min value
in the view and the min value in the inseteted tuples are compared,
then the smaller one is used as the latest min value. On the other
hand, when tuples are deleted, if the current min value in the view
equals to the min in the deleted tuples, we need re-computation the
latest min value from base tables. Otherwise, the current value in
the view remains.
---
src/backend/commands/createas.c | 45 +++
src/backend/commands/matview.c | 644 +++++++++++++++++++++++++++++++-
2 files changed, 680 insertions(+), 9 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index c8aa558f2e..c40ea6b2bc 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -1312,6 +1312,51 @@ check_aggregate_supports_ivm(Oid aggfnoid)
case F_AVG_FLOAT8:
case F_AVG_INTERVAL:
+ /* min */
+ case F_MIN_ANYARRAY:
+ case F_MIN_INT8:
+ case F_MIN_INT4:
+ case F_MIN_INT2:
+ case F_MIN_OID:
+ case F_MIN_FLOAT4:
+ case F_MIN_FLOAT8:
+ case F_MIN_DATE:
+ case F_MIN_TIME:
+ case F_MIN_TIMETZ:
+ case F_MIN_MONEY:
+ case F_MIN_TIMESTAMP:
+ case F_MIN_TIMESTAMPTZ:
+ case F_MIN_INTERVAL:
+ case F_MIN_TEXT:
+ case F_MIN_NUMERIC:
+ case F_MIN_BPCHAR:
+ case F_MIN_TID:
+ case F_MIN_ANYENUM:
+ case F_MIN_INET:
+ case F_MIN_PG_LSN:
+
+ /* max */
+ case F_MAX_ANYARRAY:
+ case F_MAX_INT8:
+ case F_MAX_INT4:
+ case F_MAX_INT2:
+ case F_MAX_OID:
+ case F_MAX_FLOAT4:
+ case F_MAX_FLOAT8:
+ case F_MAX_DATE:
+ case F_MAX_TIME:
+ case F_MAX_TIMETZ:
+ case F_MAX_MONEY:
+ case F_MAX_TIMESTAMP:
+ case F_MAX_TIMESTAMPTZ:
+ case F_MAX_INTERVAL:
+ case F_MAX_TEXT:
+ case F_MAX_NUMERIC:
+ case F_MAX_BPCHAR:
+ case F_MAX_TID:
+ case F_MAX_ANYENUM:
+ case F_MAX_INET:
+ case F_MAX_PG_LSN:
return true;
default:
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index ee41f0007d..eff512d40c 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -73,6 +73,34 @@ typedef struct
#define MV_INIT_QUERYHASHSIZE 16
+/* MV query type codes */
+#define MV_PLAN_RECALC 1
+#define MV_PLAN_SET_VALUE 2
+
+/*
+ * MI_QueryKey
+ *
+ * The key identifying a prepared SPI plan in our query hashtable
+ */
+typedef struct MV_QueryKey
+{
+ Oid matview_id; /* OID of materialized view */
+ int32 query_type; /* query type ID, see MV_PLAN_XXX above */
+} MV_QueryKey;
+
+/*
+ * MV_QueryHashEntry
+ *
+ * Hash entry for cached plans used to maintain materialized views.
+ */
+typedef struct MV_QueryHashEntry
+{
+ MV_QueryKey key;
+ SPIPlanPtr plan;
+ SearchPathMatcher *search_path; /* search_path used for parsing
+ * and planning */
+} MV_QueryHashEntry;
+
/*
* MV_TriggerHashEntry
*
@@ -109,6 +137,7 @@ typedef struct MV_TriggerTable
TupleTableSlot *slot; /* for checking visibility in the pre-state table */
} MV_TriggerTable;
+static HTAB *mv_query_cache = NULL;
static HTAB *mv_trigger_info = NULL;
static bool in_delta_calculation = false;
@@ -169,6 +198,9 @@ static void append_set_clause_for_sum(const char *resname, StringInfo buf_old,
static void append_set_clause_for_avg(const char *resname, StringInfo buf_old,
StringInfo buf_new, StringInfo aggs_list,
const char *aggtype);
+static void append_set_clause_for_minmax(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ bool is_min);
static char *get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
const char* count_col, const char *castType);
static char *get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
@@ -177,17 +209,30 @@ static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
List *keys, StringInfo aggs_list, StringInfo aggs_set,
- const char *count_colname);
+ List *minmax_list, List *is_min_list,
+ const char *count_colname,
+ SPITupleTable **tuptable_recalc, uint64 *num_recalc);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
List *keys, StringInfo target_list, StringInfo aggs_set,
const char* count_colname);
static char *get_matching_condition_string(List *keys);
+static char *get_returning_string(List *minmax_list, List *is_min_list, List *keys);
+static char *get_minmax_recalc_condition_string(List *minmax_list, List *is_min_list);
+static char *get_select_for_recalc_string(List *keys);
+static void recalc_and_set_values(SPITupleTable *tuptable_recalc, int64 num_tuples,
+ List *namelist, List *keys, Relation matviewRel);
+static SPIPlanPtr get_plan_for_recalc(Oid matviewOid, List *namelist, List *keys, Oid *keyTypes);
+static SPIPlanPtr get_plan_for_set_values(Oid matviewOid, char *matviewname, List *namelist,
+ Oid *valTypes);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
static void mv_InitHashTables(void);
+static SPIPlanPtr mv_FetchPreparedPlan(MV_QueryKey *key);
+static void mv_HashPreparedPlan(MV_QueryKey *key, SPIPlanPtr plan);
+static void mv_BuildQueryKey(MV_QueryKey *key, Oid matview_id, int32 query_type);
static void clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort);
/*
@@ -2101,6 +2146,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
ListCell *lc;
int i;
List *keys = NIL;
+ List *minmax_list = NIL;
+ List *is_min_list = NIL;
/*
@@ -2182,6 +2229,17 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
append_set_clause_for_avg(resname, aggs_set_old, aggs_set_new, aggs_list_buf,
format_type_be(aggref->aggtype));
+ /* min/max */
+ else if (!strcmp(aggname, "min") || !strcmp(aggname, "max"))
+ {
+ bool is_min = (!strcmp(aggname, "min"));
+
+ append_set_clause_for_minmax(resname, aggs_set_old, aggs_set_new, aggs_list_buf, is_min);
+
+ /* make a resname list of min and max aggregates */
+ minmax_list = lappend(minmax_list, resname);
+ is_min_list = lappend_int(is_min_list, is_min);
+ }
else
elog(ERROR, "unsupported aggregate function: %s", aggname);
}
@@ -2211,6 +2269,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
{
EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ SPITupleTable *tuptable_recalc = NULL;
+ uint64 num_recalc;
int rc;
/* convert tuplestores to ENR, and register for SPI */
@@ -2229,10 +2289,18 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
/* apply old delta and get rows to be recalculated */
apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
keys, aggs_list_buf, aggs_set_old,
- count_colname);
+ minmax_list, is_min_list,
+ count_colname, &tuptable_recalc, &num_recalc);
else
apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+ /*
+ * If we have min or max, we might have to recalculate aggregate values from base tables
+ * on some tuples. TIDs and keys such tuples are returned as a result of the above query.
+ */
+ if (minmax_list && tuptable_recalc)
+ recalc_and_set_values(tuptable_recalc, num_recalc, minmax_list, keys, matviewRel);
+
}
/* For tuple insertion */
if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
@@ -2424,6 +2492,70 @@ append_set_clause_for_avg(const char *resname, StringInfo buf_old,
);
}
+/*
+ * append_set_clause_for_minmax
+ *
+ * Append SET clause string for min or max aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ * is_min is true if this is min, false if not.
+ */
+static void
+append_set_clause_for_minmax(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ bool is_min)
+{
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /*
+ * If the new value doesn't became NULL then use the value remaining
+ * in the view although this will be recomputated afterwords.
+ */
+ appendStringInfo(buf_old,
+ ", %s = CASE WHEN %s THEN NULL ELSE %s END",
+ quote_qualified_identifier(NULL, resname),
+ get_null_condition_string(IVM_SUB, "mv", "t", count_col),
+ quote_qualified_identifier("mv", resname)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /*
+ * min = LEAST(mv.min, diff.min)
+ * max = GREATEST(mv.max, diff.max)
+ */
+ appendStringInfo(buf_new,
+ ", %s = CASE WHEN %s THEN NULL ELSE %s(%s,%s) END",
+ quote_qualified_identifier(NULL, resname),
+ get_null_condition_string(IVM_ADD, "mv", "diff", count_col),
+
+ is_min ? "LEAST" : "GREATEST",
+ quote_qualified_identifier("mv", resname),
+ quote_qualified_identifier("diff", resname)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
/*
* get_operation_string
*
@@ -2526,19 +2658,44 @@ get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
* list to identify a tuple in the view. If the view has aggregates, this
* requires strings representing resnames of aggregates and SET clause for
* updating aggregate values.
+ *
+ * If the view has min or max aggregate, this requires a list of resnames of
+ * min/max aggregates and a list of boolean which represents which entries in
+ * minmax_list is min. These are necessary to check if we need to recalculate
+ * min or max aggregate values. In this case, this query returns TID and keys
+ * of tuples which need to be recalculated. This result and the number of rows
+ * are stored in tuptables and num_recalc repectedly.
+ *
*/
static void
apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
List *keys, StringInfo aggs_list, StringInfo aggs_set,
- const char *count_colname)
+ List *minmax_list, List *is_min_list,
+ const char *count_colname,
+ SPITupleTable **tuptable_recalc, uint64 *num_recalc)
{
StringInfoData querybuf;
char *match_cond;
+ char *updt_returning = "";
+ char *select_for_recalc = "SELECT";
bool agg_without_groupby = (list_length(keys) == 0);
+ Assert(tuptable_recalc != NULL);
+ Assert(num_recalc != NULL);
+
/* build WHERE condition for searching tuples to be deleted */
match_cond = get_matching_condition_string(keys);
+ /*
+ * We need a special RETURNING clause and SELECT statement for min/max to
+ * check which tuple needs re-calculation from base tables.
+ */
+ if (minmax_list)
+ {
+ updt_returning = get_returning_string(minmax_list, is_min_list, keys);
+ select_for_recalc = get_select_for_recalc_string(keys);
+ }
+
/* Search for matching tuples from the view and update or delete if found. */
initStringInfo(&querybuf);
appendStringInfo(&querybuf,
@@ -2553,10 +2710,11 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
"%s" /* SET clauses for aggregates */
"FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
- ")"
- /* delete a tuple if this is to be deleted */
- "DELETE FROM %s AS mv USING t "
- "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
+ "%s" /* RETURNING clause for recalc infomation */
+ "), dlt AS (" /* delete a tuple if this is to be deleted */
+ "DELETE FROM %s AS mv USING t "
+ "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt"
+ ") %s", /* SELECT returning which tuples need to be recalculated */
count_colname,
count_colname, count_colname, (agg_without_groupby ? "false" : "true"),
(aggs_list != NULL ? aggs_list->data : ""),
@@ -2564,10 +2722,25 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
match_cond,
matviewname, count_colname, count_colname, count_colname,
(aggs_set != NULL ? aggs_set->data : ""),
- matviewname);
+ updt_returning,
+ matviewname,
+ select_for_recalc);
- if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_SELECT)
elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+
+
+ /* Return tuples to be recalculated. */
+ if (minmax_list)
+ {
+ *tuptable_recalc = SPI_tuptable;
+ *num_recalc = SPI_processed;
+ }
+ else
+ {
+ *tuptable_recalc = NULL;
+ *num_recalc = 0;
+ }
}
/*
@@ -2750,6 +2923,349 @@ get_matching_condition_string(List *keys)
return match_cond.data;
}
+/*
+ * get_returning_string
+ *
+ * Build a string for RETURNING clause of UPDATE used in apply_old_delta_with_count.
+ * This clause returns ctid and a boolean value that indicates if we need to
+ * recalculate min or max value, for each updated row.
+ */
+static char *
+get_returning_string(List *minmax_list, List *is_min_list, List *keys)
+{
+ StringInfoData returning;
+ char *recalc_cond;
+ ListCell *lc;
+
+ Assert(minmax_list != NIL && is_min_list != NIL);
+ recalc_cond = get_minmax_recalc_condition_string(minmax_list, is_min_list);
+
+ initStringInfo(&returning);
+
+ appendStringInfo(&returning, "RETURNING mv.ctid AS tid, (%s) AS recalc", recalc_cond);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&returning, ", %s", quote_qualified_identifier("mv", resname));
+ }
+
+ return returning.data;
+}
+
+/*
+ * get_minmax_recalc_condition_string
+ *
+ * Build a predicate string for checking if any min/max aggregate
+ * value needs to be recalculated.
+ */
+static char *
+get_minmax_recalc_condition_string(List *minmax_list, List *is_min_list)
+{
+ StringInfoData recalc_cond;
+ ListCell *lc1, *lc2;
+
+ initStringInfo(&recalc_cond);
+
+ Assert (list_length(minmax_list) == list_length(is_min_list));
+
+ forboth (lc1, minmax_list, lc2, is_min_list)
+ {
+ char *resname = (char *) lfirst(lc1);
+ bool is_min = (bool) lfirst_int(lc2);
+ char *op_str = (is_min ? ">=" : "<=");
+
+ appendStringInfo(&recalc_cond, "%s OPERATOR(pg_catalog.%s) %s",
+ quote_qualified_identifier("mv", resname),
+ op_str,
+ quote_qualified_identifier("t", resname)
+ );
+
+ if (lnext(minmax_list, lc1))
+ appendStringInfo(&recalc_cond, " OR ");
+ }
+
+ return recalc_cond.data;
+}
+
+/*
+ * get_select_for_recalc_string
+ *
+ * Build a query to return tid and keys of tuples which need
+ * recalculation. This is used as the result of the query
+ * built by apply_old_delta.
+ */
+static char *
+get_select_for_recalc_string(List *keys)
+{
+ StringInfoData qry;
+ ListCell *lc;
+
+ initStringInfo(&qry);
+
+ appendStringInfo(&qry, "SELECT tid");
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ appendStringInfo(&qry, ", %s", NameStr(attr->attname));
+ }
+
+ appendStringInfo(&qry, " FROM updt WHERE recalc");
+
+ return qry.data;
+}
+
+/*
+ * recalc_and_set_values
+ *
+ * Recalculate tuples in a materialized from base tables and update these.
+ * The tuples which needs recalculation are specified by keys, and resnames
+ * of columns to be updated are specified by namelist. TIDs and key values
+ * are given by tuples in tuptable_recalc. Its first attribute must be TID
+ * and key values must be following this.
+ */
+static void
+recalc_and_set_values(SPITupleTable *tuptable_recalc, int64 num_tuples,
+ List *namelist, List *keys, Relation matviewRel)
+{
+ TupleDesc tupdesc_recalc = tuptable_recalc->tupdesc;
+ Oid *keyTypes = NULL, *types = NULL;
+ char *keyNulls = NULL, *nulls = NULL;
+ Datum *keyVals = NULL, *vals = NULL;
+ int num_vals = list_length(namelist);
+ int num_keys = list_length(keys);
+ uint64 i;
+ Oid matviewOid;
+ char *matviewname;
+
+ matviewOid = RelationGetRelid(matviewRel);
+ matviewname = quote_qualified_identifier(get_namespace_name(RelationGetNamespace(matviewRel)),
+ RelationGetRelationName(matviewRel));
+
+ /* If we have keys, initialize arrays for them. */
+ if (keys)
+ {
+ keyTypes = palloc(sizeof(Oid) * num_keys);
+ keyNulls = palloc(sizeof(char) * num_keys);
+ keyVals = palloc(sizeof(Datum) * num_keys);
+ /* a tuple contains keys to be recalculated and ctid to be updated*/
+ Assert(tupdesc_recalc->natts == num_keys + 1);
+
+ /* Types of key attributes */
+ for (i = 0; i < num_keys; i++)
+ keyTypes[i] = TupleDescAttr(tupdesc_recalc, i + 1)->atttypid;
+ }
+
+ /* allocate memory for all attribute names and tid */
+ types = palloc(sizeof(Oid) * (num_vals + 1));
+ nulls = palloc(sizeof(char) * (num_vals + 1));
+ vals = palloc(sizeof(Datum) * (num_vals + 1));
+
+ /* For each tuple which needs recalculation */
+ for (i = 0; i < num_tuples; i++)
+ {
+ int j;
+ bool isnull;
+ SPIPlanPtr plan;
+ SPITupleTable *tuptable_newvals;
+ TupleDesc tupdesc_newvals;
+
+ /* Set group key values as parameters if needed. */
+ if (keys)
+ {
+ for (j = 0; j < num_keys; j++)
+ {
+ keyVals[j] = SPI_getbinval(tuptable_recalc->vals[i], tupdesc_recalc, j + 2, &isnull);
+ if (isnull)
+ keyNulls[j] = 'n';
+ else
+ keyNulls[j] = ' ';
+ }
+ }
+
+ /*
+ * Get recalculated values from base tables. The result must be
+ * only one tuple thich contains the new values for specified keys.
+ */
+ plan = get_plan_for_recalc(matviewOid, namelist, keys, keyTypes);
+ if (SPI_execute_plan(plan, keyVals, keyNulls, false, 0) != SPI_OK_SELECT)
+ elog(ERROR, "SPI_execute_plan");
+ if (SPI_processed != 1)
+ elog(ERROR, "SPI_execute_plan returned zero or more than one rows");
+
+ tuptable_newvals = SPI_tuptable;
+ tupdesc_newvals = tuptable_newvals->tupdesc;
+
+ Assert(tupdesc_newvals->natts == num_vals);
+
+ /* Set the new values as parameters */
+ for (j = 0; j < tupdesc_newvals->natts; j++)
+ {
+ if (i == 0)
+ types[j] = TupleDescAttr(tupdesc_newvals, j)->atttypid;
+
+ vals[j] = SPI_getbinval(tuptable_newvals->vals[0], tupdesc_newvals, j + 1, &isnull);
+ if (isnull)
+ nulls[j] = 'n';
+ else
+ nulls[j] = ' ';
+ }
+ /* Set TID of the view tuple to be updated as a parameter */
+ types[j] = TIDOID;
+ vals[j] = SPI_getbinval(tuptable_recalc->vals[i], tupdesc_recalc, 1, &isnull);
+ nulls[j] = ' ';
+
+ /* Update the view tuple to the new values */
+ plan = get_plan_for_set_values(matviewOid, matviewname, namelist, types);
+ if (SPI_execute_plan(plan, vals, nulls, false, 0) != SPI_OK_UPDATE)
+ elog(ERROR, "SPI_execute_plan");
+ }
+}
+
+
+/*
+ * get_plan_for_recalc
+ *
+ * Create or fetch a plan for recalculating value in the view's target list
+ * from base tables using the definition query of materialized view specified
+ * by matviewOid. namelist is a list of resnames of values to be recalculated.
+ *
+ * keys is a list of keys to identify tuples to be recalculated if this is not
+ * empty. KeyTypes is an array of types of keys.
+ */
+static SPIPlanPtr
+get_plan_for_recalc(Oid matviewOid, List *namelist, List *keys, Oid *keyTypes)
+{
+ MV_QueryKey hash_key;
+ SPIPlanPtr plan;
+
+ /* Fetch or prepare a saved plan for the recalculation */
+ mv_BuildQueryKey(&hash_key, matviewOid, MV_PLAN_RECALC);
+ if ((plan = mv_FetchPreparedPlan(&hash_key)) == NULL)
+ {
+ ListCell *lc;
+ StringInfoData str;
+ char *viewdef;
+
+ /* get view definition of matview */
+ viewdef = text_to_cstring((text *) DatumGetPointer(
+ DirectFunctionCall1(pg_get_viewdef, ObjectIdGetDatum(matviewOid))));
+ /* get rid of trailing semi-colon */
+ viewdef[strlen(viewdef)-1] = '\0';
+
+ /*
+ * Build a query string for recalculating values. This is like
+ *
+ * SELECT x1, x2, x3, ... FROM ( ... view definition query ...) mv
+ * WHERE (key1, key2, ...) = ($1, $2, ...);
+ */
+
+ initStringInfo(&str);
+ appendStringInfo(&str, "SELECT ");
+ foreach (lc, namelist)
+ {
+ appendStringInfo(&str, "%s", (char *) lfirst(lc));
+ if (lnext(namelist, lc))
+ appendStringInfoString(&str, ", ");
+ }
+ appendStringInfo(&str, " FROM (%s) mv", viewdef);
+
+ if (keys)
+ {
+ int i = 1;
+ char paramname[16];
+
+ appendStringInfo(&str, " WHERE (");
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ Oid typid = attr->atttypid;
+
+ sprintf(paramname, "$%d", i);
+ appendStringInfo(&str, "(");
+ generate_equal(&str, typid, resname, paramname);
+ appendStringInfo(&str, " OR (%s IS NULL AND %s IS NULL))",
+ resname, paramname);
+
+ if (lnext(keys, lc))
+ appendStringInfoString(&str, " AND ");
+ i++;
+ }
+ appendStringInfo(&str, ")");
+ }
+ else
+ keyTypes = NULL;
+
+ plan = SPI_prepare(str.data, list_length(keys), keyTypes);
+ if (plan == NULL)
+ elog(ERROR, "SPI_prepare returned %s for %s", SPI_result_code_string(SPI_result), str.data);
+
+ SPI_keepplan(plan);
+ mv_HashPreparedPlan(&hash_key, plan);
+ }
+
+ return plan;
+}
+
+/*
+ * get_plan_for_set_values
+ *
+ * Create or fetch a plan for applying new values calculated by
+ * get_plan_for_recalc to a materialized view specified by matviewOid.
+ * matviewname is the name of the view. namelist is a list of resnames
+ * of attributes to be updated, and valTypes is an array of types of the
+ * values.
+ */
+static SPIPlanPtr
+get_plan_for_set_values(Oid matviewOid, char *matviewname, List *namelist,
+ Oid *valTypes)
+{
+ MV_QueryKey key;
+ SPIPlanPtr plan;
+
+ /* Fetch or prepare a saved plan for the real check */
+ mv_BuildQueryKey(&key, matviewOid, MV_PLAN_SET_VALUE);
+ if ((plan = mv_FetchPreparedPlan(&key)) == NULL)
+ {
+ ListCell *lc;
+ StringInfoData str;
+ int i;
+
+ /*
+ * Build a query string for applying min/max values. This is like
+ *
+ * UPDATE matviewname AS mv
+ * SET (x1, x2, x3, x4) = ($1, $2, $3, $4)
+ * WHERE ctid = $5;
+ */
+
+ initStringInfo(&str);
+ appendStringInfo(&str, "UPDATE %s AS mv SET (", matviewname);
+ foreach (lc, namelist)
+ {
+ appendStringInfo(&str, "%s", (char *) lfirst(lc));
+ if (lnext(namelist, lc))
+ appendStringInfoString(&str, ", ");
+ }
+ appendStringInfo(&str, ") = ROW(");
+
+ for (i = 1; i <= list_length(namelist); i++)
+ appendStringInfo(&str, "%s$%d", (i==1 ? "" : ", "), i);
+
+ appendStringInfo(&str, ") WHERE ctid OPERATOR(pg_catalog.=) $%d", i);
+
+ plan = SPI_prepare(str.data, list_length(namelist) + 1, valTypes);
+ if (plan == NULL)
+ elog(ERROR, "SPI_prepare returned %s for %s", SPI_result_code_string(SPI_result), str.data);
+
+ SPI_keepplan(plan);
+ mv_HashPreparedPlan(&key, plan);
+ }
+
+ return plan;
+}
+
/*
* generate_equals
*
@@ -2783,6 +3299,13 @@ mv_InitHashTables(void)
{
HASHCTL ctl;
+ memset(&ctl, 0, sizeof(ctl));
+ ctl.keysize = sizeof(MV_QueryKey);
+ ctl.entrysize = sizeof(MV_QueryHashEntry);
+ mv_query_cache = hash_create("MV query cache",
+ MV_INIT_QUERYHASHSIZE,
+ &ctl, HASH_ELEM | HASH_BLOBS);
+
memset(&ctl, 0, sizeof(ctl));
ctl.keysize = sizeof(Oid);
ctl.entrysize = sizeof(MV_TriggerHashEntry);
@@ -2791,6 +3314,109 @@ mv_InitHashTables(void)
&ctl, HASH_ELEM | HASH_BLOBS);
}
+/*
+ * mv_FetchPreparedPlan
+ */
+static SPIPlanPtr
+mv_FetchPreparedPlan(MV_QueryKey *key)
+{
+ MV_QueryHashEntry *entry;
+ SPIPlanPtr plan;
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_query_cache)
+ mv_InitHashTables();
+
+ /*
+ * Lookup for the key
+ */
+ entry = (MV_QueryHashEntry *) hash_search(mv_query_cache,
+ (void *) key,
+ HASH_FIND, NULL);
+ if (entry == NULL)
+ return NULL;
+
+ /*
+ * Check whether the plan is still valid. If it isn't, we don't want to
+ * simply rely on plancache.c to regenerate it; rather we should start
+ * from scratch and rebuild the query text too. This is to cover cases
+ * such as table/column renames. We depend on the plancache machinery to
+ * detect possible invalidations, though.
+ *
+ * CAUTION: this check is only trustworthy if the caller has already
+ * locked both materialized views and base tables.
+ *
+ * Also, check whether the search_path is still the same as when we made it.
+ * If it isn't, we need to rebuild the query text because the result of
+ * pg_ivm_get_viewdef() will change.
+ */
+ plan = entry->plan;
+ if (plan && SPI_plan_is_valid(plan) &&
+ SearchPathMatchesCurrentEnvironment(entry->search_path))
+ return plan;
+
+ /*
+ * Otherwise we might as well flush the cached plan now, to free a little
+ * memory space before we make a new one.
+ */
+ if (plan)
+ SPI_freeplan(plan);
+ if (entry->search_path)
+ pfree(entry->search_path);
+
+ entry->plan = NULL;
+ entry->search_path = NULL;
+
+ return NULL;
+}
+
+/*
+ * mv_HashPreparedPlan
+ *
+ * Add another plan to our private SPI query plan hashtable.
+ */
+static void
+mv_HashPreparedPlan(MV_QueryKey *key, SPIPlanPtr plan)
+{
+ MV_QueryHashEntry *entry;
+ bool found;
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_query_cache)
+ mv_InitHashTables();
+
+ /*
+ * Add the new plan. We might be overwriting an entry previously found
+ * invalid by mv_FetchPreparedPlan.
+ */
+ entry = (MV_QueryHashEntry *) hash_search(mv_query_cache,
+ (void *) key,
+ HASH_ENTER, &found);
+ Assert(!found || entry->plan == NULL);
+ entry->plan = plan;
+ entry->search_path = GetSearchPathMatcher(TopMemoryContext);
+}
+
+/*
+ * mv_BuildQueryKey
+ *
+ * Construct a hashtable key for a prepared SPI plan for IVM.
+ */
+static void
+mv_BuildQueryKey(MV_QueryKey *key, Oid matview_id, int32 query_type)
+{
+ /*
+ * We assume struct MV_QueryKey contains no padding bytes, else we'd need
+ * to use memset to clear them.
+ */
+ key->matview_id = matview_id;
+ key->query_type = query_type;
+}
+
/*
* AtAbort_IVM
*
--
2.25.1
v29-0010-Add-regression-tests-for-Incremental-View-Mainte.patchtext/x-diff; name=v29-0010-Add-regression-tests-for-Incremental-View-Mainte.patchDownload
From 7190c9493f7466f5554aee389419c9c3cef82cb6 Mon Sep 17 00:00:00 2001
From: Takuma Hoshiai <takuma.hoshiai@gmail.com>
Date: Wed, 10 Mar 2021 11:11:13 +0900
Subject: [PATCH v29 10/11] Add regression tests for Incremental View
Maintenance
---
.../regress/expected/incremental_matview.out | 1030 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/incremental_matview.sql | 533 +++++++++
3 files changed, 1564 insertions(+), 1 deletion(-)
create mode 100644 src/test/regress/expected/incremental_matview.out
create mode 100644 src/test/regress/sql/incremental_matview.sql
diff --git a/src/test/regress/expected/incremental_matview.out b/src/test/regress/expected/incremental_matview.out
new file mode 100644
index 0000000000..8946d09f5d
--- /dev/null
+++ b/src/test/regress/expected/incremental_matview.out
@@ -0,0 +1,1030 @@
+-- create a table to use as a basis for views and materialized views in various combinations
+CREATE TABLE mv_base_a (i int, j int);
+INSERT INTO mv_base_a VALUES
+ (1,10),
+ (2,20),
+ (3,30),
+ (4,40),
+ (5,50);
+CREATE TABLE mv_base_b (i int, k int);
+INSERT INTO mv_base_b VALUES
+ (1,101),
+ (2,102),
+ (3,103),
+ (4,104);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_1 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) WITH NO DATA;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ERROR: materialized view "mv_ivm_1" has not been populated
+HINT: Use the REFRESH MATERIALIZED VIEW command.
+REFRESH MATERIALIZED VIEW mv_ivm_1;
+NOTICE: could not create an index on materialized view "mv_ivm_1" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+-- REFRESH WITH NO DATA
+BEGIN;
+CREATE FUNCTION dummy_ivm_trigger_func() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+CREATE CONSTRAINT TRIGGER dummy_ivm_trigger AFTER INSERT
+ON mv_base_a FROM mv_ivm_1 FOR EACH ROW
+EXECUTE PROCEDURE dummy_ivm_trigger_func();
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ count
+-------
+ 17
+(1 row)
+
+REFRESH MATERIALIZED VIEW mv_ivm_1 WITH NO DATA;
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+-- immediate maintenance
+BEGIN;
+INSERT INTO mv_base_b VALUES(5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+ 5 | 50 | 105
+(5 rows)
+
+UPDATE mv_base_a SET j = 0 WHERE i = 1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 0 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+ 5 | 50 | 105
+(5 rows)
+
+DELETE FROM mv_base_b WHERE (i,k) = (5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 0 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+ROLLBACK;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+-- rename of IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS SELECT DISTINCT * FROM mv_base_a;
+NOTICE: created index "mv_ivm_rename_index" on materialized view "mv_ivm_rename"
+ALTER MATERIALIZED VIEW mv_ivm_rename RENAME COLUMN __ivm_count__ TO xxx;
+ERROR: IVM column can not be renamed
+DROP MATERIALIZED VIEW mv_ivm_rename;
+-- unique index on IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_unique AS SELECT DISTINCT * FROM mv_base_a;
+NOTICE: created index "mv_ivm_unique_index" on materialized view "mv_ivm_unique"
+CREATE UNIQUE INDEX ON mv_ivm_unique(__ivm_count__);
+ERROR: unique index creation on IVM columns is not supported
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__));
+ERROR: unique index creation on IVM columns is not supported
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__ + 1));
+ERROR: unique index creation on IVM columns is not supported
+DROP MATERIALIZED VIEW mv_ivm_unique;
+-- TRUNCATE a base table in join views
+BEGIN;
+TRUNCATE mv_base_a;
+SELECT * FROM mv_ivm_1;
+ i | j | k
+---+---+---
+(0 rows)
+
+ROLLBACK;
+BEGIN;
+TRUNCATE mv_base_b;
+SELECT * FROM mv_ivm_1;
+ i | j | k
+---+---+---
+(0 rows)
+
+ROLLBACK;
+-- some query syntax
+BEGIN;
+CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql'
+ AS 'SELECT 1' IMMUTABLE;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_func AS SELECT * FROM ivm_func();
+NOTICE: could not create an index on materialized view "mv_ivm_func" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_no_tbl AS SELECT 1;
+NOTICE: could not create an index on materialized view "mv_ivm_no_tbl" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+ROLLBACK;
+-- result of materialized view have DISTINCT clause or the duplicate result.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_duplicate AS SELECT j FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_duplicate" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_distinct AS SELECT DISTINCT j FROM mv_base_a;
+NOTICE: created index "mv_ivm_distinct_index" on materialized view "mv_ivm_distinct"
+INSERT INTO mv_base_a VALUES(6,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 20
+ 30
+ 40
+ 50
+(6 rows)
+
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+ROLLBACK;
+-- support SUM(), COUNT() and AVG() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 120 | 2 | 60.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+UPDATE mv_base_a SET j = 200 WHERE (i,j) = (2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+----------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 220 | 2 | 110.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (2,200);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+ROLLBACK;
+-- support COUNT(*) aggregate function
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ i | sum | count
+---+-----+-------
+ 1 | 10 | 1
+ 2 | 20 | 1
+ 3 | 30 | 1
+ 4 | 40 | 1
+ 5 | 50 | 1
+(5 rows)
+
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ i | sum | count
+---+-----+-------
+ 1 | 10 | 1
+ 2 | 120 | 2
+ 3 | 30 | 1
+ 4 | 40 | 1
+ 5 | 50 | 1
+(5 rows)
+
+ROLLBACK;
+-- TRUNCATE a base table in aggregate views
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+TRUNCATE mv_base_a;
+SELECT sum, count FROM mv_ivm_agg;
+ sum | count
+-----+-------
+(0 rows)
+
+SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+ i | sum | count
+---+-----+-------
+(0 rows)
+
+ROLLBACK;
+-- support aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_group" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+---------------------
+ 150 | 5 | 30.0000000000000000
+(1 row)
+
+INSERT INTO mv_base_a VALUES(6,60);
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+---------------------
+ 210 | 6 | 35.0000000000000000
+(1 row)
+
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+ROLLBACK;
+-- TRUNCATE a base table in aggregate views without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_group" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+TRUNCATE mv_base_a;
+SELECT sum, count, avg FROM mv_ivm_group;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+ROLLBACK;
+-- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_avg_bug AS SELECT i, SUM(j), COUNT(j), AVG(j) FROM mv_base_A GROUP BY i;
+NOTICE: created index "mv_ivm_avg_bug_index" on materialized view "mv_ivm_avg_bug"
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+INSERT INTO mv_base_a VALUES
+ (1,0),
+ (1,0),
+ (2,30),
+ (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 3 | 3.3333333333333333
+ 2 | 80 | 3 | 26.6666666666666667
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (1,0);
+DELETE FROM mv_base_a WHERE (i,j) = (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+ROLLBACK;
+-- support MIN(), MAX() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_min_max_index" on materialized view "mv_ivm_min_max"
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 10 | 10
+ 2 | 20 | 20
+ 3 | 30 | 30
+ 4 | 40 | 40
+ 5 | 50 | 50
+(5 rows)
+
+INSERT INTO mv_base_a VALUES
+ (1,11), (1,12),
+ (2,21), (2,22),
+ (3,31), (3,32),
+ (4,41), (4,42),
+ (5,51), (5,52);
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 10 | 12
+ 2 | 20 | 22
+ 3 | 30 | 32
+ 4 | 40 | 42
+ 5 | 50 | 52
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) IN ((1,10), (2,21), (3,32));
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 11 | 12
+ 2 | 20 | 22
+ 3 | 30 | 31
+ 4 | 40 | 42
+ 5 | 50 | 52
+(5 rows)
+
+ROLLBACK;
+-- support MIN(), MAX() aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT MIN(j), MAX(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_min_max" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 10 | 50
+(1 row)
+
+INSERT INTO mv_base_a VALUES
+ (0,0), (6,60), (7,70);
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 0 | 70
+(1 row)
+
+DELETE FROM mv_base_a WHERE (i,j) IN ((0,0), (7,70));
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 10 | 60
+(1 row)
+
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ |
+(1 row)
+
+ROLLBACK;
+-- Test MIN/MAX after search_path change
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min AS SELECT MIN(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_min" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 10
+(1 row)
+
+CREATE SCHEMA myschema;
+GRANT ALL ON SCHEMA myschema TO public;
+CREATE TABLE myschema.mv_base_a (j int);
+INSERT INTO myschema.mv_base_a VALUES (1);
+DELETE FROM mv_base_a WHERE (i,j) = (1,10);
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 20
+(1 row)
+
+SET search_path TO myschema,public,pg_catalog;
+DELETE FROM public.mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 30
+(1 row)
+
+ROLLBACK;
+-- aggregate views with column names specified
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ a | sum
+---+------
+ 1 | 110
+ 2 | 2200
+ 3 | 300
+ 4 | 40
+ 5 | 50
+(5 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ a | b
+---+------
+ 1 | 110
+ 2 | 2200
+ 3 | 300
+ 4 | 40
+ 5 | 50
+(5 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b,c) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+ERROR: too many column names were specified
+ROLLBACK;
+-- support self join view and multiple change on the same table
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_self(v1, v2) AS
+ SELECT t1.v, t2.v FROM base_t AS t1 JOIN base_t AS t2 ON t1.i = t2.i;
+NOTICE: could not create an index on materialized view "mv_self" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+----+----
+ 10 | 10
+ 20 | 20
+ 30 | 30
+(3 rows)
+
+INSERT INTO base_t VALUES (4,40);
+DELETE FROM base_t WHERE i = 1;
+UPDATE base_t SET v = v*10 WHERE i=2;
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+-----+-----
+ 30 | 30
+ 40 | 40
+ 200 | 200
+(3 rows)
+
+WITH
+ ins_t1 AS (INSERT INTO base_t VALUES (5,50) RETURNING 1),
+ ins_t2 AS (INSERT INTO base_t VALUES (6,60) RETURNING 1),
+ upd_t AS (UPDATE base_t SET v = v + 100 RETURNING 1),
+ dlt_t AS (DELETE FROM base_t WHERE i IN (4,5) RETURNING 1)
+SELECT NULL;
+ ?column?
+----------
+
+(1 row)
+
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+-----+-----
+ 50 | 50
+ 60 | 60
+ 130 | 130
+ 300 | 300
+(4 rows)
+
+--- with sub-transactions
+SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,70);
+RELEASE SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,77);
+SELECT * FROM mv_self ORDER BY v1, v2;
+ v1 | v2
+-----+-----
+ 50 | 50
+ 60 | 60
+ 70 | 70
+ 70 | 77
+ 77 | 70
+ 77 | 77
+ 130 | 130
+ 300 | 300
+(8 rows)
+
+ROLLBACK;
+-- support simultaneous table changes
+BEGIN;
+CREATE TABLE base_r (i int, v int);
+CREATE TABLE base_s (i int, v int);
+INSERT INTO base_r VALUES (1, 10), (2, 20), (3, 30);
+INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300);
+CREATE INCREMENTAL MATERIALIZED VIEW mv(v1, v2) AS
+ SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i);
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY v1;
+ v1 | v2
+----+-----
+ 10 | 100
+ 20 | 200
+ 30 | 300
+(3 rows)
+
+WITH
+ ins_r AS (INSERT INTO base_r VALUES (1,11) RETURNING 1),
+ ins_r2 AS (INSERT INTO base_r VALUES (3,33) RETURNING 1),
+ ins_s AS (INSERT INTO base_s VALUES (2,222) RETURNING 1),
+ upd_r AS (UPDATE base_r SET v = v + 1000 WHERE i = 2 RETURNING 1),
+ dlt_s AS (DELETE FROM base_s WHERE i = 3 RETURNING 1)
+SELECT NULL;
+ ?column?
+----------
+
+(1 row)
+
+SELECT * FROM mv ORDER BY v1;
+ v1 | v2
+------+-----
+ 10 | 100
+ 11 | 100
+ 1020 | 200
+ 1020 | 222
+(4 rows)
+
+ROLLBACK;
+-- support foreign reference constraints
+BEGIN;
+CREATE TABLE ri1 (i int PRIMARY KEY);
+CREATE TABLE ri2 (i int PRIMARY KEY REFERENCES ri1(i) ON UPDATE CASCADE ON DELETE CASCADE, v int);
+INSERT INTO ri1 VALUES (1),(2),(3);
+INSERT INTO ri2 VALUES (1),(2),(3);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ri(i1, i2) AS
+ SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i);
+NOTICE: created index "mv_ri_index" on materialized view "mv_ri"
+SELECT * FROM mv_ri ORDER BY i1;
+ i1 | i2
+----+----
+ 1 | 1
+ 2 | 2
+ 3 | 3
+(3 rows)
+
+UPDATE ri1 SET i=10 where i=1;
+DELETE FROM ri1 WHERE i=2;
+SELECT * FROM mv_ri ORDER BY i2;
+ i1 | i2
+----+----
+ 3 | 3
+ 10 | 10
+(2 rows)
+
+ROLLBACK;
+-- views including NULL
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1,10),(2, NULL);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY i;
+ i | v
+---+----
+ 1 | 10
+ 2 |
+(2 rows)
+
+UPDATE base_t SET v = 20 WHERE i = 2;
+SELECT * FROM mv ORDER BY i;
+ i | v
+---+----
+ 1 | 10
+ 2 | 20
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY i;
+ i
+---
+(0 rows)
+
+INSERT INTO base_t VALUES (1),(NULL);
+SELECT * FROM mv ORDER BY i;
+ i
+---
+ 1
+
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, sum(v) FROM base_t GROUP BY i;
+NOTICE: created index "mv_index" on materialized view "mv"
+SELECT * FROM mv ORDER BY i;
+ i | sum
+---+-----
+ 1 | 30
+ | 3
+(2 rows)
+
+UPDATE base_t SET v = v * 10;
+SELECT * FROM mv ORDER BY i;
+ i | sum
+---+-----
+ 1 | 300
+ | 30
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, min(v), max(v) FROM base_t GROUP BY i;
+NOTICE: created index "mv_index" on materialized view "mv"
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 1 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 1;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 3;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 5;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 4
+(1 row)
+
+ROLLBACK;
+-- IMMV containing user defined type
+BEGIN;
+CREATE TYPE mytype;
+CREATE FUNCTION mytype_in(cstring)
+ RETURNS mytype AS 'int4in'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+NOTICE: return type mytype is only a shell
+CREATE FUNCTION mytype_out(mytype)
+ RETURNS cstring AS 'int4out'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+NOTICE: argument type mytype is only a shell
+CREATE TYPE mytype (
+ LIKE = int4,
+ INPUT = mytype_in,
+ OUTPUT = mytype_out
+);
+CREATE FUNCTION mytype_eq(mytype, mytype)
+ RETURNS bool AS 'int4eq'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_lt(mytype, mytype)
+ RETURNS bool AS 'int4lt'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_cmp(mytype, mytype)
+ RETURNS integer AS 'btint4cmp'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE OPERATOR = (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_eq);
+CREATE OPERATOR < (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_lt);
+CREATE OPERATOR CLASS mytype_ops
+ DEFAULT FOR TYPE mytype USING btree AS
+ OPERATOR 1 <,
+ OPERATOR 3 = ,
+ FUNCTION 1 mytype_cmp(mytype,mytype);
+CREATE TABLE t_mytype (x mytype);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_mytype AS
+ SELECT * FROM t_mytype;
+NOTICE: could not create an index on materialized view "mv_mytype" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+INSERT INTO t_mytype VALUES ('1'::mytype);
+SELECT * FROM mv_mytype;
+ x
+---
+ 1
+(1 row)
+
+ROLLBACK;
+-- outer join is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv(a,b) AS SELECT a.i, b.i FROM mv_base_a a LEFT JOIN mv_base_b b ON a.i=b.i;
+ERROR: OUTER JOIN is not supported on incrementally maintainable materialized view
+-- CTE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS
+ WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i;
+ERROR: CTE is not supported on incrementally maintainable materialized view
+-- contain system column
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm01 AS SELECT i,j,xmin FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT i,j,xmin::text AS x_min FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm06 AS SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+-- contain subquery
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm03 AS SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 );
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT * FROM mv_base_b) b WHERE a.i = b.i;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm05 AS SELECT i,j, (SELECT k FROM mv_base_b b WHERE a.i = b.i) FROM mv_base_a a;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+-- contain ORDER BY
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) ORDER BY i,j,k;
+ERROR: ORDER BY clause is not supported on incrementally maintainable materialized view
+-- contain HAVING
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) GROUP BY i,j,k HAVING SUM(i) > 5;
+ERROR: HAVING clause is not supported on incrementally maintainable materialized view
+-- contain view or materialized view
+CREATE VIEW b_view AS SELECT i,k FROM mv_base_b;
+CREATE MATERIALIZED VIEW b_mview AS SELECT i,k FROM mv_base_b;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT a.i,a.j FROM mv_base_a a,b_view b WHERE a.i = b.i;
+ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT a.i,a.j FROM mv_base_a a,b_mview b WHERE a.i = b.i;
+ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm09 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) b WHERE a.i = b.i;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm10 AS SELECT a.i,a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) OR a.i > 5;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+-- contain mutable functions
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+ERROR: mutable function is not supported on incrementally maintainable materialized view
+HINT: functions must be marked IMMUTABLE
+-- LIMIT/OFFSET is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm13 AS SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5;
+ERROR: LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view
+-- DISTINCT ON is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm14 AS SELECT DISTINCT ON(i) i, j FROM mv_base_a;
+ERROR: DISTINCT ON is not supported on incrementally maintainable materialized view
+-- TABLESAMPLE clause is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm15 AS SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50);
+ERROR: TABLESAMPLE clause is not supported on incrementally maintainable materialized view
+-- window functions are not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm16 AS SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a;
+ERROR: window functions are not supported on incrementally maintainable materialized view
+-- aggregate function with some options is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm17 AS SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a;
+ERROR: aggregate function with FILTER clause is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm18 AS SELECT COUNT(DISTINCT i) FROM mv_base_a;
+ERROR: aggregate function with DISTINCT arguments is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm19 AS SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a;
+ERROR: aggregate function with ORDER clause is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm20 AS SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),());
+ERROR: GROUPING SETS, ROLLUP, or CUBE clauses is not supported on incrementally maintainable materialized view
+-- inheritance parent is not supported
+BEGIN;
+CREATE TABLE parent (i int, v int);
+CREATE TABLE child_a(options text) INHERITS(parent);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm21 AS SELECT * FROM parent;
+ERROR: inheritance parent is not supported on incrementally maintainable materialized view
+ROLLBACK;
+-- UNION statement is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm22 AS SELECT i,j FROM mv_base_a UNION ALL SELECT i,k FROM mv_base_b;;
+ERROR: UNION/INTERSECT/EXCEPT statements are not supported on incrementally maintainable materialized view
+-- empty target list is not allowed with IVM
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm25 AS SELECT FROM mv_base_a;
+ERROR: empty target list is not supported on incrementally maintainable materialized view
+-- FOR UPDATE/SHARE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm26 AS SELECT i,j FROM mv_base_a FOR UPDATE;
+ERROR: FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view
+-- tartget list cannot contain ivm column that start with '__ivm'
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm28 AS SELECT i AS "__ivm_count__" FROM mv_base_a;
+ERROR: column name __ivm_count__ is not supported on incrementally maintainable materialized view
+-- expressions specified in GROUP BY must appear in the target list.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm29 AS SELECT COUNT(i) FROM mv_base_a GROUP BY i;
+ERROR: GROUP BY expression not appearing in select list is not supported on incrementally maintainable materialized view
+-- experssions containing an aggregate is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm30 AS SELECT sum(i)*0.5 FROM mv_base_a;
+ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm31 AS SELECT sum(i)/sum(j) FROM mv_base_a;
+ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view
+-- VALUES is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_only_values1 AS values(1);
+ERROR: VALUES is not supported on incrementally maintainable materialized view
+-- views containing base tables with Row Level Security
+DROP USER IF EXISTS ivm_admin;
+NOTICE: role "ivm_admin" does not exist, skipping
+DROP USER IF EXISTS ivm_user;
+NOTICE: role "ivm_user" does not exist, skipping
+CREATE USER ivm_admin;
+CREATE USER ivm_user;
+--- create a table with RLS
+SET SESSION AUTHORIZATION ivm_admin;
+CREATE TABLE rls_tbl(id int, data text, owner name);
+INSERT INTO rls_tbl VALUES
+ (1,'foo','ivm_user'),
+ (2,'bar','postgres');
+CREATE TABLE num_tbl(id int, num text);
+INSERT INTO num_tbl VALUES
+ (1,'one'),
+ (2,'two'),
+ (3,'three'),
+ (4,'four'),
+ (5,'five'),
+ (6,'six');
+--- Users can access only their own rows
+CREATE POLICY rls_tbl_policy ON rls_tbl FOR SELECT TO PUBLIC USING(owner = current_user);
+ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
+GRANT ALL on rls_tbl TO PUBLIC;
+GRANT ALL on num_tbl TO PUBLIC;
+--- create a view owned by ivm_user
+SET SESSION AUTHORIZATION ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls AS SELECT * FROM rls_tbl;
+NOTICE: could not create an index on materialized view "ivm_rls" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+------+----------
+ 1 | foo | ivm_user
+(1 row)
+
+RESET SESSION AUTHORIZATION;
+--- inserts rows owned by different users
+INSERT INTO rls_tbl VALUES
+ (3,'baz','ivm_user'),
+ (4,'qux','postgres');
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+------+----------
+ 1 | foo | ivm_user
+ 3 | baz | ivm_user
+(2 rows)
+
+--- combination of diffent kinds of commands
+WITH
+ i AS (INSERT INTO rls_tbl VALUES(5,'quux','postgres'), (6,'corge','ivm_user')),
+ u AS (UPDATE rls_tbl SET owner = 'postgres' WHERE id = 1),
+ u2 AS (UPDATE rls_tbl SET owner = 'ivm_user' WHERE id = 2)
+SELECT;
+--
+(1 row)
+
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+-------+----------
+ 2 | bar | ivm_user
+ 3 | baz | ivm_user
+ 6 | corge | ivm_user
+(3 rows)
+
+---
+SET SESSION AUTHORIZATION ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls2 AS SELECT * FROM rls_tbl JOIN num_tbl USING(id);
+NOTICE: could not create an index on materialized view "ivm_rls2" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+RESET SESSION AUTHORIZATION;
+WITH
+ x AS (UPDATE rls_tbl SET data = data || '_2' where id in (3,4)),
+ y AS (UPDATE num_tbl SET num = num || '_2' where id in (3,4))
+SELECT;
+--
+(1 row)
+
+SELECT * FROM ivm_rls2 ORDER BY 1,2,3;
+ id | data | owner | num
+----+-------+----------+---------
+ 2 | bar | ivm_user | two
+ 3 | baz_2 | ivm_user | three_2
+ 6 | corge | ivm_user | six
+(3 rows)
+
+-- automatic index creation
+CREATE TABLE base_a (i int primary key, j int);
+CREATE TABLE base_b (i int primary key, j int);
+--- group by: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx1 AS SELECT i, sum(j) FROM base_a GROUP BY i;
+NOTICE: created index "mv_idx1_index" on materialized view "mv_idx1"
+--- distinct: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx2 AS SELECT DISTINCT j FROM base_a;
+NOTICE: created index "mv_idx2_index" on materialized view "mv_idx2"
+--- with all pkey columns: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx3(i_a, i_b) AS SELECT a.i, b.i FROM base_a a, base_b b;
+NOTICE: created index "mv_idx3_index" on materialized view "mv_idx3"
+--- missing some pkey columns: no index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx4 AS SELECT j FROM base_a;
+NOTICE: could not create an index on materialized view "mv_idx4" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx5 AS SELECT a.i, b.j FROM base_a a, base_b b;
+NOTICE: could not create an index on materialized view "mv_idx5" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+-- cleanup
+DROP TABLE rls_tbl CASCADE;
+NOTICE: drop cascades to 2 other objects
+DETAIL: drop cascades to materialized view ivm_rls
+drop cascades to materialized view ivm_rls2
+DROP TABLE num_tbl CASCADE;
+DROP USER ivm_user;
+DROP USER ivm_admin;
+DROP TABLE mv_base_b CASCADE;
+NOTICE: drop cascades to 3 other objects
+DETAIL: drop cascades to materialized view mv_ivm_1
+drop cascades to view b_view
+drop cascades to materialized view b_mview
+DROP TABLE mv_base_a CASCADE;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 4df9d8503b..21f7247a07 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -78,7 +78,7 @@ test: brin_bloom brin_multi
# psql depends on create_am
# amutils depends on geometry, create_index_spgist, hash_index, brin
# ----------
-test: create_table_like alter_generic alter_operator misc async dbsize merge misc_functions sysviews tsrf tid tidscan tidrangescan collate.icu.utf8 incremental_sort create_role
+test: create_table_like alter_generic alter_operator misc async dbsize merge misc_functions sysviews tsrf tid tidscan tidrangescan collate.icu.utf8 incremental_sort create_role incremental_matview
# collate.*.utf8 tests cannot be run in parallel with each other
test: rules psql psql_crosstab amutils stats_ext collate.linux.utf8 collate.windows.win1252
diff --git a/src/test/regress/sql/incremental_matview.sql b/src/test/regress/sql/incremental_matview.sql
new file mode 100644
index 0000000000..82686f9324
--- /dev/null
+++ b/src/test/regress/sql/incremental_matview.sql
@@ -0,0 +1,533 @@
+-- create a table to use as a basis for views and materialized views in various combinations
+CREATE TABLE mv_base_a (i int, j int);
+INSERT INTO mv_base_a VALUES
+ (1,10),
+ (2,20),
+ (3,30),
+ (4,40),
+ (5,50);
+CREATE TABLE mv_base_b (i int, k int);
+INSERT INTO mv_base_b VALUES
+ (1,101),
+ (2,102),
+ (3,103),
+ (4,104);
+
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_1 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) WITH NO DATA;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+REFRESH MATERIALIZED VIEW mv_ivm_1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+
+-- REFRESH WITH NO DATA
+BEGIN;
+CREATE FUNCTION dummy_ivm_trigger_func() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+
+CREATE CONSTRAINT TRIGGER dummy_ivm_trigger AFTER INSERT
+ON mv_base_a FROM mv_ivm_1 FOR EACH ROW
+EXECUTE PROCEDURE dummy_ivm_trigger_func();
+
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+
+REFRESH MATERIALIZED VIEW mv_ivm_1 WITH NO DATA;
+
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ROLLBACK;
+
+-- immediate maintenance
+BEGIN;
+INSERT INTO mv_base_b VALUES(5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+UPDATE mv_base_a SET j = 0 WHERE i = 1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+DELETE FROM mv_base_b WHERE (i,k) = (5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ROLLBACK;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+
+-- rename of IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS SELECT DISTINCT * FROM mv_base_a;
+ALTER MATERIALIZED VIEW mv_ivm_rename RENAME COLUMN __ivm_count__ TO xxx;
+DROP MATERIALIZED VIEW mv_ivm_rename;
+
+-- unique index on IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_unique AS SELECT DISTINCT * FROM mv_base_a;
+CREATE UNIQUE INDEX ON mv_ivm_unique(__ivm_count__);
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__));
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__ + 1));
+DROP MATERIALIZED VIEW mv_ivm_unique;
+
+-- TRUNCATE a base table in join views
+BEGIN;
+TRUNCATE mv_base_a;
+SELECT * FROM mv_ivm_1;
+ROLLBACK;
+
+BEGIN;
+TRUNCATE mv_base_b;
+SELECT * FROM mv_ivm_1;
+ROLLBACK;
+
+-- some query syntax
+BEGIN;
+CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql'
+ AS 'SELECT 1' IMMUTABLE;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_func AS SELECT * FROM ivm_func();
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_no_tbl AS SELECT 1;
+ROLLBACK;
+
+-- result of materialized view have DISTINCT clause or the duplicate result.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_duplicate AS SELECT j FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_distinct AS SELECT DISTINCT j FROM mv_base_a;
+INSERT INTO mv_base_a VALUES(6,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+DELETE FROM mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ROLLBACK;
+
+-- support SUM(), COUNT() and AVG() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+UPDATE mv_base_a SET j = 200 WHERE (i,j) = (2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+DELETE FROM mv_base_a WHERE (i,j) = (2,200);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ROLLBACK;
+
+-- support COUNT(*) aggregate function
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ROLLBACK;
+
+-- TRUNCATE a base table in aggregate views
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+TRUNCATE mv_base_a;
+SELECT sum, count FROM mv_ivm_agg;
+SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+ROLLBACK;
+
+-- support aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+INSERT INTO mv_base_a VALUES(6,60);
+SELECT * FROM mv_ivm_group ORDER BY 1;
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ROLLBACK;
+
+-- TRUNCATE a base table in aggregate views without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+TRUNCATE mv_base_a;
+SELECT sum, count, avg FROM mv_ivm_group;
+SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+ROLLBACK;
+
+-- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_avg_bug AS SELECT i, SUM(j), COUNT(j), AVG(j) FROM mv_base_A GROUP BY i;
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES
+ (1,0),
+ (1,0),
+ (2,30),
+ (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+DELETE FROM mv_base_a WHERE (i,j) = (1,0);
+DELETE FROM mv_base_a WHERE (i,j) = (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ROLLBACK;
+
+-- support MIN(), MAX() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES
+ (1,11), (1,12),
+ (2,21), (2,22),
+ (3,31), (3,32),
+ (4,41), (4,42),
+ (5,51), (5,52);
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+DELETE FROM mv_base_a WHERE (i,j) IN ((1,10), (2,21), (3,32));
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ROLLBACK;
+
+-- support MIN(), MAX() aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT MIN(j), MAX(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+INSERT INTO mv_base_a VALUES
+ (0,0), (6,60), (7,70);
+SELECT * FROM mv_ivm_min_max;
+DELETE FROM mv_base_a WHERE (i,j) IN ((0,0), (7,70));
+SELECT * FROM mv_ivm_min_max;
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+ROLLBACK;
+
+-- Test MIN/MAX after search_path change
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min AS SELECT MIN(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_min;
+
+CREATE SCHEMA myschema;
+GRANT ALL ON SCHEMA myschema TO public;
+CREATE TABLE myschema.mv_base_a (j int);
+INSERT INTO myschema.mv_base_a VALUES (1);
+
+DELETE FROM mv_base_a WHERE (i,j) = (1,10);
+SELECT * FROM mv_ivm_min;
+
+SET search_path TO myschema,public,pg_catalog;
+DELETE FROM public.mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_min;
+ROLLBACK;
+
+-- aggregate views with column names specified
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b,c) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+ROLLBACK;
+
+-- support self join view and multiple change on the same table
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_self(v1, v2) AS
+ SELECT t1.v, t2.v FROM base_t AS t1 JOIN base_t AS t2 ON t1.i = t2.i;
+SELECT * FROM mv_self ORDER BY v1;
+INSERT INTO base_t VALUES (4,40);
+DELETE FROM base_t WHERE i = 1;
+UPDATE base_t SET v = v*10 WHERE i=2;
+SELECT * FROM mv_self ORDER BY v1;
+WITH
+ ins_t1 AS (INSERT INTO base_t VALUES (5,50) RETURNING 1),
+ ins_t2 AS (INSERT INTO base_t VALUES (6,60) RETURNING 1),
+ upd_t AS (UPDATE base_t SET v = v + 100 RETURNING 1),
+ dlt_t AS (DELETE FROM base_t WHERE i IN (4,5) RETURNING 1)
+SELECT NULL;
+SELECT * FROM mv_self ORDER BY v1;
+
+--- with sub-transactions
+SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,70);
+RELEASE SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,77);
+SELECT * FROM mv_self ORDER BY v1, v2;
+
+ROLLBACK;
+
+-- support simultaneous table changes
+BEGIN;
+CREATE TABLE base_r (i int, v int);
+CREATE TABLE base_s (i int, v int);
+INSERT INTO base_r VALUES (1, 10), (2, 20), (3, 30);
+INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300);
+CREATE INCREMENTAL MATERIALIZED VIEW mv(v1, v2) AS
+ SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i);
+SELECT * FROM mv ORDER BY v1;
+WITH
+ ins_r AS (INSERT INTO base_r VALUES (1,11) RETURNING 1),
+ ins_r2 AS (INSERT INTO base_r VALUES (3,33) RETURNING 1),
+ ins_s AS (INSERT INTO base_s VALUES (2,222) RETURNING 1),
+ upd_r AS (UPDATE base_r SET v = v + 1000 WHERE i = 2 RETURNING 1),
+ dlt_s AS (DELETE FROM base_s WHERE i = 3 RETURNING 1)
+SELECT NULL;
+SELECT * FROM mv ORDER BY v1;
+ROLLBACK;
+
+-- support foreign reference constraints
+BEGIN;
+CREATE TABLE ri1 (i int PRIMARY KEY);
+CREATE TABLE ri2 (i int PRIMARY KEY REFERENCES ri1(i) ON UPDATE CASCADE ON DELETE CASCADE, v int);
+INSERT INTO ri1 VALUES (1),(2),(3);
+INSERT INTO ri2 VALUES (1),(2),(3);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ri(i1, i2) AS
+ SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i);
+SELECT * FROM mv_ri ORDER BY i1;
+UPDATE ri1 SET i=10 where i=1;
+DELETE FROM ri1 WHERE i=2;
+SELECT * FROM mv_ri ORDER BY i2;
+ROLLBACK;
+
+-- views including NULL
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1,10),(2, NULL);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+SELECT * FROM mv ORDER BY i;
+UPDATE base_t SET v = 20 WHERE i = 2;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+SELECT * FROM mv ORDER BY i;
+INSERT INTO base_t VALUES (1),(NULL);
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, sum(v) FROM base_t GROUP BY i;
+SELECT * FROM mv ORDER BY i;
+UPDATE base_t SET v = v * 10;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, min(v), max(v) FROM base_t GROUP BY i;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 1;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 3;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 5;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+-- IMMV containing user defined type
+BEGIN;
+
+CREATE TYPE mytype;
+CREATE FUNCTION mytype_in(cstring)
+ RETURNS mytype AS 'int4in'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_out(mytype)
+ RETURNS cstring AS 'int4out'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE TYPE mytype (
+ LIKE = int4,
+ INPUT = mytype_in,
+ OUTPUT = mytype_out
+);
+
+CREATE FUNCTION mytype_eq(mytype, mytype)
+ RETURNS bool AS 'int4eq'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_lt(mytype, mytype)
+ RETURNS bool AS 'int4lt'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_cmp(mytype, mytype)
+ RETURNS integer AS 'btint4cmp'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+
+CREATE OPERATOR = (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_eq);
+CREATE OPERATOR < (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_lt);
+
+CREATE OPERATOR CLASS mytype_ops
+ DEFAULT FOR TYPE mytype USING btree AS
+ OPERATOR 1 <,
+ OPERATOR 3 = ,
+ FUNCTION 1 mytype_cmp(mytype,mytype);
+
+CREATE TABLE t_mytype (x mytype);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_mytype AS
+ SELECT * FROM t_mytype;
+INSERT INTO t_mytype VALUES ('1'::mytype);
+SELECT * FROM mv_mytype;
+
+ROLLBACK;
+
+-- outer join is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv(a,b) AS SELECT a.i, b.i FROM mv_base_a a LEFT JOIN mv_base_b b ON a.i=b.i;
+-- CTE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS
+ WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i;
+-- contain system column
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm01 AS SELECT i,j,xmin FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT i,j,xmin::text AS x_min FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm06 AS SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a;
+-- contain subquery
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm03 AS SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 );
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT * FROM mv_base_b) b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm05 AS SELECT i,j, (SELECT k FROM mv_base_b b WHERE a.i = b.i) FROM mv_base_a a;
+-- contain ORDER BY
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) ORDER BY i,j,k;
+-- contain HAVING
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) GROUP BY i,j,k HAVING SUM(i) > 5;
+
+-- contain view or materialized view
+CREATE VIEW b_view AS SELECT i,k FROM mv_base_b;
+CREATE MATERIALIZED VIEW b_mview AS SELECT i,k FROM mv_base_b;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT a.i,a.j FROM mv_base_a a,b_view b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT a.i,a.j FROM mv_base_a a,b_mview b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm09 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm10 AS SELECT a.i,a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) OR a.i > 5;
+
+-- contain mutable functions
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+
+-- LIMIT/OFFSET is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm13 AS SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5;
+
+-- DISTINCT ON is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm14 AS SELECT DISTINCT ON(i) i, j FROM mv_base_a;
+
+-- TABLESAMPLE clause is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm15 AS SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50);
+
+-- window functions are not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm16 AS SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a;
+
+-- aggregate function with some options is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm17 AS SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm18 AS SELECT COUNT(DISTINCT i) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm19 AS SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm20 AS SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),());
+
+-- inheritance parent is not supported
+BEGIN;
+CREATE TABLE parent (i int, v int);
+CREATE TABLE child_a(options text) INHERITS(parent);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm21 AS SELECT * FROM parent;
+ROLLBACK;
+
+-- UNION statement is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm22 AS SELECT i,j FROM mv_base_a UNION ALL SELECT i,k FROM mv_base_b;;
+
+-- empty target list is not allowed with IVM
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm25 AS SELECT FROM mv_base_a;
+
+-- FOR UPDATE/SHARE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm26 AS SELECT i,j FROM mv_base_a FOR UPDATE;
+
+-- tartget list cannot contain ivm column that start with '__ivm'
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm28 AS SELECT i AS "__ivm_count__" FROM mv_base_a;
+
+-- expressions specified in GROUP BY must appear in the target list.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm29 AS SELECT COUNT(i) FROM mv_base_a GROUP BY i;
+
+-- experssions containing an aggregate is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm30 AS SELECT sum(i)*0.5 FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm31 AS SELECT sum(i)/sum(j) FROM mv_base_a;
+
+-- VALUES is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_only_values1 AS values(1);
+
+-- views containing base tables with Row Level Security
+DROP USER IF EXISTS ivm_admin;
+DROP USER IF EXISTS ivm_user;
+CREATE USER ivm_admin;
+CREATE USER ivm_user;
+
+--- create a table with RLS
+SET SESSION AUTHORIZATION ivm_admin;
+CREATE TABLE rls_tbl(id int, data text, owner name);
+INSERT INTO rls_tbl VALUES
+ (1,'foo','ivm_user'),
+ (2,'bar','postgres');
+CREATE TABLE num_tbl(id int, num text);
+INSERT INTO num_tbl VALUES
+ (1,'one'),
+ (2,'two'),
+ (3,'three'),
+ (4,'four'),
+ (5,'five'),
+ (6,'six');
+
+--- Users can access only their own rows
+CREATE POLICY rls_tbl_policy ON rls_tbl FOR SELECT TO PUBLIC USING(owner = current_user);
+ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
+GRANT ALL on rls_tbl TO PUBLIC;
+GRANT ALL on num_tbl TO PUBLIC;
+
+--- create a view owned by ivm_user
+SET SESSION AUTHORIZATION ivm_user;
+
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls AS SELECT * FROM rls_tbl;
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+RESET SESSION AUTHORIZATION;
+
+--- inserts rows owned by different users
+INSERT INTO rls_tbl VALUES
+ (3,'baz','ivm_user'),
+ (4,'qux','postgres');
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+
+--- combination of diffent kinds of commands
+WITH
+ i AS (INSERT INTO rls_tbl VALUES(5,'quux','postgres'), (6,'corge','ivm_user')),
+ u AS (UPDATE rls_tbl SET owner = 'postgres' WHERE id = 1),
+ u2 AS (UPDATE rls_tbl SET owner = 'ivm_user' WHERE id = 2)
+SELECT;
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+
+---
+SET SESSION AUTHORIZATION ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls2 AS SELECT * FROM rls_tbl JOIN num_tbl USING(id);
+RESET SESSION AUTHORIZATION;
+
+WITH
+ x AS (UPDATE rls_tbl SET data = data || '_2' where id in (3,4)),
+ y AS (UPDATE num_tbl SET num = num || '_2' where id in (3,4))
+SELECT;
+SELECT * FROM ivm_rls2 ORDER BY 1,2,3;
+
+-- automatic index creation
+CREATE TABLE base_a (i int primary key, j int);
+CREATE TABLE base_b (i int primary key, j int);
+
+--- group by: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx1 AS SELECT i, sum(j) FROM base_a GROUP BY i;
+
+--- distinct: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx2 AS SELECT DISTINCT j FROM base_a;
+
+--- with all pkey columns: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx3(i_a, i_b) AS SELECT a.i, b.i FROM base_a a, base_b b;
+
+--- missing some pkey columns: no index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx4 AS SELECT j FROM base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx5 AS SELECT a.i, b.j FROM base_a a, base_b b;
+
+-- cleanup
+
+DROP TABLE rls_tbl CASCADE;
+DROP TABLE num_tbl CASCADE;
+DROP USER ivm_user;
+DROP USER ivm_admin;
+
+DROP TABLE mv_base_b CASCADE;
+DROP TABLE mv_base_a CASCADE;
--
2.25.1
v29-0011-Add-documentations-about-Incremental-View-Mainte.patchtext/x-diff; name=v29-0011-Add-documentations-about-Incremental-View-Mainte.patchDownload
From 1e62b83fb2b6002ac690eae0b71262940bc23bf9 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:25:34 +0900
Subject: [PATCH v29 11/11] Add documentations about Incremental View
Maintenance
---
doc/src/sgml/catalogs.sgml | 9 +
.../sgml/ref/create_materialized_view.sgml | 124 ++++-
.../sgml/ref/refresh_materialized_view.sgml | 8 +-
doc/src/sgml/rules.sgml | 437 ++++++++++++++++++
doc/src/sgml/system-views.sgml | 9 +
5 files changed, 583 insertions(+), 4 deletions(-)
diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index d17ff51e28..3de3303cac 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -2224,6 +2224,15 @@ SCRAM-SHA-256$<replaceable><iteration count></replaceable>:<replaceable>&l
</para></entry>
</row>
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>relisivm</structfield> <type>bool</type>
+ </para>
+ <para>
+ True if relation is incrementally maintainable materialized view
+ </para></entry>
+ </row>
+
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>relrewrite</structfield> <type>oid</type>
diff --git a/doc/src/sgml/ref/create_materialized_view.sgml b/doc/src/sgml/ref/create_materialized_view.sgml
index 0d2fea2b97..8c574062db 100644
--- a/doc/src/sgml/ref/create_materialized_view.sgml
+++ b/doc/src/sgml/ref/create_materialized_view.sgml
@@ -21,7 +21,7 @@ PostgreSQL documentation
<refsynopsisdiv>
<synopsis>
-CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
+CREATE [ INCREMENTAL ] MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
[ (<replaceable>column_name</replaceable> [, ...] ) ]
[ USING <replaceable class="parameter">method</replaceable> ]
[ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
@@ -60,6 +60,125 @@ CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
<title>Parameters</title>
<variablelist>
+ <varlistentry>
+ <term><literal>INCREMENTAL</literal></term>
+ <listitem>
+ <para>
+ If specified, some triggers are automatically created so that the rows
+ of the materialized view are immediately updated when base tables of the
+ materialized view are updated. In general, this allows faster update of
+ the materialized view at a price of slower update of the base tables
+ because the triggers will be invoked. We call this form of materialized
+ view as "Incrementally Maintainable Materialized View" (IMMV).
+ </para>
+ <para>
+ When <acronym>IMMV</acronym> is defined without using <command>WITH NO DATA</command>,
+ a unique index is created on the view automatically if possible. If the view
+ definition query has a GROUP BY clause, a unique index is created on the columns
+ of GROUP BY expressions. Also, if the view has DISTINCT clause, a unique index
+ is created on all columns in the target list. Otherwise, if the view contains all
+ primary key attritubes of its base tables in the target list, a unique index is
+ created on these attritubes. In other cases, no index is created.
+ </para>
+ <para>
+ There are restrictions of query definitions allowed to use this
+ option. The following are supported in query definitions for IMMV:
+ <itemizedlist>
+
+ <listitem>
+ <para>
+ Inner joins (including self-joins).
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Some built-in aggregate functions (count, sum, avg, min, max) without a HAVING
+ clause.
+ </para>
+ </listitem>
+ </itemizedlist>
+
+ Unsupported queries with this option include the following:
+
+ <itemizedlist>
+ <listitem>
+ <para>
+ Outer joins.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Sub-queries.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Aggregate functions other than built-in count, sum, avg, min and max.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ Aggregate functions with a HAVING clause.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ DISTINCT ON, WINDOW, VALUES, LIMIT and OFFSET clause.
+ </para>
+ </listitem>
+ </itemizedlist>
+
+ Other restrictions include:
+ <itemizedlist>
+
+ <listitem>
+ <para>
+ IMMVs must be based on simple base tables. It's not supported to
+ create them on top of views or materialized views.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ It is not supported to include system columns in an IMMV.
+ <programlisting>
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+ERROR: system column is not supported with IVM
+ </programlisting>
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Non-immutable functions are not supported.
+ <programlisting>
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+ERROR: functions in IMMV must be marked IMMUTABLE
+ </programlisting>
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ IMMVs do not support expressions that contains aggregates
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Logical replication does not support IMMVs.
+ </para>
+ </listitem>
+
+ </itemizedlist>
+
+ </para>
+ </listitem>
+ </varlistentry>
+
<varlistentry>
<term><literal>IF NOT EXISTS</literal></term>
<listitem>
@@ -155,7 +274,8 @@ CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
This clause specifies whether or not the materialized view should be
populated at creation time. If not, the materialized view will be
flagged as unscannable and cannot be queried until <command>REFRESH
- MATERIALIZED VIEW</command> is used.
+ MATERIALIZED VIEW</command> is used. Also, if the view is IMMV,
+ triggers for maintaining the view are not created.
</para>
</listitem>
</varlistentry>
diff --git a/doc/src/sgml/ref/refresh_materialized_view.sgml b/doc/src/sgml/ref/refresh_materialized_view.sgml
index 675d6090f3..c29cfc19b6 100644
--- a/doc/src/sgml/ref/refresh_materialized_view.sgml
+++ b/doc/src/sgml/ref/refresh_materialized_view.sgml
@@ -35,9 +35,13 @@ REFRESH MATERIALIZED VIEW [ CONCURRENTLY ] <replaceable class="parameter">name</
owner of the materialized view. The old contents are discarded. If
<literal>WITH DATA</literal> is specified (or defaults) the backing query
is executed to provide the new data, and the materialized view is left in a
- scannable state. If <literal>WITH NO DATA</literal> is specified no new
+ scannable state. If the view is an incrementally maintainable materialized
+ view (IMMV) and was 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 <literal>WITH NO DATA</literal> is specified no new
data is generated and the materialized view is left in an unscannable
- state.
+ state. If the view is IMMV, the triggers are dropped.
</para>
<para>
<literal>CONCURRENTLY</literal> and <literal>WITH NO DATA</literal> may not
diff --git a/doc/src/sgml/rules.sgml b/doc/src/sgml/rules.sgml
index d229b94d39..22e4cad103 100644
--- a/doc/src/sgml/rules.sgml
+++ b/doc/src/sgml/rules.sgml
@@ -1096,6 +1096,443 @@ SELECT word FROM words ORDER BY word <-> 'caterpiler' LIMIT 10;
</sect1>
+<sect1 id="rules-ivm">
+<title>Incremental View Maintenance</title>
+
+<indexterm zone="rules-ivm">
+ <primary>incremental view maintenance</primary>
+</indexterm>
+
+<indexterm zone="rules-ivm">
+ <primary>materialized view</primary>
+ <secondary>incremental view maintenance</secondary>
+</indexterm>
+
+<indexterm zone="rules-ivm">
+ <primary>view</primary>
+ <secondary>incremental view maintenance</secondary>
+</indexterm>
+
+<sect2 id="rules-ivm-overview">
+<title>Overview</title>
+
+<para>
+ Incremental View Maintenance (<acronym>IVM</acronym>) is a way to make
+ materialized views up-to-date in which only incremental changes are computed
+ and applied on views rather than recomputing the contents from scratch as
+ <command>REFRESH MATERIALIZED VIEW</command> does. <acronym>IVM</acronym>
+ can update materialized views more efficiently than recomputation when only
+ small parts of the view are changed.
+</para>
+
+<para>
+ There are two approaches with regard to timing of view maintenance:
+ immediate and deferred. In immediate maintenance, views are updated in the
+ same transaction that its base table is modified. In deferred maintenance,
+ views are updated after the transaction is committed, for example, when the
+ view is accessed, as a response to user command like <command>REFRESH
+ MATERIALIZED VIEW</command>, or periodically in background, and so on.
+ <productname>PostgreSQL</productname> currently implements only a kind of
+ immediate maintenance, in which materialized views are updated immediately
+ in AFTER triggers when a base table is modified.
+</para>
+
+<para>
+ To create materialized views supporting <acronym>IVM</acronym>, use the
+ <command>CREATE INCREMENTAL MATERIALIZED VIEW</command>, for example:
+<programlisting>
+CREATE <emphasis>INCREMENTAL</emphasis> MATERIALIZED VIEW mymatview AS SELECT * FROM mytab;
+</programlisting>
+ When a materialized view is created with the <literal>INCREMENTAL</literal>
+ keyword, some triggers are automatically created so that the view's contents are
+ immediately updated when its base tables are modified. We call this form
+ of materialized view an Incrementally Maintainable Materialized View
+ (<acronym>IMMV</acronym>).
+<programlisting>
+postgres=# CREATE INCREMENTAL MATERIALIZED VIEW m AS SELECT * FROM t0;
+NOTICE: could not create an index on materialized view "m" automatically
+HINT: Create an index on the materialized view for effcient incremental maintenance.
+SELECT 3
+postgres=# SELECT * FROM m;
+ i
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+postgres=# INSERT INTO t0 VALUES (4);
+INSERT 0 1
+postgres=# SELECT * FROM m; -- automatically updated
+ i
+---
+ 1
+ 2
+ 3
+ 4
+(4 rows)
+</programlisting>
+</para>
+
+<para>
+ Some <acronym>IMMV</acronym>s have hidden columns which are added
+ automatically when a materialized view is created. Their name starts
+ with <literal>__ivm_</literal> and they contain information required
+ for maintaining the <acronym>IMMV</acronym>. Such columns are not visible
+ when the <acronym>IMMV</acronym> is accessed by <literal>SELECT *</literal>
+ but are visible if the column name is explicitly specified in the target
+ list. We can also see the hidden columns in <literal>\d</literal>
+ meta-commands of <command>psql</command> commands.
+</para>
+
+<para>
+ In general, <acronym>IMMV</acronym>s allow faster updates of materialized
+ views at the price of slower updates to their base tables. Updates of
+ <acronym>IMMV</acronym> is slower because triggers will be invoked and the
+ view is updated in triggers per modification statement.
+</para>
+
+<para>
+ For example, suppose a normal materialized view defined as below:
+
+<programlisting>
+test=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm AS
+ SELECT a.aid, b.bid, a.abalance, b.bbalance
+ FROM pgbench_accounts a JOIN pgbench_branches b USING(bid);
+SELECT 10000000
+
+</programlisting>
+
+ Updating a tuple in a base table of this materialized view is rapid but the
+ <command>REFRESH MATERIALIZED VIEW</command> command on this view takes a long time:
+
+<programlisting>
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 0.990 ms
+
+test=# REFRESH MATERIALIZED VIEW mv_normal ;
+REFRESH MATERIALIZED VIEW
+Time: 33533.952 ms (00:33.534)
+</programlisting>
+</para>
+
+<para>
+ On the other hand, after creating <acronym>IMMV</acronym> with the same view
+ definition as below:
+
+<programlisting>
+test=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm AS
+ SELECT a.aid, b.bid, a.abalance, b.bbalance
+ FROM pgbench_accounts a JOIN pgbench_branches b USING(bid);
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+NOTICE: created index "mv_ivm_index" on materialized view "mv_ivm"
+</programlisting>
+
+ updating a tuple in a base table takes more than the normal view,
+ but its content is updated automatically and this is faster than the
+ <command>REFRESH MATERIALIZED VIEW</command> command.
+
+<programlisting>
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 13.068 ms
+</programlisting>
+
+</para>
+
+<para>
+ Appropriate indexes on <acronym>IMMV</acronym>s are necessary for
+ efficient <acronym>IVM</acronym> because it looks for tuples to be
+ updated in <acronym>IMMV</acronym>. If there are no indexes, it
+ will take a long time.
+</para>
+
+<para>
+ Therefore, when <acronym>IMMV</acronym> is defined, a unique index is created on the view
+ automatically if possible. If the view definition query has a GROUP BY clause, a unique
+ index is created on the columns of GROUP BY expressions. Also, if the view has DISTINCT
+ clause, a unique index is created on all columns in the target list. Otherwise, if the
+ view contains all primary key attritubes of its base tables in the target list, a unique
+ index is created on these attritubes. In other cases, no index is created.
+</para>
+
+<para>
+ In the previous example, a unique index "mv_ivm_index" is created on aid and bid
+ columns of materialized view "mv_ivm", and this enables the rapid update of the view.
+ Dropping this index make updating the view take a loger time.
+<programlisting>
+test=# DROP INDEX mv_ivm_index;
+DROP INDEX
+Time: 67.081 ms
+
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 16386.245 ms (00:16.386)
+</programlisting>
+
+</para>
+
+<para>
+ <acronym>IVM</acronym> is effective when we want to keep a materialized
+ view up-to-date and small fraction of a base table is modified
+ infrequently. Due to the overhead of immediate maintenance, <acronym>IVM</acronym>
+ 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, <acronym>IVM</acronym> is not effective and the cost of
+ maintenance can be larger than the <command>REFRESH MATERIALIZED VIEW</command>
+ command. In such situation, we can use <command>REFRESH MATERIALIZED VIEW</command>
+ and specify <literal>WITH NO DATA</literal> to disable immediate
+ maintenance before modifying a base table. After a base table modification,
+ execute the <command>REFRESH MATERIALIZED VIEW</command> (with <literal>WITH DATA</literal>)
+ command to refresh the view data and enable immediate maintenance.
+</para>
+
+</sect2>
+
+<sect2 id="rules-ivm-support">
+<title>Supported View Definitions and Restrictions</title>
+
+<para>
+ Currently, we can create <acronym>IMMV</acronym>s using inner joins, and some
+ aggregates. However, several restrictions apply to the definition of IMMV.
+</para>
+
+<sect3 id="rules-ivm-support-joins">
+<title>Joins</title>
+<para>
+ Inner joins including self-join are supported. Outer joins are not supported.
+</para>
+</sect3>
+
+<sect3 id="rules-ivm-support-aggregates">
+<title>Aggregates</title>
+<para>
+ Supported aggregate functions are <function>count</function>, <function>sum</function>,
+ <function>avg</function>, <function>min</function>, and <function>max</function>.
+ Currently, only built-in aggregate functions are supported and user defined
+ aggregates cannot be used. When a base table is modified, the new aggregated
+ values are incrementally calculated using the old aggregated values and values
+ of related hidden columns stored in <acronym>IMMV</acronym>.
+</para>
+
+<para>
+ Note that for <function>min</function> or <function>max</function>, the new values
+ could be re-calculated from base tables with regard to the affected groups when a
+ tuple containing the current minimal or maximal values are deleted from a base table.
+ Therefore, it can takes a long time to update an <acronym>IMMV</acronym> containing
+ these functions.
+</para>
+
+<para>
+ Also note that using <function>sum</function> or <function>avg</function> on
+ <type>real</type> (<type>float4</type>) type or <type>double precision</type>
+ (<type>float8</type>) type in <acronym>IMMV</acronym> is unsafe. This is
+ because aggregated values in <acronym>IMMV</acronym> can become different from
+ results calculated from base tables due to the limited precision of these types.
+ To avoid this problem, use the <type>numeric</type> type instead.
+</para>
+
+ <sect4 id="rules-ivm-restrictions-aggregates">
+ <title>Restrictions on Aggregates</title>
+ <para>
+ There are the following restrictions:
+ <itemizedlist>
+ <listitem>
+ <para>
+ If we have a <literal>GROUP BY</literal> clause, expressions specified in
+ <literal>GROUP BY</literal> must appear in the target list. This is
+ how tuples to be updated in the <acronym>IMMV</acronym> are identified.
+ These attributes are used as scan keys for searching tuples in the
+ <acronym>IMMV</acronym>, so indexes on them are required for efficient
+ <acronym>IVM</acronym>.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <literal>HAVING</literal> clause cannot be used.
+ </para>
+ </listitem>
+ </itemizedlist>
+ </para>
+ </sect4>
+</sect3>
+
+<sect3 id="rules-ivm-general-restricitons">
+<title>Other General Restrictions</title>
+<para>
+ There are other restrictions which generally apply to <acronym>IMMV</acronym>:
+ <itemizedlist>
+ <listitem>
+ <para>
+ Sub-queries cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ CTEs cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Window functions cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s must be based on simple base tables. It's not
+ supported to create them on top of views, materialized views, foreign tables, inhe.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ LIMIT and OFFSET clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s cannot contain system columns.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s cannot contain non-immutable functions.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ UNION/INTERSECT/EXCEPT clauses cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ DISTINCT ON clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ TABLESAMPLE parameter cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ inheritance parent tables cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ VALUES clause cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <literal>GROUPING SETS</literal> and <literal>FILTER</literal> clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ FOR UPDATE/SHARE cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ targetlist cannot contain columns whose name start with <literal>__ivm_</literal>.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ targetlist cannot contain expressions which contain an aggregate in it.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Logical replication is not supported, that is, even when a base table
+ at a publisher node is modified, <acronym>IMMV</acronym>s at subscriber
+ nodes are not updated.
+ </para>
+ </listitem>
+
+ </itemizedlist>
+</para>
+</sect3>
+
+</sect2>
+
+<sect2 id="rules-ivm-distinct">
+<title><literal>DISTINCT</literal></title>
+
+<para>
+ <productname>PostgreSQL</productname> supports <acronym>IMMV</acronym> with
+ <literal>DISTINCT</literal>. For example, suppose a <acronym>IMMV</acronym>
+ defined with <literal>DISTINCT</literal> on a base table containing duplicate
+ tuples. When tuples are deleted from the base table, a tuple in the view is
+ deleted if and only if the multiplicity of the tuple becomes zero. Moreover,
+ when tuples are inserted into the base table, a tuple is inserted into the
+ view only if the same tuple doesn't already exist in it.
+</para>
+
+<para>
+ Physically, an <acronym>IMMV</acronym> defined with <literal>DISTINCT</literal>
+ contains tuples after eliminating duplicates, and the multiplicity of each tuple
+ is stored in a hidden column named <literal>__ivm_count__</literal>.
+</para>
+</sect2>
+
+<sect2 id="rules-ivm-concurrent-transactions">
+<title>Concurrent Transactions</title>
+<para>
+ Suppose an <acronym>IMMV</acronym> is defined on two base tables and each
+ table was modified in different a concurrent transaction simultaneously.
+ In the transaction which was committed first, <acronym>IMMV</acronym> can
+ be updated considering only the change which happened in this transaction.
+ On the other hand, in order to update the view correctly in the transaction
+ which was committed later, we need to know the changes occurred in
+ both transactions. For this reason, <literal>ExclusiveLock</literal>
+ is held on an <acronym>IMMV</acronym> immediately after a base table is
+ modified in <literal>READ COMMITTED</literal> mode to make sure that
+ the <acronym>IMMV</acronym> is updated in the latter transaction after
+ the former transaction is committed. In <literal>REPEATABLE READ</literal>
+ or <literal>SERIALIZABLE</literal> mode, an error is raised immediately
+ if lock acquisition fails because any changes which occurred in
+ other transactions are not be visible in these modes and
+ <acronym>IMMV</acronym> cannot be updated correctly in such situations.
+ However, as an exception if the view has only one base table and
+ <command>INSERT</command> is performed on the table,
+ the lock held on thew view is <literal>RowExclusiveLock</literal>.
+</para>
+</sect2>
+
+<sect2 id="rules-ivm-rls">
+<title>Row Level Security</title>
+<para>
+ If some base tables have row level security policy, rows that are not visible
+ to the materialized view's owner are excluded from the result. In addition, such
+ rows are excluded as well when views are incrementally maintained. However, if a
+ new policy is defined or policies are changed after the materialized view was created,
+ the new policy will not be applied to the view contents. To apply the new policy,
+ you need to refresh materialized views.
+</para>
+</sect2>
+
+</sect1>
+
<sect1 id="rules-update">
<title>Rules on <command>INSERT</command>, <command>UPDATE</command>, and <command>DELETE</command></title>
diff --git a/doc/src/sgml/system-views.sgml b/doc/src/sgml/system-views.sgml
index 2b35c2f91b..5366f707eb 100644
--- a/doc/src/sgml/system-views.sgml
+++ b/doc/src/sgml/system-views.sgml
@@ -1787,6 +1787,15 @@ SELECT * FROM pg_locks pl LEFT JOIN pg_prepared_xacts ppx
</para></entry>
</row>
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>isimmv</structfield> <type>bool</type>
+ </para>
+ <para>
+ True if materialized view is incrementally maintainable
+ </para></entry>
+ </row>
+
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>definition</structfield> <type>text</type>
--
2.25.1
hi
based on v29.
based on https://stackoverflow.com/a/4014981/1560347:
I added a new function append_update_set_caluse, and deleted
functions: {append_set_clause_for_count, append_set_clause_for_sum,
append_set_clause_for_avg, append_set_clause_for_minmax}
I guess this way is more extensible/generic than yours.
replaced the following code with the generic function: append_update_set_caluse.
+ /* For views with aggregates, we need to build SET clause for
updating aggregate
+ * values. */
+ if (query->hasAggs && IsA(tle->expr, Aggref))
+ {
+ Aggref *aggref = (Aggref *) tle->expr;
+ const char *aggname = get_func_name(aggref->aggfnoid);
+
+ /*
+ * We can use function names here because it is already checked if these
+ * can be used in IMMV by its OID at the definition time.
+ */
+
+ /* count */
+ if (!strcmp(aggname, "count"))
+ append_set_clause_for_count(resname, aggs_set_old, aggs_set_new,
aggs_list_buf);
+
+ /* sum */
+ else if (!strcmp(aggname, "sum"))
+ append_set_clause_for_sum(resname, aggs_set_old, aggs_set_new, aggs_list_buf);
+
+ /* avg */
+ else if (!strcmp(aggname, "avg"))
+ append_set_clause_for_avg(resname, aggs_set_old, aggs_set_new, aggs_list_buf,
+ format_type_be(aggref->aggtype));
+
+ else
+ elog(ERROR, "unsupported aggregate function: %s", aggname);
+ }
----------------------<<<
attached is my refactor. there is some whitespace errors in the
patches, you need use
git apply --reject --whitespace=fix
basedon_v29_matview_c_refactor_update_set_clause.patch
Also you patch cannot use git apply, i finally found out bulk apply
using gnu patch from
https://serverfault.com/questions/102324/apply-multiple-patch-files.
previously I just did it manually one by one.
I think if you use { for i in $PATCHES/v29*.patch; do patch -p1 < $i;
done } GNU patch, it will generate an .orig file for every modified
file?
-----------------<<<<<
src/backend/commands/matview.c
2268: /* For tuple deletion */
maybe "/* For tuple deletion and update*/" is more accurate?
-----------------<<<<<
currently at here: src/test/regress/sql/incremental_matview.sql
98: -- support SUM(), COUNT() and AVG() aggregate functions
99: BEGIN;
100: CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i,
SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i;
101: SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
102: INSERT INTO mv_base_a VALUES(2,100);
src/backend/commands/matview.c
2858: if (SPI_exec(querybuf.data, 0) != SPI_OK_INSERT)
2859: elog(ERROR, "SPI_exec failed: %s", querybuf.data);
then I debug, print out querybuf.data:
WITH updt AS (UPDATE public.mv_ivm_agg AS mv SET __ivm_count__ =
mv.__ivm_count__ OPERATOR(pg_catalog.+) diff.__ivm_count__ , sum =
(CASE WHEN mv.__ivm_count_sum__ OPERATOR(pg_catalog.=) 0 AND
diff.__ivm_count_sum__ OPERATOR(pg_catalog.=) 0 THEN NULL WHEN mv.sum
IS NULL THEN diff.sum WHEN diff.sum IS NULL THEN mv.sum ELSE (mv.sum
OPERATOR(pg_catalog.+) diff.sum) END), __ivm_count_sum__ =
(mv.__ivm_count_sum__ OPERATOR(pg_catalog.+) diff.__ivm_count_sum__),
count = (mv.count OPERATOR(pg_catalog.+) diff.count), avg = (CASE WHEN
mv.__ivm_count_avg__ OPERATOR(pg_catalog.=) 0 AND
diff.__ivm_count_avg__ OPERATOR(pg_catalog.=) 0 THEN NULL WHEN
mv.__ivm_sum_avg__ IS NULL THEN diff.__ivm_sum_avg__ WHEN
diff.__ivm_sum_avg__ IS NULL THEN mv.__ivm_sum_avg__ ELSE
(mv.__ivm_sum_avg__ OPERATOR(pg_catalog.+)
diff.__ivm_sum_avg__)::numeric END) OPERATOR(pg_catalog./)
(mv.__ivm_count_avg__ OPERATOR(pg_catalog.+) diff.__ivm_count_avg__),
__ivm_sum_avg__ = (CASE WHEN mv.__ivm_count_avg__
OPERATOR(pg_catalog.=) 0 AND diff.__ivm_count_avg__
OPERATOR(pg_catalog.=) 0 THEN NULL WHEN mv.__ivm_sum_avg__ IS NULL
THEN diff.__ivm_sum_avg__ WHEN diff.__ivm_sum_avg__ IS NULL THEN
mv.__ivm_sum_avg__ ELSE (mv.__ivm_sum_avg__ OPERATOR(pg_catalog.+)
diff.__ivm_sum_avg__) END), __ivm_count_avg__ = (mv.__ivm_count_avg__
OPERATOR(pg_catalog.+) diff.__ivm_count_avg__) FROM new_delta AS diff
WHERE (mv.i OPERATOR(pg_catalog.=) diff.i OR (mv.i IS NULL AND diff.i
IS NULL)) RETURNING mv.i) INSERT INTO public.mv_ivm_agg (i, sum,
count, avg, __ivm_count_sum__, __ivm_count_avg__, __ivm_sum_avg__,
__ivm_count__) SELECT i, sum, count, avg, __ivm_count_sum__,
__ivm_count_avg__, __ivm_sum_avg__, __ivm_count__ FROM new_delta AS
diff WHERE NOT EXISTS (SELECT 1 FROM updt AS mv WHERE (mv.i
OPERATOR(pg_catalog.=) diff.i OR (mv.i IS NULL AND diff.i IS NULL)));
At this final SPI_exec, we have a update statement with related
columns { __ivm_count_sum__, sum, __ivm_count__, count, avg,
__ivm_sum_avg__, __ivm_count_avg__}. At this time, my mind stops
working, querybuf.data is way too big, but I still feel like there is
some logic associated with these columns, maybe we can use it as an
assertion to prove that this query (querybuf.len = 1834) is indeed
correct.
Since the apply delta query is quite complex, I feel like adding some
"if debug then print out the final querybuf.data end if" would be a
good idea.
we add hidden columns somewhere, also to avoid corner cases, so maybe
somewhere we should assert total attribute number is sane.
Attachments:
basedon_v29_matview_c_refactor_update_set_clause.patchtext/x-patch; charset=US-ASCII; name=basedon_v29_matview_c_refactor_update_set_clause.patchDownload
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index eff512d4..33f385cb 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -149,12 +149,39 @@ typedef enum
IVM_SUB
} IvmOp;
+typedef enum
+{
+ BAD_AGGFUNC,
+ IVM_COUNT,
+ IVM_SUM,
+ IVM_AVG,
+ IVM_MIN,
+ IVM_MAX
+} IvmAggType;
+
+typedef struct aggname_entry
+{
+ const char *agg_name;
+ int val;
+} aggname_entry;
+
+/* map aggregate name with enum */
+static aggname_entry ivm_agg_lookup[] =
+{
+ { "count",IVM_COUNT},
+ { "sum", IVM_SUM},
+ { "avg", IVM_AVG},
+ { "min",IVM_MIN},
+ { "max",IVM_MAX}
+};
+
/* ENR name for materialized view delta */
#define NEW_DELTA_ENRNAME "new_delta"
#define OLD_DELTA_ENRNAME "old_delta"
static int matview_maintenance_depth = 0;
+static int get_ivm_aggfunc(const char *agg_name);
static void transientrel_startup(DestReceiver *self, int operation, TupleDesc typeinfo);
static bool transientrel_receive(TupleTableSlot *slot, DestReceiver *self);
static void transientrel_shutdown(DestReceiver *self);
@@ -191,16 +218,7 @@ static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *
static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
Query *query, bool use_count, char *count_colname);
-static void append_set_clause_for_count(const char *resname, StringInfo buf_old,
- StringInfo buf_new,StringInfo aggs_list);
-static void append_set_clause_for_sum(const char *resname, StringInfo buf_old,
- StringInfo buf_new, StringInfo aggs_list);
-static void append_set_clause_for_avg(const char *resname, StringInfo buf_old,
- StringInfo buf_new, StringInfo aggs_list,
- const char *aggtype);
-static void append_set_clause_for_minmax(const char *resname, StringInfo buf_old,
- StringInfo buf_new, StringInfo aggs_list,
- bool is_min);
+
static char *get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
const char* count_col, const char *castType);
static char *get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
@@ -235,6 +253,25 @@ static void mv_HashPreparedPlan(MV_QueryKey *key, SPIPlanPtr plan);
static void mv_BuildQueryKey(MV_QueryKey *key, Oid matview_id, int32 query_type);
static void clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort);
+static void append_update_set_caluse(const char *aggname, char *resname, StringInfo buf_old,
+ StringInfo buf_new,StringInfo aggs_list,
+ char *aggtype);
+
+int
+get_ivm_aggfunc(const char *agg_name)
+{
+#define NKEYS (sizeof(ivm_agg_lookup)/sizeof(aggname_entry))
+
+ int i;
+ for (i=0; i < NKEYS; i++)
+ {
+ aggname_entry *entry = &ivm_agg_lookup[i];
+ if (strcmp(entry->agg_name, agg_name) == 0)
+ return entry->val;
+ }
+ return BAD_AGGFUNC;
+}
+
/*
* SetMatViewPopulatedState
* Mark a materialized view as populated, or not.
@@ -2210,38 +2247,23 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
{
Aggref *aggref = (Aggref *) tle->expr;
const char *aggname = get_func_name(aggref->aggfnoid);
+ char *aggtype = format_type_be(aggref->aggtype);
/*
* We can use function names here because it is already checked if these
* can be used in IMMV by its OID at the definition time.
*/
-
- /* count */
- if (!strcmp(aggname, "count"))
- append_set_clause_for_count(resname, aggs_set_old, aggs_set_new, aggs_list_buf);
-
- /* sum */
- else if (!strcmp(aggname, "sum"))
- append_set_clause_for_sum(resname, aggs_set_old, aggs_set_new, aggs_list_buf);
-
- /* avg */
- else if (!strcmp(aggname, "avg"))
- append_set_clause_for_avg(resname, aggs_set_old, aggs_set_new, aggs_list_buf,
- format_type_be(aggref->aggtype));
-
- /* min/max */
- else if (!strcmp(aggname, "min") || !strcmp(aggname, "max"))
+ (void) append_update_set_caluse(aggname, resname, aggs_set_old,
+ aggs_set_new, aggs_list_buf, aggtype);
+
+ if (!strcmp(aggname, "min") || !strcmp(aggname, "max"))
{
bool is_min = (!strcmp(aggname, "min"));
- append_set_clause_for_minmax(resname, aggs_set_old, aggs_set_new, aggs_list_buf, is_min);
-
/* make a resname list of min and max aggregates */
minmax_list = lappend(minmax_list, resname);
is_min_list = lappend_int(is_min_list, is_min);
}
- else
- elog(ERROR, "unsupported aggregate function: %s", aggname);
}
}
@@ -2338,224 +2360,6 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_finish failed");
}
-/*
- * append_set_clause_for_count
- *
- * Append SET clause string for count aggregation to given buffers.
- * Also, append resnames required for calculating the aggregate value.
- */
-static void
-append_set_clause_for_count(const char *resname, StringInfo buf_old,
- StringInfo buf_new,StringInfo aggs_list)
-{
- /* For tuple deletion */
- if (buf_old)
- {
- /* resname = mv.resname - t.resname */
- appendStringInfo(buf_old,
- ", %s = %s",
- quote_qualified_identifier(NULL, resname),
- get_operation_string(IVM_SUB, resname, "mv", "t", NULL, NULL));
- }
- /* For tuple insertion */
- if (buf_new)
- {
- /* resname = mv.resname + diff.resname */
- appendStringInfo(buf_new,
- ", %s = %s",
- quote_qualified_identifier(NULL, resname),
- get_operation_string(IVM_ADD, resname, "mv", "diff", NULL, NULL));
- }
-
- appendStringInfo(aggs_list, ", %s",
- quote_qualified_identifier("diff", resname)
- );
-}
-
-/*
- * append_set_clause_for_sum
- *
- * Append SET clause string for sum aggregation to given buffers.
- * Also, append resnames required for calculating the aggregate value.
- */
-static void
-append_set_clause_for_sum(const char *resname, StringInfo buf_old,
- StringInfo buf_new, StringInfo aggs_list)
-{
- char *count_col = IVM_colname("count", resname);
-
- /* For tuple deletion */
- if (buf_old)
- {
- /* sum = mv.sum - t.sum */
- appendStringInfo(buf_old,
- ", %s = %s",
- quote_qualified_identifier(NULL, resname),
- get_operation_string(IVM_SUB, resname, "mv", "t", count_col, NULL)
- );
- /* count = mv.count - t.count */
- appendStringInfo(buf_old,
- ", %s = %s",
- quote_qualified_identifier(NULL, count_col),
- get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
- );
- }
- /* For tuple insertion */
- if (buf_new)
- {
- /* sum = mv.sum + diff.sum */
- appendStringInfo(buf_new,
- ", %s = %s",
- quote_qualified_identifier(NULL, resname),
- get_operation_string(IVM_ADD, resname, "mv", "diff", count_col, NULL)
- );
- /* count = mv.count + diff.count */
- appendStringInfo(buf_new,
- ", %s = %s",
- quote_qualified_identifier(NULL, count_col),
- get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
- );
- }
-
- appendStringInfo(aggs_list, ", %s, %s",
- quote_qualified_identifier("diff", resname),
- quote_qualified_identifier("diff", IVM_colname("count", resname))
- );
-}
-
-/*
- * append_set_clause_for_avg
- *
- * Append SET clause string for avg aggregation to given buffers.
- * Also, append resnames required for calculating the aggregate value.
- */
-static void
-append_set_clause_for_avg(const char *resname, StringInfo buf_old,
- StringInfo buf_new, StringInfo aggs_list,
- const char *aggtype)
-{
- char *sum_col = IVM_colname("sum", resname);
- char *count_col = IVM_colname("count", resname);
-
- /* For tuple deletion */
- if (buf_old)
- {
- /* avg = (mv.sum - t.sum)::aggtype / (mv.count - t.count) */
- appendStringInfo(buf_old,
- ", %s = %s OPERATOR(pg_catalog./) %s",
- quote_qualified_identifier(NULL, resname),
- get_operation_string(IVM_SUB, sum_col, "mv", "t", count_col, aggtype),
- get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
- );
- /* sum = mv.sum - t.sum */
- appendStringInfo(buf_old,
- ", %s = %s",
- quote_qualified_identifier(NULL, sum_col),
- get_operation_string(IVM_SUB, sum_col, "mv", "t", count_col, NULL)
- );
- /* count = mv.count - t.count */
- appendStringInfo(buf_old,
- ", %s = %s",
- quote_qualified_identifier(NULL, count_col),
- get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
- );
-
- }
- /* For tuple insertion */
- if (buf_new)
- {
- /* avg = (mv.sum + diff.sum)::aggtype / (mv.count + diff.count) */
- appendStringInfo(buf_new,
- ", %s = %s OPERATOR(pg_catalog./) %s",
- quote_qualified_identifier(NULL, resname),
- get_operation_string(IVM_ADD, sum_col, "mv", "diff", count_col, aggtype),
- get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
- );
- /* sum = mv.sum + diff.sum */
- appendStringInfo(buf_new,
- ", %s = %s",
- quote_qualified_identifier(NULL, sum_col),
- get_operation_string(IVM_ADD, sum_col, "mv", "diff", count_col, NULL)
- );
- /* count = mv.count + diff.count */
- appendStringInfo(buf_new,
- ", %s = %s",
- quote_qualified_identifier(NULL, count_col),
- get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
- );
- }
-
- appendStringInfo(aggs_list, ", %s, %s, %s",
- quote_qualified_identifier("diff", resname),
- quote_qualified_identifier("diff", IVM_colname("sum", resname)),
- quote_qualified_identifier("diff", IVM_colname("count", resname))
- );
-}
-
-/*
- * append_set_clause_for_minmax
- *
- * Append SET clause string for min or max aggregation to given buffers.
- * Also, append resnames required for calculating the aggregate value.
- * is_min is true if this is min, false if not.
- */
-static void
-append_set_clause_for_minmax(const char *resname, StringInfo buf_old,
- StringInfo buf_new, StringInfo aggs_list,
- bool is_min)
-{
- char *count_col = IVM_colname("count", resname);
-
- /* For tuple deletion */
- if (buf_old)
- {
- /*
- * If the new value doesn't became NULL then use the value remaining
- * in the view although this will be recomputated afterwords.
- */
- appendStringInfo(buf_old,
- ", %s = CASE WHEN %s THEN NULL ELSE %s END",
- quote_qualified_identifier(NULL, resname),
- get_null_condition_string(IVM_SUB, "mv", "t", count_col),
- quote_qualified_identifier("mv", resname)
- );
- /* count = mv.count - t.count */
- appendStringInfo(buf_old,
- ", %s = %s",
- quote_qualified_identifier(NULL, count_col),
- get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
- );
- }
- /* For tuple insertion */
- if (buf_new)
- {
- /*
- * min = LEAST(mv.min, diff.min)
- * max = GREATEST(mv.max, diff.max)
- */
- appendStringInfo(buf_new,
- ", %s = CASE WHEN %s THEN NULL ELSE %s(%s,%s) END",
- quote_qualified_identifier(NULL, resname),
- get_null_condition_string(IVM_ADD, "mv", "diff", count_col),
-
- is_min ? "LEAST" : "GREATEST",
- quote_qualified_identifier("mv", resname),
- quote_qualified_identifier("diff", resname)
- );
- /* count = mv.count + diff.count */
- appendStringInfo(buf_new,
- ", %s = %s",
- quote_qualified_identifier(NULL, count_col),
- get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
- );
- }
-
- appendStringInfo(aggs_list, ", %s, %s",
- quote_qualified_identifier("diff", resname),
- quote_qualified_identifier("diff", IVM_colname("count", resname))
- );
-}
-
/*
* get_operation_string
*
@@ -3482,3 +3286,228 @@ isIvmName(const char *s)
return (strncmp(s, "__ivm_", 6) == 0);
return false;
}
+
+void
+append_update_set_caluse(const char *aggname, char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ char *aggtype)
+{
+ char *count_col = IVM_colname("count", resname);
+ char *sum_col = IVM_colname("sum", resname);
+
+ switch (get_ivm_aggfunc(aggname))
+ {
+ case IVM_COUNT:
+ if (buf_old)
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, resname, "mv", "t", NULL, NULL));
+
+ if (buf_new)
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, resname, "mv", "diff", NULL, NULL));
+
+ appendStringInfo(aggs_list, ", %s",
+ quote_qualified_identifier("diff", resname));
+ break;
+
+ case IVM_SUM:
+ if (buf_old)
+ {
+ /* sum = mv.sum - t.sum */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, resname, "mv", "t", count_col, NULL)
+ );
+
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ }
+
+ if (buf_new)
+ {
+ /* sum = mv.sum + diff.sum */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, resname, "mv", "diff", count_col, NULL)
+ );
+
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("count", resname)));
+ break;
+
+ case IVM_AVG:
+ if (buf_old)
+ {
+ /* avg = (mv.sum - t.sum)::aggtype / (mv.count - t.count) */
+ appendStringInfo(buf_old,
+ ", %s = %s OPERATOR(pg_catalog./) %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, sum_col, "mv", "t", count_col, aggtype),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+
+ /* sum = mv.sum - t.sum */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, sum_col),
+ get_operation_string(IVM_SUB, sum_col, "mv", "t", count_col, NULL)
+ );
+
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ }
+
+ if (buf_new)
+ {
+ /* avg = (mv.sum + diff.sum)::aggtype / (mv.count + diff.count) */
+ appendStringInfo(buf_new,
+ ", %s = %s OPERATOR(pg_catalog./) %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, sum_col, "mv", "diff", count_col, aggtype),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ /* sum = mv.sum + diff.sum */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, sum_col),
+ get_operation_string(IVM_ADD, sum_col, "mv", "diff", count_col, NULL)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("sum", resname)),
+ quote_qualified_identifier("diff", IVM_colname("count", resname)));
+
+ break;
+
+ case IVM_MIN:
+ if (buf_old)
+ {
+ /*
+ * If the new value doesn't became NULL then use the value remaining
+ * in the view although this will be recomputated afterwords.
+ */
+ appendStringInfo(buf_old,
+ ", %s = CASE WHEN %s THEN NULL ELSE %s END",
+ quote_qualified_identifier(NULL, resname),
+ get_null_condition_string(IVM_SUB, "mv", "t", count_col),
+ quote_qualified_identifier("mv", resname)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ }
+
+ if (buf_new)
+ {
+ /* min = LEAST(mv.min, diff.min) */
+ appendStringInfo(buf_new,
+ ", %s = CASE WHEN %s THEN NULL ELSE %s(%s,%s) END",
+ quote_qualified_identifier(NULL, resname),
+ get_null_condition_string(IVM_ADD, "mv", "diff", count_col),
+ "LEAST",
+ quote_qualified_identifier("mv", resname),
+ quote_qualified_identifier("diff", resname)
+ );
+
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+ appendStringInfo(aggs_list, ", %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("count", resname)));
+ break;
+
+ case IVM_MAX:
+ if (buf_old)
+ {
+ /*
+ * If the new value doesn't became NULL then use the value remaining
+ * in the view although this will be recomputated afterwords.
+ */
+ appendStringInfo(buf_old,
+ ", %s = CASE WHEN %s THEN NULL ELSE %s END",
+ quote_qualified_identifier(NULL, resname),
+ get_null_condition_string(IVM_SUB, "mv", "t", count_col),
+ quote_qualified_identifier("mv", resname)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ }
+
+ if (buf_new)
+ {
+ /* max = GREATEST(mv.max, diff.max) */
+ appendStringInfo(buf_new,
+ ", %s = CASE WHEN %s THEN NULL ELSE %s(%s,%s) END",
+ quote_qualified_identifier(NULL, resname),
+ get_null_condition_string(IVM_ADD, "mv", "diff", count_col),
+ "GREATEST",
+ quote_qualified_identifier("mv", resname),
+ quote_qualified_identifier("diff", resname)
+ );
+
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("count", resname)));
+ break;
+
+ case BAD_AGGFUNC:
+ elog(ERROR, "unsupported aggregate function: %s", aggname);
+ break;
+
+ default:
+ elog(ERROR, "unsupported aggregate function: %s", aggname);
+ break;
+ }
+ return;
+}
\ No newline at end of file
attached is my refactor. there is some whitespace errors in the
patches, you need use
git apply --reject --whitespace=fix
basedon_v29_matview_c_refactor_update_set_clause.patchAlso you patch cannot use git apply, i finally found out bulk apply
I have no problem with applying Yugo's v29 patches using git apply, no
white space errors.
$ git apply ~/v29*
(the patches are saved under my home directory).
I suggest you to check your email application whether it correctly
saved the patch files for you.
FYI, here are results from sha256sum:
ffac37cb455788c1105ffc01c6b606de75f53321c2f235f7efa19f3f52d12b9e v29-0001-Add-a-syntax-to-create-Incrementally-Maintainabl.patch
f684485e7c9ac1b2990943a3c73fa49a9091a268917547d9e116baef5118cca7 v29-0002-Add-relisivm-column-to-pg_class-system-catalog.patch
fcf5bc8ae562ed1c2ab397b499544ddab03ad2c3acb2263d0195a3ec799b131c v29-0003-Allow-to-prolong-life-span-of-transition-tables-.patch
a7a13ef8e73c4717166db079d5607f78d21199379de341a0e8175beef5ea1c1a v29-0004-Add-Incremental-View-Maintenance-support-to-pg_d.patch
a2aa51d035774867bfab1580ef14143998dc71c1b941bd1a3721dc019bc62649 v29-0005-Add-Incremental-View-Maintenance-support-to-psql.patch
fe0225d761a08eb80082f1a2c039b9b8b20626169b03abaf649db9c74fe99194 v29-0006-Add-Incremental-View-Maintenance-support.patch
68b007befedcf92fc83ab8c3347ac047a50816f061c77b69281e12d52944db82 v29-0007-Add-DISTINCT-support-for-IVM.patch
2201241a22095f736a17383fc8b26d48a459ebf1c2f5cf120896cfc0ce5e03e4 v29-0008-Add-aggregates-support-in-IVM.patch
6390117c559bf1585349c5a09b77b784e086ccc22eb530cd364ce78371c66741 v29-0009-Add-support-for-min-max-aggregates-for-IVM.patch
7019a116c64127783bd9c682ddf1ee3792286d0e41c91a33010111e7be2c9459 v29-0010-Add-regression-tests-for-Incremental-View-Mainte.patch
189afdc7da866bd958e2d554ba12adf93d7e6d0acb581290a48d72fcf640e243 v29-0011-Add-documentations-about-Incremental-View-Mainte.patch
Best reagards,
--
Tatsuo Ishii
SRA OSS LLC
English: http://www.sraoss.co.jp/index_en/
Japanese:http://www.sraoss.co.jp
On Sat, Sep 2, 2023 at 7:46 PM Tatsuo Ishii <ishii@sraoss.co.jp> wrote:
attached is my refactor. there is some whitespace errors in the
patches, you need use
git apply --reject --whitespace=fix
basedon_v29_matview_c_refactor_update_set_clause.patchAlso you patch cannot use git apply, i finally found out bulk apply
I have no problem with applying Yugo's v29 patches using git apply, no
white space errors.
thanks. I downloaded the patches from the postgres website, then the
problem was solved.
other ideas based on v29.
src/include/utils/rel.h
680: #define RelationIsIVM(relation) ((relation)->rd_rel->relisivm)
I guess it would be better to add some comments to address the usage.
Since all peer macros all have some comments.
pg_class change, I guess we need bump CATALOG_VERSION_NO?
small issue. makeIvmAggColumn and calc_delta need to add an empty
return statement?
style issue. in gram.y, "incremental" upper case?
+ CREATE OptNoLog incremental MATERIALIZED VIEW
create_mv_target AS SelectStmt opt_with_data
I don't know how pgident works, do you need to add some keywords to
src/tools/pgindent/typedefs.list to make indentation work?
in
/* If this is not the last AFTER trigger call, immediately exit. */
Assert (entry->before_trig_count >= entry->after_trig_count);
if (entry->before_trig_count != entry->after_trig_count)
return PointerGetDatum(NULL);
before returning NULL, do you also need clean_up_IVM_hash_entry? (I
don't know when this case will happen)
in
/* Replace the modified table with the new delta table and
calculate the new view delta*/
replace_rte_with_delta(rte, table, true, queryEnv);
refresh_matview_datafill(dest_new, query, queryEnv, tupdesc_new, "");
replace_rte_with_delta does not change the argument: table, argument:
queryEnv. refresh_matview_datafill just uses the partial argument of
the function calc_delta. So I guess, I am confused by the usage of
replace_rte_with_delta. also I think it should return void, since you
just modify the input argument. Here refresh_matview_datafill is just
persisting new delta content to dest_new?
2024-01 Commitfest.
Hi, This patch has a CF status of "Needs Review" [1]https://commitfest.postgresql.org/46/4337/, but it seems
like there was some CFbot test failure last time it was run [2]https://cirrus-ci.com/task/6607979311529984.
Please have a look and post an updated version if necessary.
======
[1]: https://commitfest.postgresql.org/46/4337/
[2]: https://cirrus-ci.com/task/6607979311529984
Kind Regards,
Peter Smith.
On Mon, 22 Jan 2024 13:51:08 +1100
Peter Smith <smithpb2250@gmail.com> wrote:
2024-01 Commitfest.
Hi, This patch has a CF status of "Needs Review" [1], but it seems
like there was some CFbot test failure last time it was run [2].
Please have a look and post an updated version if necessary.
Thank you for pointing out it. The CFbot failure is caused by
a post [1]/messages/by-id/CACJufxEoCCJE1vntJp1SWjen8vBUa3vZLgL=swPwar4zim976g@mail.gmail.com not by my patch-set, but regardless of it, I will
heck if we need rebase and send the new version if necessary soon.
[1]: /messages/by-id/CACJufxEoCCJE1vntJp1SWjen8vBUa3vZLgL=swPwar4zim976g@mail.gmail.com
Regards,
Yugo Nagata
======
[1] https://commitfest.postgresql.org/46/4337/
[2] https://cirrus-ci.com/task/6607979311529984Kind Regards,
Peter Smith.
--
Yugo NAGATA <nagata@sraoss.co.jp>
On Fri, 1 Sep 2023 15:42:17 +0800
jian he <jian.universality@gmail.com> wrote:
I apologize for this late reply.
I added a new function append_update_set_caluse, and deleted
functions: {append_set_clause_for_count, append_set_clause_for_sum,
append_set_clause_for_avg, append_set_clause_for_minmax}I guess this way is more extensible/generic than yours.
Do you mean that consolidating such functions to a general function
make easier to support a new aggregate function in future? I'm not
convinced completely yet it because your suggestion seems that every
functions' logic are just put into a new function, but providing a
common interface might make a sense a bit.
By the way, when you attach files other than updated patches that
can be applied to master branch, using ".patch" or ".diff" as the
file extension help to avoid to confuse cfbot (for example, like
basedon_v29_matview_c_refactor_update_set_clause.patch.txt).
src/backend/commands/matview.c
2268: /* For tuple deletion */
maybe "/* For tuple deletion and update*/" is more accurate?
This "deletion" means deletion of tuple from the view rather
than DELETE statement, so I think this is ok.
Since the apply delta query is quite complex, I feel like adding some
"if debug then print out the final querybuf.data end if" would be a
good idea.
Agreed, it would be helpful for debugging. I think it would be good
to add a debug macro that works if DEBUG_IVM is defined rather than
adding GUC like debug_print_..., how about it?
we add hidden columns somewhere, also to avoid corner cases, so maybe
somewhere we should assert total attribute number is sane.
The number of hidden columns to be added depends on the view definition
query, so I wonder the Assert condition would be a bit complex. Could
you explain what are you assume about like for example?
Regards,
Yugo Nagata
--
Yugo NAGATA <nagata@sraoss.co.jp>
On Mon, 4 Sep 2023 16:48:02 +0800
jian he <jian.universality@gmail.com> wrote:
other ideas based on v29.
src/include/utils/rel.h
680: #define RelationIsIVM(relation) ((relation)->rd_rel->relisivm)
I guess it would be better to add some comments to address the usage.
Since all peer macros all have some comments.
OK. I will add comments on this macro.
pg_class change, I guess we need bump CATALOG_VERSION_NO?
CATALOG_VERSION_NO is frequently bumped up when new features are
committed, so including it in the patch causes frequent needs for
rebase during the review of the patch even if no meaningful change
is made. Therefore, I wonder we don't have to included it in the
patch at this time.
small issue. makeIvmAggColumn and calc_delta need to add an empty
return statement?
I'm sorry but I could not understand what you suggested, so could
you give me more explanation?
style issue. in gram.y, "incremental" upper case?
+ CREATE OptNoLog incremental MATERIALIZED VIEW
create_mv_target AS SelectStmt opt_with_data
This "incremental" is defined as INCREMENTAL or empty, as below.
incremental: INCREMENTAL { $$ = true; }
| /*EMPTY*/ { $$ = false; }
I don't know how pgident works, do you need to add some keywords to
src/tools/pgindent/typedefs.list to make indentation work?
I'm not sure typedefs.list should be updated in each patch, because
tools/pgindent/README said that the latest typedef file is downloaded
from the buildfarm when pgindent is run.
in
/* If this is not the last AFTER trigger call, immediately exit. */
Assert (entry->before_trig_count >= entry->after_trig_count);
if (entry->before_trig_count != entry->after_trig_count)
return PointerGetDatum(NULL);before returning NULL, do you also need clean_up_IVM_hash_entry? (I
don't know when this case will happen)
No, clean_up_IVM_hash_entry is not necessary in this case.
When multiple tables are updated in a statement, statement-level AFTER
triggers collects every information of the tables, and the last AFTER
trigger have to perform the actual maintenance of the view. To make sure
this, the number that BEFORE and AFTER trigger is fired is counted
respectively, and when they match it is regarded the last AFTER trigger
call performing the maintenance. Until this, collected information have
to keep, so we cannot call clean_up_IVM_hash_entry.
in
/* Replace the modified table with the new delta table and
calculate the new view delta*/
replace_rte_with_delta(rte, table, true, queryEnv);
refresh_matview_datafill(dest_new, query, queryEnv, tupdesc_new, "");replace_rte_with_delta does not change the argument: table, argument:
queryEnv. refresh_matview_datafill just uses the partial argument of
the function calc_delta. So I guess, I am confused by the usage of
replace_rte_with_delta. also I think it should return void, since you
just modify the input argument. Here refresh_matview_datafill is just
persisting new delta content to dest_new?
Yes, refresh_matview_datafill executes the query and the result rows to
"dest_new". And, replace_rte_with_delta updates the input argument "rte"
and returns the result to it, so it may be better that this returns void,
as you suggested.
Regards,
Yugo Nagata
--
Yugo NAGATA <nagata@sraoss.co.jp>
On Tue, 23 Jan 2024 16:23:27 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:
On Mon, 22 Jan 2024 13:51:08 +1100
Peter Smith <smithpb2250@gmail.com> wrote:2024-01 Commitfest.
Hi, This patch has a CF status of "Needs Review" [1], but it seems
like there was some CFbot test failure last time it was run [2].
Please have a look and post an updated version if necessary.
I attached a rebased patch-set, v30.
Regards,
Yugo Nagata
--
Yugo NAGATA <nagata@sraoss.co.jp>
Attachments:
v30-0001-Add-a-syntax-to-create-Incrementally-Maintainabl.patchtext/x-diff; name=v30-0001-Add-a-syntax-to-create-Incrementally-Maintainabl.patchDownload
From 90ba29707b5a0ae66c7f1c3042357dac1d8309b9 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:05:02 +0900
Subject: [PATCH v30 01/11] Add a syntax to create Incrementally Maintainable
Materialized Views
Allow to create Incrementally Maintainable Materialized View (IMMV)
by using INCREMENTAL option in CREATE MATERIALIZED VIEW command
as follow:
CREATE [INCREMANTAL] MATERIALIZED VIEW xxxxx AS SELECT ....;
---
src/backend/parser/gram.y | 32 +++++++++++++++++++++-----------
src/include/nodes/primnodes.h | 1 +
src/include/parser/kwlist.h | 1 +
3 files changed, 23 insertions(+), 11 deletions(-)
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 130f7fc7c3..7ba972ae5d 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -466,6 +466,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <range> OptTempTableName
%type <into> into_clause create_as_target create_mv_target
+%type <boolean> incremental
%type <defelt> createfunc_opt_item common_func_opt_item dostmt_opt_item
%type <fun_param> func_arg func_arg_with_default table_func_column aggr_arg
@@ -719,7 +720,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
HANDLER HAVING HEADER_P HOLD HOUR_P
IDENTITY_P IF_P ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IMPORT_P IN_P INCLUDE
- INCLUDING INCREMENT INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
+ INCLUDING INCREMENT INCREMENTAL INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
@@ -4696,32 +4697,34 @@ opt_with_data:
*****************************************************************************/
CreateMatViewStmt:
- CREATE OptNoLog MATERIALIZED VIEW create_mv_target AS SelectStmt opt_with_data
+ CREATE OptNoLog incremental MATERIALIZED VIEW create_mv_target AS SelectStmt opt_with_data
{
CreateTableAsStmt *ctas = makeNode(CreateTableAsStmt);
- ctas->query = $7;
- ctas->into = $5;
+ ctas->query = $8;
+ ctas->into = $6;
ctas->objtype = OBJECT_MATVIEW;
ctas->is_select_into = false;
ctas->if_not_exists = false;
/* cram additional flags into the IntoClause */
- $5->rel->relpersistence = $2;
- $5->skipData = !($8);
+ $6->rel->relpersistence = $2;
+ $6->skipData = !($9);
+ $6->ivm = $3;
$$ = (Node *) ctas;
}
- | CREATE OptNoLog MATERIALIZED VIEW IF_P NOT EXISTS create_mv_target AS SelectStmt opt_with_data
+ | CREATE OptNoLog incremental MATERIALIZED VIEW IF_P NOT EXISTS create_mv_target AS SelectStmt opt_with_data
{
CreateTableAsStmt *ctas = makeNode(CreateTableAsStmt);
- ctas->query = $10;
- ctas->into = $8;
+ ctas->query = $11;
+ ctas->into = $9;
ctas->objtype = OBJECT_MATVIEW;
ctas->is_select_into = false;
ctas->if_not_exists = true;
/* cram additional flags into the IntoClause */
- $8->rel->relpersistence = $2;
- $8->skipData = !($11);
+ $9->rel->relpersistence = $2;
+ $9->skipData = !($12);
+ $9->ivm = $3;
$$ = (Node *) ctas;
}
;
@@ -4738,9 +4741,14 @@ create_mv_target:
$$->tableSpaceName = $5;
$$->viewQuery = NULL; /* filled at analysis time */
$$->skipData = false; /* might get changed later */
+ $$->ivm = false;
}
;
+incremental: INCREMENTAL { $$ = true; }
+ | /*EMPTY*/ { $$ = false; }
+ ;
+
OptNoLog: UNLOGGED { $$ = RELPERSISTENCE_UNLOGGED; }
| /*EMPTY*/ { $$ = RELPERSISTENCE_PERMANENT; }
;
@@ -17252,6 +17260,7 @@ unreserved_keyword:
| INCLUDE
| INCLUDING
| INCREMENT
+ | INCREMENTAL
| INDENT
| INDEX
| INDEXES
@@ -17820,6 +17829,7 @@ bare_label_keyword:
| INCLUDE
| INCLUDING
| INCREMENT
+ | INCREMENTAL
| INDENT
| INDEX
| INDEXES
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 4a154606d2..5d61964f37 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -154,6 +154,7 @@ typedef struct IntoClause
/* materialized view's SELECT query */
Node *viewQuery pg_node_attr(query_jumble_ignore);
bool skipData; /* true for WITH NO DATA */
+ bool ivm; /* true for WITH IVM */
} IntoClause;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 2331acac09..ab92b54642 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -207,6 +207,7 @@ PG_KEYWORD("in", IN_P, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("include", INCLUDE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("including", INCLUDING, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("increment", INCREMENT, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("incremental", INCREMENTAL, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("indent", INDENT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("index", INDEX, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("indexes", INDEXES, UNRESERVED_KEYWORD, BARE_LABEL)
--
2.25.1
v30-0002-Add-relisivm-column-to-pg_class-system-catalog.patchtext/x-diff; name=v30-0002-Add-relisivm-column-to-pg_class-system-catalog.patchDownload
From 145dd87d7a95078564a820fa795f9ac113d94d88 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:07:23 +0900
Subject: [PATCH v30 02/11] Add relisivm column to pg_class system catalog
If this boolean column is true, a relations is Incrementally Maintainable
Materialized View (IMMV). This is set when IMMV is created.
Also, isimmv columns is added to pg_matviews system view.
isimmv
---
src/backend/catalog/heap.c | 1 +
src/backend/catalog/index.c | 1 +
src/backend/catalog/system_views.sql | 1 +
src/backend/utils/cache/lsyscache.c | 24 ++++++++++++++++++++++++
src/backend/utils/cache/relcache.c | 2 ++
src/include/catalog/pg_class.h | 3 +++
src/include/utils/lsyscache.h | 1 +
src/include/utils/rel.h | 2 ++
src/test/regress/expected/rules.out | 1 +
9 files changed, 36 insertions(+)
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index 348943e36c..b186d9e82c 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -927,6 +927,7 @@ InsertPgClassTuple(Relation pg_class_desc,
values[Anum_pg_class_relrewrite - 1] = ObjectIdGetDatum(rd_rel->relrewrite);
values[Anum_pg_class_relfrozenxid - 1] = TransactionIdGetDatum(rd_rel->relfrozenxid);
values[Anum_pg_class_relminmxid - 1] = MultiXactIdGetDatum(rd_rel->relminmxid);
+ values[Anum_pg_class_relisivm - 1] = BoolGetDatum(rd_rel->relisivm);
if (relacl != (Datum) 0)
values[Anum_pg_class_relacl - 1] = relacl;
else
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index 4b88a9cb87..3b59c44b0e 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -992,6 +992,7 @@ index_create(Relation heapRelation,
indexRelation->rd_rel->relowner = heapRelation->rd_rel->relowner;
indexRelation->rd_rel->relam = accessMethodId;
indexRelation->rd_rel->relispartition = OidIsValid(parentIndexRelid);
+ indexRelation->rd_rel->relisivm = false;
/*
* store index's pg_class entry
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index 04227a72d1..273ae3062f 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -146,6 +146,7 @@ CREATE VIEW pg_matviews AS
T.spcname AS tablespace,
C.relhasindex AS hasindexes,
C.relispopulated AS ispopulated,
+ C.relisivm AS isimmv,
pg_get_viewdef(C.oid) AS definition
FROM pg_class C LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
LEFT JOIN pg_tablespace T ON (T.oid = C.reltablespace)
diff --git a/src/backend/utils/cache/lsyscache.c b/src/backend/utils/cache/lsyscache.c
index f730aa26c4..20b873b38e 100644
--- a/src/backend/utils/cache/lsyscache.c
+++ b/src/backend/utils/cache/lsyscache.c
@@ -2019,6 +2019,30 @@ get_rel_relispartition(Oid relid)
return false;
}
+/*
+ * get_rel_relisivm
+ *
+ * Returns the relisivm flag associated with a given relation.
+ */
+bool
+get_rel_relisivm(Oid relid)
+{
+ HeapTuple tp;
+
+ tp = SearchSysCache1(RELOID, ObjectIdGetDatum(relid));
+ if (HeapTupleIsValid(tp))
+ {
+ Form_pg_class reltup = (Form_pg_class) GETSTRUCT(tp);
+ bool result;
+
+ result = reltup->relisivm;
+ ReleaseSysCache(tp);
+ return result;
+ }
+ else
+ return false;
+}
+
/*
* get_rel_tablespace
*
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 50acae4529..278b8519b1 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -1927,6 +1927,8 @@ formrdesc(const char *relationName, Oid relationReltype,
/* ... and they're always populated, too */
relation->rd_rel->relispopulated = true;
+ /* ... and they're always no ivm, too */
+ relation->rd_rel->relisivm = false;
relation->rd_rel->relreplident = REPLICA_IDENTITY_NOTHING;
relation->rd_rel->relpages = 0;
diff --git a/src/include/catalog/pg_class.h b/src/include/catalog/pg_class.h
index 3b7533e7bb..23a933e46c 100644
--- a/src/include/catalog/pg_class.h
+++ b/src/include/catalog/pg_class.h
@@ -119,6 +119,9 @@ CATALOG(pg_class,1259,RelationRelationId) BKI_BOOTSTRAP BKI_ROWTYPE_OID(83,Relat
/* is relation a partition? */
bool relispartition BKI_DEFAULT(f);
+ /* is relation a matview with ivm? */
+ bool relisivm BKI_DEFAULT(f);
+
/* link to original rel during table rewrite; otherwise 0 */
Oid relrewrite BKI_DEFAULT(0) BKI_LOOKUP_OPT(pg_class);
diff --git a/src/include/utils/lsyscache.h b/src/include/utils/lsyscache.h
index e4a200b00e..544fa94a68 100644
--- a/src/include/utils/lsyscache.h
+++ b/src/include/utils/lsyscache.h
@@ -137,6 +137,7 @@ extern Oid get_rel_namespace(Oid relid);
extern Oid get_rel_type_id(Oid relid);
extern char get_rel_relkind(Oid relid);
extern bool get_rel_relispartition(Oid relid);
+extern bool get_rel_relisivm(Oid relid);
extern Oid get_rel_tablespace(Oid relid);
extern char get_rel_persistence(Oid relid);
extern Oid get_transform_fromsql(Oid typid, Oid langid, List *trftypes);
diff --git a/src/include/utils/rel.h b/src/include/utils/rel.h
index ab9fa4faf9..ae693adaa5 100644
--- a/src/include/utils/rel.h
+++ b/src/include/utils/rel.h
@@ -675,6 +675,8 @@ RelationCloseSmgr(Relation relation)
*/
#define RelationIsPopulated(relation) ((relation)->rd_rel->relispopulated)
+#define RelationIsIVM(relation) ((relation)->rd_rel->relisivm)
+
/*
* RelationIsAccessibleInLogicalDecoding
* True if we need to log enough information to have access via
diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out
index 0cd2c64fca..984fe16bb8 100644
--- a/src/test/regress/expected/rules.out
+++ b/src/test/regress/expected/rules.out
@@ -1392,6 +1392,7 @@ pg_matviews| SELECT n.nspname AS schemaname,
t.spcname AS tablespace,
c.relhasindex AS hasindexes,
c.relispopulated AS ispopulated,
+ c.relisivm AS isimmv,
pg_get_viewdef(c.oid) AS definition
FROM ((pg_class c
LEFT JOIN pg_namespace n ON ((n.oid = c.relnamespace)))
--
2.25.1
v30-0003-Allow-to-prolong-life-span-of-transition-tables-.patchtext/x-diff; name=v30-0003-Allow-to-prolong-life-span-of-transition-tables-.patchDownload
From e833717e13f65553a4d0170a3ae20bf695718a54 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:09:45 +0900
Subject: [PATCH v30 03/11] Allow to prolong life span of transition tables
until transaction end
Originally, tuplestores of AFTER trigger's transition tables were
freed for each query depth. For our IVM implementation, we would like
to prolong life of the tuplestores because we have to preserve them
for a whole query assuming that some base tables might be changed
in some trigger functions.
---
src/backend/commands/trigger.c | 83 ++++++++++++++++++++++++++++++++--
src/include/commands/trigger.h | 2 +
2 files changed, 81 insertions(+), 4 deletions(-)
diff --git a/src/backend/commands/trigger.c b/src/backend/commands/trigger.c
index c344ff0944..364e3a53f7 100644
--- a/src/backend/commands/trigger.c
+++ b/src/backend/commands/trigger.c
@@ -3761,6 +3761,10 @@ typedef struct AfterTriggerEventList
* end of the list, so it is relatively easy to discard them. The event
* list chunks themselves are stored in event_cxt.
*
+ * prolonged_tuplestored is a list of transition table tuplestores whose
+ * life are prolonged to the end of the outmost query instead of each nested
+ * query.
+ *
* query_depth is the current depth of nested AfterTriggerBeginQuery calls
* (-1 when the stack is empty).
*
@@ -3826,6 +3830,7 @@ typedef struct AfterTriggersData
SetConstraintState state; /* the active S C state */
AfterTriggerEventList events; /* deferred-event list */
MemoryContext event_cxt; /* memory context for events, if any */
+ List *prolonged_tuplestores; /* list of prolonged tuplestores */
/* per-query-level data: */
AfterTriggersQueryData *query_stack; /* array of structs shown below */
@@ -3861,6 +3866,7 @@ struct AfterTriggersTableData
bool closed; /* true when no longer OK to add tuples */
bool before_trig_done; /* did we already queue BS triggers? */
bool after_trig_done; /* did we already queue AS triggers? */
+ bool prolonged; /* are transition tables prolonged? */
AfterTriggerEventList after_trig_events; /* if so, saved list pointer */
/*
@@ -3910,6 +3916,7 @@ static void TransitionTableAddTuple(EState *estate,
TupleTableSlot *original_insert_tuple,
Tuplestorestate *tuplestore);
static void AfterTriggerFreeQuery(AfterTriggersQueryData *qs);
+static void release_or_prolong_tuplestore(Tuplestorestate *ts, bool prolonged);
static SetConstraintState SetConstraintStateCreate(int numalloc);
static SetConstraintState SetConstraintStateCopy(SetConstraintState origstate);
static SetConstraintState SetConstraintStateAddItem(SetConstraintState state,
@@ -4787,6 +4794,45 @@ afterTriggerInvokeEvents(AfterTriggerEventList *events,
}
+/*
+ * SetTransitionTablePreserved
+ *
+ * Prolong lifespan of transition tables corresponding specified relid and
+ * command type to the end of the outmost query instead of each nested query.
+ * This enables to use nested AFTER trigger's transition tables from outer
+ * query's triggers. Currently, only immediate incremental view maintenance
+ * uses this.
+ */
+void
+SetTransitionTablePreserved(Oid relid, CmdType cmdType)
+{
+ AfterTriggersTableData *table;
+ AfterTriggersQueryData *qs;
+ bool found = false;
+ ListCell *lc;
+
+ /* Check state, like AfterTriggerSaveEvent. */
+ if (afterTriggers.query_depth < 0)
+ elog(ERROR, "SetTransitionTablePreserved() called outside of query");
+
+ qs = &afterTriggers.query_stack[afterTriggers.query_depth];
+
+ foreach(lc, qs->tables)
+ {
+ table = (AfterTriggersTableData *) lfirst(lc);
+ if (table->relid == relid && table->cmdType == cmdType &&
+ table->closed)
+ {
+ table->prolonged = true;
+ found = true;
+ }
+ }
+
+ if (!found)
+ elog(ERROR,"could not find table with OID %d and command type %d", relid, cmdType);
+}
+
+
/*
* GetAfterTriggersTableData
*
@@ -4997,6 +5043,7 @@ AfterTriggerBeginXact(void)
*/
afterTriggers.firing_counter = (CommandId) 1; /* mustn't be 0 */
afterTriggers.query_depth = -1;
+ afterTriggers.prolonged_tuplestores = NIL;
/*
* Verify that there is no leftover state remaining. If these assertions
@@ -5157,19 +5204,19 @@ AfterTriggerFreeQuery(AfterTriggersQueryData *qs)
ts = table->old_upd_tuplestore;
table->old_upd_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->new_upd_tuplestore;
table->new_upd_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->old_del_tuplestore;
table->old_del_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->new_ins_tuplestore;
table->new_ins_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
if (table->storeslot)
{
TupleTableSlot *slot = table->storeslot;
@@ -5186,6 +5233,34 @@ AfterTriggerFreeQuery(AfterTriggersQueryData *qs)
*/
qs->tables = NIL;
list_free_deep(tables);
+
+ /* Release prolonged tuplestores at the end of the outmost query */
+ if (afterTriggers.query_depth == 0)
+ {
+ foreach(lc, afterTriggers.prolonged_tuplestores)
+ {
+ ts = (Tuplestorestate *) lfirst(lc);
+ if (ts)
+ tuplestore_end(ts);
+ }
+ afterTriggers.prolonged_tuplestores = NIL;
+ }
+}
+
+/*
+ * Release the tuplestore, or append it to the prolonged tuplestores list.
+ */
+static void
+release_or_prolong_tuplestore(Tuplestorestate *ts, bool prolonged)
+{
+ if (prolonged && afterTriggers.query_depth > 0)
+ {
+ MemoryContext oldcxt = MemoryContextSwitchTo(CurTransactionContext);
+ afterTriggers.prolonged_tuplestores = lappend(afterTriggers.prolonged_tuplestores, ts);
+ MemoryContextSwitchTo(oldcxt);
+ }
+ else
+ tuplestore_end(ts);
}
diff --git a/src/include/commands/trigger.h b/src/include/commands/trigger.h
index 8a5a9fe642..6718514d34 100644
--- a/src/include/commands/trigger.h
+++ b/src/include/commands/trigger.h
@@ -265,6 +265,8 @@ extern void AfterTriggerEndSubXact(bool isCommit);
extern void AfterTriggerSetState(ConstraintsSetStmt *stmt);
extern bool AfterTriggerPendingOnRel(Oid relid);
+extern void SetTransitionTablePreserved(Oid relid, CmdType cmdType);
+
/*
* in utils/adt/ri_triggers.c
--
2.25.1
v30-0004-Add-Incremental-View-Maintenance-support-to-pg_d.patchtext/x-diff; name=v30-0004-Add-Incremental-View-Maintenance-support-to-pg_d.patchDownload
From 9fe3f585d2ec688240ca33102c08d4c269dc2839 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 11 Nov 2020 17:01:25 +0900
Subject: [PATCH v30 04/11] Add Incremental View Maintenance support to pg_dump
Support CREATE INCREMENTAL MATERIALIZED VIEW syntax.
---
src/bin/pg_dump/pg_dump.c | 18 +++++++++++++++---
src/bin/pg_dump/pg_dump.h | 2 ++
src/bin/pg_dump/t/002_pg_dump.pl | 18 ++++++++++++++++++
3 files changed, 35 insertions(+), 3 deletions(-)
diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c
index 2225a12718..009958fdd4 100644
--- a/src/bin/pg_dump/pg_dump.c
+++ b/src/bin/pg_dump/pg_dump.c
@@ -6648,6 +6648,7 @@ getTables(Archive *fout, int *numTables)
int i_relacl;
int i_acldefault;
int i_ispartition;
+ int i_isivm;
/*
* Find all the tables and table-like objects.
@@ -6750,10 +6751,17 @@ getTables(Archive *fout, int *numTables)
if (fout->remoteVersion >= 100000)
appendPQExpBufferStr(query,
- "c.relispartition AS ispartition ");
+ "c.relispartition AS ispartition, ");
else
appendPQExpBufferStr(query,
- "false AS ispartition ");
+ "false AS ispartition, ");
+
+ if (fout->remoteVersion >= 170000)
+ appendPQExpBufferStr(query,
+ "c.relisivm AS isivm ");
+ else
+ appendPQExpBufferStr(query,
+ "false AS isivm ");
/*
* Left join to pg_depend to pick up dependency info linking sequences to
@@ -6862,6 +6870,7 @@ getTables(Archive *fout, int *numTables)
i_relacl = PQfnumber(res, "relacl");
i_acldefault = PQfnumber(res, "acldefault");
i_ispartition = PQfnumber(res, "ispartition");
+ i_isivm = PQfnumber(res, "isivm");
if (dopt->lockWaitTimeout)
{
@@ -6941,6 +6950,7 @@ getTables(Archive *fout, int *numTables)
tblinfo[i].amname = pg_strdup(PQgetvalue(res, i, i_amname));
tblinfo[i].is_identity_sequence = (strcmp(PQgetvalue(res, i, i_is_identity_sequence), "t") == 0);
tblinfo[i].ispartition = (strcmp(PQgetvalue(res, i, i_ispartition), "t") == 0);
+ tblinfo[i].isivm = (strcmp(PQgetvalue(res, i, i_isivm), "t") == 0);
/* other fields were zeroed above */
@@ -15977,9 +15987,11 @@ dumpTableSchema(Archive *fout, const TableInfo *tbinfo)
binary_upgrade_set_pg_class_oids(fout, q,
tbinfo->dobj.catId.oid, false);
- appendPQExpBuffer(q, "CREATE %s%s %s",
+ appendPQExpBuffer(q, "CREATE %s%s%s %s",
tbinfo->relpersistence == RELPERSISTENCE_UNLOGGED ?
"UNLOGGED " : "",
+ tbinfo->relkind == RELKIND_MATVIEW && tbinfo->isivm ?
+ "INCREMENTAL " : "",
reltypename,
qualrelname);
diff --git a/src/bin/pg_dump/pg_dump.h b/src/bin/pg_dump/pg_dump.h
index 77db42e354..7f05cbaec6 100644
--- a/src/bin/pg_dump/pg_dump.h
+++ b/src/bin/pg_dump/pg_dump.h
@@ -325,6 +325,8 @@ typedef struct _tableInfo
int numParents; /* number of (immediate) parent tables */
struct _tableInfo **parents; /* TableInfos of immediate parents */
+ bool isivm; /* is incrementally maintainable materialized view? */
+
/*
* These fields are computed only if we decide the table is interesting
* (it's either a table to dump, or a direct parent of a dumpable table).
diff --git a/src/bin/pg_dump/t/002_pg_dump.pl b/src/bin/pg_dump/t/002_pg_dump.pl
index 00b5092713..fff9419347 100644
--- a/src/bin/pg_dump/t/002_pg_dump.pl
+++ b/src/bin/pg_dump/t/002_pg_dump.pl
@@ -2832,6 +2832,24 @@ my %tests = (
},
},
+ 'CREATE MATERIALIZED VIEW matview_ivm' => {
+ create_order => 21,
+ create_sql => 'CREATE INCREMENTAL MATERIALIZED VIEW dump_test.matview_ivm (col1) AS
+ SELECT col1 FROM dump_test.test_table;',
+ regexp => qr/^
+ \QCREATE INCREMENTAL MATERIALIZED VIEW dump_test.matview_ivm AS\E
+ \n\s+\QSELECT col1\E
+ \n\s+\QFROM dump_test.test_table\E
+ \n\s+\QWITH NO DATA;\E
+ /xm,
+ like =>
+ { %full_runs, %dump_test_schema_runs, section_pre_data => 1, },
+ unlike => {
+ exclude_dump_test_schema => 1,
+ only_dump_measurement => 1,
+ },
+ },
+
'CREATE POLICY p1 ON test_table' => {
create_order => 22,
create_sql => 'CREATE POLICY p1 ON dump_test.test_table
--
2.25.1
v30-0005-Add-Incremental-View-Maintenance-support-to-psql.patchtext/x-diff; name=v30-0005-Add-Incremental-View-Maintenance-support-to-psql.patchDownload
From 64c8b33092cb33553ea19440d76d13d59868c418 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:21:54 +0900
Subject: [PATCH v30 05/11] Add Incremental View Maintenance support to psql
Add tab completion and meta-command output for IVM.
---
src/bin/psql/describe.c | 32 +++++++++++++++++++++++++++++++-
src/bin/psql/tab-complete.c | 14 +++++++++-----
2 files changed, 40 insertions(+), 6 deletions(-)
diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c
index b6a4eb1d56..3664371aa6 100644
--- a/src/bin/psql/describe.c
+++ b/src/bin/psql/describe.c
@@ -1570,6 +1570,7 @@ describeOneTableDetails(const char *schemaname,
char relpersistence;
char relreplident;
char *relam;
+ bool isivm;
} tableinfo;
bool show_column_details = false;
@@ -1582,7 +1583,26 @@ describeOneTableDetails(const char *schemaname,
initPQExpBuffer(&tmpbuf);
/* Get general table info */
- if (pset.sversion >= 120000)
+ if (pset.sversion >= 170000)
+ {
+ printfPQExpBuffer(&buf,
+ "SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
+ "c.relhastriggers, c.relrowsecurity, c.relforcerowsecurity, "
+ "false AS relhasoids, c.relispartition, %s, c.reltablespace, "
+ "CASE WHEN c.reloftype = 0 THEN '' ELSE c.reloftype::pg_catalog.regtype::pg_catalog.text END, "
+ "c.relpersistence, c.relreplident, am.amname, "
+ "c.relisivm\n"
+ "FROM pg_catalog.pg_class c\n "
+ "LEFT JOIN pg_catalog.pg_class tc ON (c.reltoastrelid = tc.oid)\n"
+ "LEFT JOIN pg_catalog.pg_am am ON (c.relam = am.oid)\n"
+ "WHERE c.oid = '%s';",
+ (verbose ?
+ "pg_catalog.array_to_string(c.reloptions || "
+ "array(select 'toast.' || x from pg_catalog.unnest(tc.reloptions) x), ', ')\n"
+ : "''"),
+ oid);
+ }
+ else if (pset.sversion >= 120000)
{
printfPQExpBuffer(&buf,
"SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
@@ -1702,6 +1722,10 @@ describeOneTableDetails(const char *schemaname,
(char *) NULL : pg_strdup(PQgetvalue(res, 0, 14));
else
tableinfo.relam = NULL;
+ if (pset.sversion >= 170000)
+ tableinfo.isivm = strcmp(PQgetvalue(res, 0, 15), "t") == 0;
+ else
+ tableinfo.isivm = false;
PQclear(res);
res = NULL;
@@ -3555,6 +3579,12 @@ describeOneTableDetails(const char *schemaname,
printfPQExpBuffer(&buf, _("Access method: %s"), tableinfo.relam);
printTableAddFooter(&cont, buf.data);
}
+
+ /* Incremental view maintance info */
+ if (verbose && tableinfo.relkind == RELKIND_MATVIEW && tableinfo.isivm)
+ {
+ printTableAddFooter(&cont, _("Incremental view maintenance: yes"));
+ }
}
/* reloptions, if verbose */
diff --git a/src/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c
index aa1acf8523..9977df2e28 100644
--- a/src/bin/psql/tab-complete.c
+++ b/src/bin/psql/tab-complete.c
@@ -1245,6 +1245,7 @@ static const pgsql_thing_t words_after_create[] = {
{"FOREIGN TABLE", NULL, NULL, NULL},
{"FUNCTION", NULL, NULL, Query_for_list_of_functions},
{"GROUP", Query_for_list_of_roles},
+ {"INCREMENTAL MATERIALIZED VIEW", NULL, NULL, &Query_for_list_of_matviews, NULL, THING_NO_DROP | THING_NO_ALTER},
{"INDEX", NULL, NULL, &Query_for_list_of_indexes},
{"LANGUAGE", Query_for_list_of_languages},
{"LARGE OBJECT", NULL, NULL, NULL, NULL, THING_NO_CREATE | THING_NO_DROP},
@@ -3252,7 +3253,7 @@ psql_completion(const char *text, int start, int end)
if (HeadMatches("CREATE", "SCHEMA"))
COMPLETE_WITH("TABLE", "SEQUENCE");
else
- COMPLETE_WITH("TABLE", "SEQUENCE", "MATERIALIZED VIEW");
+ COMPLETE_WITH("TABLE", "SEQUENCE", "MATERIALIZED VIEW", "INCREMENTAL MATERIALIZED VIEW");
}
/* Complete PARTITION BY with RANGE ( or LIST ( or ... */
else if (TailMatches("PARTITION", "BY"))
@@ -3597,13 +3598,16 @@ psql_completion(const char *text, int start, int end)
COMPLETE_WITH("SELECT");
/* CREATE MATERIALIZED VIEW */
- else if (Matches("CREATE", "MATERIALIZED"))
+ else if (Matches("CREATE", "MATERIALIZED") ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED"))
COMPLETE_WITH("VIEW");
- /* Complete CREATE MATERIALIZED VIEW <name> with AS */
- else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny))
+ /* Complete CREATE MATERIALIZED VIEW <name> with AS */
+ else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny) ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED", "VIEW", MatchAny))
COMPLETE_WITH("AS");
/* Complete "CREATE MATERIALIZED VIEW <sth> AS with "SELECT" */
- else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny, "AS"))
+ else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny, "AS") ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED", "VIEW", MatchAny, "AS"))
COMPLETE_WITH("SELECT");
/* CREATE EVENT TRIGGER */
--
2.25.1
v30-0006-Add-Incremental-View-Maintenance-support.patchtext/x-diff; name=v30-0006-Add-Incremental-View-Maintenance-support.patchDownload
From f65cb5773ddc4960a88e7faaa954faca3461ab55 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 18:59:50 +0900
Subject: [PATCH v30 06/11] Add Incremental View Maintenance support
In this implementation, AFTER triggers are used to collect
tuplestores containing transition table contents. When multiple tables
are changed, multiple AFTER triggers are invoked, then the final AFTER
trigger performs actual update of the matview. In addition, BEFORE
triggers are also used to handle global information for view
maintenance.
To calculate view deltas, we need both pre-state and post-state of base
tables. Post-update states are available in AFTER trigger, and pre-update
states can be calculated by removing inserted tuples and appending deleted
tuples. Insterted tuples are filtered using the snapshot taken before
table modiication, and deleted tuples are contained in the old transition
table.
Incrementally Maintainable Materialized Views (IMMV) can contain
duplicated tuples.
This patch also allows self-join, simultaneous updates of more than
one base table, and multiple updates of the same base table.
---
src/backend/access/transam/xact.c | 5 +
src/backend/commands/createas.c | 681 ++++++++++++++
src/backend/commands/matview.c | 1466 ++++++++++++++++++++++++++++-
src/include/catalog/pg_proc.dat | 10 +
src/include/commands/createas.h | 4 +
src/include/commands/matview.h | 9 +
6 files changed, 2140 insertions(+), 35 deletions(-)
diff --git a/src/backend/access/transam/xact.c b/src/backend/access/transam/xact.c
index 70ab6e27a1..0de7ab6abe 100644
--- a/src/backend/access/transam/xact.c
+++ b/src/backend/access/transam/xact.c
@@ -36,6 +36,7 @@
#include "catalog/pg_enum.h"
#include "catalog/storage.h"
#include "commands/async.h"
+#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/trigger.h"
#include "common/pg_prng.h"
@@ -2819,6 +2820,7 @@ AbortTransaction(void)
AtAbort_Notify();
AtEOXact_RelationMap(false, is_parallel_worker);
AtAbort_Twophase();
+ AtAbort_IVM();
/*
* Advertise the fact that we aborted in pg_xact (assuming that we got as
@@ -5097,6 +5099,9 @@ AbortSubTransaction(void)
pgstat_progress_end_command();
UnlockBuffers();
+ /* Clean up hash entries for incremental view maintenance */
+ AtAbort_IVM();
+
/* Reset WAL record construction state */
XLogResetInsertion();
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index 16a2fe65e6..08262100ea 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -32,15 +32,26 @@
#include "access/xact.h"
#include "access/xlog.h"
#include "catalog/namespace.h"
+#include "catalog/index.h"
+#include "catalog/pg_constraint.h"
+#include "catalog/pg_inherits.h"
+#include "catalog/pg_trigger.h"
#include "catalog/toasting.h"
#include "commands/createas.h"
+#include "commands/defrem.h"
#include "commands/matview.h"
#include "commands/prepare.h"
#include "commands/tablecmds.h"
+#include "commands/tablespace.h"
+#include "commands/trigger.h"
#include "commands/view.h"
#include "miscadmin.h"
+#include "optimizer/optimizer.h"
+#include "optimizer/prep.h"
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
+#include "parser/parser.h"
+#include "parser/parsetree.h"
#include "parser/parse_clause.h"
#include "rewrite/rewriteHandler.h"
#include "storage/smgr.h"
@@ -73,6 +84,12 @@ static bool intorel_receive(TupleTableSlot *slot, DestReceiver *self);
static void intorel_shutdown(DestReceiver *self);
static void intorel_destroy(DestReceiver *self);
+static void CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid matviewOid,
+ Relids *relids, bool ex_lock);
+static void CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock);
+static void check_ivm_restriction(Node *node);
+static bool check_ivm_restriction_walker(Node *node, void *context);
+static Bitmapset *get_primary_key_attnos_from_query(Query *query, List **constraintList);
/*
* create_ctas_internal
@@ -282,6 +299,18 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
save_nestlevel = NewGUCNestLevel();
}
+ if (is_matview && into->ivm)
+ {
+ /* check if the query is supported in IMMV definition */
+ if (contain_mutable_functions((Node *) query))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("mutable function is not supported on incrementally maintainable materialized view"),
+ errhint("functions must be marked IMMUTABLE")));
+
+ check_ivm_restriction((Node *) query);
+ }
+
if (into->skipData)
{
/*
@@ -358,6 +387,27 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
/* Restore userid and security context */
SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ if (into->ivm)
+ {
+ Oid matviewOid = address.objectId;
+ Relation matviewRel = table_open(matviewOid, NoLock);
+
+ /*
+ * Mark relisivm field, if it's a matview and into->ivm is true.
+ */
+ SetMatViewIVMState(matviewRel, true);
+
+ if (!into->skipData)
+ {
+ /* Create an index on incremental maintainable materialized view, if possible */
+ CreateIndexOnIMMV((Query *) into->viewQuery, matviewRel);
+
+ /* Create triggers on incremental maintainable materialized view */
+ CreateIvmTriggersOnBaseTables((Query *) into->viewQuery, matviewOid);
+ }
+ table_close(matviewRel, NoLock);
+ }
}
return address;
@@ -635,3 +685,634 @@ intorel_destroy(DestReceiver *self)
{
pfree(self);
}
+
+/*
+ * CreateIvmTriggersOnBaseTables -- create IVM triggers on all base tables
+ */
+void
+CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid)
+{
+ Relids relids = NULL;
+ bool ex_lock = false;
+ RangeTblEntry *rte;
+
+ /* Immediately return if we don't have any base tables. */
+ if (list_length(qry->rtable) < 1)
+ return;
+
+ /*
+ * If the view has more than one base tables, we need an exclusive lock
+ * on the view so that the view would be maintained serially to avoid
+ * the inconsistency that occurs when two base tables are modified in
+ * concurrent transactions. However, if the view has only one table,
+ * we can use a weaker lock.
+ *
+ * The type of lock should be determined here, because if we check the
+ * view definition at maintenance time, we need to acquire a weaker lock,
+ * and upgrading the lock level after this increases probability of
+ * deadlock.
+ */
+
+ rte = list_nth(qry->rtable, 0);
+ if (list_length(qry->rtable) > 1 || rte->rtekind != RTE_RELATION)
+ ex_lock = true;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, (Node *)qry, matviewOid, &relids, ex_lock);
+
+ bms_free(relids);
+}
+
+static void
+CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid matviewOid,
+ Relids *relids, bool ex_lock)
+{
+ if (node == NULL)
+ return;
+
+ /* This can recurse, so check for excessive recursion */
+ check_stack_depth();
+
+ switch (nodeTag(node))
+ {
+ case T_Query:
+ {
+ Query *query = (Query *) node;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, (Node *)query->jointree, matviewOid, relids, ex_lock);
+ }
+ break;
+
+ case T_RangeTblRef:
+ {
+ int rti = ((RangeTblRef *) node)->rtindex;
+ RangeTblEntry *rte = rt_fetch(rti, qry->rtable);
+
+ if (rte->rtekind == RTE_RELATION && !bms_is_member(rte->relid, *relids))
+ {
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_INSERT, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_DELETE, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_UPDATE, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_TRUNCATE, TRIGGER_TYPE_BEFORE, true);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_INSERT, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_DELETE, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_UPDATE, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_TRUNCATE, TRIGGER_TYPE_AFTER, true);
+
+ *relids = bms_add_member(*relids, rte->relid);
+ }
+ }
+ break;
+
+ case T_FromExpr:
+ {
+ FromExpr *f = (FromExpr *) node;
+ ListCell *l;
+
+ foreach(l, f->fromlist)
+ CreateIvmTriggersOnBaseTablesRecurse(qry, lfirst(l), matviewOid, relids, ex_lock);
+ }
+ break;
+
+ case T_JoinExpr:
+ {
+ JoinExpr *j = (JoinExpr *) node;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, j->larg, matviewOid, relids, ex_lock);
+ CreateIvmTriggersOnBaseTablesRecurse(qry, j->rarg, matviewOid, relids, ex_lock);
+ }
+ break;
+
+ default:
+ elog(ERROR, "unrecognized node type: %d", (int) nodeTag(node));
+ }
+}
+
+/*
+ * CreateIvmTrigger -- create IVM trigger on a base table
+ */
+static void
+CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock)
+{
+ ObjectAddress refaddr;
+ ObjectAddress address;
+ CreateTrigStmt *ivm_trigger;
+ List *transitionRels = NIL;
+
+ Assert(timing == TRIGGER_TYPE_BEFORE || timing == TRIGGER_TYPE_AFTER);
+
+ refaddr.classId = RelationRelationId;
+ refaddr.objectId = viewOid;
+ refaddr.objectSubId = 0;
+
+ ivm_trigger = makeNode(CreateTrigStmt);
+ ivm_trigger->relation = NULL;
+ ivm_trigger->row = false;
+
+ ivm_trigger->timing = timing;
+ ivm_trigger->events = type;
+
+ switch (type)
+ {
+ case TRIGGER_TYPE_INSERT:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_ins_before" : "IVM_trigger_ins_after");
+ break;
+ case TRIGGER_TYPE_DELETE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_del_before" : "IVM_trigger_del_after");
+ break;
+ case TRIGGER_TYPE_UPDATE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_upd_before" : "IVM_trigger_upd_after");
+ break;
+ case TRIGGER_TYPE_TRUNCATE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_truncate_before" : "IVM_trigger_truncate_after");
+ break;
+ default:
+ elog(ERROR, "unsupported trigger type");
+ }
+
+ if (timing == TRIGGER_TYPE_AFTER)
+ {
+ if (type == TRIGGER_TYPE_INSERT || type == TRIGGER_TYPE_UPDATE)
+ {
+ TriggerTransition *n = makeNode(TriggerTransition);
+ n->name = "__ivm_newtable";
+ n->isNew = true;
+ n->isTable = true;
+
+ transitionRels = lappend(transitionRels, n);
+ }
+ if (type == TRIGGER_TYPE_DELETE || type == TRIGGER_TYPE_UPDATE)
+ {
+ TriggerTransition *n = makeNode(TriggerTransition);
+ n->name = "__ivm_oldtable";
+ n->isNew = false;
+ n->isTable = true;
+
+ transitionRels = lappend(transitionRels, n);
+ }
+ }
+
+ /*
+ * XXX: When using DELETE or UPDATE, we must use exclusive lock for now
+ * because apply_old_delta(_with_count) uses ctid to identify the tuple
+ * to be deleted/deleted, but doesn't work in concurrent situations.
+ *
+ * If the view doesn't have aggregate, distinct, or tuple duplicate,
+ * then it would work even in concurrent situations. However, we don't have
+ * any way to guarantee the view has a unique key before opening the IMMV
+ * at the maintenance time because users may drop the unique index.
+ */
+
+ if (type == TRIGGER_TYPE_DELETE || type == TRIGGER_TYPE_UPDATE)
+ ex_lock = true;
+
+ ivm_trigger->funcname =
+ (timing == TRIGGER_TYPE_BEFORE ? SystemFuncName("IVM_immediate_before") : SystemFuncName("IVM_immediate_maintenance"));
+
+ ivm_trigger->columns = NIL;
+ ivm_trigger->transitionRels = transitionRels;
+ ivm_trigger->whenClause = NULL;
+ ivm_trigger->isconstraint = false;
+ ivm_trigger->deferrable = false;
+ ivm_trigger->initdeferred = false;
+ ivm_trigger->constrrel = NULL;
+ ivm_trigger->args = list_make2(
+ makeString(DatumGetPointer(DirectFunctionCall1(oidout, ObjectIdGetDatum(viewOid)))),
+ makeString(DatumGetPointer(DirectFunctionCall1(boolout, BoolGetDatum(ex_lock))))
+ );
+
+ address = CreateTrigger(ivm_trigger, NULL, relOid, InvalidOid, InvalidOid,
+ InvalidOid, InvalidOid, InvalidOid, NULL, true, false);
+
+ recordDependencyOn(&address, &refaddr, DEPENDENCY_AUTO);
+
+ /* Make changes-so-far visible */
+ CommandCounterIncrement();
+}
+
+/*
+ * check_ivm_restriction --- look for specify nodes in the query tree
+ */
+static void
+check_ivm_restriction(Node *node)
+{
+ check_ivm_restriction_walker(node, NULL);
+}
+
+static bool
+check_ivm_restriction_walker(Node *node, void *context)
+{
+ if (node == NULL)
+ return false;
+
+ /*
+ * We currently don't support Sub-Query.
+ */
+ if (IsA(node, SubPlan) || IsA(node, SubLink))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("subquery is not supported on incrementally maintainable materialized view")));
+
+ /* This can recurse, so check for excessive recursion */
+ check_stack_depth();
+
+ switch (nodeTag(node))
+ {
+ case T_Query:
+ {
+ Query *qry = (Query *)node;
+ ListCell *lc;
+ List *vars;
+
+ /* if contained CTE, return error */
+ if (qry->cteList != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("CTE is not supported on incrementally maintainable materialized view")));
+ if (qry->havingQual != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg(" HAVING clause is not supported on incrementally maintainable materialized view")));
+ if (qry->sortClause != NIL) /* There is a possibility that we don't need to return an error */
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("ORDER BY clause is not supported on incrementally maintainable materialized view")));
+ if (qry->limitOffset != NULL || qry->limitCount != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view")));
+ if (qry->distinctClause)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("DISTINCT is not supported on incrementally maintainable materialized view")));
+ if (qry->hasDistinctOn)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("DISTINCT ON is not supported on incrementally maintainable materialized view")));
+ if (qry->hasWindowFuncs)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("window functions are not supported on incrementally maintainable materialized view")));
+ if (qry->groupingSets != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUPING SETS, ROLLUP, or CUBE clauses is not supported on incrementally maintainable materialized view")));
+ if (qry->setOperations != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("UNION/INTERSECT/EXCEPT statements are not supported on incrementally maintainable materialized view")));
+ if (list_length(qry->targetList) == 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("empty target list is not supported on incrementally maintainable materialized view")));
+ if (qry->rowMarks != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view")));
+
+ /* system column restrictions */
+ vars = pull_vars_of_level((Node *) qry, 0);
+ foreach(lc, vars)
+ {
+ if (IsA(lfirst(lc), Var))
+ {
+ Var *var = (Var *) lfirst(lc);
+ /* if system column, return error */
+ if (var->varattno < 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("system column is not supported on incrementally maintainable materialized view")));
+ }
+ }
+
+ /* restrictions for rtable */
+ foreach(lc, qry->rtable)
+ {
+ RangeTblEntry *rte = (RangeTblEntry *) lfirst(lc);
+
+ if (rte->subquery)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("subquery is not supported on incrementally maintainable materialized view")));
+
+ if (rte->tablesample != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("TABLESAMPLE clause is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitioned table is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_RELATION && has_superclass(rte->relid))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_RELATION && find_inheritance_children(rte->relid, NoLock) != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("inheritance parent is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_FOREIGN_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("foreign table is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_VIEW ||
+ rte->relkind == RELKIND_MATVIEW)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view")));
+
+ if (rte->rtekind == RTE_VALUES)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("VALUES is not supported on incrementally maintainable materialized view")));
+
+ }
+
+ query_tree_walker(qry, check_ivm_restriction_walker, NULL, QTW_IGNORE_RANGE_TABLE);
+
+ break;
+ }
+ case T_TargetEntry:
+ {
+ TargetEntry *tle = (TargetEntry *)node;
+ if (isIvmName(tle->resname))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("column name %s is not supported on incrementally maintainable materialized view", tle->resname)));
+
+ expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ break;
+ }
+ case T_JoinExpr:
+ {
+ JoinExpr *joinexpr = (JoinExpr *)node;
+
+ if (joinexpr->jointype > JOIN_INNER)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("OUTER JOIN is not supported on incrementally maintainable materialized view")));
+
+ expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ }
+ break;
+ case T_Aggref:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function is not supported on incrementally maintainable materialized view")));
+ break;
+ default:
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
+ break;
+ }
+ return false;
+}
+
+/*
+ * CreateIndexOnIMMV
+ *
+ * Create a unique index on incremental maintainable materialized view.
+ * If the view definition query has a GROUP BY clause, the index is created
+ * on the columns of GROUP BY expressions. Otherwise, if the view contains
+ * all primary key attritubes of its base tables in the target list, the index
+ * is created on these attritubes. In other cases, no index is created.
+ */
+void
+CreateIndexOnIMMV(Query *query, Relation matviewRel)
+{
+ ListCell *lc;
+ IndexStmt *index;
+ ObjectAddress address;
+ List *constraintList = NIL;
+ char idxname[NAMEDATALEN];
+ List *indexoidlist = RelationGetIndexList(matviewRel);
+ ListCell *indexoidscan;
+ Bitmapset *key_attnos;
+
+ snprintf(idxname, sizeof(idxname), "%s_index", RelationGetRelationName(matviewRel));
+
+ index = makeNode(IndexStmt);
+
+ index->unique = true;
+ index->primary = false;
+ index->isconstraint = false;
+ index->deferrable = false;
+ index->initdeferred = false;
+ index->idxname = idxname;
+ index->relation =
+ makeRangeVar(get_namespace_name(RelationGetNamespace(matviewRel)),
+ pstrdup(RelationGetRelationName(matviewRel)),
+ -1);
+ index->accessMethod = DEFAULT_INDEX_TYPE;
+ index->options = NIL;
+ index->tableSpace = get_tablespace_name(matviewRel->rd_rel->reltablespace);
+ index->whereClause = NULL;
+ index->indexParams = NIL;
+ index->indexIncludingParams = NIL;
+ index->excludeOpNames = NIL;
+ index->idxcomment = NULL;
+ index->indexOid = InvalidOid;
+ index->oldNumber = InvalidRelFileNumber;
+ index->oldCreateSubid = InvalidSubTransactionId;
+ index->oldFirstRelfilelocatorSubid = InvalidSubTransactionId;
+ index->transformed = true;
+ index->concurrent = false;
+ index->if_not_exists = false;
+
+ /* create index on the base tables' primary key columns */
+ key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
+ if (key_attnos)
+ {
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ }
+ else
+ {
+ /* create no index, just notice that an appropriate index is necessary for efficient IVM */
+ ereport(NOTICE,
+ (errmsg("could not create an index on materialized view \"%s\" automatically",
+ RelationGetRelationName(matviewRel)),
+ errdetail("This target list does not have all the primary key columns. "),
+ errhint("Create an index on the materialized view for efficient incremental maintenance.")));
+ return;
+ }
+
+ /* If we have a compatible index, we don't need to create another. */
+ foreach(indexoidscan, indexoidlist)
+ {
+ Oid indexoid = lfirst_oid(indexoidscan);
+ Relation indexRel;
+ bool hasCompatibleIndex = false;
+
+ indexRel = index_open(indexoid, AccessShareLock);
+
+ if (CheckIndexCompatible(indexRel->rd_id,
+ index->accessMethod,
+ index->indexParams,
+ index->excludeOpNames,
+ false))
+ hasCompatibleIndex = true;
+
+ index_close(indexRel, AccessShareLock);
+
+ if (hasCompatibleIndex)
+ return;
+ }
+
+ address = DefineIndex(RelationGetRelid(matviewRel),
+ index,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ -1,
+ false, true, false, false, true);
+
+ ereport(NOTICE,
+ (errmsg("created index \"%s\" on materialized view \"%s\"",
+ idxname, RelationGetRelationName(matviewRel))));
+
+ /*
+ * Make dependencies so that the index is dropped if any base tables's
+ * primary key is dropped.
+ */
+ foreach(lc, constraintList)
+ {
+ Oid constraintOid = lfirst_oid(lc);
+ ObjectAddress refaddr;
+
+ refaddr.classId = ConstraintRelationId;
+ refaddr.objectId = constraintOid;
+ refaddr.objectSubId = 0;
+
+ recordDependencyOn(&address, &refaddr, DEPENDENCY_NORMAL);
+ }
+}
+
+
+/*
+ * get_primary_key_attnos_from_query
+ *
+ * Identify the columns in base tables' primary keys in the target list.
+ *
+ * Returns a Bitmapset of the column attnos of the primary key's columns of
+ * tables that used in the query. The attnos are offset by
+ * FirstLowInvalidHeapAttributeNumber as same as get_primary_key_attnos.
+ *
+ * If any table has no primary key or any primary key's columns is not in
+ * the target list, return NULL. We also return NULL if any pkey constraint
+ * is deferrable.
+ *
+ * constraintList is set to a list of the OIDs of the pkey constraints.
+ */
+static Bitmapset *
+get_primary_key_attnos_from_query(Query *query, List **constraintList)
+{
+ List *key_attnos_list = NIL;
+ ListCell *lc;
+ int i;
+ Bitmapset *keys = NULL;
+ Relids rels_in_from;
+
+ /*
+ * Collect primary key attributes from all tables used in query. The key attributes
+ * sets for each table are stored in key_attnos_list in order by RTE index.
+ */
+ foreach(lc, query->rtable)
+ {
+ RangeTblEntry *r = (RangeTblEntry*) lfirst(lc);
+ Bitmapset *key_attnos;
+ bool has_pkey = true;
+
+ /* for tables, call get_primary_key_attnos */
+ if (r->rtekind == RTE_RELATION)
+ {
+ Oid constraintOid;
+ key_attnos = get_primary_key_attnos(r->relid, false, &constraintOid);
+ *constraintList = lappend_oid(*constraintList, constraintOid);
+ has_pkey = (key_attnos != NULL);
+ }
+ /* for other RTEs, store NULL into key_attnos_list */
+ else
+ key_attnos = NULL;
+
+ /*
+ * If any table or subquery has no primary key or its pkey constraint is deferrable,
+ * we cannot get key attributes for this query, so return NULL.
+ */
+ if (!has_pkey)
+ return NULL;
+
+ key_attnos_list = lappend(key_attnos_list, key_attnos);
+ }
+
+ /* Collect key attributes appearing in the target list */
+ i = 1;
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) flatten_join_alias_vars(NULL, query, lfirst(lc));
+
+ if (IsA(tle->expr, Var))
+ {
+ Var *var = (Var*) tle->expr;
+ Bitmapset *key_attnos = list_nth(key_attnos_list, var->varno - 1);
+
+ /* check if this attribute is from a base table's primary key */
+ if (bms_is_member(var->varattno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ /*
+ * Remove found key attributes from key_attnos_list, and add this
+ * to the result list.
+ */
+ key_attnos = bms_del_member(key_attnos, var->varattno - FirstLowInvalidHeapAttributeNumber);
+ if (bms_is_empty(key_attnos))
+ {
+ key_attnos_list = list_delete_nth_cell(key_attnos_list, var->varno - 1);
+ key_attnos_list = list_insert_nth(key_attnos_list, var->varno - 1, NULL);
+ }
+ keys = bms_add_member(keys, i - FirstLowInvalidHeapAttributeNumber);
+ }
+ }
+ i++;
+ }
+
+ /* Collect RTE indexes of relations appearing in the FROM clause */
+ rels_in_from = get_relids_in_jointree((Node *) query->jointree, false, false);
+
+ /*
+ * Check if all key attributes of relations in FROM are appearing in the target
+ * list. If an attribute remains in key_attnos_list in spite of the table is used
+ * in FROM clause, the target is missing this key attribute, so we return NULL.
+ */
+ i = 1;
+ foreach(lc, key_attnos_list)
+ {
+ Bitmapset *bms = (Bitmapset *)lfirst(lc);
+ if (!bms_is_empty(bms) && bms_is_member(i, rels_in_from))
+ return NULL;
+ i++;
+ }
+
+ return keys;
+}
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index 59920ced83..a821992a37 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -25,26 +25,37 @@
#include "catalog/indexing.h"
#include "catalog/namespace.h"
#include "catalog/pg_am.h"
+#include "catalog/pg_depend.h"
+#include "catalog/pg_trigger.h"
#include "catalog/pg_opclass.h"
#include "catalog/pg_operator.h"
#include "commands/cluster.h"
#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
+#include "commands/createas.h"
#include "executor/executor.h"
#include "executor/spi.h"
+#include "executor/tstoreReceiver.h"
#include "miscadmin.h"
+#include "nodes/makefuncs.h"
+#include "parser/analyze.h"
+#include "parser/parse_clause.h"
+#include "parser/parse_func.h"
#include "parser/parse_relation.h"
#include "pgstat.h"
#include "rewrite/rewriteHandler.h"
+#include "rewrite/rowsecurity.h"
#include "storage/lmgr.h"
#include "storage/smgr.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
+#include "utils/fmgroids.h"
#include "utils/lsyscache.h"
#include "utils/rel.h"
#include "utils/snapmgr.h"
#include "utils/syscache.h"
+#include "utils/typcache.h"
typedef struct
@@ -58,6 +69,52 @@ typedef struct
BulkInsertState bistate; /* bulk insert state */
} DR_transientrel;
+#define MV_INIT_QUERYHASHSIZE 16
+
+/*
+ * MV_TriggerHashEntry
+ *
+ * Hash entry for base tables on which IVM trigger is invoked
+ */
+typedef struct MV_TriggerHashEntry
+{
+ Oid matview_id; /* OID of the materialized view */
+ int before_trig_count; /* count of before triggers invoked */
+ int after_trig_count; /* count of after triggers invoked */
+
+ Snapshot snapshot; /* Snapshot just before table change */
+
+ List *tables; /* List of MV_TriggerTable */
+ bool has_old; /* tuples are deleted from any table? */
+ bool has_new; /* tuples are inserted into any table? */
+} MV_TriggerHashEntry;
+
+/*
+ * MV_TriggerTable
+ *
+ * IVM related data for tables on which the trigger is invoked.
+ */
+typedef struct MV_TriggerTable
+{
+ Oid table_id; /* OID of the modified table */
+ List *old_tuplestores; /* tuplestores for deleted tuples */
+ List *new_tuplestores; /* tuplestores for inserted tuples */
+
+ List *rte_indexes; /* List of RTE index of the modified table */
+ RangeTblEntry *original_rte; /* the original RTE saved before rewriting query */
+
+ Relation rel; /* relation of the modified table */
+ TupleTableSlot *slot; /* for checking visibility in the pre-state table */
+} MV_TriggerTable;
+
+static HTAB *mv_trigger_info = NULL;
+
+static bool in_delta_calculation = false;
+
+/* ENR name for materialized view delta */
+#define NEW_DELTA_ENRNAME "new_delta"
+#define OLD_DELTA_ENRNAME "old_delta"
+
static int matview_maintenance_depth = 0;
static void transientrel_startup(DestReceiver *self, int operation, TupleDesc typeinfo);
@@ -65,7 +122,9 @@ static bool transientrel_receive(TupleTableSlot *slot, DestReceiver *self);
static void transientrel_shutdown(DestReceiver *self);
static void transientrel_destroy(DestReceiver *self);
static uint64 refresh_matview_datafill(DestReceiver *dest, Query *query,
- const char *queryString);
+ QueryEnvironment *queryEnv,
+ TupleDesc *resultTupleDesc,
+ const char *queryString);
static char *make_temptable_name_n(char *tempname, int n);
static void refresh_by_match_merge(Oid matviewOid, Oid tempOid, Oid relowner,
int save_sec_context);
@@ -73,6 +132,37 @@ static void refresh_by_heap_swap(Oid matviewOid, Oid OIDNewHeap, char relpersist
static bool is_usable_unique_index(Relation indexRel);
static void OpenMatViewIncrementalMaintenance(void);
static void CloseMatViewIncrementalMaintenance(void);
+static Query *get_matview_query(Relation matviewRel);
+
+static Query *rewrite_query_for_preupdate_state(Query *query, List *tables,
+ ParseState *pstate, Oid matviewid);
+static void register_delta_ENRs(ParseState *pstate, Query *query, List *tables);
+static char *make_delta_enr_name(const char *prefix, Oid relid, int count);
+static RangeTblEntry *get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *table,
+ QueryEnvironment *queryEnv, Oid matviewid);
+static RangeTblEntry *replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
+ QueryEnvironment *queryEnv);
+static Query *rewrite_query_for_counting(Query *query, ParseState *pstate);
+
+static void calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
+ DestReceiver *dest_old, DestReceiver *dest_new,
+ TupleDesc *tupdesc_old, TupleDesc *tupdesc_new,
+ QueryEnvironment *queryEnv);
+static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte_index);
+
+static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
+ TupleDesc tupdesc_old, TupleDesc tupdesc_new,
+ Query *query);
+static void apply_old_delta(const char *matviewname, const char *deltaname_old,
+ List *keys);
+static void apply_new_delta(const char *matviewname, const char *deltaname_new,
+ StringInfo target_list);
+static char *get_matching_condition_string(List *keys);
+static void generate_equal(StringInfo querybuf, Oid opttype,
+ const char *leftop, const char *rightop);
+
+static void mv_InitHashTables(void);
+static void clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort);
/*
* SetMatViewPopulatedState
@@ -114,6 +204,46 @@ SetMatViewPopulatedState(Relation relation, bool newstate)
CommandCounterIncrement();
}
+/*
+ * SetMatViewIVMState
+ * Mark a materialized view as IVM, or not.
+ *
+ * NOTE: caller must be holding an appropriate lock on the relation.
+ */
+void
+SetMatViewIVMState(Relation relation, bool newstate)
+{
+ Relation pgrel;
+ HeapTuple tuple;
+
+ Assert(relation->rd_rel->relkind == RELKIND_MATVIEW);
+
+ /*
+ * Update relation's pg_class entry. Crucial side-effect: other backends
+ * (and this one too!) are sent SI message to make them rebuild relcache
+ * entries.
+ */
+ pgrel = table_open(RelationRelationId, RowExclusiveLock);
+ tuple = SearchSysCacheCopy1(RELOID,
+ ObjectIdGetDatum(RelationGetRelid(relation)));
+ if (!HeapTupleIsValid(tuple))
+ elog(ERROR, "cache lookup failed for relation %u",
+ RelationGetRelid(relation));
+
+ ((Form_pg_class) GETSTRUCT(tuple))->relisivm = newstate;
+
+ CatalogTupleUpdate(pgrel, &tuple->t_self, tuple);
+
+ heap_freetuple(tuple);
+ table_close(pgrel, RowExclusiveLock);
+
+ /*
+ * Advance command counter to make the updated pg_class row locally
+ * visible.
+ */
+ CommandCounterIncrement();
+}
+
/*
* ExecRefreshMatView -- execute a REFRESH MATERIALIZED VIEW command
*
@@ -140,8 +270,6 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
{
Oid matviewOid;
Relation matviewRel;
- RewriteRule *rule;
- List *actions;
Query *dataQuery;
Oid tableSpace;
Oid relowner;
@@ -155,6 +283,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
int save_sec_context;
int save_nestlevel;
ObjectAddress address;
+ bool oldPopulated;
/* Determine strength of lock needed. */
concurrent = stmt->concurrent;
@@ -178,6 +307,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
SetUserIdAndSecContext(relowner,
save_sec_context | SECURITY_RESTRICTED_OPERATION);
save_nestlevel = NewGUCNestLevel();
+ oldPopulated = RelationIsPopulated(matviewRel);
/* Make sure it is a materialized view. */
if (matviewRel->rd_rel->relkind != RELKIND_MATVIEW)
@@ -199,32 +329,9 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
errmsg("%s and %s options cannot be used together",
"CONCURRENTLY", "WITH NO DATA")));
- /*
- * Check that everything is correct for a refresh. Problems at this point
- * are internal errors, so elog is sufficient.
- */
- if (matviewRel->rd_rel->relhasrules == false ||
- matviewRel->rd_rules->numLocks < 1)
- elog(ERROR,
- "materialized view \"%s\" is missing rewrite information",
- RelationGetRelationName(matviewRel));
-
- if (matviewRel->rd_rules->numLocks > 1)
- elog(ERROR,
- "materialized view \"%s\" has too many rules",
- RelationGetRelationName(matviewRel));
- rule = matviewRel->rd_rules->rules[0];
- if (rule->event != CMD_SELECT || !(rule->isInstead))
- elog(ERROR,
- "the rule for materialized view \"%s\" is not a SELECT INSTEAD OF rule",
- RelationGetRelationName(matviewRel));
+ dataQuery = get_matview_query(matviewRel);
- actions = rule->actions;
- if (list_length(actions) != 1)
- elog(ERROR,
- "the rule for materialized view \"%s\" is not a single action",
- RelationGetRelationName(matviewRel));
/*
* Check that there is a unique index with no WHERE clause on one or more
@@ -259,12 +366,6 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
errhint("Create a unique index with no WHERE clause on one or more columns of the materialized view.")));
}
- /*
- * The stored query was rewritten at the time of the MV definition, but
- * has not been scribbled on by the planner.
- */
- dataQuery = linitial_node(Query, actions);
-
/*
* Check for active uses of the relation in the current transaction, such
* as open scans.
@@ -292,6 +393,74 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
relpersistence = matviewRel->rd_rel->relpersistence;
}
+ /* delete IMMV triggers. */
+ if (RelationIsIVM(matviewRel) && stmt->skipData )
+ {
+ Relation tgRel;
+ Relation depRel;
+ ScanKeyData key;
+ SysScanDesc scan;
+ HeapTuple tup;
+ ObjectAddresses *immv_triggers;
+
+ immv_triggers = new_object_addresses();
+
+ tgRel = table_open(TriggerRelationId, RowExclusiveLock);
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ /* search triggers that depends on IMMV. */
+ ScanKeyInit(&key,
+ Anum_pg_depend_refobjid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(matviewOid));
+ scan = systable_beginscan(depRel, DependReferenceIndexId, true,
+ NULL, 1, &key);
+ while ((tup = systable_getnext(scan)) != NULL)
+ {
+ ObjectAddress obj;
+ Form_pg_depend foundDep = (Form_pg_depend) GETSTRUCT(tup);
+
+ if (foundDep->classid == TriggerRelationId)
+ {
+ HeapTuple tgtup;
+ ScanKeyData tgkey[1];
+ SysScanDesc tgscan;
+ Form_pg_trigger tgform;
+
+ /* Find the trigger name. */
+ ScanKeyInit(&tgkey[0],
+ Anum_pg_trigger_oid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(foundDep->objid));
+
+ tgscan = systable_beginscan(tgRel, TriggerOidIndexId, true,
+ NULL, 1, tgkey);
+ tgtup = systable_getnext(tgscan);
+ if (!HeapTupleIsValid(tgtup))
+ elog(ERROR, "could not find tuple for immv trigger %u", foundDep->objid);
+
+ tgform = (Form_pg_trigger) GETSTRUCT(tgtup);
+
+ /* If trigger is created by IMMV, delete it. */
+ if (strncmp(NameStr(tgform->tgname), "IVM_trigger_", 12) == 0)
+ {
+ obj.classId = foundDep->classid;
+ obj.objectId = foundDep->objid;
+ obj.objectSubId = foundDep->refobjsubid;
+ add_exact_object_address(&obj, immv_triggers);
+ }
+ systable_endscan(tgscan);
+ }
+ }
+ systable_endscan(scan);
+
+ performMultipleDeletions(immv_triggers, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ table_close(depRel, RowExclusiveLock);
+ table_close(tgRel, RowExclusiveLock);
+ free_object_addresses(immv_triggers);
+ }
+
/*
* Create the transient table that will receive the regenerated data. Lock
* it against access by any other process until commit (by which time it
@@ -305,7 +474,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
/* Generate the data, if wanted. */
if (!stmt->skipData)
- processed = refresh_matview_datafill(dest, dataQuery, queryString);
+ processed = refresh_matview_datafill(dest, dataQuery, NULL, NULL, queryString);
/* Make the matview match the newly generated data. */
if (concurrent)
@@ -340,6 +509,12 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
pgstat_count_heap_insert(matviewRel, processed);
}
+ if (!stmt->skipData && RelationIsIVM(matviewRel) && !oldPopulated)
+ {
+ CreateIndexOnIMMV(dataQuery, matviewRel);
+ CreateIvmTriggersOnBaseTables(dataQuery, matviewOid);
+ }
+
table_close(matviewRel, NoLock);
/* Roll back any GUC changes */
@@ -374,6 +549,8 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
*/
static uint64
refresh_matview_datafill(DestReceiver *dest, Query *query,
+ QueryEnvironment *queryEnv,
+ TupleDesc *resultTupleDesc,
const char *queryString)
{
List *rewritten;
@@ -410,7 +587,7 @@ refresh_matview_datafill(DestReceiver *dest, Query *query,
/* Create a QueryDesc, redirecting output to our tuple receiver */
queryDesc = CreateQueryDesc(plan, queryString,
GetActiveSnapshot(), InvalidSnapshot,
- dest, NULL, NULL, 0);
+ dest, NULL, queryEnv ? queryEnv: NULL, 0);
/* call ExecutorStart to prepare the plan for execution */
ExecutorStart(queryDesc, 0);
@@ -420,6 +597,9 @@ refresh_matview_datafill(DestReceiver *dest, Query *query,
processed = queryDesc->estate->es_processed;
+ if (resultTupleDesc)
+ *resultTupleDesc = CreateTupleDescCopy(queryDesc->tupDesc);
+
/* and clean up */
ExecutorFinish(queryDesc);
ExecutorEnd(queryDesc);
@@ -953,3 +1133,1219 @@ CloseMatViewIncrementalMaintenance(void)
matview_maintenance_depth--;
Assert(matview_maintenance_depth >= 0);
}
+
+/*
+ * get_matview_query - get the Query from a matview's _RETURN rule.
+ */
+static Query *
+get_matview_query(Relation matviewRel)
+{
+ RewriteRule *rule;
+ List * actions;
+
+ /*
+ * Check that everything is correct for a refresh. Problems at this point
+ * are internal errors, so elog is sufficient.
+ */
+ if (matviewRel->rd_rel->relhasrules == false ||
+ matviewRel->rd_rules->numLocks < 1)
+ elog(ERROR,
+ "materialized view \"%s\" is missing rewrite information",
+ RelationGetRelationName(matviewRel));
+
+ if (matviewRel->rd_rules->numLocks > 1)
+ elog(ERROR,
+ "materialized view \"%s\" has too many rules",
+ RelationGetRelationName(matviewRel));
+
+ rule = matviewRel->rd_rules->rules[0];
+ if (rule->event != CMD_SELECT || !(rule->isInstead))
+ elog(ERROR,
+ "the rule for materialized view \"%s\" is not a SELECT INSTEAD OF rule",
+ RelationGetRelationName(matviewRel));
+
+ actions = rule->actions;
+ if (list_length(actions) != 1)
+ elog(ERROR,
+ "the rule for materialized view \"%s\" is not a single action",
+ RelationGetRelationName(matviewRel));
+
+ /*
+ * The stored query was rewritten at the time of the MV definition, but
+ * has not been scribbled on by the planner.
+ */
+ return linitial_node(Query, actions);
+}
+
+
+/* ----------------------------------------------------
+ * Incremental View Maintenance routines
+ * ---------------------------------------------------
+ */
+
+/*
+ * IVM_immediate_before
+ *
+ * IVM trigger function invoked before base table is modified. If this is
+ * invoked firstly in the same statement, we save the transaction id and the
+ * command id at that time.
+ */
+Datum
+IVM_immediate_before(PG_FUNCTION_ARGS)
+{
+ TriggerData *trigdata = (TriggerData *) fcinfo->context;
+ char *matviewOid_text = trigdata->tg_trigger->tgargs[0];
+ char *ex_lock_text = trigdata->tg_trigger->tgargs[1];
+ Oid matviewOid;
+ MV_TriggerHashEntry *entry;
+ bool found;
+ bool ex_lock;
+
+ matviewOid = DatumGetObjectId(DirectFunctionCall1(oidin, CStringGetDatum(matviewOid_text)));
+ ex_lock = DatumGetBool(DirectFunctionCall1(boolin, CStringGetDatum(ex_lock_text)));
+
+ /* If the view has more than one tables, we have to use an exclusive lock. */
+ if (ex_lock)
+ {
+ /*
+ * Wait for concurrent transactions which update this materialized view at
+ * READ COMMITED. This is needed to see changes committed in other
+ * transactions. No wait and raise an error at REPEATABLE READ or
+ * SERIALIZABLE to prevent update anomalies of matviews.
+ * XXX: dead-lock is possible here.
+ */
+ if (!IsolationUsesXactSnapshot())
+ LockRelationOid(matviewOid, ExclusiveLock);
+ else if (!ConditionalLockRelationOid(matviewOid, ExclusiveLock))
+ {
+ /* try to throw error by name; relation could be deleted... */
+ char *relname = get_rel_name(matviewOid);
+
+ if (!relname)
+ ereport(ERROR,
+ (errcode(ERRCODE_LOCK_NOT_AVAILABLE),
+ errmsg("could not obtain lock on materialized view during incremental maintenance")));
+
+ ereport(ERROR,
+ (errcode(ERRCODE_LOCK_NOT_AVAILABLE),
+ errmsg("could not obtain lock on materialized view \"%s\" during incremental maintenance",
+ relname)));
+ }
+ }
+ else
+ LockRelationOid(matviewOid, RowExclusiveLock);
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_trigger_info)
+ mv_InitHashTables();
+
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_ENTER, &found);
+
+ /* On the first BEFORE to update the view, initialize trigger data */
+ if (!found)
+ {
+ /*
+ * Get a snapshot just before the table was modified for checking
+ * tuple visibility in the pre-update state of the table.
+ */
+ Snapshot snapshot = GetActiveSnapshot();
+
+ entry->matview_id = matviewOid;
+ entry->before_trig_count = 0;
+ entry->after_trig_count = 0;
+ entry->snapshot = RegisterSnapshot(snapshot);
+ entry->tables = NIL;
+ entry->has_old = false;
+ entry->has_new = false;
+ }
+
+ entry->before_trig_count++;
+
+ return PointerGetDatum(NULL);
+}
+
+/*
+ * IVM_immediate_maintenance
+ *
+ * IVM trigger function invoked after base table is modified.
+ * For each table, tuplestores of transition tables are collected.
+ * and after the last modification
+ */
+Datum
+IVM_immediate_maintenance(PG_FUNCTION_ARGS)
+{
+ TriggerData *trigdata = (TriggerData *) fcinfo->context;
+ Relation rel;
+ Oid relid;
+ Oid matviewOid;
+ Query *query;
+ Query *rewritten = NULL;
+ char *matviewOid_text = trigdata->tg_trigger->tgargs[0];
+ Relation matviewRel;
+ int old_depth = matview_maintenance_depth;
+
+ Oid relowner;
+ Tuplestorestate *old_tuplestore = NULL;
+ Tuplestorestate *new_tuplestore = NULL;
+ DestReceiver *dest_new = NULL, *dest_old = NULL;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ MV_TriggerHashEntry *entry;
+ MV_TriggerTable *table;
+ bool found;
+
+ ParseState *pstate;
+ QueryEnvironment *queryEnv = create_queryEnv();
+ MemoryContext oldcxt;
+ ListCell *lc;
+ int i;
+
+
+ /* Create a ParseState for rewriting the view definition query */
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ rel = trigdata->tg_relation;
+ relid = rel->rd_id;
+
+ matviewOid = DatumGetObjectId(DirectFunctionCall1(oidin, CStringGetDatum(matviewOid_text)));
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_trigger_info)
+ mv_InitHashTables();
+
+ /* get the entry for this materialized view */
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_FIND, &found);
+ Assert (found && entry != NULL);
+ entry->after_trig_count++;
+
+ /* search the entry for the modified table and create new entry if not found */
+ found = false;
+ foreach(lc, entry->tables)
+ {
+ table = (MV_TriggerTable *) lfirst(lc);
+ if (table->table_id == relid)
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ table = (MV_TriggerTable *) palloc0(sizeof(MV_TriggerTable));
+ table->table_id = relid;
+ table->old_tuplestores = NIL;
+ table->new_tuplestores = NIL;
+ table->rte_indexes = NIL;
+ table->slot = MakeSingleTupleTableSlot(RelationGetDescr(rel), table_slot_callbacks(rel));
+ table->rel = table_open(RelationGetRelid(rel), NoLock);
+ entry->tables = lappend(entry->tables, table);
+
+ MemoryContextSwitchTo(oldcxt);
+ }
+
+ /* Save the transition tables and make a request to not free immediately */
+ if (trigdata->tg_oldtable)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+ table->old_tuplestores = lappend(table->old_tuplestores, trigdata->tg_oldtable);
+ entry->has_old = true;
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (trigdata->tg_newtable)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+ table->new_tuplestores = lappend(table->new_tuplestores, trigdata->tg_newtable);
+ entry->has_new = true;
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (entry->has_new || entry->has_old)
+ {
+ CmdType cmd;
+
+ if (TRIGGER_FIRED_BY_INSERT(trigdata->tg_event))
+ cmd = CMD_INSERT;
+ else if (TRIGGER_FIRED_BY_DELETE(trigdata->tg_event))
+ cmd = CMD_DELETE;
+ else if (TRIGGER_FIRED_BY_UPDATE(trigdata->tg_event))
+ cmd = CMD_UPDATE;
+ else
+ elog(ERROR,"unsupported trigger type");
+
+ /* Prolong lifespan of transition tables to the end of the last AFTER trigger */
+ SetTransitionTablePreserved(relid, cmd);
+ }
+
+
+ /* If this is not the last AFTER trigger call, immediately exit. */
+ Assert (entry->before_trig_count >= entry->after_trig_count);
+ if (entry->before_trig_count != entry->after_trig_count)
+ return PointerGetDatum(NULL);
+
+ /*
+ * If this is the last AFTER trigger call, continue and update the view.
+ */
+
+ /*
+ * Advance command counter to make the updated base table row locally
+ * visible.
+ */
+ CommandCounterIncrement();
+
+ matviewRel = table_open(matviewOid, NoLock);
+
+ /* Make sure it is a materialized view. */
+ Assert(matviewRel->rd_rel->relkind == RELKIND_MATVIEW);
+
+ /*
+ * Get and push the latast snapshot to see any changes which is committed
+ * during waiting in other transactions at READ COMMITTED level.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /*
+ * Check for active uses of the relation in the current transaction, such
+ * as open scans.
+ *
+ * NB: We count on this to protect us against problems with refreshing the
+ * data using TABLE_INSERT_FROZEN.
+ */
+ CheckTableNotInUse(matviewRel, "refresh a materialized view incrementally");
+
+ /*
+ * Switch to the owner's userid, so that any functions are run as that
+ * user. Also arrange to make GUC variable changes local to this command.
+ * We will switch modes when we are about to execute user code.
+ */
+ relowner = matviewRel->rd_rel->relowner;
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+
+ /* get view query*/
+ query = get_matview_query(matviewRel);
+
+ /*
+ * When a base table is truncated, the view content will be empty if the
+ * view definition query does not contain an aggregate without a GROUP clause.
+ * Therefore, such views can be truncated.
+ */
+ if (TRIGGER_FIRED_BY_TRUNCATE(trigdata->tg_event))
+ {
+ ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
+ NIL, DROP_RESTRICT, false, false);
+
+ /* Clean up hash entry and delete tuplestores */
+ clean_up_IVM_hash_entry(entry, false);
+
+ /* Pop the original snapshot. */
+ PopActiveSnapshot();
+
+ table_close(matviewRel, NoLock);
+
+ /* Roll back any GUC changes */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ return PointerGetDatum(NULL);
+ }
+
+ /*
+ * rewrite query for calculating deltas
+ */
+
+ rewritten = copyObject(query);
+
+ /* Replace resnames in a target list with materialized view's attnames */
+ i = 0;
+ foreach (lc, rewritten->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
+
+ tle->resname = pstrdup(resname);
+ i++;
+ }
+
+ /* Set all tables in the query to pre-update state */
+ rewritten = rewrite_query_for_preupdate_state(rewritten, entry->tables,
+ pstate, matviewOid);
+ /* Rewrite for counting duplicated tuples */
+ rewritten = rewrite_query_for_counting(rewritten, pstate);
+
+ /* Create tuplestores to store view deltas */
+ if (entry->has_old)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ old_tuplestore = tuplestore_begin_heap(false, false, work_mem);
+ dest_old = CreateDestReceiver(DestTuplestore);
+ SetTuplestoreDestReceiverParams(dest_old,
+ old_tuplestore,
+ TopTransactionContext,
+ false,
+ NULL,
+ NULL);
+
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (entry->has_new)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ new_tuplestore = tuplestore_begin_heap(false, false, work_mem);
+ dest_new = CreateDestReceiver(DestTuplestore);
+ SetTuplestoreDestReceiverParams(dest_new,
+ new_tuplestore,
+ TopTransactionContext,
+ false,
+ NULL,
+ NULL);
+ MemoryContextSwitchTo(oldcxt);
+ }
+
+ /* for all modified tables */
+ foreach(lc, entry->tables)
+ {
+ ListCell *lc2;
+
+ table = (MV_TriggerTable *) lfirst(lc);
+
+ /* loop for self-join */
+ foreach(lc2, table->rte_indexes)
+ {
+ int rte_index = lfirst_int(lc2);
+ TupleDesc tupdesc_old;
+ TupleDesc tupdesc_new;
+
+ /* calculate delta tables */
+ calc_delta(table, rte_index, rewritten, dest_old, dest_new,
+ &tupdesc_old, &tupdesc_new, queryEnv);
+
+ /* Set the table in the query to post-update state */
+ rewritten = rewrite_query_for_postupdate_state(rewritten, table, rte_index);
+
+ PG_TRY();
+ {
+ /* apply the delta tables to the materialized view */
+ apply_delta(matviewOid, old_tuplestore, new_tuplestore,
+ tupdesc_old, tupdesc_new, query);
+ }
+ PG_CATCH();
+ {
+ matview_maintenance_depth = old_depth;
+ PG_RE_THROW();
+ }
+ PG_END_TRY();
+
+ /* clear view delta tuplestores */
+ if (old_tuplestore)
+ tuplestore_clear(old_tuplestore);
+ if (new_tuplestore)
+ tuplestore_clear(new_tuplestore);
+ }
+ }
+
+ /* Clean up hash entry and delete tuplestores */
+ clean_up_IVM_hash_entry(entry, false);
+ if (old_tuplestore)
+ {
+ dest_old->rDestroy(dest_old);
+ tuplestore_end(old_tuplestore);
+ }
+ if (new_tuplestore)
+ {
+ dest_new->rDestroy(dest_new);
+ tuplestore_end(new_tuplestore);
+ }
+
+ /* Pop the original snapshot. */
+ PopActiveSnapshot();
+
+ table_close(matviewRel, NoLock);
+
+ /* Roll back any GUC changes */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ return PointerGetDatum(NULL);
+}
+
+/*
+ * rewrite_query_for_preupdate_state
+ *
+ * Rewrite the query so that base tables' RTEs will represent "pre-update"
+ * state of tables. This is necessary to calculate view delta after multiple
+ * tables are modified.
+ */
+static Query*
+rewrite_query_for_preupdate_state(Query *query, List *tables,
+ ParseState *pstate, Oid matviewid)
+{
+ ListCell *lc;
+ int num_rte = list_length(query->rtable);
+ int i;
+
+
+ /* register delta ENRs */
+ register_delta_ENRs(pstate, query, tables);
+
+ /* XXX: Is necessary? Is this right timing? */
+ AcquireRewriteLocks(query, true, false);
+
+ i = 1;
+ foreach(lc, query->rtable)
+ {
+ RangeTblEntry *r = (RangeTblEntry*) lfirst(lc);
+
+ ListCell *lc2;
+ foreach(lc2, tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc2);
+ /*
+ * if the modified table is found then replace the original RTE with
+ * "pre-state" RTE and append its index to the list.
+ */
+ if (r->relid == table->table_id)
+ {
+ List *securityQuals;
+ List *withCheckOptions;
+ bool hasRowSecurity;
+ bool hasSubLinks;
+
+ RangeTblEntry *rte_pre = get_prestate_rte(r, table, pstate->p_queryEnv, matviewid);
+
+ /*
+ * Set a row security poslicies of the modified table to the subquery RTE which
+ * represents the pre-update state of the table.
+ */
+ get_row_security_policies(query, table->original_rte, i,
+ &securityQuals, &withCheckOptions,
+ &hasRowSecurity, &hasSubLinks);
+
+ if (hasRowSecurity)
+ {
+ query->hasRowSecurity = true;
+ rte_pre->security_barrier = true;
+ }
+ if (hasSubLinks)
+ query->hasSubLinks = true;
+
+ rte_pre->securityQuals = securityQuals;
+ lfirst(lc) = rte_pre;
+
+ table->rte_indexes = lappend_int(table->rte_indexes, i);
+ break;
+ }
+ }
+
+ /* finish the loop if we processed all RTE included in the original query */
+ if (i++ >= num_rte)
+ break;
+ }
+
+ return query;
+}
+
+/*
+ * register_delta_ENRs
+ *
+ * For all modified tables, make ENRs for their transition tables
+ * and register them to the queryEnv. ENR's RTEs are also appended
+ * into the list in query tree.
+ */
+static void
+register_delta_ENRs(ParseState *pstate, Query *query, List *tables)
+{
+ QueryEnvironment *queryEnv = pstate->p_queryEnv;
+ ListCell *lc;
+ RangeTblEntry *rte;
+
+ foreach(lc, tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc);
+ ListCell *lc2;
+ int count;
+
+ count = 0;
+ foreach(lc2, table->old_tuplestores)
+ {
+ Tuplestorestate *oldtable = (Tuplestorestate *) lfirst(lc2);
+ EphemeralNamedRelation enr =
+ palloc(sizeof(EphemeralNamedRelationData));
+ ParseNamespaceItem *nsitem;
+
+ enr->md.name = make_delta_enr_name("old", table->table_id, count);
+ enr->md.reliddesc = table->table_id;
+ enr->md.tupdesc = NULL;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(oldtable);
+ enr->reldata = oldtable;
+ register_ENR(queryEnv, enr);
+
+ nsitem = addRangeTableEntryForENR(pstate, makeRangeVar(NULL, enr->md.name, -1), true);
+ rte = nsitem->p_rte;
+
+ query->rtable = lappend(query->rtable, rte);
+
+ count++;
+ }
+
+ count = 0;
+ foreach(lc2, table->new_tuplestores)
+ {
+ Tuplestorestate *newtable = (Tuplestorestate *) lfirst(lc2);
+ EphemeralNamedRelation enr =
+ palloc(sizeof(EphemeralNamedRelationData));
+ ParseNamespaceItem *nsitem;
+
+ enr->md.name = make_delta_enr_name("new", table->table_id, count);
+ enr->md.reliddesc = table->table_id;
+ enr->md.tupdesc = NULL;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(newtable);
+ enr->reldata = newtable;
+ register_ENR(queryEnv, enr);
+
+ nsitem = addRangeTableEntryForENR(pstate, makeRangeVar(NULL, enr->md.name, -1), true);
+ rte = nsitem->p_rte;
+
+ query->rtable = lappend(query->rtable, rte);
+
+ count++;
+ }
+ }
+}
+
+#define DatumGetItemPointer(X) ((ItemPointer) DatumGetPointer(X))
+#define PG_GETARG_ITEMPOINTER(n) DatumGetItemPointer(PG_GETARG_DATUM(n))
+
+/*
+ * ivm_visible_in_prestate
+ *
+ * Check visibility of a tuple specified by the tableoid and item pointer
+ * using the snapshot taken just before the table was modified.
+ */
+Datum
+ivm_visible_in_prestate(PG_FUNCTION_ARGS)
+{
+ Oid tableoid = PG_GETARG_OID(0);
+ ItemPointer itemPtr = PG_GETARG_ITEMPOINTER(1);
+ Oid matviewOid = PG_GETARG_OID(2);
+ MV_TriggerHashEntry *entry;
+ MV_TriggerTable *table = NULL;
+ ListCell *lc;
+ bool found;
+ bool result;
+
+ if (!in_delta_calculation)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("ivm_visible_in_prestate can be called only in delta calculation")));
+
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_FIND, &found);
+ Assert (found && entry != NULL);
+
+ foreach(lc, entry->tables)
+ {
+ table = (MV_TriggerTable *) lfirst(lc);
+ if (table->table_id == tableoid)
+ break;
+ }
+
+ Assert (table != NULL);
+
+ result = table_tuple_fetch_row_version(table->rel, itemPtr, entry->snapshot, table->slot);
+
+ PG_RETURN_BOOL(result);
+}
+
+/*
+ * get_prestate_rte
+ *
+ * Rewrite RTE of the modified table to a subquery which represents
+ * "pre-state" table. The original RTE is saved in table->rte_original.
+ */
+static RangeTblEntry*
+get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *table,
+ QueryEnvironment *queryEnv, Oid matviewid)
+{
+ StringInfoData str;
+ RawStmt *raw;
+ Query *subquery;
+ Relation rel;
+ ParseState *pstate;
+ char *relname;
+ int i;
+
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ /*
+ * We can use NoLock here since AcquireRewriteLocks should
+ * have locked the relation already.
+ */
+ rel = table_open(table->table_id, NoLock);
+ relname = quote_qualified_identifier(
+ get_namespace_name(RelationGetNamespace(rel)),
+ RelationGetRelationName(rel));
+ table_close(rel, NoLock);
+
+ /*
+ * Filtering inserted row using the snapshot taken before the table
+ * is modified. ctid is required for maintaining outer join views.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str,
+ "SELECT t.* FROM %s t"
+ " WHERE pg_catalog.ivm_visible_in_prestate(t.tableoid, t.ctid ,%d::pg_catalog.oid)",
+ relname, matviewid);
+
+ /*
+ * Append deleted rows contained in old transition tables.
+ */
+ for (i = 0; i < list_length(table->old_tuplestores); i++)
+ {
+ appendStringInfo(&str, " UNION ALL ");
+ appendStringInfo(&str," SELECT * FROM %s",
+ make_delta_enr_name("old", table->table_id, i));
+ }
+
+ /* Get a subquery representing pre-state of the table */
+ raw = (RawStmt*)linitial(raw_parser(str.data, RAW_PARSE_DEFAULT));
+ subquery = transformStmt(pstate, raw->stmt);
+
+ /* save the original RTE */
+ table->original_rte = copyObject(rte);
+
+ rte->rtekind = RTE_SUBQUERY;
+ rte->subquery = subquery;
+ rte->security_barrier = false;
+
+ /* Clear fields that should not be set in a subquery RTE */
+ rte->relid = InvalidOid;
+ rte->relkind = 0;
+ rte->rellockmode = 0;
+ rte->tablesample = NULL;
+ rte->perminfoindex = 0; /* no permission checking for this RTE */
+ rte->inh = false; /* must not be set for a subquery */
+
+ return rte;
+}
+
+/*
+ * make_delta_enr_name
+ *
+ * Make a name for ENR of a transition table from the base table's oid.
+ * prefix will be "new" or "old" depending on its transition table kind..
+ */
+static char*
+make_delta_enr_name(const char *prefix, Oid relid, int count)
+{
+ char buf[NAMEDATALEN];
+ char *name;
+
+ snprintf(buf, NAMEDATALEN, "__ivm_%s_%u_%u", prefix, relid, count);
+ name = pstrdup(buf);
+
+ return name;
+}
+
+/*
+ * replace_rte_with_delta
+ *
+ * Replace RTE of the modified table with a single table delta that combine its
+ * all transition tables.
+ */
+static RangeTblEntry*
+replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
+ QueryEnvironment *queryEnv)
+{
+ Oid relid = table->table_id;
+ StringInfoData str;
+ ParseState *pstate;
+ RawStmt *raw;
+ Query *sub;
+ int num_tuplestores = list_length(is_new ? table->new_tuplestores : table->old_tuplestores);
+ int i;
+
+ /* the previous RTE must be a subquery which represents "pre-state" table */
+ Assert(rte->rtekind == RTE_SUBQUERY);
+
+ /* Create a ParseState for rewriting the view definition query */
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ initStringInfo(&str);
+
+ for (i = 0; i < num_tuplestores; i++)
+ {
+ if (i > 0)
+ appendStringInfo(&str, " UNION ALL ");
+
+ appendStringInfo(&str,
+ " SELECT * FROM %s",
+ make_delta_enr_name(is_new ? "new" : "old", relid, i));
+ }
+
+ raw = (RawStmt*)linitial(raw_parser(str.data, RAW_PARSE_DEFAULT));
+ sub = transformStmt(pstate, raw->stmt);
+
+ /*
+ * Update the subquery so that it represent the combined transition
+ * table. Note that we leave the security_barrier and securityQuals
+ * fields so that the subquery relation can be protected by the RLS
+ * policy as same as the modified table.
+ */
+ rte->rtekind = RTE_SUBQUERY;
+ rte->subquery = sub;
+
+ return rte;
+}
+
+/*
+ * rewrite_query_for_counting
+ *
+ * Rewrite query for counting duplicated tuples.
+ */
+static Query *
+rewrite_query_for_counting(Query *query, ParseState *pstate)
+{
+ TargetEntry *tle_count;
+ FuncCall *fn;
+ Node *node;
+
+ /* Add count(*) for counting distinct tuples in views */
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+ fn->agg_star = true;
+ if (!query->groupClause && !query->hasAggs)
+ query->groupClause = transformDistinctClause(NULL, &query->targetList, query->sortClause, false);
+
+ node = ParseFuncOrColumn(pstate, fn->funcname, NIL, NULL, fn, false, -1);
+
+ tle_count = makeTargetEntry((Expr *) node,
+ list_length(query->targetList) + 1,
+ pstrdup("__ivm_count__"),
+ false);
+ query->targetList = lappend(query->targetList, tle_count);
+ query->hasAggs = true;
+
+ return query;
+}
+
+/*
+ * calc_delta
+ *
+ * Calculate view deltas generated under the modification of a table specified
+ * by the RTE index.
+ */
+static void
+calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
+ DestReceiver *dest_old, DestReceiver *dest_new,
+ TupleDesc *tupdesc_old, TupleDesc *tupdesc_new,
+ QueryEnvironment *queryEnv)
+{
+ ListCell *lc = list_nth_cell(query->rtable, rte_index - 1);
+ RangeTblEntry *rte = (RangeTblEntry *) lfirst(lc);
+
+ in_delta_calculation = true;
+
+ /* Generate old delta */
+ if (list_length(table->old_tuplestores) > 0)
+ {
+ /* Replace the modified table with the old delta table and calculate the old view delta. */
+ replace_rte_with_delta(rte, table, false, queryEnv);
+ refresh_matview_datafill(dest_old, query, queryEnv, tupdesc_old, "");
+ }
+
+ /* Generate new delta */
+ if (list_length(table->new_tuplestores) > 0)
+ {
+ /* Replace the modified table with the new delta table and calculate the new view delta*/
+ replace_rte_with_delta(rte, table, true, queryEnv);
+ refresh_matview_datafill(dest_new, query, queryEnv, tupdesc_new, "");
+ }
+
+ in_delta_calculation = false;
+}
+
+/*
+ * rewrite_query_for_postupdate_state
+ *
+ * Rewrite the query so that the specified base table's RTEs will represent
+ * "post-update" state of tables. This is called after the view delta
+ * calculation due to changes on this table finishes.
+ */
+static Query*
+rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte_index)
+{
+ ListCell *lc = list_nth_cell(query->rtable, rte_index - 1);
+
+ /* Retore the original RTE */
+ lfirst(lc) = table->original_rte;
+
+ return query;
+}
+
+/*
+ * apply_delta
+ *
+ * Apply deltas to the materialized view. In outer join cases, this requires
+ * the view maintenance graph.
+ */
+static void
+apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
+ TupleDesc tupdesc_old, TupleDesc tupdesc_new,
+ Query *query)
+{
+ StringInfoData querybuf;
+ StringInfoData target_list_buf;
+ Relation matviewRel;
+ char *matviewname;
+ ListCell *lc;
+ int i;
+ List *keys = NIL;
+
+
+ /*
+ * get names of the materialized view and delta tables
+ */
+
+ matviewRel = table_open(matviewOid, NoLock);
+ matviewname = quote_qualified_identifier(get_namespace_name(RelationGetNamespace(matviewRel)),
+ RelationGetRelationName(matviewRel));
+
+ /*
+ * Build parts of the maintenance queries
+ */
+
+ initStringInfo(&querybuf);
+ initStringInfo(&target_list_buf);
+
+ /* build string of target list */
+ for (i = 0; i < matviewRel->rd_att->natts; i++)
+ {
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
+
+ if (i != 0)
+ appendStringInfo(&target_list_buf, ", ");
+ appendStringInfo(&target_list_buf, "%s", quote_qualified_identifier(NULL, resname));
+ }
+
+ i = 0;
+ foreach (lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+
+ i++;
+
+ if (tle->resjunk)
+ continue;
+
+ keys = lappend(keys, attr);
+ }
+
+ /* Start maintaining the materialized view. */
+ OpenMatViewIncrementalMaintenance();
+
+ /* Open SPI context. */
+ if (SPI_connect() != SPI_OK_CONNECT)
+ elog(ERROR, "SPI_connect failed");
+
+ /* For tuple deletion */
+ if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
+ {
+ EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ int rc;
+
+ /* convert tuplestores to ENR, and register for SPI */
+ enr->md.name = pstrdup(OLD_DELTA_ENRNAME);
+ enr->md.reliddesc = InvalidOid;
+ enr->md.tupdesc = tupdesc_old;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(old_tuplestores);
+ enr->reldata = old_tuplestores;
+
+ rc = SPI_register_relation(enr);
+ if (rc != SPI_OK_REL_REGISTER)
+ elog(ERROR, "SPI_register failed");
+
+ apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+
+ }
+ /* For tuple insertion */
+ if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
+ {
+ EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ int rc;
+
+ /* convert tuplestores to ENR, and register for SPI */
+ enr->md.name = pstrdup(NEW_DELTA_ENRNAME);
+ enr->md.reliddesc = InvalidOid;
+ enr->md.tupdesc = tupdesc_new;;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(new_tuplestores);
+ enr->reldata = new_tuplestores;
+
+ rc = SPI_register_relation(enr);
+ if (rc != SPI_OK_REL_REGISTER)
+ elog(ERROR, "SPI_register failed");
+
+ /* apply new delta */
+ apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
+ }
+
+ /* We're done maintaining the materialized view. */
+ CloseMatViewIncrementalMaintenance();
+
+ table_close(matviewRel, NoLock);
+
+ /* Close SPI context. */
+ if (SPI_finish() != SPI_OK_FINISH)
+ elog(ERROR, "SPI_finish failed");
+}
+
+/*
+ * apply_old_delta
+ *
+ * Execute a query for applying a delta table given by deltname_old
+ * which contains tuples to be deleted from to a materialized view given by
+ * matviewname. This is used when counting is not required.
+ */
+static void
+apply_old_delta(const char *matviewname, const char *deltaname_old,
+ List *keys)
+{
+ StringInfoData querybuf;
+ StringInfoData keysbuf;
+ char *match_cond;
+ ListCell *lc;
+
+ /* build WHERE condition for searching tuples to be deleted */
+ match_cond = get_matching_condition_string(keys);
+
+ /* build string of keys list */
+ initStringInfo(&keysbuf);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&keysbuf, "%s", quote_qualified_identifier("mv", resname));
+ if (lnext(keys, lc))
+ appendStringInfo(&keysbuf, ", ");
+ }
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "DELETE FROM %s WHERE ctid IN ("
+ "SELECT tid FROM (SELECT pg_catalog.row_number() over (partition by %s) AS \"__ivm_row_number__\","
+ "mv.ctid AS tid,"
+ "diff.\"__ivm_count__\""
+ "FROM %s AS mv, %s AS diff "
+ "WHERE %s) v "
+ "WHERE v.\"__ivm_row_number__\" OPERATOR(pg_catalog.<=) v.\"__ivm_count__\")",
+ matviewname,
+ keysbuf.data,
+ matviewname, deltaname_old,
+ match_cond);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
+/*
+ * apply_new_delta
+ *
+ * Execute a query for applying a delta table given by deltname_new
+ * which contains tuples to be inserted into a materialized view given by
+ * matviewname. This is used when counting is not required.
+ */
+static void
+apply_new_delta(const char *matviewname, const char *deltaname_new,
+ StringInfo target_list)
+{
+ StringInfoData querybuf;
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "INSERT INTO %s (%s) SELECT %s FROM ("
+ "SELECT diff.*, pg_catalog.generate_series(1, diff.\"__ivm_count__\")"
+ " AS __ivm_generate_series__ "
+ "FROM %s AS diff) AS v",
+ matviewname, target_list->data, target_list->data,
+ deltaname_new);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_INSERT)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
+/*
+ * get_matching_condition_string
+ *
+ * Build a predicate string for looking for a tuple with given keys.
+ */
+static char *
+get_matching_condition_string(List *keys)
+{
+ StringInfoData match_cond;
+ ListCell *lc;
+
+ /* If there is no key columns, the condition is always true. */
+ if (keys == NIL)
+ return "true";
+
+ initStringInfo(&match_cond);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ char *mv_resname = quote_qualified_identifier("mv", resname);
+ char *diff_resname = quote_qualified_identifier("diff", resname);
+ Oid typid = attr->atttypid;
+
+ /* Considering NULL values, we can not use simple = operator. */
+ appendStringInfo(&match_cond, "(");
+ generate_equal(&match_cond, typid, mv_resname, diff_resname);
+ appendStringInfo(&match_cond, " OR (%s IS NULL AND %s IS NULL))",
+ mv_resname, diff_resname);
+
+ if (lnext(keys, lc))
+ appendStringInfo(&match_cond, " AND ");
+ }
+
+ return match_cond.data;
+}
+
+/*
+ * generate_equals
+ *
+ * Generate an equality clause using given operands' default equality
+ * operator.
+ */
+static void
+generate_equal(StringInfo querybuf, Oid opttype,
+ const char *leftop, const char *rightop)
+{
+ TypeCacheEntry *typentry;
+
+ typentry = lookup_type_cache(opttype, TYPECACHE_EQ_OPR);
+ if (!OidIsValid(typentry->eq_opr))
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_FUNCTION),
+ errmsg("could not identify an equality operator for type %s",
+ format_type_be_qualified(opttype))));
+
+ generate_operator_clause(querybuf,
+ leftop, opttype,
+ typentry->eq_opr,
+ rightop, opttype);
+}
+
+/*
+ * mv_InitHashTables
+ */
+static void
+mv_InitHashTables(void)
+{
+ HASHCTL ctl;
+
+ memset(&ctl, 0, sizeof(ctl));
+ ctl.keysize = sizeof(Oid);
+ ctl.entrysize = sizeof(MV_TriggerHashEntry);
+ mv_trigger_info = hash_create("MV trigger info",
+ MV_INIT_QUERYHASHSIZE,
+ &ctl, HASH_ELEM | HASH_BLOBS);
+}
+
+/*
+ * AtAbort_IVM
+ *
+ * Clean up hash entries for all materialized views. This is called at
+ * transaction abort.
+ */
+void
+AtAbort_IVM()
+{
+ HASH_SEQ_STATUS seq;
+ MV_TriggerHashEntry *entry;
+
+ if (mv_trigger_info)
+ {
+ hash_seq_init(&seq, mv_trigger_info);
+ while ((entry = hash_seq_search(&seq)) != NULL)
+ clean_up_IVM_hash_entry(entry, true);
+ }
+ in_delta_calculation = false;
+}
+
+/*
+ * clean_up_IVM_hash_entry
+ *
+ * Clean up tuple stores and hash entries for a materialized view after its
+ * maintenance finished.
+ */
+static void
+clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort)
+{
+ bool found;
+ ListCell *lc;
+
+ foreach(lc, entry->tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc);
+
+ list_free(table->old_tuplestores);
+ list_free(table->new_tuplestores);
+ if (!is_abort)
+ {
+ ExecDropSingleTupleTableSlot(table->slot);
+ table_close(table->rel, NoLock);
+ }
+ }
+ list_free(entry->tables);
+
+ if (!is_abort)
+ UnregisterSnapshot(entry->snapshot);
+
+ hash_search(mv_trigger_info, (void *) &entry->matview_id, HASH_REMOVE, &found);
+}
+
+/*
+ * isIvmName
+ *
+ * Check if this is a IVM hidden column from the name.
+ */
+bool
+isIvmName(const char *s)
+{
+ if (s)
+ return (strncmp(s, "__ivm_", 6) == 0);
+ return false;
+}
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index 9c120fc2b7..e111f11bf5 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -12174,4 +12174,14 @@
proargtypes => 'int2',
prosrc => 'gist_stratnum_identity' },
+# IVM
+{ oid => '786', descr => 'ivm trigger (before)',
+ proname => 'IVM_immediate_before', provolatile => 'v', prorettype => 'trigger',
+ proargtypes => '', prosrc => 'IVM_immediate_before' },
+{ oid => '787', descr => 'ivm trigger (after)',
+ proname => 'IVM_immediate_maintenance', provolatile => 'v', prorettype => 'trigger',
+ proargtypes => '', prosrc => 'IVM_immediate_maintenance' },
+{ oid => '788', descr => 'ivm filetring ',
+ proname => 'ivm_visible_in_prestate', provolatile => 's', prorettype => 'bool',
+ proargtypes => 'oid tid oid', prosrc => 'ivm_visible_in_prestate' },
]
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 94678e3834..396ad1bb4c 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -16,6 +16,7 @@
#include "catalog/objectaddress.h"
#include "nodes/params.h"
+#include "nodes/pathnodes.h"
#include "parser/parse_node.h"
#include "tcop/dest.h"
#include "utils/queryenvironment.h"
@@ -25,6 +26,9 @@ extern ObjectAddress ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *st
ParamListInfo params, QueryEnvironment *queryEnv,
QueryCompletion *qc);
+extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
+extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
+
extern int GetIntoRelEFlags(IntoClause *intoClause);
extern DestReceiver *CreateIntoRelDestReceiver(IntoClause *intoClause);
diff --git a/src/include/commands/matview.h b/src/include/commands/matview.h
index 817b2ba0b6..3257e1adff 100644
--- a/src/include/commands/matview.h
+++ b/src/include/commands/matview.h
@@ -15,6 +15,7 @@
#define MATVIEW_H
#include "catalog/objectaddress.h"
+#include "fmgr.h"
#include "nodes/params.h"
#include "nodes/parsenodes.h"
#include "tcop/dest.h"
@@ -23,6 +24,8 @@
extern void SetMatViewPopulatedState(Relation relation, bool newstate);
+extern void SetMatViewIVMState(Relation relation, bool newstate);
+
extern ObjectAddress ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
ParamListInfo params, QueryCompletion *qc);
@@ -30,4 +33,10 @@ extern DestReceiver *CreateTransientRelDestReceiver(Oid transientoid);
extern bool MatViewIncrementalMaintenanceIsEnabled(void);
+extern Datum IVM_immediate_before(PG_FUNCTION_ARGS);
+extern Datum IVM_immediate_maintenance(PG_FUNCTION_ARGS);
+extern Datum IVM_visible_in_prestate(PG_FUNCTION_ARGS);
+extern void AtAbort_IVM(void);
+extern bool isIvmName(const char *s);
+
#endif /* MATVIEW_H */
--
2.25.1
v30-0007-Add-DISTINCT-support-for-IVM.patchtext/x-diff; name=v30-0007-Add-DISTINCT-support-for-IVM.patchDownload
From 50ca8947479dd7a711fb2e745a00b10dcaa61cbd Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 19:08:51 +0900
Subject: [PATCH v30 07/11] Add DISTINCT support for IVM
When IMMV is created with DISTINCT, multiplicity of tuples is
counted and stored in "__ivm_count__" column, which is a hidden
column of IMMV. The value in __ivm_count__ is updated when IMMV
is maintained incrementally. A tuple in IMMV can be removed if
and only if the count becomes zero.
---
src/backend/commands/createas.c | 141 ++++++++++++++++++++------
src/backend/commands/indexcmds.c | 40 ++++++++
src/backend/commands/matview.c | 148 ++++++++++++++++++++++++++--
src/backend/commands/tablecmds.c | 9 ++
src/backend/parser/parse_relation.c | 18 +++-
src/backend/rewrite/rewriteDefine.c | 3 +-
src/include/commands/createas.h | 2 +
src/include/nodes/parsenodes.h | 1 +
8 files changed, 317 insertions(+), 45 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index 08262100ea..cce44278fa 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -53,6 +53,7 @@
#include "parser/parser.h"
#include "parser/parsetree.h"
#include "parser/parse_clause.h"
+#include "parser/parse_func.h"
#include "rewrite/rewriteHandler.h"
#include "storage/smgr.h"
#include "tcop/tcopprot.h"
@@ -309,6 +310,9 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
errhint("functions must be marked IMMUTABLE")));
check_ivm_restriction((Node *) query);
+
+ /* For IMMV, we need to rewrite matview query */
+ query = rewriteQueryForIMMV(query, into->colNames);
}
if (into->skipData)
@@ -413,6 +417,49 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
return address;
}
+/*
+ * rewriteQueryForIMMV -- rewrite view definition query for IMMV
+ *
+ * count(*) is added for counting distinct tuples in views.
+ */
+Query *
+rewriteQueryForIMMV(Query *query, List *colNames)
+{
+ Query *rewritten;
+
+ Node *node;
+ ParseState *pstate = make_parsestate(NULL);
+ FuncCall *fn;
+
+ rewritten = copyObject(query);
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ /*
+ * Convert DISTINCT to GROUP BY and add count(*) for counting distinct
+ * tuples in views.
+ */
+ if (rewritten->distinctClause)
+ {
+ TargetEntry *tle;
+
+ rewritten->groupClause = transformDistinctClause(NULL, &rewritten->targetList, rewritten->sortClause, false);
+
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+ fn->agg_star = true;
+
+ node = ParseFuncOrColumn(pstate, fn->funcname, NIL, NULL, fn, false, -1);
+
+ tle = makeTargetEntry((Expr *) node,
+ list_length(rewritten->targetList) + 1,
+ pstrdup("__ivm_count__"),
+ false);
+ rewritten->targetList = lappend(rewritten->targetList, tle);
+ rewritten->hasAggs = true;
+ }
+
+ return rewritten;
+}
+
/*
* GetIntoRelEFlags --- compute executor flags needed for CREATE TABLE AS
*
@@ -536,7 +583,8 @@ intorel_startup(DestReceiver *self, int operation, TupleDesc typeinfo)
ColumnDef *col;
char *colname;
- if (lc)
+ /* Don't override hidden columns added for IVM */
+ if (lc && !isIvmName(NameStr(attribute->attname)))
{
colname = strVal(lfirst(lc));
lc = lnext(into->colNames, lc);
@@ -940,10 +988,6 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view")));
- if (qry->distinctClause)
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("DISTINCT is not supported on incrementally maintainable materialized view")));
if (qry->hasDistinctOn)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
@@ -1090,12 +1134,18 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
char idxname[NAMEDATALEN];
List *indexoidlist = RelationGetIndexList(matviewRel);
ListCell *indexoidscan;
- Bitmapset *key_attnos;
snprintf(idxname, sizeof(idxname), "%s_index", RelationGetRelationName(matviewRel));
index = makeNode(IndexStmt);
+ /*
+ * We consider null values not distinct to make sure that views with DISTINCT
+ * or GROUP BY don't contain multiple NULL rows when NULL is inserted to
+ * a base table concurrently.
+ */
+ index->nulls_not_distinct = true;
+
index->unique = true;
index->primary = false;
index->isconstraint = false;
@@ -1122,41 +1172,68 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
index->concurrent = false;
index->if_not_exists = false;
- /* create index on the base tables' primary key columns */
- key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
- if (key_attnos)
+ if (query->distinctClause)
{
+ /* create unique constraint on all columns */
foreach(lc, query->targetList)
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
-
- if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
- {
- IndexElem *iparam;
-
- iparam = makeNode(IndexElem);
- iparam->name = pstrdup(NameStr(attr->attname));
- iparam->expr = NULL;
- iparam->indexcolname = NULL;
- iparam->collation = NIL;
- iparam->opclass = NIL;
- iparam->opclassopts = NIL;
- iparam->ordering = SORTBY_DEFAULT;
- iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
- index->indexParams = lappend(index->indexParams, iparam);
- }
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
}
}
else
{
- /* create no index, just notice that an appropriate index is necessary for efficient IVM */
- ereport(NOTICE,
- (errmsg("could not create an index on materialized view \"%s\" automatically",
- RelationGetRelationName(matviewRel)),
- errdetail("This target list does not have all the primary key columns. "),
- errhint("Create an index on the materialized view for efficient incremental maintenance.")));
- return;
+ Bitmapset *key_attnos;
+
+ /* create index on the base tables' primary key columns */
+ key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
+ if (key_attnos)
+ {
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ }
+ else
+ {
+ /* create no index, just notice that an appropriate index is necessary for efficient IVM */
+ ereport(NOTICE,
+ (errmsg("could not create an index on materialized view \"%s\" automatically",
+ RelationGetRelationName(matviewRel)),
+ errdetail("This target list does not have all the primary key columns, "
+ "or this view does not contain DISTINCT clause."),
+ errhint("Create an index on the materialized view for efficient incremental maintenance.")));
+ return;
+ }
}
/* If we have a compatible index, we don't need to create another. */
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index 7a87626f5f..d661fbbb48 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -39,6 +39,7 @@
#include "commands/dbcommands.h"
#include "commands/defrem.h"
#include "commands/event_trigger.h"
+#include "commands/matview.h"
#include "commands/progress.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
@@ -1129,6 +1130,45 @@ DefineIndex(Oid tableId,
safe_index = indexInfo->ii_Expressions == NIL &&
indexInfo->ii_Predicate == NIL;
+ /*
+ * We disallow unique indexes on IVM columns of IMMVs.
+ */
+ if (RelationIsIVM(rel) && stmt->unique)
+ {
+ for (int i = 0; i < indexInfo->ii_NumIndexKeyAttrs; i++)
+ {
+ AttrNumber attno = indexInfo->ii_IndexAttrNumbers[i];
+ if (attno > 0)
+ {
+ char *name = NameStr(TupleDescAttr(rel->rd_att, attno - 1)->attname);
+ if (name && isIvmName(name))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("unique index creation on IVM columns is not supported")));
+ }
+ }
+
+ if (indexInfo->ii_Expressions)
+ {
+ Bitmapset *indexattrs = NULL;
+ int varno = -1;
+
+ pull_varattnos((Node *) indexInfo->ii_Expressions, 1, &indexattrs);
+
+ while ((varno = bms_next_member(indexattrs, varno)) >= 0)
+ {
+ int attno = varno + FirstLowInvalidHeapAttributeNumber;
+ char *name = NameStr(TupleDescAttr(rel->rd_att, attno - 1)->attname);
+ if (name && isIvmName(name))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("unique index creation on IVM columns is not supported")));
+ }
+
+ }
+ }
+
+
/*
* Report index creation if appropriate (delay this till after most of the
* error checks)
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index a821992a37..dbcbc79fff 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -152,11 +152,15 @@ static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *
static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
- Query *query);
+ Query *query, bool use_count, char *count_colname);
static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
+static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
+ List *keys, const char *count_colname);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
+static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
+ List *keys, StringInfo target_list, const char* count_colname);
static char *get_matching_condition_string(List *keys);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
@@ -271,6 +275,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
Oid matviewOid;
Relation matviewRel;
Query *dataQuery;
+ Query *viewQuery;
Oid tableSpace;
Oid relowner;
Oid OIDNewHeap;
@@ -330,8 +335,13 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
"CONCURRENTLY", "WITH NO DATA")));
- dataQuery = get_matview_query(matviewRel);
+ viewQuery = get_matview_query(matviewRel);
+ /* For IMMV, we need to rewrite matview query */
+ if (!stmt->skipData && RelationIsIVM(matviewRel))
+ dataQuery = rewriteQueryForIMMV(viewQuery,NIL);
+ else
+ dataQuery = viewQuery;
/*
* Check that there is a unique index with no WHERE clause on one or more
@@ -511,8 +521,8 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
if (!stmt->skipData && RelationIsIVM(matviewRel) && !oldPopulated)
{
- CreateIndexOnIMMV(dataQuery, matviewRel);
- CreateIvmTriggersOnBaseTables(dataQuery, matviewOid);
+ CreateIndexOnIMMV(viewQuery, matviewRel);
+ CreateIvmTriggersOnBaseTables(viewQuery, matviewOid);
}
table_close(matviewRel, NoLock);
@@ -1534,6 +1544,13 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
int rte_index = lfirst_int(lc2);
TupleDesc tupdesc_old;
TupleDesc tupdesc_new;
+ bool use_count = false;
+ char *count_colname = NULL;
+
+ count_colname = pstrdup("__ivm_count__");
+
+ if (query->distinctClause)
+ use_count = true;
/* calculate delta tables */
calc_delta(table, rte_index, rewritten, dest_old, dest_new,
@@ -1546,7 +1563,8 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
{
/* apply the delta tables to the materialized view */
apply_delta(matviewOid, old_tuplestore, new_tuplestore,
- tupdesc_old, tupdesc_new, query);
+ tupdesc_old, tupdesc_new, query, use_count,
+ count_colname);
}
PG_CATCH();
{
@@ -2019,7 +2037,7 @@ rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte
static void
apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
- Query *query)
+ Query *query, bool use_count, char *count_colname)
{
StringInfoData querybuf;
StringInfoData target_list_buf;
@@ -2095,7 +2113,12 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (rc != SPI_OK_REL_REGISTER)
elog(ERROR, "SPI_register failed");
- apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+ if (use_count)
+ /* apply old delta and get rows to be recalculated */
+ apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
+ keys, count_colname);
+ else
+ apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
}
/* For tuple insertion */
@@ -2117,7 +2140,11 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_register failed");
/* apply new delta */
- apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
+ if (use_count)
+ apply_new_delta_with_count(matviewname, NEW_DELTA_ENRNAME,
+ keys, &target_list_buf, count_colname);
+ else
+ apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
}
/* We're done maintaining the materialized view. */
@@ -2130,6 +2157,51 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_finish failed");
}
+/*
+ * apply_old_delta_with_count
+ *
+ * Execute a query for applying a delta table given by deltname_old
+ * which contains tuples to be deleted from to a materialized view given by
+ * matviewname. This is used when counting is required, that is, the view
+ * has aggregate or distinct.
+ */
+static void
+apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
+ List *keys, const char *count_colname)
+{
+ StringInfoData querybuf;
+ char *match_cond;
+
+ /* build WHERE condition for searching tuples to be deleted */
+ match_cond = get_matching_condition_string(keys);
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "WITH t AS (" /* collecting tid of target tuples in the view */
+ "SELECT diff.%s, " /* count column */
+ "(diff.%s OPERATOR(pg_catalog.=) mv.%s) AS for_dlt, "
+ "mv.ctid "
+ "FROM %s AS mv, %s AS diff "
+ "WHERE %s" /* tuple matching condition */
+ "), updt AS (" /* update a tuple if this is not to be deleted */
+ "UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
+ "FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
+ ")"
+ /* delete a tuple if this is to be deleted */
+ "DELETE FROM %s AS mv USING t "
+ "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
+ count_colname,
+ count_colname, count_colname,
+ matviewname, deltaname_old,
+ match_cond,
+ matviewname, count_colname, count_colname, count_colname,
+ matviewname);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
/*
* apply_old_delta
*
@@ -2179,6 +2251,66 @@ apply_old_delta(const char *matviewname, const char *deltaname_old,
elog(ERROR, "SPI_exec failed: %s", querybuf.data);
}
+/*
+ * apply_new_delta_with_count
+ *
+ * Execute a query for applying a delta table given by deltname_new
+ * which contains tuples to be inserted into a materialized view given by
+ * matviewname. This is used when counting is required, that is, the view
+ * has aggregate or distinct. Also, when a table in EXISTS sub queries
+ * is modified.
+ */
+static void
+apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
+ List *keys, StringInfo target_list, const char* count_colname)
+{
+ StringInfoData querybuf;
+ StringInfoData returning_keys;
+ ListCell *lc;
+ char *match_cond = "";
+
+ /* build WHERE condition for searching tuples to be updated */
+ match_cond = get_matching_condition_string(keys);
+
+ /* build string of keys list */
+ initStringInfo(&returning_keys);
+ if (keys)
+ {
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&returning_keys, "%s", quote_qualified_identifier("mv", resname));
+ if (lnext(keys, lc))
+ appendStringInfo(&returning_keys, ", ");
+ }
+ }
+ else
+ appendStringInfo(&returning_keys, "NULL");
+
+ /* Search for matching tuples from the view and update if found or insert if not. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "WITH updt AS (" /* update a tuple if this exists in the view */
+ "UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.+) diff.%s "
+ "FROM %s AS diff "
+ "WHERE %s " /* tuple matching condition */
+ "RETURNING %s" /* returning keys of updated tuples */
+ ") INSERT INTO %s (%s) " /* insert a new tuple if this doesn't exist */
+ "SELECT %s FROM %s AS diff "
+ "WHERE NOT EXISTS (SELECT 1 FROM updt AS mv WHERE %s);",
+ matviewname, count_colname, count_colname, count_colname,
+ deltaname_new,
+ match_cond,
+ returning_keys.data,
+ matviewname, target_list->data,
+ target_list->data, deltaname_new,
+ match_cond);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_INSERT)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
/*
* apply_new_delta
*
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index f798794556..02a688acb7 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -53,6 +53,7 @@
#include "commands/cluster.h"
#include "commands/comment.h"
#include "commands/defrem.h"
+#include "commands/matview.h"
#include "commands/event_trigger.h"
#include "commands/policy.h"
#include "commands/sequence.h"
@@ -3784,6 +3785,14 @@ renameatt_internal(Oid myrelid,
targetrelation = relation_open(myrelid, AccessExclusiveLock);
renameatt_check(myrelid, RelationGetForm(targetrelation), recursing);
+ /*
+ * Don't rename IVM columns.
+ */
+ if (RelationIsIVM(targetrelation) && isIvmName(oldattname))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("IVM column can not be renamed")));
+
/*
* if the 'recurse' flag is set then we are supposed to rename this
* attribute in all classes that inherit from 'relname' (as well as in
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index 34a0ec5901..d5b45c587d 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -36,6 +36,7 @@
#include "utils/rel.h"
#include "utils/syscache.h"
#include "utils/varlena.h"
+#include "commands/matview.h"
/*
@@ -97,7 +98,7 @@ static void expandTupleDesc(TupleDesc tupdesc, Alias *eref,
int count, int offset,
int rtindex, int sublevels_up,
int location, bool include_dropped,
- List **colnames, List **colvars);
+ List **colnames, List **colvars, bool is_ivm);
static int specialAttNum(const char *attname);
static bool rte_visible_if_lateral(ParseState *pstate, RangeTblEntry *rte);
static bool rte_visible_if_qualified(ParseState *pstate, RangeTblEntry *rte);
@@ -1502,6 +1503,7 @@ addRangeTableEntry(ParseState *pstate,
rte->relid = RelationGetRelid(rel);
rte->relkind = rel->rd_rel->relkind;
rte->rellockmode = lockmode;
+ rte->relisivm = rel->rd_rel->relisivm;
/*
* Build the list of effective column names using user-supplied aliases
@@ -1587,6 +1589,7 @@ addRangeTableEntryForRelation(ParseState *pstate,
rte->relid = RelationGetRelid(rel);
rte->relkind = rel->rd_rel->relkind;
rte->rellockmode = lockmode;
+ rte->relisivm = rel->rd_rel->relisivm;
/*
* Build the list of effective column names using user-supplied aliases
@@ -2758,7 +2761,7 @@ expandRTE(RangeTblEntry *rte, int rtindex, int sublevels_up,
expandTupleDesc(tupdesc, rte->eref,
rtfunc->funccolcount, atts_done,
rtindex, sublevels_up, location,
- include_dropped, colnames, colvars);
+ include_dropped, colnames, colvars, false);
}
else if (functypclass == TYPEFUNC_SCALAR)
{
@@ -3026,7 +3029,7 @@ expandRelation(Oid relid, Alias *eref, int rtindex, int sublevels_up,
expandTupleDesc(rel->rd_att, eref, rel->rd_att->natts, 0,
rtindex, sublevels_up,
location, include_dropped,
- colnames, colvars);
+ colnames, colvars, RelationIsIVM(rel));
relation_close(rel, AccessShareLock);
}
@@ -3043,7 +3046,7 @@ static void
expandTupleDesc(TupleDesc tupdesc, Alias *eref, int count, int offset,
int rtindex, int sublevels_up,
int location, bool include_dropped,
- List **colnames, List **colvars)
+ List **colnames, List **colvars, bool is_ivm)
{
ListCell *aliascell;
int varattno;
@@ -3056,6 +3059,9 @@ expandTupleDesc(TupleDesc tupdesc, Alias *eref, int count, int offset,
{
Form_pg_attribute attr = TupleDescAttr(tupdesc, varattno);
+ if (is_ivm && isIvmName(NameStr(attr->attname)) && !MatViewIncrementalMaintenanceIsEnabled())
+ continue;
+
if (attr->attisdropped)
{
if (include_dropped)
@@ -3218,6 +3224,10 @@ expandNSItemAttrs(ParseState *pstate, ParseNamespaceItem *nsitem,
Var *varnode = (Var *) lfirst(var);
TargetEntry *te;
+ /* if transform * into columnlist with IMMV, remove IVM columns */
+ if (rte->relisivm && isIvmName(label) && !MatViewIncrementalMaintenanceIsEnabled())
+ continue;
+
te = makeTargetEntry((Expr *) varnode,
(AttrNumber) pstate->p_next_resno++,
label,
diff --git a/src/backend/rewrite/rewriteDefine.c b/src/backend/rewrite/rewriteDefine.c
index b449244a53..b9d161d6a3 100644
--- a/src/backend/rewrite/rewriteDefine.c
+++ b/src/backend/rewrite/rewriteDefine.c
@@ -621,7 +621,8 @@ checkRuleResultList(List *targetList, TupleDesc resultDesc, bool isSelect,
attr->atttypmod))));
}
- if (i != resultDesc->natts)
+ /* No check for materialized views since this could have special columns for IVM */
+ if ((!isSelect || requireColumnNameMatch) && i != resultDesc->natts)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
isSelect ?
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 396ad1bb4c..6b47e66bfd 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -29,6 +29,8 @@ extern ObjectAddress ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *st
extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
+extern Query *rewriteQueryForIMMV(Query *query, List *colNames);
+
extern int GetIntoRelEFlags(IntoClause *intoClause);
extern DestReceiver *CreateIntoRelDestReceiver(IntoClause *intoClause);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index d60e148ff2..fa3a95897c 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1074,6 +1074,7 @@ typedef struct RangeTblEntry
int rellockmode; /* lock level that query requires on the rel */
struct TableSampleClause *tablesample; /* sampling info, or NULL */
Index perminfoindex;
+ bool relisivm;
/*
* Fields valid for a subquery RTE (else NULL):
--
2.25.1
v30-0008-Add-aggregates-support-in-IVM.patchtext/x-diff; name=v30-0008-Add-aggregates-support-in-IVM.patchDownload
From db49209eeb87d662e870ff4fab2c3441aa9eae70 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 20:46:32 +0900
Subject: [PATCH v30 08/11] Add aggregates support in IVM
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit
count, sum, adn avg are supported.
As a restriction, expressions specified in GROUP BY must appear in
the target list because tuples to be updated in IMMV are identified
by using this group key. However, in the case of aggregates without
GROUP BY, there is only one tuple in the view, so keys are not uses
to identify tuples.
When creating a IMMV, in addition to __ivm_count column, some hidden
columns for each aggregate are added to the target list. For example,
names of these hidden columns are ivm_count_avg and ivm_sum_avg for
the average function, and so on.
When a base table is modified, the aggregated values and related
hidden columns are also updated as well as __ivm_count__. The
way of update depends the kind of aggregate function. Specifically,
sum and count are updated by simply adding or subtracting delta value
calculated from delta tables. avg is updated by using values of sum
and count stored in views as hidden columns and deltas calculated
from delta tables.
About aggregate functions except "count()" (sum and avg), NULLs in input
values are ignored, and the result of aggegate should be NULL when no
rows are selected. To support this specification, the numbers of non-NULL
input values are counted and stored in hidden columns. In the case of
count(), count(x) returns zero when no rows are selected, but count(*)
doesn't ignore NULL input.
---
src/backend/commands/createas.c | 264 +++++++++++++++++--
src/backend/commands/matview.c | 433 ++++++++++++++++++++++++++++++--
src/include/commands/createas.h | 1 +
3 files changed, 661 insertions(+), 37 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index cce44278fa..d93eec3eec 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -54,14 +54,19 @@
#include "parser/parsetree.h"
#include "parser/parse_clause.h"
#include "parser/parse_func.h"
+#include "parser/parse_type.h"
#include "rewrite/rewriteHandler.h"
+#include "rewrite/rewriteManip.h"
#include "storage/smgr.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
#include "utils/lsyscache.h"
+#include "utils/regproc.h"
+#include "utils/fmgroids.h"
#include "utils/rel.h"
#include "utils/rls.h"
#include "utils/snapmgr.h"
+#include "utils/syscache.h"
typedef struct
{
@@ -75,6 +80,11 @@ typedef struct
BulkInsertState bistate; /* bulk insert state */
} DR_intorel;
+typedef struct
+{
+ bool has_agg;
+} check_ivm_restriction_context;
+
/* utility functions for CTAS definition creation */
static ObjectAddress create_ctas_internal(List *attrList, IntoClause *into);
static ObjectAddress create_ctas_nodata(List *tlist, IntoClause *into);
@@ -89,8 +99,9 @@ static void CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid mat
Relids *relids, bool ex_lock);
static void CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock);
static void check_ivm_restriction(Node *node);
-static bool check_ivm_restriction_walker(Node *node, void *context);
+static bool check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context);
static Bitmapset *get_primary_key_attnos_from_query(Query *query, List **constraintList);
+static bool check_aggregate_supports_ivm(Oid aggfnoid);
/*
* create_ctas_internal
@@ -421,6 +432,7 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
* rewriteQueryForIMMV -- rewrite view definition query for IMMV
*
* count(*) is added for counting distinct tuples in views.
+ * Also, additional hidden columns are added for aggregate values.
*/
Query *
rewriteQueryForIMMV(Query *query, List *colNames)
@@ -434,16 +446,49 @@ rewriteQueryForIMMV(Query *query, List *colNames)
rewritten = copyObject(query);
pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
- /*
- * Convert DISTINCT to GROUP BY and add count(*) for counting distinct
- * tuples in views.
- */
- if (rewritten->distinctClause)
+ /* group keys must be in targetlist */
+ if (rewritten->groupClause)
{
- TargetEntry *tle;
+ ListCell *lc;
+ foreach(lc, rewritten->groupClause)
+ {
+ SortGroupClause *scl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(scl, rewritten->targetList);
+ if (tle->resjunk)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUP BY expression not appearing in select list is not supported on incrementally maintainable materialized view")));
+ }
+ }
+ /* Convert DISTINCT to GROUP BY. count(*) will be added afterward. */
+ else if (!rewritten->hasAggs && rewritten->distinctClause)
rewritten->groupClause = transformDistinctClause(NULL, &rewritten->targetList, rewritten->sortClause, false);
+ /* Add additional columns for aggregate values */
+ if (rewritten->hasAggs)
+ {
+ ListCell *lc;
+ List *aggs = NIL;
+ AttrNumber next_resno = list_length(rewritten->targetList) + 1;
+
+ foreach(lc, rewritten->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ char *resname = (colNames == NIL || foreach_current_index(lc) >= list_length(colNames) ?
+ tle->resname : strVal(list_nth(colNames, tle->resno - 1)));
+
+ if (IsA(tle->expr, Aggref))
+ makeIvmAggColumn(pstate, (Aggref *) tle->expr, resname, &next_resno, &aggs);
+ }
+ rewritten->targetList = list_concat(rewritten->targetList, aggs);
+ }
+
+ /* Add count(*) for counting distinct tuples in views */
+ if (rewritten->distinctClause || rewritten->hasAggs)
+ {
+ TargetEntry *tle;
+
fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
fn->agg_star = true;
@@ -460,6 +505,91 @@ rewriteQueryForIMMV(Query *query, List *colNames)
return rewritten;
}
+/*
+ * makeIvmAggColumn -- make additional aggregate columns for IVM
+ *
+ * For an aggregate column specified by aggref, additional aggregate columns
+ * are added, which are used to calculate the new aggregate value in IMMV.
+ * An additional aggregate columns has a name based on resname
+ * (ex. ivm_count_resname), and resno specified by next_resno. The created
+ * columns are returned to aggs, and the resno for the next column is also
+ * returned to next_resno.
+ *
+ * Currently, an additional count() is created for aggref other than count.
+ * In addition, sum() is created for avg aggregate column.
+ */
+void
+makeIvmAggColumn(ParseState *pstate, Aggref *aggref, char *resname, AttrNumber *next_resno, List **aggs)
+{
+ TargetEntry *tle_count;
+ Node *node;
+ FuncCall *fn;
+ Const *dmy_arg = makeConst(INT4OID,
+ -1,
+ InvalidOid,
+ sizeof(int32),
+ Int32GetDatum(1),
+ false,
+ true); /* pass by value */
+ const char *aggname = get_func_name(aggref->aggfnoid);
+
+ /*
+ * For aggregate functions except count, add count() func with the same arg parameters.
+ * This count result is used for determining if the aggregate value should be NULL or not.
+ * Also, add sum() func for avg because we need to calculate an average value as sum/count.
+ *
+ * XXX: If there are same expressions explicitly in the target list, we can use this instead
+ * of adding new duplicated one.
+ */
+ if (strcmp(aggname, "count") != 0)
+ {
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+
+ /* Make a Func with a dummy arg, and then override this by the original agg's args. */
+ node = ParseFuncOrColumn(pstate, fn->funcname, list_make1(dmy_arg), NULL, fn, false, -1);
+ ((Aggref *)node)->args = aggref->args;
+
+ tle_count = makeTargetEntry((Expr *) node,
+ *next_resno,
+ pstrdup(makeObjectName("__ivm_count",resname, "_")),
+ false);
+ *aggs = lappend(*aggs, tle_count);
+ (*next_resno)++;
+ }
+ if (strcmp(aggname, "avg") == 0)
+ {
+ List *dmy_args = NIL;
+ ListCell *lc;
+ foreach(lc, aggref->aggargtypes)
+ {
+ Oid typeid = lfirst_oid(lc);
+ Type type = typeidType(typeid);
+
+ Const *con = makeConst(typeid,
+ -1,
+ typeTypeCollation(type),
+ typeLen(type),
+ (Datum) 0,
+ true,
+ typeByVal(type));
+ dmy_args = lappend(dmy_args, con);
+ ReleaseSysCache(type);
+ }
+ fn = makeFuncCall(SystemFuncName("sum"), NIL, COERCE_EXPLICIT_CALL, -1);
+
+ /* Make a Func with dummy args, and then override this by the original agg's args. */
+ node = ParseFuncOrColumn(pstate, fn->funcname, dmy_args, NULL, fn, false, -1);
+ ((Aggref *)node)->args = aggref->args;
+
+ tle_count = makeTargetEntry((Expr *) node,
+ *next_resno,
+ pstrdup(makeObjectName("__ivm_sum",resname, "_")),
+ false);
+ *aggs = lappend(*aggs, tle_count);
+ (*next_resno)++;
+ }
+}
+
/*
* GetIntoRelEFlags --- compute executor flags needed for CREATE TABLE AS
*
@@ -943,11 +1073,13 @@ CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock
static void
check_ivm_restriction(Node *node)
{
- check_ivm_restriction_walker(node, NULL);
+ check_ivm_restriction_context context = {false};
+
+ check_ivm_restriction_walker(node, &context);
}
static bool
-check_ivm_restriction_walker(Node *node, void *context)
+check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context)
{
if (node == NULL)
return false;
@@ -976,6 +1108,10 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("CTE is not supported on incrementally maintainable materialized view")));
+ if (qry->groupClause != NIL && !qry->hasAggs)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUP BY clause without aggregate is not supported on incrementally maintainable materialized view")));
if (qry->havingQual != NULL)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
@@ -1028,6 +1164,8 @@ check_ivm_restriction_walker(Node *node, void *context)
}
}
+ context->has_agg |= qry->hasAggs;
+
/* restrictions for rtable */
foreach(lc, qry->rtable)
{
@@ -1076,7 +1214,7 @@ check_ivm_restriction_walker(Node *node, void *context)
}
- query_tree_walker(qry, check_ivm_restriction_walker, NULL, QTW_IGNORE_RANGE_TABLE);
+ query_tree_walker(qry, check_ivm_restriction_walker, (void *) context, QTW_IGNORE_RANGE_TABLE);
break;
}
@@ -1087,8 +1225,12 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("column name %s is not supported on incrementally maintainable materialized view", tle->resname)));
+ if (context->has_agg && !IsA(tle->expr, Aggref) && contain_aggs_of_level((Node *) tle->expr, 0))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("expression containing an aggregate in it is not supported on incrementally maintainable materialized view")));
- expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
break;
}
case T_JoinExpr:
@@ -1100,14 +1242,36 @@ check_ivm_restriction_walker(Node *node, void *context)
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("OUTER JOIN is not supported on incrementally maintainable materialized view")));
- expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
+ break;
}
- break;
case T_Aggref:
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("aggregate function is not supported on incrementally maintainable materialized view")));
- break;
+ {
+ /* Check if this supports IVM */
+ Aggref *aggref = (Aggref *) node;
+ const char *aggname = format_procedure(aggref->aggfnoid);
+
+ if (aggref->aggfilter != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with FILTER clause is not supported on incrementally maintainable materialized view")));
+
+ if (aggref->aggdistinct != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with DISTINCT arguments is not supported on incrementally maintainable materialized view")));
+
+ if (aggref->aggorder != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with ORDER clause is not supported on incrementally maintainable materialized view")));
+
+ if (!check_aggregate_supports_ivm(aggref->aggfnoid))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function %s is not supported on incrementally maintainable materialized view", aggname)));
+ break;
+ }
default:
expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
break;
@@ -1115,6 +1279,46 @@ check_ivm_restriction_walker(Node *node, void *context)
return false;
}
+/*
+ * check_aggregate_supports_ivm
+ *
+ * Check if the given aggregate function is supporting IVM
+ */
+static bool
+check_aggregate_supports_ivm(Oid aggfnoid)
+{
+ switch (aggfnoid)
+ {
+ /* count */
+ case F_COUNT_ANY:
+ case F_COUNT_:
+
+ /* sum */
+ case F_SUM_INT8:
+ case F_SUM_INT4:
+ case F_SUM_INT2:
+ case F_SUM_FLOAT4:
+ case F_SUM_FLOAT8:
+ case F_SUM_MONEY:
+ case F_SUM_INTERVAL:
+ case F_SUM_NUMERIC:
+
+ /* avg */
+ case F_AVG_INT8:
+ case F_AVG_INT4:
+ case F_AVG_INT2:
+ case F_AVG_NUMERIC:
+ case F_AVG_FLOAT4:
+ case F_AVG_FLOAT8:
+ case F_AVG_INTERVAL:
+
+ return true;
+
+ default:
+ return false;
+ }
+}
+
/*
* CreateIndexOnIMMV
*
@@ -1172,7 +1376,29 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
index->concurrent = false;
index->if_not_exists = false;
- if (query->distinctClause)
+ if (query->groupClause)
+ {
+ /* create unique constraint on GROUP BY expression columns */
+ foreach(lc, query->groupClause)
+ {
+ SortGroupClause *scl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(scl, query->targetList);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ else if (query->distinctClause)
{
/* create unique constraint on all columns */
foreach(lc, query->targetList)
@@ -1230,7 +1456,7 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
(errmsg("could not create an index on materialized view \"%s\" automatically",
RelationGetRelationName(matviewRel)),
errdetail("This target list does not have all the primary key columns, "
- "or this view does not contain DISTINCT clause."),
+ "or this view does not contain GROUP BY or DISTINCT clause."),
errhint("Create an index on the materialized view for efficient incremental maintenance.")));
return;
}
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index dbcbc79fff..3c523991ed 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -30,6 +30,7 @@
#include "catalog/pg_opclass.h"
#include "catalog/pg_operator.h"
#include "commands/cluster.h"
+#include "commands/defrem.h"
#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
@@ -39,6 +40,7 @@
#include "executor/tstoreReceiver.h"
#include "miscadmin.h"
#include "nodes/makefuncs.h"
+#include "optimizer/optimizer.h"
#include "parser/analyze.h"
#include "parser/parse_clause.h"
#include "parser/parse_func.h"
@@ -111,6 +113,13 @@ static HTAB *mv_trigger_info = NULL;
static bool in_delta_calculation = false;
+/* kind of IVM operation for the view */
+typedef enum
+{
+ IVM_ADD,
+ IVM_SUB
+} IvmOp;
+
/* ENR name for materialized view delta */
#define NEW_DELTA_ENRNAME "new_delta"
#define OLD_DELTA_ENRNAME "old_delta"
@@ -142,7 +151,7 @@ static RangeTblEntry *get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *tabl
QueryEnvironment *queryEnv, Oid matviewid);
static RangeTblEntry *replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
QueryEnvironment *queryEnv);
-static Query *rewrite_query_for_counting(Query *query, ParseState *pstate);
+static Query *rewrite_query_for_counting_and_aggregates(Query *query, ParseState *pstate);
static void calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
DestReceiver *dest_old, DestReceiver *dest_new,
@@ -153,14 +162,27 @@ static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *
static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
Query *query, bool use_count, char *count_colname);
+static void append_set_clause_for_count(const char *resname, StringInfo buf_old,
+ StringInfo buf_new,StringInfo aggs_list);
+static void append_set_clause_for_sum(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list);
+static void append_set_clause_for_avg(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ const char *aggtype);
+static char *get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
+ const char* count_col, const char *castType);
+static char *get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
+ const char* count_col);
static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
- List *keys, const char *count_colname);
+ List *keys, StringInfo aggs_list, StringInfo aggs_set,
+ const char *count_colname);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
- List *keys, StringInfo target_list, const char* count_colname);
+ List *keys, StringInfo target_list, StringInfo aggs_set,
+ const char* count_colname);
static char *get_matching_condition_string(List *keys);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
@@ -1453,11 +1475,44 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
* When a base table is truncated, the view content will be empty if the
* view definition query does not contain an aggregate without a GROUP clause.
* Therefore, such views can be truncated.
+ *
+ * Aggregate views without a GROUP clause always have one row. Therefore,
+ * if a base table is truncated, the view will not be empty and will contain
+ * a row with NULL value (or 0 for count()). So, in this case, we refresh the
+ * view instead of truncating it.
*/
if (TRIGGER_FIRED_BY_TRUNCATE(trigdata->tg_event))
{
- ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
- NIL, DROP_RESTRICT, false, false);
+ if (!(query->hasAggs && query->groupClause == NIL))
+ ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
+ NIL, DROP_RESTRICT, false, false);
+ else
+ {
+ Oid OIDNewHeap;
+ DestReceiver *dest;
+ uint64 processed = 0;
+ Query *dataQuery = rewriteQueryForIMMV(query, NIL);
+ char relpersistence = matviewRel->rd_rel->relpersistence;
+
+ /*
+ * Create the transient table that will receive the regenerated data. Lock
+ * it against access by any other process until commit (by which time it
+ * will be gone).
+ */
+ OIDNewHeap = make_new_heap(matviewOid, matviewRel->rd_rel->reltablespace,
+ matviewRel->rd_rel->relam,
+ relpersistence, ExclusiveLock);
+ LockRelationOid(OIDNewHeap, AccessExclusiveLock);
+ dest = CreateTransientRelDestReceiver(OIDNewHeap);
+
+ /* Generate the data */
+ processed = refresh_matview_datafill(dest, dataQuery, NULL, NULL, "");
+ refresh_by_heap_swap(matviewOid, OIDNewHeap, relpersistence);
+
+ /* Inform cumulative stats system about our activity */
+ pgstat_count_truncate(matviewRel);
+ pgstat_count_heap_insert(matviewRel, processed);
+ }
/* Clean up hash entry and delete tuplestores */
clean_up_IVM_hash_entry(entry, false);
@@ -1497,8 +1552,8 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
/* Set all tables in the query to pre-update state */
rewritten = rewrite_query_for_preupdate_state(rewritten, entry->tables,
pstate, matviewOid);
- /* Rewrite for counting duplicated tuples */
- rewritten = rewrite_query_for_counting(rewritten, pstate);
+ /* Rewrite for counting duplicated tuples and aggregates functions*/
+ rewritten = rewrite_query_for_counting_and_aggregates(rewritten, pstate);
/* Create tuplestores to store view deltas */
if (entry->has_old)
@@ -1549,7 +1604,7 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
count_colname = pstrdup("__ivm_count__");
- if (query->distinctClause)
+ if (query->hasAggs || query->distinctClause)
use_count = true;
/* calculate delta tables */
@@ -1945,17 +2000,34 @@ replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
}
/*
- * rewrite_query_for_counting
+ * rewrite_query_for_counting_and_aggregates
*
- * Rewrite query for counting duplicated tuples.
+ * Rewrite query for counting duplicated tuples and aggregate functions.
*/
static Query *
-rewrite_query_for_counting(Query *query, ParseState *pstate)
+rewrite_query_for_counting_and_aggregates(Query *query, ParseState *pstate)
{
TargetEntry *tle_count;
FuncCall *fn;
Node *node;
+ /* For aggregate views */
+ if (query->hasAggs)
+ {
+ ListCell *lc;
+ List *aggs = NIL;
+ AttrNumber next_resno = list_length(query->targetList) + 1;
+
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+
+ if (IsA(tle->expr, Aggref))
+ makeIvmAggColumn(pstate, (Aggref *)tle->expr, tle->resname, &next_resno, &aggs);
+ }
+ query->targetList = list_concat(query->targetList, aggs);
+ }
+
/* Add count(*) for counting distinct tuples in views */
fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
fn->agg_star = true;
@@ -2028,6 +2100,8 @@ rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte
return query;
}
+#define IVM_colname(type, col) makeObjectName("__ivm_" type, col, "_")
+
/*
* apply_delta
*
@@ -2041,6 +2115,9 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
{
StringInfoData querybuf;
StringInfoData target_list_buf;
+ StringInfo aggs_list_buf = NULL;
+ StringInfo aggs_set_old = NULL;
+ StringInfo aggs_set_new = NULL;
Relation matviewRel;
char *matviewname;
ListCell *lc;
@@ -2063,6 +2140,15 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
initStringInfo(&querybuf);
initStringInfo(&target_list_buf);
+ if (query->hasAggs)
+ {
+ if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
+ aggs_set_old = makeStringInfo();
+ if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
+ aggs_set_new = makeStringInfo();
+ aggs_list_buf = makeStringInfo();
+ }
+
/* build string of target list */
for (i = 0; i < matviewRel->rd_att->natts; i++)
{
@@ -2079,13 +2165,61 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
i++;
if (tle->resjunk)
continue;
- keys = lappend(keys, attr);
+ /*
+ * For views without aggregates, all attributes are used as keys to identify a
+ * tuple in a view.
+ */
+ if (!query->hasAggs)
+ keys = lappend(keys, attr);
+
+ /* For views with aggregates, we need to build SET clause for updating aggregate
+ * values. */
+ if (query->hasAggs && IsA(tle->expr, Aggref))
+ {
+ Aggref *aggref = (Aggref *) tle->expr;
+ const char *aggname = get_func_name(aggref->aggfnoid);
+
+ /*
+ * We can use function names here because it is already checked if these
+ * can be used in IMMV by its OID at the definition time.
+ */
+
+ /* count */
+ if (!strcmp(aggname, "count"))
+ append_set_clause_for_count(resname, aggs_set_old, aggs_set_new, aggs_list_buf);
+
+ /* sum */
+ else if (!strcmp(aggname, "sum"))
+ append_set_clause_for_sum(resname, aggs_set_old, aggs_set_new, aggs_list_buf);
+
+ /* avg */
+ else if (!strcmp(aggname, "avg"))
+ append_set_clause_for_avg(resname, aggs_set_old, aggs_set_new, aggs_list_buf,
+ format_type_be(aggref->aggtype));
+
+ else
+ elog(ERROR, "unsupported aggregate function: %s", aggname);
+ }
+ }
+
+ /* If we have GROUP BY clause, we use its entries as keys. */
+ if (query->hasAggs && query->groupClause)
+ {
+ foreach (lc, query->groupClause)
+ {
+ SortGroupClause *sgcl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(sgcl, query->targetList);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ keys = lappend(keys, attr);
+ }
}
/* Start maintaining the materialized view. */
@@ -2116,7 +2250,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (use_count)
/* apply old delta and get rows to be recalculated */
apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
- keys, count_colname);
+ keys, aggs_list_buf, aggs_set_old,
+ count_colname);
else
apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
@@ -2142,7 +2277,7 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
/* apply new delta */
if (use_count)
apply_new_delta_with_count(matviewname, NEW_DELTA_ENRNAME,
- keys, &target_list_buf, count_colname);
+ keys, aggs_set_new, &target_list_buf, count_colname);
else
apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
}
@@ -2157,6 +2292,250 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_finish failed");
}
+/*
+ * append_set_clause_for_count
+ *
+ * Append SET clause string for count aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_count(const char *resname, StringInfo buf_old,
+ StringInfo buf_new,StringInfo aggs_list)
+{
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* resname = mv.resname - t.resname */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, resname, "mv", "t", NULL, NULL));
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* resname = mv.resname + diff.resname */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, resname, "mv", "diff", NULL, NULL));
+ }
+
+ appendStringInfo(aggs_list, ", %s",
+ quote_qualified_identifier("diff", resname)
+ );
+}
+
+/*
+ * append_set_clause_for_sum
+ *
+ * Append SET clause string for sum aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_sum(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list)
+{
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* sum = mv.sum - t.sum */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, resname, "mv", "t", count_col, NULL)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* sum = mv.sum + diff.sum */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, resname, "mv", "diff", count_col, NULL)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
+/*
+ * append_set_clause_for_avg
+ *
+ * Append SET clause string for avg aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_avg(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ const char *aggtype)
+{
+ char *sum_col = IVM_colname("sum", resname);
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* avg = (mv.sum - t.sum)::aggtype / (mv.count - t.count) */
+ appendStringInfo(buf_old,
+ ", %s = %s OPERATOR(pg_catalog./) %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, sum_col, "mv", "t", count_col, aggtype),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ /* sum = mv.sum - t.sum */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, sum_col),
+ get_operation_string(IVM_SUB, sum_col, "mv", "t", count_col, NULL)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* avg = (mv.sum + diff.sum)::aggtype / (mv.count + diff.count) */
+ appendStringInfo(buf_new,
+ ", %s = %s OPERATOR(pg_catalog./) %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, sum_col, "mv", "diff", count_col, aggtype),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ /* sum = mv.sum + diff.sum */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, sum_col),
+ get_operation_string(IVM_ADD, sum_col, "mv", "diff", count_col, NULL)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("sum", resname)),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
+/*
+ * get_operation_string
+ *
+ * Build a string to calculate the new aggregate values.
+ */
+static char *
+get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
+ const char* count_col, const char *castType)
+{
+ StringInfoData buf;
+ StringInfoData castString;
+ char *col1 = quote_qualified_identifier(arg1, col);
+ char *col2 = quote_qualified_identifier(arg2, col);
+ char op_char = (op == IVM_SUB ? '-' : '+');
+
+ initStringInfo(&buf);
+ initStringInfo(&castString);
+
+ if (castType)
+ appendStringInfo(&castString, "::%s", castType);
+
+ if (!count_col)
+ {
+ /*
+ * If the attributes don't have count columns then calc the result
+ * by using the operator simply.
+ */
+ appendStringInfo(&buf, "(%s OPERATOR(pg_catalog.%c) %s)%s",
+ col1, op_char, col2, castString.data);
+ }
+ else
+ {
+ /*
+ * If the attributes have count columns then consider the condition
+ * where the result becomes NULL.
+ */
+ char *null_cond = get_null_condition_string(op, arg1, arg2, count_col);
+
+ appendStringInfo(&buf,
+ "(CASE WHEN %s THEN NULL "
+ "WHEN %s IS NULL THEN %s "
+ "WHEN %s IS NULL THEN %s "
+ "ELSE (%s OPERATOR(pg_catalog.%c) %s)%s END)",
+ null_cond,
+ col1, col2,
+ col2, col1,
+ col1, op_char, col2, castString.data
+ );
+ }
+
+ return buf.data;
+}
+
+/*
+ * get_null_condition_string
+ *
+ * Build a predicate string for CASE clause to check if an aggregate value
+ * will became NULL after the given operation is applied.
+ */
+static char *
+get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
+ const char* count_col)
+{
+ StringInfoData null_cond;
+ initStringInfo(&null_cond);
+
+ switch (op)
+ {
+ case IVM_ADD:
+ appendStringInfo(&null_cond,
+ "%s OPERATOR(pg_catalog.=) 0 AND %s OPERATOR(pg_catalog.=) 0",
+ quote_qualified_identifier(arg1, count_col),
+ quote_qualified_identifier(arg2, count_col)
+ );
+ break;
+ case IVM_SUB:
+ appendStringInfo(&null_cond,
+ "%s OPERATOR(pg_catalog.=) %s",
+ quote_qualified_identifier(arg1, count_col),
+ quote_qualified_identifier(arg2, count_col)
+ );
+ break;
+ default:
+ elog(ERROR,"unknown operation");
+ }
+
+ return null_cond.data;
+}
+
+
/*
* apply_old_delta_with_count
*
@@ -2164,13 +2543,20 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
* which contains tuples to be deleted from to a materialized view given by
* matviewname. This is used when counting is required, that is, the view
* has aggregate or distinct.
+ *
+ * If the view desn't have aggregates or has GROUP BY, this requires a keys
+ * list to identify a tuple in the view. If the view has aggregates, this
+ * requires strings representing resnames of aggregates and SET clause for
+ * updating aggregate values.
*/
static void
apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
- List *keys, const char *count_colname)
+ List *keys, StringInfo aggs_list, StringInfo aggs_set,
+ const char *count_colname)
{
StringInfoData querybuf;
char *match_cond;
+ bool agg_without_groupby = (list_length(keys) == 0);
/* build WHERE condition for searching tuples to be deleted */
match_cond = get_matching_condition_string(keys);
@@ -2180,22 +2566,26 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
appendStringInfo(&querybuf,
"WITH t AS (" /* collecting tid of target tuples in the view */
"SELECT diff.%s, " /* count column */
- "(diff.%s OPERATOR(pg_catalog.=) mv.%s) AS for_dlt, "
+ "(diff.%s OPERATOR(pg_catalog.=) mv.%s AND %s) AS for_dlt, "
"mv.ctid "
+ "%s " /* aggregate columns */
"FROM %s AS mv, %s AS diff "
"WHERE %s" /* tuple matching condition */
"), updt AS (" /* update a tuple if this is not to be deleted */
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
+ "%s" /* SET clauses for aggregates */
"FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
")"
/* delete a tuple if this is to be deleted */
"DELETE FROM %s AS mv USING t "
"WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
count_colname,
- count_colname, count_colname,
+ count_colname, count_colname, (agg_without_groupby ? "false" : "true"),
+ (aggs_list != NULL ? aggs_list->data : ""),
matviewname, deltaname_old,
match_cond,
matviewname, count_colname, count_colname, count_colname,
+ (aggs_set != NULL ? aggs_set->data : ""),
matviewname);
if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
@@ -2259,10 +2649,15 @@ apply_old_delta(const char *matviewname, const char *deltaname_old,
* matviewname. This is used when counting is required, that is, the view
* has aggregate or distinct. Also, when a table in EXISTS sub queries
* is modified.
+ *
+ * If the view desn't have aggregates or has GROUP BY, this requires a keys
+ * list to identify a tuple in the view. If the view has aggregates, this
+ * requires strings representing SET clause for updating aggregate values.
*/
static void
apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
- List *keys, StringInfo target_list, const char* count_colname)
+ List *keys, StringInfo aggs_set, StringInfo target_list,
+ const char* count_colname)
{
StringInfoData querybuf;
StringInfoData returning_keys;
@@ -2293,6 +2688,7 @@ apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
appendStringInfo(&querybuf,
"WITH updt AS (" /* update a tuple if this exists in the view */
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.+) diff.%s "
+ "%s " /* SET clauses for aggregates */
"FROM %s AS diff "
"WHERE %s " /* tuple matching condition */
"RETURNING %s" /* returning keys of updated tuples */
@@ -2300,6 +2696,7 @@ apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
"SELECT %s FROM %s AS diff "
"WHERE NOT EXISTS (SELECT 1 FROM updt AS mv WHERE %s);",
matviewname, count_colname, count_colname, count_colname,
+ (aggs_set != NULL ? aggs_set->data : ""),
deltaname_new,
match_cond,
returning_keys.data,
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 6b47e66bfd..af3a5b4b27 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -30,6 +30,7 @@ extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
extern Query *rewriteQueryForIMMV(Query *query, List *colNames);
+extern void makeIvmAggColumn(ParseState *pstate, Aggref *aggref, char *resname, AttrNumber *next_resno, List **aggs);
extern int GetIntoRelEFlags(IntoClause *intoClause);
--
2.25.1
v30-0009-Add-support-for-min-max-aggregates-for-IVM.patchtext/x-diff; name=v30-0009-Add-support-for-min-max-aggregates-for-IVM.patchDownload
From d75d1a9f68f767b1f292624ca04e4c0d2661a52b Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 20:58:25 +0900
Subject: [PATCH v30 09/11] Add support for min/max aggregates for IVM
Supporting min and max is more complicated than count, sum, or avg.
For an example of min, when tuples are inserted, the current min value
in the view and the min value in the inseteted tuples are compared,
then the smaller one is used as the latest min value. On the other
hand, when tuples are deleted, if the current min value in the view
equals to the min in the deleted tuples, we need re-computation the
latest min value from base tables. Otherwise, the current value in
the view remains.
---
src/backend/commands/createas.c | 45 +++
src/backend/commands/matview.c | 644 +++++++++++++++++++++++++++++++-
2 files changed, 680 insertions(+), 9 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index d93eec3eec..0536e44b9e 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -1312,6 +1312,51 @@ check_aggregate_supports_ivm(Oid aggfnoid)
case F_AVG_FLOAT8:
case F_AVG_INTERVAL:
+ /* min */
+ case F_MIN_ANYARRAY:
+ case F_MIN_INT8:
+ case F_MIN_INT4:
+ case F_MIN_INT2:
+ case F_MIN_OID:
+ case F_MIN_FLOAT4:
+ case F_MIN_FLOAT8:
+ case F_MIN_DATE:
+ case F_MIN_TIME:
+ case F_MIN_TIMETZ:
+ case F_MIN_MONEY:
+ case F_MIN_TIMESTAMP:
+ case F_MIN_TIMESTAMPTZ:
+ case F_MIN_INTERVAL:
+ case F_MIN_TEXT:
+ case F_MIN_NUMERIC:
+ case F_MIN_BPCHAR:
+ case F_MIN_TID:
+ case F_MIN_ANYENUM:
+ case F_MIN_INET:
+ case F_MIN_PG_LSN:
+
+ /* max */
+ case F_MAX_ANYARRAY:
+ case F_MAX_INT8:
+ case F_MAX_INT4:
+ case F_MAX_INT2:
+ case F_MAX_OID:
+ case F_MAX_FLOAT4:
+ case F_MAX_FLOAT8:
+ case F_MAX_DATE:
+ case F_MAX_TIME:
+ case F_MAX_TIMETZ:
+ case F_MAX_MONEY:
+ case F_MAX_TIMESTAMP:
+ case F_MAX_TIMESTAMPTZ:
+ case F_MAX_INTERVAL:
+ case F_MAX_TEXT:
+ case F_MAX_NUMERIC:
+ case F_MAX_BPCHAR:
+ case F_MAX_TID:
+ case F_MAX_ANYENUM:
+ case F_MAX_INET:
+ case F_MAX_PG_LSN:
return true;
default:
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index 3c523991ed..e60f92226c 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -73,6 +73,34 @@ typedef struct
#define MV_INIT_QUERYHASHSIZE 16
+/* MV query type codes */
+#define MV_PLAN_RECALC 1
+#define MV_PLAN_SET_VALUE 2
+
+/*
+ * MI_QueryKey
+ *
+ * The key identifying a prepared SPI plan in our query hashtable
+ */
+typedef struct MV_QueryKey
+{
+ Oid matview_id; /* OID of materialized view */
+ int32 query_type; /* query type ID, see MV_PLAN_XXX above */
+} MV_QueryKey;
+
+/*
+ * MV_QueryHashEntry
+ *
+ * Hash entry for cached plans used to maintain materialized views.
+ */
+typedef struct MV_QueryHashEntry
+{
+ MV_QueryKey key;
+ SPIPlanPtr plan;
+ SearchPathMatcher *search_path; /* search_path used for parsing
+ * and planning */
+} MV_QueryHashEntry;
+
/*
* MV_TriggerHashEntry
*
@@ -109,6 +137,7 @@ typedef struct MV_TriggerTable
TupleTableSlot *slot; /* for checking visibility in the pre-state table */
} MV_TriggerTable;
+static HTAB *mv_query_cache = NULL;
static HTAB *mv_trigger_info = NULL;
static bool in_delta_calculation = false;
@@ -169,6 +198,9 @@ static void append_set_clause_for_sum(const char *resname, StringInfo buf_old,
static void append_set_clause_for_avg(const char *resname, StringInfo buf_old,
StringInfo buf_new, StringInfo aggs_list,
const char *aggtype);
+static void append_set_clause_for_minmax(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ bool is_min);
static char *get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
const char* count_col, const char *castType);
static char *get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
@@ -177,17 +209,30 @@ static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
List *keys, StringInfo aggs_list, StringInfo aggs_set,
- const char *count_colname);
+ List *minmax_list, List *is_min_list,
+ const char *count_colname,
+ SPITupleTable **tuptable_recalc, uint64 *num_recalc);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
List *keys, StringInfo target_list, StringInfo aggs_set,
const char* count_colname);
static char *get_matching_condition_string(List *keys);
+static char *get_returning_string(List *minmax_list, List *is_min_list, List *keys);
+static char *get_minmax_recalc_condition_string(List *minmax_list, List *is_min_list);
+static char *get_select_for_recalc_string(List *keys);
+static void recalc_and_set_values(SPITupleTable *tuptable_recalc, int64 num_tuples,
+ List *namelist, List *keys, Relation matviewRel);
+static SPIPlanPtr get_plan_for_recalc(Oid matviewOid, List *namelist, List *keys, Oid *keyTypes);
+static SPIPlanPtr get_plan_for_set_values(Oid matviewOid, char *matviewname, List *namelist,
+ Oid *valTypes);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
static void mv_InitHashTables(void);
+static SPIPlanPtr mv_FetchPreparedPlan(MV_QueryKey *key);
+static void mv_HashPreparedPlan(MV_QueryKey *key, SPIPlanPtr plan);
+static void mv_BuildQueryKey(MV_QueryKey *key, Oid matview_id, int32 query_type);
static void clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort);
/*
@@ -2123,6 +2168,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
ListCell *lc;
int i;
List *keys = NIL;
+ List *minmax_list = NIL;
+ List *is_min_list = NIL;
/*
@@ -2204,6 +2251,17 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
append_set_clause_for_avg(resname, aggs_set_old, aggs_set_new, aggs_list_buf,
format_type_be(aggref->aggtype));
+ /* min/max */
+ else if (!strcmp(aggname, "min") || !strcmp(aggname, "max"))
+ {
+ bool is_min = (!strcmp(aggname, "min"));
+
+ append_set_clause_for_minmax(resname, aggs_set_old, aggs_set_new, aggs_list_buf, is_min);
+
+ /* make a resname list of min and max aggregates */
+ minmax_list = lappend(minmax_list, resname);
+ is_min_list = lappend_int(is_min_list, is_min);
+ }
else
elog(ERROR, "unsupported aggregate function: %s", aggname);
}
@@ -2233,6 +2291,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
{
EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ SPITupleTable *tuptable_recalc = NULL;
+ uint64 num_recalc;
int rc;
/* convert tuplestores to ENR, and register for SPI */
@@ -2251,10 +2311,18 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
/* apply old delta and get rows to be recalculated */
apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
keys, aggs_list_buf, aggs_set_old,
- count_colname);
+ minmax_list, is_min_list,
+ count_colname, &tuptable_recalc, &num_recalc);
else
apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+ /*
+ * If we have min or max, we might have to recalculate aggregate values from base tables
+ * on some tuples. TIDs and keys such tuples are returned as a result of the above query.
+ */
+ if (minmax_list && tuptable_recalc)
+ recalc_and_set_values(tuptable_recalc, num_recalc, minmax_list, keys, matviewRel);
+
}
/* For tuple insertion */
if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
@@ -2446,6 +2514,70 @@ append_set_clause_for_avg(const char *resname, StringInfo buf_old,
);
}
+/*
+ * append_set_clause_for_minmax
+ *
+ * Append SET clause string for min or max aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ * is_min is true if this is min, false if not.
+ */
+static void
+append_set_clause_for_minmax(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ bool is_min)
+{
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /*
+ * If the new value doesn't became NULL then use the value remaining
+ * in the view although this will be recomputated afterwords.
+ */
+ appendStringInfo(buf_old,
+ ", %s = CASE WHEN %s THEN NULL ELSE %s END",
+ quote_qualified_identifier(NULL, resname),
+ get_null_condition_string(IVM_SUB, "mv", "t", count_col),
+ quote_qualified_identifier("mv", resname)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /*
+ * min = LEAST(mv.min, diff.min)
+ * max = GREATEST(mv.max, diff.max)
+ */
+ appendStringInfo(buf_new,
+ ", %s = CASE WHEN %s THEN NULL ELSE %s(%s,%s) END",
+ quote_qualified_identifier(NULL, resname),
+ get_null_condition_string(IVM_ADD, "mv", "diff", count_col),
+
+ is_min ? "LEAST" : "GREATEST",
+ quote_qualified_identifier("mv", resname),
+ quote_qualified_identifier("diff", resname)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
/*
* get_operation_string
*
@@ -2548,19 +2680,44 @@ get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
* list to identify a tuple in the view. If the view has aggregates, this
* requires strings representing resnames of aggregates and SET clause for
* updating aggregate values.
+ *
+ * If the view has min or max aggregate, this requires a list of resnames of
+ * min/max aggregates and a list of boolean which represents which entries in
+ * minmax_list is min. These are necessary to check if we need to recalculate
+ * min or max aggregate values. In this case, this query returns TID and keys
+ * of tuples which need to be recalculated. This result and the number of rows
+ * are stored in tuptables and num_recalc repectedly.
+ *
*/
static void
apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
List *keys, StringInfo aggs_list, StringInfo aggs_set,
- const char *count_colname)
+ List *minmax_list, List *is_min_list,
+ const char *count_colname,
+ SPITupleTable **tuptable_recalc, uint64 *num_recalc)
{
StringInfoData querybuf;
char *match_cond;
+ char *updt_returning = "";
+ char *select_for_recalc = "SELECT";
bool agg_without_groupby = (list_length(keys) == 0);
+ Assert(tuptable_recalc != NULL);
+ Assert(num_recalc != NULL);
+
/* build WHERE condition for searching tuples to be deleted */
match_cond = get_matching_condition_string(keys);
+ /*
+ * We need a special RETURNING clause and SELECT statement for min/max to
+ * check which tuple needs re-calculation from base tables.
+ */
+ if (minmax_list)
+ {
+ updt_returning = get_returning_string(minmax_list, is_min_list, keys);
+ select_for_recalc = get_select_for_recalc_string(keys);
+ }
+
/* Search for matching tuples from the view and update or delete if found. */
initStringInfo(&querybuf);
appendStringInfo(&querybuf,
@@ -2575,10 +2732,11 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
"%s" /* SET clauses for aggregates */
"FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
- ")"
- /* delete a tuple if this is to be deleted */
- "DELETE FROM %s AS mv USING t "
- "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
+ "%s" /* RETURNING clause for recalc infomation */
+ "), dlt AS (" /* delete a tuple if this is to be deleted */
+ "DELETE FROM %s AS mv USING t "
+ "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt"
+ ") %s", /* SELECT returning which tuples need to be recalculated */
count_colname,
count_colname, count_colname, (agg_without_groupby ? "false" : "true"),
(aggs_list != NULL ? aggs_list->data : ""),
@@ -2586,10 +2744,25 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
match_cond,
matviewname, count_colname, count_colname, count_colname,
(aggs_set != NULL ? aggs_set->data : ""),
- matviewname);
+ updt_returning,
+ matviewname,
+ select_for_recalc);
- if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_SELECT)
elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+
+
+ /* Return tuples to be recalculated. */
+ if (minmax_list)
+ {
+ *tuptable_recalc = SPI_tuptable;
+ *num_recalc = SPI_processed;
+ }
+ else
+ {
+ *tuptable_recalc = NULL;
+ *num_recalc = 0;
+ }
}
/*
@@ -2772,6 +2945,349 @@ get_matching_condition_string(List *keys)
return match_cond.data;
}
+/*
+ * get_returning_string
+ *
+ * Build a string for RETURNING clause of UPDATE used in apply_old_delta_with_count.
+ * This clause returns ctid and a boolean value that indicates if we need to
+ * recalculate min or max value, for each updated row.
+ */
+static char *
+get_returning_string(List *minmax_list, List *is_min_list, List *keys)
+{
+ StringInfoData returning;
+ char *recalc_cond;
+ ListCell *lc;
+
+ Assert(minmax_list != NIL && is_min_list != NIL);
+ recalc_cond = get_minmax_recalc_condition_string(minmax_list, is_min_list);
+
+ initStringInfo(&returning);
+
+ appendStringInfo(&returning, "RETURNING mv.ctid AS tid, (%s) AS recalc", recalc_cond);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&returning, ", %s", quote_qualified_identifier("mv", resname));
+ }
+
+ return returning.data;
+}
+
+/*
+ * get_minmax_recalc_condition_string
+ *
+ * Build a predicate string for checking if any min/max aggregate
+ * value needs to be recalculated.
+ */
+static char *
+get_minmax_recalc_condition_string(List *minmax_list, List *is_min_list)
+{
+ StringInfoData recalc_cond;
+ ListCell *lc1, *lc2;
+
+ initStringInfo(&recalc_cond);
+
+ Assert (list_length(minmax_list) == list_length(is_min_list));
+
+ forboth (lc1, minmax_list, lc2, is_min_list)
+ {
+ char *resname = (char *) lfirst(lc1);
+ bool is_min = (bool) lfirst_int(lc2);
+ char *op_str = (is_min ? ">=" : "<=");
+
+ appendStringInfo(&recalc_cond, "%s OPERATOR(pg_catalog.%s) %s",
+ quote_qualified_identifier("mv", resname),
+ op_str,
+ quote_qualified_identifier("t", resname)
+ );
+
+ if (lnext(minmax_list, lc1))
+ appendStringInfo(&recalc_cond, " OR ");
+ }
+
+ return recalc_cond.data;
+}
+
+/*
+ * get_select_for_recalc_string
+ *
+ * Build a query to return tid and keys of tuples which need
+ * recalculation. This is used as the result of the query
+ * built by apply_old_delta.
+ */
+static char *
+get_select_for_recalc_string(List *keys)
+{
+ StringInfoData qry;
+ ListCell *lc;
+
+ initStringInfo(&qry);
+
+ appendStringInfo(&qry, "SELECT tid");
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ appendStringInfo(&qry, ", %s", NameStr(attr->attname));
+ }
+
+ appendStringInfo(&qry, " FROM updt WHERE recalc");
+
+ return qry.data;
+}
+
+/*
+ * recalc_and_set_values
+ *
+ * Recalculate tuples in a materialized from base tables and update these.
+ * The tuples which needs recalculation are specified by keys, and resnames
+ * of columns to be updated are specified by namelist. TIDs and key values
+ * are given by tuples in tuptable_recalc. Its first attribute must be TID
+ * and key values must be following this.
+ */
+static void
+recalc_and_set_values(SPITupleTable *tuptable_recalc, int64 num_tuples,
+ List *namelist, List *keys, Relation matviewRel)
+{
+ TupleDesc tupdesc_recalc = tuptable_recalc->tupdesc;
+ Oid *keyTypes = NULL, *types = NULL;
+ char *keyNulls = NULL, *nulls = NULL;
+ Datum *keyVals = NULL, *vals = NULL;
+ int num_vals = list_length(namelist);
+ int num_keys = list_length(keys);
+ uint64 i;
+ Oid matviewOid;
+ char *matviewname;
+
+ matviewOid = RelationGetRelid(matviewRel);
+ matviewname = quote_qualified_identifier(get_namespace_name(RelationGetNamespace(matviewRel)),
+ RelationGetRelationName(matviewRel));
+
+ /* If we have keys, initialize arrays for them. */
+ if (keys)
+ {
+ keyTypes = palloc(sizeof(Oid) * num_keys);
+ keyNulls = palloc(sizeof(char) * num_keys);
+ keyVals = palloc(sizeof(Datum) * num_keys);
+ /* a tuple contains keys to be recalculated and ctid to be updated*/
+ Assert(tupdesc_recalc->natts == num_keys + 1);
+
+ /* Types of key attributes */
+ for (i = 0; i < num_keys; i++)
+ keyTypes[i] = TupleDescAttr(tupdesc_recalc, i + 1)->atttypid;
+ }
+
+ /* allocate memory for all attribute names and tid */
+ types = palloc(sizeof(Oid) * (num_vals + 1));
+ nulls = palloc(sizeof(char) * (num_vals + 1));
+ vals = palloc(sizeof(Datum) * (num_vals + 1));
+
+ /* For each tuple which needs recalculation */
+ for (i = 0; i < num_tuples; i++)
+ {
+ int j;
+ bool isnull;
+ SPIPlanPtr plan;
+ SPITupleTable *tuptable_newvals;
+ TupleDesc tupdesc_newvals;
+
+ /* Set group key values as parameters if needed. */
+ if (keys)
+ {
+ for (j = 0; j < num_keys; j++)
+ {
+ keyVals[j] = SPI_getbinval(tuptable_recalc->vals[i], tupdesc_recalc, j + 2, &isnull);
+ if (isnull)
+ keyNulls[j] = 'n';
+ else
+ keyNulls[j] = ' ';
+ }
+ }
+
+ /*
+ * Get recalculated values from base tables. The result must be
+ * only one tuple thich contains the new values for specified keys.
+ */
+ plan = get_plan_for_recalc(matviewOid, namelist, keys, keyTypes);
+ if (SPI_execute_plan(plan, keyVals, keyNulls, false, 0) != SPI_OK_SELECT)
+ elog(ERROR, "SPI_execute_plan");
+ if (SPI_processed != 1)
+ elog(ERROR, "SPI_execute_plan returned zero or more than one rows");
+
+ tuptable_newvals = SPI_tuptable;
+ tupdesc_newvals = tuptable_newvals->tupdesc;
+
+ Assert(tupdesc_newvals->natts == num_vals);
+
+ /* Set the new values as parameters */
+ for (j = 0; j < tupdesc_newvals->natts; j++)
+ {
+ if (i == 0)
+ types[j] = TupleDescAttr(tupdesc_newvals, j)->atttypid;
+
+ vals[j] = SPI_getbinval(tuptable_newvals->vals[0], tupdesc_newvals, j + 1, &isnull);
+ if (isnull)
+ nulls[j] = 'n';
+ else
+ nulls[j] = ' ';
+ }
+ /* Set TID of the view tuple to be updated as a parameter */
+ types[j] = TIDOID;
+ vals[j] = SPI_getbinval(tuptable_recalc->vals[i], tupdesc_recalc, 1, &isnull);
+ nulls[j] = ' ';
+
+ /* Update the view tuple to the new values */
+ plan = get_plan_for_set_values(matviewOid, matviewname, namelist, types);
+ if (SPI_execute_plan(plan, vals, nulls, false, 0) != SPI_OK_UPDATE)
+ elog(ERROR, "SPI_execute_plan");
+ }
+}
+
+
+/*
+ * get_plan_for_recalc
+ *
+ * Create or fetch a plan for recalculating value in the view's target list
+ * from base tables using the definition query of materialized view specified
+ * by matviewOid. namelist is a list of resnames of values to be recalculated.
+ *
+ * keys is a list of keys to identify tuples to be recalculated if this is not
+ * empty. KeyTypes is an array of types of keys.
+ */
+static SPIPlanPtr
+get_plan_for_recalc(Oid matviewOid, List *namelist, List *keys, Oid *keyTypes)
+{
+ MV_QueryKey hash_key;
+ SPIPlanPtr plan;
+
+ /* Fetch or prepare a saved plan for the recalculation */
+ mv_BuildQueryKey(&hash_key, matviewOid, MV_PLAN_RECALC);
+ if ((plan = mv_FetchPreparedPlan(&hash_key)) == NULL)
+ {
+ ListCell *lc;
+ StringInfoData str;
+ char *viewdef;
+
+ /* get view definition of matview */
+ viewdef = text_to_cstring((text *) DatumGetPointer(
+ DirectFunctionCall1(pg_get_viewdef, ObjectIdGetDatum(matviewOid))));
+ /* get rid of trailing semi-colon */
+ viewdef[strlen(viewdef)-1] = '\0';
+
+ /*
+ * Build a query string for recalculating values. This is like
+ *
+ * SELECT x1, x2, x3, ... FROM ( ... view definition query ...) mv
+ * WHERE (key1, key2, ...) = ($1, $2, ...);
+ */
+
+ initStringInfo(&str);
+ appendStringInfo(&str, "SELECT ");
+ foreach (lc, namelist)
+ {
+ appendStringInfo(&str, "%s", (char *) lfirst(lc));
+ if (lnext(namelist, lc))
+ appendStringInfoString(&str, ", ");
+ }
+ appendStringInfo(&str, " FROM (%s) mv", viewdef);
+
+ if (keys)
+ {
+ int i = 1;
+ char paramname[16];
+
+ appendStringInfo(&str, " WHERE (");
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ Oid typid = attr->atttypid;
+
+ sprintf(paramname, "$%d", i);
+ appendStringInfo(&str, "(");
+ generate_equal(&str, typid, resname, paramname);
+ appendStringInfo(&str, " OR (%s IS NULL AND %s IS NULL))",
+ resname, paramname);
+
+ if (lnext(keys, lc))
+ appendStringInfoString(&str, " AND ");
+ i++;
+ }
+ appendStringInfo(&str, ")");
+ }
+ else
+ keyTypes = NULL;
+
+ plan = SPI_prepare(str.data, list_length(keys), keyTypes);
+ if (plan == NULL)
+ elog(ERROR, "SPI_prepare returned %s for %s", SPI_result_code_string(SPI_result), str.data);
+
+ SPI_keepplan(plan);
+ mv_HashPreparedPlan(&hash_key, plan);
+ }
+
+ return plan;
+}
+
+/*
+ * get_plan_for_set_values
+ *
+ * Create or fetch a plan for applying new values calculated by
+ * get_plan_for_recalc to a materialized view specified by matviewOid.
+ * matviewname is the name of the view. namelist is a list of resnames
+ * of attributes to be updated, and valTypes is an array of types of the
+ * values.
+ */
+static SPIPlanPtr
+get_plan_for_set_values(Oid matviewOid, char *matviewname, List *namelist,
+ Oid *valTypes)
+{
+ MV_QueryKey key;
+ SPIPlanPtr plan;
+
+ /* Fetch or prepare a saved plan for the real check */
+ mv_BuildQueryKey(&key, matviewOid, MV_PLAN_SET_VALUE);
+ if ((plan = mv_FetchPreparedPlan(&key)) == NULL)
+ {
+ ListCell *lc;
+ StringInfoData str;
+ int i;
+
+ /*
+ * Build a query string for applying min/max values. This is like
+ *
+ * UPDATE matviewname AS mv
+ * SET (x1, x2, x3, x4) = ($1, $2, $3, $4)
+ * WHERE ctid = $5;
+ */
+
+ initStringInfo(&str);
+ appendStringInfo(&str, "UPDATE %s AS mv SET (", matviewname);
+ foreach (lc, namelist)
+ {
+ appendStringInfo(&str, "%s", (char *) lfirst(lc));
+ if (lnext(namelist, lc))
+ appendStringInfoString(&str, ", ");
+ }
+ appendStringInfo(&str, ") = ROW(");
+
+ for (i = 1; i <= list_length(namelist); i++)
+ appendStringInfo(&str, "%s$%d", (i==1 ? "" : ", "), i);
+
+ appendStringInfo(&str, ") WHERE ctid OPERATOR(pg_catalog.=) $%d", i);
+
+ plan = SPI_prepare(str.data, list_length(namelist) + 1, valTypes);
+ if (plan == NULL)
+ elog(ERROR, "SPI_prepare returned %s for %s", SPI_result_code_string(SPI_result), str.data);
+
+ SPI_keepplan(plan);
+ mv_HashPreparedPlan(&key, plan);
+ }
+
+ return plan;
+}
+
/*
* generate_equals
*
@@ -2805,6 +3321,13 @@ mv_InitHashTables(void)
{
HASHCTL ctl;
+ memset(&ctl, 0, sizeof(ctl));
+ ctl.keysize = sizeof(MV_QueryKey);
+ ctl.entrysize = sizeof(MV_QueryHashEntry);
+ mv_query_cache = hash_create("MV query cache",
+ MV_INIT_QUERYHASHSIZE,
+ &ctl, HASH_ELEM | HASH_BLOBS);
+
memset(&ctl, 0, sizeof(ctl));
ctl.keysize = sizeof(Oid);
ctl.entrysize = sizeof(MV_TriggerHashEntry);
@@ -2813,6 +3336,109 @@ mv_InitHashTables(void)
&ctl, HASH_ELEM | HASH_BLOBS);
}
+/*
+ * mv_FetchPreparedPlan
+ */
+static SPIPlanPtr
+mv_FetchPreparedPlan(MV_QueryKey *key)
+{
+ MV_QueryHashEntry *entry;
+ SPIPlanPtr plan;
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_query_cache)
+ mv_InitHashTables();
+
+ /*
+ * Lookup for the key
+ */
+ entry = (MV_QueryHashEntry *) hash_search(mv_query_cache,
+ (void *) key,
+ HASH_FIND, NULL);
+ if (entry == NULL)
+ return NULL;
+
+ /*
+ * Check whether the plan is still valid. If it isn't, we don't want to
+ * simply rely on plancache.c to regenerate it; rather we should start
+ * from scratch and rebuild the query text too. This is to cover cases
+ * such as table/column renames. We depend on the plancache machinery to
+ * detect possible invalidations, though.
+ *
+ * CAUTION: this check is only trustworthy if the caller has already
+ * locked both materialized views and base tables.
+ *
+ * Also, check whether the search_path is still the same as when we made it.
+ * If it isn't, we need to rebuild the query text because the result of
+ * pg_ivm_get_viewdef() will change.
+ */
+ plan = entry->plan;
+ if (plan && SPI_plan_is_valid(plan) &&
+ SearchPathMatchesCurrentEnvironment(entry->search_path))
+ return plan;
+
+ /*
+ * Otherwise we might as well flush the cached plan now, to free a little
+ * memory space before we make a new one.
+ */
+ if (plan)
+ SPI_freeplan(plan);
+ if (entry->search_path)
+ pfree(entry->search_path);
+
+ entry->plan = NULL;
+ entry->search_path = NULL;
+
+ return NULL;
+}
+
+/*
+ * mv_HashPreparedPlan
+ *
+ * Add another plan to our private SPI query plan hashtable.
+ */
+static void
+mv_HashPreparedPlan(MV_QueryKey *key, SPIPlanPtr plan)
+{
+ MV_QueryHashEntry *entry;
+ bool found;
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_query_cache)
+ mv_InitHashTables();
+
+ /*
+ * Add the new plan. We might be overwriting an entry previously found
+ * invalid by mv_FetchPreparedPlan.
+ */
+ entry = (MV_QueryHashEntry *) hash_search(mv_query_cache,
+ (void *) key,
+ HASH_ENTER, &found);
+ Assert(!found || entry->plan == NULL);
+ entry->plan = plan;
+ entry->search_path = GetSearchPathMatcher(TopMemoryContext);
+}
+
+/*
+ * mv_BuildQueryKey
+ *
+ * Construct a hashtable key for a prepared SPI plan for IVM.
+ */
+static void
+mv_BuildQueryKey(MV_QueryKey *key, Oid matview_id, int32 query_type)
+{
+ /*
+ * We assume struct MV_QueryKey contains no padding bytes, else we'd need
+ * to use memset to clear them.
+ */
+ key->matview_id = matview_id;
+ key->query_type = query_type;
+}
+
/*
* AtAbort_IVM
*
--
2.25.1
v30-0010-Add-regression-tests-for-Incremental-View-Mainte.patchtext/x-diff; name=v30-0010-Add-regression-tests-for-Incremental-View-Mainte.patchDownload
From 2b72ecdadab40039abe2e7c5a26245e95e51b8d2 Mon Sep 17 00:00:00 2001
From: Takuma Hoshiai <takuma.hoshiai@gmail.com>
Date: Wed, 10 Mar 2021 11:11:13 +0900
Subject: [PATCH v30 10/11] Add regression tests for Incremental View
Maintenance
---
.../regress/expected/incremental_matview.out | 1030 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/incremental_matview.sql | 533 +++++++++
3 files changed, 1564 insertions(+), 1 deletion(-)
create mode 100644 src/test/regress/expected/incremental_matview.out
create mode 100644 src/test/regress/sql/incremental_matview.sql
diff --git a/src/test/regress/expected/incremental_matview.out b/src/test/regress/expected/incremental_matview.out
new file mode 100644
index 0000000000..8946d09f5d
--- /dev/null
+++ b/src/test/regress/expected/incremental_matview.out
@@ -0,0 +1,1030 @@
+-- create a table to use as a basis for views and materialized views in various combinations
+CREATE TABLE mv_base_a (i int, j int);
+INSERT INTO mv_base_a VALUES
+ (1,10),
+ (2,20),
+ (3,30),
+ (4,40),
+ (5,50);
+CREATE TABLE mv_base_b (i int, k int);
+INSERT INTO mv_base_b VALUES
+ (1,101),
+ (2,102),
+ (3,103),
+ (4,104);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_1 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) WITH NO DATA;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ERROR: materialized view "mv_ivm_1" has not been populated
+HINT: Use the REFRESH MATERIALIZED VIEW command.
+REFRESH MATERIALIZED VIEW mv_ivm_1;
+NOTICE: could not create an index on materialized view "mv_ivm_1" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+-- REFRESH WITH NO DATA
+BEGIN;
+CREATE FUNCTION dummy_ivm_trigger_func() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+CREATE CONSTRAINT TRIGGER dummy_ivm_trigger AFTER INSERT
+ON mv_base_a FROM mv_ivm_1 FOR EACH ROW
+EXECUTE PROCEDURE dummy_ivm_trigger_func();
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ count
+-------
+ 17
+(1 row)
+
+REFRESH MATERIALIZED VIEW mv_ivm_1 WITH NO DATA;
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+-- immediate maintenance
+BEGIN;
+INSERT INTO mv_base_b VALUES(5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+ 5 | 50 | 105
+(5 rows)
+
+UPDATE mv_base_a SET j = 0 WHERE i = 1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 0 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+ 5 | 50 | 105
+(5 rows)
+
+DELETE FROM mv_base_b WHERE (i,k) = (5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 0 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+ROLLBACK;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+-- rename of IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS SELECT DISTINCT * FROM mv_base_a;
+NOTICE: created index "mv_ivm_rename_index" on materialized view "mv_ivm_rename"
+ALTER MATERIALIZED VIEW mv_ivm_rename RENAME COLUMN __ivm_count__ TO xxx;
+ERROR: IVM column can not be renamed
+DROP MATERIALIZED VIEW mv_ivm_rename;
+-- unique index on IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_unique AS SELECT DISTINCT * FROM mv_base_a;
+NOTICE: created index "mv_ivm_unique_index" on materialized view "mv_ivm_unique"
+CREATE UNIQUE INDEX ON mv_ivm_unique(__ivm_count__);
+ERROR: unique index creation on IVM columns is not supported
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__));
+ERROR: unique index creation on IVM columns is not supported
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__ + 1));
+ERROR: unique index creation on IVM columns is not supported
+DROP MATERIALIZED VIEW mv_ivm_unique;
+-- TRUNCATE a base table in join views
+BEGIN;
+TRUNCATE mv_base_a;
+SELECT * FROM mv_ivm_1;
+ i | j | k
+---+---+---
+(0 rows)
+
+ROLLBACK;
+BEGIN;
+TRUNCATE mv_base_b;
+SELECT * FROM mv_ivm_1;
+ i | j | k
+---+---+---
+(0 rows)
+
+ROLLBACK;
+-- some query syntax
+BEGIN;
+CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql'
+ AS 'SELECT 1' IMMUTABLE;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_func AS SELECT * FROM ivm_func();
+NOTICE: could not create an index on materialized view "mv_ivm_func" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_no_tbl AS SELECT 1;
+NOTICE: could not create an index on materialized view "mv_ivm_no_tbl" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+ROLLBACK;
+-- result of materialized view have DISTINCT clause or the duplicate result.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_duplicate AS SELECT j FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_duplicate" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_distinct AS SELECT DISTINCT j FROM mv_base_a;
+NOTICE: created index "mv_ivm_distinct_index" on materialized view "mv_ivm_distinct"
+INSERT INTO mv_base_a VALUES(6,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 20
+ 30
+ 40
+ 50
+(6 rows)
+
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+ROLLBACK;
+-- support SUM(), COUNT() and AVG() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 120 | 2 | 60.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+UPDATE mv_base_a SET j = 200 WHERE (i,j) = (2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+----------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 220 | 2 | 110.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (2,200);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+ROLLBACK;
+-- support COUNT(*) aggregate function
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ i | sum | count
+---+-----+-------
+ 1 | 10 | 1
+ 2 | 20 | 1
+ 3 | 30 | 1
+ 4 | 40 | 1
+ 5 | 50 | 1
+(5 rows)
+
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ i | sum | count
+---+-----+-------
+ 1 | 10 | 1
+ 2 | 120 | 2
+ 3 | 30 | 1
+ 4 | 40 | 1
+ 5 | 50 | 1
+(5 rows)
+
+ROLLBACK;
+-- TRUNCATE a base table in aggregate views
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+TRUNCATE mv_base_a;
+SELECT sum, count FROM mv_ivm_agg;
+ sum | count
+-----+-------
+(0 rows)
+
+SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+ i | sum | count
+---+-----+-------
+(0 rows)
+
+ROLLBACK;
+-- support aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_group" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+---------------------
+ 150 | 5 | 30.0000000000000000
+(1 row)
+
+INSERT INTO mv_base_a VALUES(6,60);
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+---------------------
+ 210 | 6 | 35.0000000000000000
+(1 row)
+
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+ROLLBACK;
+-- TRUNCATE a base table in aggregate views without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_group" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+TRUNCATE mv_base_a;
+SELECT sum, count, avg FROM mv_ivm_group;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+ROLLBACK;
+-- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_avg_bug AS SELECT i, SUM(j), COUNT(j), AVG(j) FROM mv_base_A GROUP BY i;
+NOTICE: created index "mv_ivm_avg_bug_index" on materialized view "mv_ivm_avg_bug"
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+INSERT INTO mv_base_a VALUES
+ (1,0),
+ (1,0),
+ (2,30),
+ (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 3 | 3.3333333333333333
+ 2 | 80 | 3 | 26.6666666666666667
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (1,0);
+DELETE FROM mv_base_a WHERE (i,j) = (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+ROLLBACK;
+-- support MIN(), MAX() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_min_max_index" on materialized view "mv_ivm_min_max"
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 10 | 10
+ 2 | 20 | 20
+ 3 | 30 | 30
+ 4 | 40 | 40
+ 5 | 50 | 50
+(5 rows)
+
+INSERT INTO mv_base_a VALUES
+ (1,11), (1,12),
+ (2,21), (2,22),
+ (3,31), (3,32),
+ (4,41), (4,42),
+ (5,51), (5,52);
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 10 | 12
+ 2 | 20 | 22
+ 3 | 30 | 32
+ 4 | 40 | 42
+ 5 | 50 | 52
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) IN ((1,10), (2,21), (3,32));
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 11 | 12
+ 2 | 20 | 22
+ 3 | 30 | 31
+ 4 | 40 | 42
+ 5 | 50 | 52
+(5 rows)
+
+ROLLBACK;
+-- support MIN(), MAX() aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT MIN(j), MAX(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_min_max" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 10 | 50
+(1 row)
+
+INSERT INTO mv_base_a VALUES
+ (0,0), (6,60), (7,70);
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 0 | 70
+(1 row)
+
+DELETE FROM mv_base_a WHERE (i,j) IN ((0,0), (7,70));
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 10 | 60
+(1 row)
+
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ |
+(1 row)
+
+ROLLBACK;
+-- Test MIN/MAX after search_path change
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min AS SELECT MIN(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_min" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 10
+(1 row)
+
+CREATE SCHEMA myschema;
+GRANT ALL ON SCHEMA myschema TO public;
+CREATE TABLE myschema.mv_base_a (j int);
+INSERT INTO myschema.mv_base_a VALUES (1);
+DELETE FROM mv_base_a WHERE (i,j) = (1,10);
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 20
+(1 row)
+
+SET search_path TO myschema,public,pg_catalog;
+DELETE FROM public.mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 30
+(1 row)
+
+ROLLBACK;
+-- aggregate views with column names specified
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ a | sum
+---+------
+ 1 | 110
+ 2 | 2200
+ 3 | 300
+ 4 | 40
+ 5 | 50
+(5 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ a | b
+---+------
+ 1 | 110
+ 2 | 2200
+ 3 | 300
+ 4 | 40
+ 5 | 50
+(5 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b,c) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+ERROR: too many column names were specified
+ROLLBACK;
+-- support self join view and multiple change on the same table
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_self(v1, v2) AS
+ SELECT t1.v, t2.v FROM base_t AS t1 JOIN base_t AS t2 ON t1.i = t2.i;
+NOTICE: could not create an index on materialized view "mv_self" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+----+----
+ 10 | 10
+ 20 | 20
+ 30 | 30
+(3 rows)
+
+INSERT INTO base_t VALUES (4,40);
+DELETE FROM base_t WHERE i = 1;
+UPDATE base_t SET v = v*10 WHERE i=2;
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+-----+-----
+ 30 | 30
+ 40 | 40
+ 200 | 200
+(3 rows)
+
+WITH
+ ins_t1 AS (INSERT INTO base_t VALUES (5,50) RETURNING 1),
+ ins_t2 AS (INSERT INTO base_t VALUES (6,60) RETURNING 1),
+ upd_t AS (UPDATE base_t SET v = v + 100 RETURNING 1),
+ dlt_t AS (DELETE FROM base_t WHERE i IN (4,5) RETURNING 1)
+SELECT NULL;
+ ?column?
+----------
+
+(1 row)
+
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+-----+-----
+ 50 | 50
+ 60 | 60
+ 130 | 130
+ 300 | 300
+(4 rows)
+
+--- with sub-transactions
+SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,70);
+RELEASE SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,77);
+SELECT * FROM mv_self ORDER BY v1, v2;
+ v1 | v2
+-----+-----
+ 50 | 50
+ 60 | 60
+ 70 | 70
+ 70 | 77
+ 77 | 70
+ 77 | 77
+ 130 | 130
+ 300 | 300
+(8 rows)
+
+ROLLBACK;
+-- support simultaneous table changes
+BEGIN;
+CREATE TABLE base_r (i int, v int);
+CREATE TABLE base_s (i int, v int);
+INSERT INTO base_r VALUES (1, 10), (2, 20), (3, 30);
+INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300);
+CREATE INCREMENTAL MATERIALIZED VIEW mv(v1, v2) AS
+ SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i);
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY v1;
+ v1 | v2
+----+-----
+ 10 | 100
+ 20 | 200
+ 30 | 300
+(3 rows)
+
+WITH
+ ins_r AS (INSERT INTO base_r VALUES (1,11) RETURNING 1),
+ ins_r2 AS (INSERT INTO base_r VALUES (3,33) RETURNING 1),
+ ins_s AS (INSERT INTO base_s VALUES (2,222) RETURNING 1),
+ upd_r AS (UPDATE base_r SET v = v + 1000 WHERE i = 2 RETURNING 1),
+ dlt_s AS (DELETE FROM base_s WHERE i = 3 RETURNING 1)
+SELECT NULL;
+ ?column?
+----------
+
+(1 row)
+
+SELECT * FROM mv ORDER BY v1;
+ v1 | v2
+------+-----
+ 10 | 100
+ 11 | 100
+ 1020 | 200
+ 1020 | 222
+(4 rows)
+
+ROLLBACK;
+-- support foreign reference constraints
+BEGIN;
+CREATE TABLE ri1 (i int PRIMARY KEY);
+CREATE TABLE ri2 (i int PRIMARY KEY REFERENCES ri1(i) ON UPDATE CASCADE ON DELETE CASCADE, v int);
+INSERT INTO ri1 VALUES (1),(2),(3);
+INSERT INTO ri2 VALUES (1),(2),(3);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ri(i1, i2) AS
+ SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i);
+NOTICE: created index "mv_ri_index" on materialized view "mv_ri"
+SELECT * FROM mv_ri ORDER BY i1;
+ i1 | i2
+----+----
+ 1 | 1
+ 2 | 2
+ 3 | 3
+(3 rows)
+
+UPDATE ri1 SET i=10 where i=1;
+DELETE FROM ri1 WHERE i=2;
+SELECT * FROM mv_ri ORDER BY i2;
+ i1 | i2
+----+----
+ 3 | 3
+ 10 | 10
+(2 rows)
+
+ROLLBACK;
+-- views including NULL
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1,10),(2, NULL);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY i;
+ i | v
+---+----
+ 1 | 10
+ 2 |
+(2 rows)
+
+UPDATE base_t SET v = 20 WHERE i = 2;
+SELECT * FROM mv ORDER BY i;
+ i | v
+---+----
+ 1 | 10
+ 2 | 20
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY i;
+ i
+---
+(0 rows)
+
+INSERT INTO base_t VALUES (1),(NULL);
+SELECT * FROM mv ORDER BY i;
+ i
+---
+ 1
+
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, sum(v) FROM base_t GROUP BY i;
+NOTICE: created index "mv_index" on materialized view "mv"
+SELECT * FROM mv ORDER BY i;
+ i | sum
+---+-----
+ 1 | 30
+ | 3
+(2 rows)
+
+UPDATE base_t SET v = v * 10;
+SELECT * FROM mv ORDER BY i;
+ i | sum
+---+-----
+ 1 | 300
+ | 30
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, min(v), max(v) FROM base_t GROUP BY i;
+NOTICE: created index "mv_index" on materialized view "mv"
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 1 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 1;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 3;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 5;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 4
+(1 row)
+
+ROLLBACK;
+-- IMMV containing user defined type
+BEGIN;
+CREATE TYPE mytype;
+CREATE FUNCTION mytype_in(cstring)
+ RETURNS mytype AS 'int4in'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+NOTICE: return type mytype is only a shell
+CREATE FUNCTION mytype_out(mytype)
+ RETURNS cstring AS 'int4out'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+NOTICE: argument type mytype is only a shell
+CREATE TYPE mytype (
+ LIKE = int4,
+ INPUT = mytype_in,
+ OUTPUT = mytype_out
+);
+CREATE FUNCTION mytype_eq(mytype, mytype)
+ RETURNS bool AS 'int4eq'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_lt(mytype, mytype)
+ RETURNS bool AS 'int4lt'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_cmp(mytype, mytype)
+ RETURNS integer AS 'btint4cmp'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE OPERATOR = (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_eq);
+CREATE OPERATOR < (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_lt);
+CREATE OPERATOR CLASS mytype_ops
+ DEFAULT FOR TYPE mytype USING btree AS
+ OPERATOR 1 <,
+ OPERATOR 3 = ,
+ FUNCTION 1 mytype_cmp(mytype,mytype);
+CREATE TABLE t_mytype (x mytype);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_mytype AS
+ SELECT * FROM t_mytype;
+NOTICE: could not create an index on materialized view "mv_mytype" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+INSERT INTO t_mytype VALUES ('1'::mytype);
+SELECT * FROM mv_mytype;
+ x
+---
+ 1
+(1 row)
+
+ROLLBACK;
+-- outer join is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv(a,b) AS SELECT a.i, b.i FROM mv_base_a a LEFT JOIN mv_base_b b ON a.i=b.i;
+ERROR: OUTER JOIN is not supported on incrementally maintainable materialized view
+-- CTE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS
+ WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i;
+ERROR: CTE is not supported on incrementally maintainable materialized view
+-- contain system column
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm01 AS SELECT i,j,xmin FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT i,j,xmin::text AS x_min FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm06 AS SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+-- contain subquery
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm03 AS SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 );
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT * FROM mv_base_b) b WHERE a.i = b.i;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm05 AS SELECT i,j, (SELECT k FROM mv_base_b b WHERE a.i = b.i) FROM mv_base_a a;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+-- contain ORDER BY
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) ORDER BY i,j,k;
+ERROR: ORDER BY clause is not supported on incrementally maintainable materialized view
+-- contain HAVING
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) GROUP BY i,j,k HAVING SUM(i) > 5;
+ERROR: HAVING clause is not supported on incrementally maintainable materialized view
+-- contain view or materialized view
+CREATE VIEW b_view AS SELECT i,k FROM mv_base_b;
+CREATE MATERIALIZED VIEW b_mview AS SELECT i,k FROM mv_base_b;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT a.i,a.j FROM mv_base_a a,b_view b WHERE a.i = b.i;
+ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT a.i,a.j FROM mv_base_a a,b_mview b WHERE a.i = b.i;
+ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm09 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) b WHERE a.i = b.i;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm10 AS SELECT a.i,a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) OR a.i > 5;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+-- contain mutable functions
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+ERROR: mutable function is not supported on incrementally maintainable materialized view
+HINT: functions must be marked IMMUTABLE
+-- LIMIT/OFFSET is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm13 AS SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5;
+ERROR: LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view
+-- DISTINCT ON is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm14 AS SELECT DISTINCT ON(i) i, j FROM mv_base_a;
+ERROR: DISTINCT ON is not supported on incrementally maintainable materialized view
+-- TABLESAMPLE clause is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm15 AS SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50);
+ERROR: TABLESAMPLE clause is not supported on incrementally maintainable materialized view
+-- window functions are not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm16 AS SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a;
+ERROR: window functions are not supported on incrementally maintainable materialized view
+-- aggregate function with some options is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm17 AS SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a;
+ERROR: aggregate function with FILTER clause is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm18 AS SELECT COUNT(DISTINCT i) FROM mv_base_a;
+ERROR: aggregate function with DISTINCT arguments is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm19 AS SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a;
+ERROR: aggregate function with ORDER clause is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm20 AS SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),());
+ERROR: GROUPING SETS, ROLLUP, or CUBE clauses is not supported on incrementally maintainable materialized view
+-- inheritance parent is not supported
+BEGIN;
+CREATE TABLE parent (i int, v int);
+CREATE TABLE child_a(options text) INHERITS(parent);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm21 AS SELECT * FROM parent;
+ERROR: inheritance parent is not supported on incrementally maintainable materialized view
+ROLLBACK;
+-- UNION statement is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm22 AS SELECT i,j FROM mv_base_a UNION ALL SELECT i,k FROM mv_base_b;;
+ERROR: UNION/INTERSECT/EXCEPT statements are not supported on incrementally maintainable materialized view
+-- empty target list is not allowed with IVM
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm25 AS SELECT FROM mv_base_a;
+ERROR: empty target list is not supported on incrementally maintainable materialized view
+-- FOR UPDATE/SHARE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm26 AS SELECT i,j FROM mv_base_a FOR UPDATE;
+ERROR: FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view
+-- tartget list cannot contain ivm column that start with '__ivm'
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm28 AS SELECT i AS "__ivm_count__" FROM mv_base_a;
+ERROR: column name __ivm_count__ is not supported on incrementally maintainable materialized view
+-- expressions specified in GROUP BY must appear in the target list.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm29 AS SELECT COUNT(i) FROM mv_base_a GROUP BY i;
+ERROR: GROUP BY expression not appearing in select list is not supported on incrementally maintainable materialized view
+-- experssions containing an aggregate is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm30 AS SELECT sum(i)*0.5 FROM mv_base_a;
+ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm31 AS SELECT sum(i)/sum(j) FROM mv_base_a;
+ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view
+-- VALUES is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_only_values1 AS values(1);
+ERROR: VALUES is not supported on incrementally maintainable materialized view
+-- views containing base tables with Row Level Security
+DROP USER IF EXISTS ivm_admin;
+NOTICE: role "ivm_admin" does not exist, skipping
+DROP USER IF EXISTS ivm_user;
+NOTICE: role "ivm_user" does not exist, skipping
+CREATE USER ivm_admin;
+CREATE USER ivm_user;
+--- create a table with RLS
+SET SESSION AUTHORIZATION ivm_admin;
+CREATE TABLE rls_tbl(id int, data text, owner name);
+INSERT INTO rls_tbl VALUES
+ (1,'foo','ivm_user'),
+ (2,'bar','postgres');
+CREATE TABLE num_tbl(id int, num text);
+INSERT INTO num_tbl VALUES
+ (1,'one'),
+ (2,'two'),
+ (3,'three'),
+ (4,'four'),
+ (5,'five'),
+ (6,'six');
+--- Users can access only their own rows
+CREATE POLICY rls_tbl_policy ON rls_tbl FOR SELECT TO PUBLIC USING(owner = current_user);
+ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
+GRANT ALL on rls_tbl TO PUBLIC;
+GRANT ALL on num_tbl TO PUBLIC;
+--- create a view owned by ivm_user
+SET SESSION AUTHORIZATION ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls AS SELECT * FROM rls_tbl;
+NOTICE: could not create an index on materialized view "ivm_rls" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+------+----------
+ 1 | foo | ivm_user
+(1 row)
+
+RESET SESSION AUTHORIZATION;
+--- inserts rows owned by different users
+INSERT INTO rls_tbl VALUES
+ (3,'baz','ivm_user'),
+ (4,'qux','postgres');
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+------+----------
+ 1 | foo | ivm_user
+ 3 | baz | ivm_user
+(2 rows)
+
+--- combination of diffent kinds of commands
+WITH
+ i AS (INSERT INTO rls_tbl VALUES(5,'quux','postgres'), (6,'corge','ivm_user')),
+ u AS (UPDATE rls_tbl SET owner = 'postgres' WHERE id = 1),
+ u2 AS (UPDATE rls_tbl SET owner = 'ivm_user' WHERE id = 2)
+SELECT;
+--
+(1 row)
+
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+-------+----------
+ 2 | bar | ivm_user
+ 3 | baz | ivm_user
+ 6 | corge | ivm_user
+(3 rows)
+
+---
+SET SESSION AUTHORIZATION ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls2 AS SELECT * FROM rls_tbl JOIN num_tbl USING(id);
+NOTICE: could not create an index on materialized view "ivm_rls2" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+RESET SESSION AUTHORIZATION;
+WITH
+ x AS (UPDATE rls_tbl SET data = data || '_2' where id in (3,4)),
+ y AS (UPDATE num_tbl SET num = num || '_2' where id in (3,4))
+SELECT;
+--
+(1 row)
+
+SELECT * FROM ivm_rls2 ORDER BY 1,2,3;
+ id | data | owner | num
+----+-------+----------+---------
+ 2 | bar | ivm_user | two
+ 3 | baz_2 | ivm_user | three_2
+ 6 | corge | ivm_user | six
+(3 rows)
+
+-- automatic index creation
+CREATE TABLE base_a (i int primary key, j int);
+CREATE TABLE base_b (i int primary key, j int);
+--- group by: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx1 AS SELECT i, sum(j) FROM base_a GROUP BY i;
+NOTICE: created index "mv_idx1_index" on materialized view "mv_idx1"
+--- distinct: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx2 AS SELECT DISTINCT j FROM base_a;
+NOTICE: created index "mv_idx2_index" on materialized view "mv_idx2"
+--- with all pkey columns: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx3(i_a, i_b) AS SELECT a.i, b.i FROM base_a a, base_b b;
+NOTICE: created index "mv_idx3_index" on materialized view "mv_idx3"
+--- missing some pkey columns: no index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx4 AS SELECT j FROM base_a;
+NOTICE: could not create an index on materialized view "mv_idx4" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx5 AS SELECT a.i, b.j FROM base_a a, base_b b;
+NOTICE: could not create an index on materialized view "mv_idx5" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+-- cleanup
+DROP TABLE rls_tbl CASCADE;
+NOTICE: drop cascades to 2 other objects
+DETAIL: drop cascades to materialized view ivm_rls
+drop cascades to materialized view ivm_rls2
+DROP TABLE num_tbl CASCADE;
+DROP USER ivm_user;
+DROP USER ivm_admin;
+DROP TABLE mv_base_b CASCADE;
+NOTICE: drop cascades to 3 other objects
+DETAIL: drop cascades to materialized view mv_ivm_1
+drop cascades to view b_view
+drop cascades to materialized view b_mview
+DROP TABLE mv_base_a CASCADE;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 1d8a414eea..84c3c5e9be 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -78,7 +78,7 @@ test: brin_bloom brin_multi
# psql depends on create_am
# amutils depends on geometry, create_index_spgist, hash_index, brin
# ----------
-test: create_table_like alter_generic alter_operator misc async dbsize merge misc_functions sysviews tsrf tid tidscan tidrangescan collate.icu.utf8 incremental_sort create_role without_overlaps
+test: create_table_like alter_generic alter_operator misc async dbsize merge misc_functions sysviews tsrf tid tidscan tidrangescan collate.icu.utf8 incremental_sort create_role without_overlaps incremental_matview
# collate.*.utf8 tests cannot be run in parallel with each other
test: rules psql psql_crosstab amutils stats_ext collate.linux.utf8 collate.windows.win1252
diff --git a/src/test/regress/sql/incremental_matview.sql b/src/test/regress/sql/incremental_matview.sql
new file mode 100644
index 0000000000..82686f9324
--- /dev/null
+++ b/src/test/regress/sql/incremental_matview.sql
@@ -0,0 +1,533 @@
+-- create a table to use as a basis for views and materialized views in various combinations
+CREATE TABLE mv_base_a (i int, j int);
+INSERT INTO mv_base_a VALUES
+ (1,10),
+ (2,20),
+ (3,30),
+ (4,40),
+ (5,50);
+CREATE TABLE mv_base_b (i int, k int);
+INSERT INTO mv_base_b VALUES
+ (1,101),
+ (2,102),
+ (3,103),
+ (4,104);
+
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_1 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) WITH NO DATA;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+REFRESH MATERIALIZED VIEW mv_ivm_1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+
+-- REFRESH WITH NO DATA
+BEGIN;
+CREATE FUNCTION dummy_ivm_trigger_func() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+
+CREATE CONSTRAINT TRIGGER dummy_ivm_trigger AFTER INSERT
+ON mv_base_a FROM mv_ivm_1 FOR EACH ROW
+EXECUTE PROCEDURE dummy_ivm_trigger_func();
+
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+
+REFRESH MATERIALIZED VIEW mv_ivm_1 WITH NO DATA;
+
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ROLLBACK;
+
+-- immediate maintenance
+BEGIN;
+INSERT INTO mv_base_b VALUES(5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+UPDATE mv_base_a SET j = 0 WHERE i = 1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+DELETE FROM mv_base_b WHERE (i,k) = (5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ROLLBACK;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+
+-- rename of IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS SELECT DISTINCT * FROM mv_base_a;
+ALTER MATERIALIZED VIEW mv_ivm_rename RENAME COLUMN __ivm_count__ TO xxx;
+DROP MATERIALIZED VIEW mv_ivm_rename;
+
+-- unique index on IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_unique AS SELECT DISTINCT * FROM mv_base_a;
+CREATE UNIQUE INDEX ON mv_ivm_unique(__ivm_count__);
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__));
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__ + 1));
+DROP MATERIALIZED VIEW mv_ivm_unique;
+
+-- TRUNCATE a base table in join views
+BEGIN;
+TRUNCATE mv_base_a;
+SELECT * FROM mv_ivm_1;
+ROLLBACK;
+
+BEGIN;
+TRUNCATE mv_base_b;
+SELECT * FROM mv_ivm_1;
+ROLLBACK;
+
+-- some query syntax
+BEGIN;
+CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql'
+ AS 'SELECT 1' IMMUTABLE;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_func AS SELECT * FROM ivm_func();
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_no_tbl AS SELECT 1;
+ROLLBACK;
+
+-- result of materialized view have DISTINCT clause or the duplicate result.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_duplicate AS SELECT j FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_distinct AS SELECT DISTINCT j FROM mv_base_a;
+INSERT INTO mv_base_a VALUES(6,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+DELETE FROM mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ROLLBACK;
+
+-- support SUM(), COUNT() and AVG() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+UPDATE mv_base_a SET j = 200 WHERE (i,j) = (2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+DELETE FROM mv_base_a WHERE (i,j) = (2,200);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ROLLBACK;
+
+-- support COUNT(*) aggregate function
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ROLLBACK;
+
+-- TRUNCATE a base table in aggregate views
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+TRUNCATE mv_base_a;
+SELECT sum, count FROM mv_ivm_agg;
+SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+ROLLBACK;
+
+-- support aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+INSERT INTO mv_base_a VALUES(6,60);
+SELECT * FROM mv_ivm_group ORDER BY 1;
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ROLLBACK;
+
+-- TRUNCATE a base table in aggregate views without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+TRUNCATE mv_base_a;
+SELECT sum, count, avg FROM mv_ivm_group;
+SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+ROLLBACK;
+
+-- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_avg_bug AS SELECT i, SUM(j), COUNT(j), AVG(j) FROM mv_base_A GROUP BY i;
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES
+ (1,0),
+ (1,0),
+ (2,30),
+ (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+DELETE FROM mv_base_a WHERE (i,j) = (1,0);
+DELETE FROM mv_base_a WHERE (i,j) = (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ROLLBACK;
+
+-- support MIN(), MAX() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES
+ (1,11), (1,12),
+ (2,21), (2,22),
+ (3,31), (3,32),
+ (4,41), (4,42),
+ (5,51), (5,52);
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+DELETE FROM mv_base_a WHERE (i,j) IN ((1,10), (2,21), (3,32));
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ROLLBACK;
+
+-- support MIN(), MAX() aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT MIN(j), MAX(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+INSERT INTO mv_base_a VALUES
+ (0,0), (6,60), (7,70);
+SELECT * FROM mv_ivm_min_max;
+DELETE FROM mv_base_a WHERE (i,j) IN ((0,0), (7,70));
+SELECT * FROM mv_ivm_min_max;
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+ROLLBACK;
+
+-- Test MIN/MAX after search_path change
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min AS SELECT MIN(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_min;
+
+CREATE SCHEMA myschema;
+GRANT ALL ON SCHEMA myschema TO public;
+CREATE TABLE myschema.mv_base_a (j int);
+INSERT INTO myschema.mv_base_a VALUES (1);
+
+DELETE FROM mv_base_a WHERE (i,j) = (1,10);
+SELECT * FROM mv_ivm_min;
+
+SET search_path TO myschema,public,pg_catalog;
+DELETE FROM public.mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_min;
+ROLLBACK;
+
+-- aggregate views with column names specified
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b,c) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+ROLLBACK;
+
+-- support self join view and multiple change on the same table
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_self(v1, v2) AS
+ SELECT t1.v, t2.v FROM base_t AS t1 JOIN base_t AS t2 ON t1.i = t2.i;
+SELECT * FROM mv_self ORDER BY v1;
+INSERT INTO base_t VALUES (4,40);
+DELETE FROM base_t WHERE i = 1;
+UPDATE base_t SET v = v*10 WHERE i=2;
+SELECT * FROM mv_self ORDER BY v1;
+WITH
+ ins_t1 AS (INSERT INTO base_t VALUES (5,50) RETURNING 1),
+ ins_t2 AS (INSERT INTO base_t VALUES (6,60) RETURNING 1),
+ upd_t AS (UPDATE base_t SET v = v + 100 RETURNING 1),
+ dlt_t AS (DELETE FROM base_t WHERE i IN (4,5) RETURNING 1)
+SELECT NULL;
+SELECT * FROM mv_self ORDER BY v1;
+
+--- with sub-transactions
+SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,70);
+RELEASE SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,77);
+SELECT * FROM mv_self ORDER BY v1, v2;
+
+ROLLBACK;
+
+-- support simultaneous table changes
+BEGIN;
+CREATE TABLE base_r (i int, v int);
+CREATE TABLE base_s (i int, v int);
+INSERT INTO base_r VALUES (1, 10), (2, 20), (3, 30);
+INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300);
+CREATE INCREMENTAL MATERIALIZED VIEW mv(v1, v2) AS
+ SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i);
+SELECT * FROM mv ORDER BY v1;
+WITH
+ ins_r AS (INSERT INTO base_r VALUES (1,11) RETURNING 1),
+ ins_r2 AS (INSERT INTO base_r VALUES (3,33) RETURNING 1),
+ ins_s AS (INSERT INTO base_s VALUES (2,222) RETURNING 1),
+ upd_r AS (UPDATE base_r SET v = v + 1000 WHERE i = 2 RETURNING 1),
+ dlt_s AS (DELETE FROM base_s WHERE i = 3 RETURNING 1)
+SELECT NULL;
+SELECT * FROM mv ORDER BY v1;
+ROLLBACK;
+
+-- support foreign reference constraints
+BEGIN;
+CREATE TABLE ri1 (i int PRIMARY KEY);
+CREATE TABLE ri2 (i int PRIMARY KEY REFERENCES ri1(i) ON UPDATE CASCADE ON DELETE CASCADE, v int);
+INSERT INTO ri1 VALUES (1),(2),(3);
+INSERT INTO ri2 VALUES (1),(2),(3);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ri(i1, i2) AS
+ SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i);
+SELECT * FROM mv_ri ORDER BY i1;
+UPDATE ri1 SET i=10 where i=1;
+DELETE FROM ri1 WHERE i=2;
+SELECT * FROM mv_ri ORDER BY i2;
+ROLLBACK;
+
+-- views including NULL
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1,10),(2, NULL);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+SELECT * FROM mv ORDER BY i;
+UPDATE base_t SET v = 20 WHERE i = 2;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+SELECT * FROM mv ORDER BY i;
+INSERT INTO base_t VALUES (1),(NULL);
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, sum(v) FROM base_t GROUP BY i;
+SELECT * FROM mv ORDER BY i;
+UPDATE base_t SET v = v * 10;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, min(v), max(v) FROM base_t GROUP BY i;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 1;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 3;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 5;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+-- IMMV containing user defined type
+BEGIN;
+
+CREATE TYPE mytype;
+CREATE FUNCTION mytype_in(cstring)
+ RETURNS mytype AS 'int4in'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_out(mytype)
+ RETURNS cstring AS 'int4out'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE TYPE mytype (
+ LIKE = int4,
+ INPUT = mytype_in,
+ OUTPUT = mytype_out
+);
+
+CREATE FUNCTION mytype_eq(mytype, mytype)
+ RETURNS bool AS 'int4eq'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_lt(mytype, mytype)
+ RETURNS bool AS 'int4lt'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_cmp(mytype, mytype)
+ RETURNS integer AS 'btint4cmp'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+
+CREATE OPERATOR = (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_eq);
+CREATE OPERATOR < (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_lt);
+
+CREATE OPERATOR CLASS mytype_ops
+ DEFAULT FOR TYPE mytype USING btree AS
+ OPERATOR 1 <,
+ OPERATOR 3 = ,
+ FUNCTION 1 mytype_cmp(mytype,mytype);
+
+CREATE TABLE t_mytype (x mytype);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_mytype AS
+ SELECT * FROM t_mytype;
+INSERT INTO t_mytype VALUES ('1'::mytype);
+SELECT * FROM mv_mytype;
+
+ROLLBACK;
+
+-- outer join is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv(a,b) AS SELECT a.i, b.i FROM mv_base_a a LEFT JOIN mv_base_b b ON a.i=b.i;
+-- CTE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS
+ WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i;
+-- contain system column
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm01 AS SELECT i,j,xmin FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT i,j,xmin::text AS x_min FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm06 AS SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a;
+-- contain subquery
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm03 AS SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 );
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT * FROM mv_base_b) b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm05 AS SELECT i,j, (SELECT k FROM mv_base_b b WHERE a.i = b.i) FROM mv_base_a a;
+-- contain ORDER BY
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) ORDER BY i,j,k;
+-- contain HAVING
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) GROUP BY i,j,k HAVING SUM(i) > 5;
+
+-- contain view or materialized view
+CREATE VIEW b_view AS SELECT i,k FROM mv_base_b;
+CREATE MATERIALIZED VIEW b_mview AS SELECT i,k FROM mv_base_b;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT a.i,a.j FROM mv_base_a a,b_view b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT a.i,a.j FROM mv_base_a a,b_mview b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm09 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm10 AS SELECT a.i,a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) OR a.i > 5;
+
+-- contain mutable functions
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+
+-- LIMIT/OFFSET is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm13 AS SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5;
+
+-- DISTINCT ON is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm14 AS SELECT DISTINCT ON(i) i, j FROM mv_base_a;
+
+-- TABLESAMPLE clause is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm15 AS SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50);
+
+-- window functions are not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm16 AS SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a;
+
+-- aggregate function with some options is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm17 AS SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm18 AS SELECT COUNT(DISTINCT i) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm19 AS SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm20 AS SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),());
+
+-- inheritance parent is not supported
+BEGIN;
+CREATE TABLE parent (i int, v int);
+CREATE TABLE child_a(options text) INHERITS(parent);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm21 AS SELECT * FROM parent;
+ROLLBACK;
+
+-- UNION statement is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm22 AS SELECT i,j FROM mv_base_a UNION ALL SELECT i,k FROM mv_base_b;;
+
+-- empty target list is not allowed with IVM
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm25 AS SELECT FROM mv_base_a;
+
+-- FOR UPDATE/SHARE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm26 AS SELECT i,j FROM mv_base_a FOR UPDATE;
+
+-- tartget list cannot contain ivm column that start with '__ivm'
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm28 AS SELECT i AS "__ivm_count__" FROM mv_base_a;
+
+-- expressions specified in GROUP BY must appear in the target list.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm29 AS SELECT COUNT(i) FROM mv_base_a GROUP BY i;
+
+-- experssions containing an aggregate is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm30 AS SELECT sum(i)*0.5 FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm31 AS SELECT sum(i)/sum(j) FROM mv_base_a;
+
+-- VALUES is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_only_values1 AS values(1);
+
+-- views containing base tables with Row Level Security
+DROP USER IF EXISTS ivm_admin;
+DROP USER IF EXISTS ivm_user;
+CREATE USER ivm_admin;
+CREATE USER ivm_user;
+
+--- create a table with RLS
+SET SESSION AUTHORIZATION ivm_admin;
+CREATE TABLE rls_tbl(id int, data text, owner name);
+INSERT INTO rls_tbl VALUES
+ (1,'foo','ivm_user'),
+ (2,'bar','postgres');
+CREATE TABLE num_tbl(id int, num text);
+INSERT INTO num_tbl VALUES
+ (1,'one'),
+ (2,'two'),
+ (3,'three'),
+ (4,'four'),
+ (5,'five'),
+ (6,'six');
+
+--- Users can access only their own rows
+CREATE POLICY rls_tbl_policy ON rls_tbl FOR SELECT TO PUBLIC USING(owner = current_user);
+ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
+GRANT ALL on rls_tbl TO PUBLIC;
+GRANT ALL on num_tbl TO PUBLIC;
+
+--- create a view owned by ivm_user
+SET SESSION AUTHORIZATION ivm_user;
+
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls AS SELECT * FROM rls_tbl;
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+RESET SESSION AUTHORIZATION;
+
+--- inserts rows owned by different users
+INSERT INTO rls_tbl VALUES
+ (3,'baz','ivm_user'),
+ (4,'qux','postgres');
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+
+--- combination of diffent kinds of commands
+WITH
+ i AS (INSERT INTO rls_tbl VALUES(5,'quux','postgres'), (6,'corge','ivm_user')),
+ u AS (UPDATE rls_tbl SET owner = 'postgres' WHERE id = 1),
+ u2 AS (UPDATE rls_tbl SET owner = 'ivm_user' WHERE id = 2)
+SELECT;
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+
+---
+SET SESSION AUTHORIZATION ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls2 AS SELECT * FROM rls_tbl JOIN num_tbl USING(id);
+RESET SESSION AUTHORIZATION;
+
+WITH
+ x AS (UPDATE rls_tbl SET data = data || '_2' where id in (3,4)),
+ y AS (UPDATE num_tbl SET num = num || '_2' where id in (3,4))
+SELECT;
+SELECT * FROM ivm_rls2 ORDER BY 1,2,3;
+
+-- automatic index creation
+CREATE TABLE base_a (i int primary key, j int);
+CREATE TABLE base_b (i int primary key, j int);
+
+--- group by: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx1 AS SELECT i, sum(j) FROM base_a GROUP BY i;
+
+--- distinct: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx2 AS SELECT DISTINCT j FROM base_a;
+
+--- with all pkey columns: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx3(i_a, i_b) AS SELECT a.i, b.i FROM base_a a, base_b b;
+
+--- missing some pkey columns: no index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx4 AS SELECT j FROM base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx5 AS SELECT a.i, b.j FROM base_a a, base_b b;
+
+-- cleanup
+
+DROP TABLE rls_tbl CASCADE;
+DROP TABLE num_tbl CASCADE;
+DROP USER ivm_user;
+DROP USER ivm_admin;
+
+DROP TABLE mv_base_b CASCADE;
+DROP TABLE mv_base_a CASCADE;
--
2.25.1
v30-0011-Add-documentations-about-Incremental-View-Mainte.patchtext/x-diff; name=v30-0011-Add-documentations-about-Incremental-View-Mainte.patchDownload
From e6f458eef5231440c2921ce2114caf3831c05074 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:25:34 +0900
Subject: [PATCH v30 11/11] Add documentations about Incremental View
Maintenance
---
doc/src/sgml/catalogs.sgml | 9 +
.../sgml/ref/create_materialized_view.sgml | 124 ++++-
.../sgml/ref/refresh_materialized_view.sgml | 8 +-
doc/src/sgml/rules.sgml | 437 ++++++++++++++++++
doc/src/sgml/system-views.sgml | 9 +
5 files changed, 583 insertions(+), 4 deletions(-)
diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index 880f717b10..f8df2951a8 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -2224,6 +2224,15 @@ SCRAM-SHA-256$<replaceable><iteration count></replaceable>:<replaceable>&l
</para></entry>
</row>
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>relisivm</structfield> <type>bool</type>
+ </para>
+ <para>
+ True if relation is incrementally maintainable materialized view
+ </para></entry>
+ </row>
+
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>relrewrite</structfield> <type>oid</type>
diff --git a/doc/src/sgml/ref/create_materialized_view.sgml b/doc/src/sgml/ref/create_materialized_view.sgml
index 0d2fea2b97..8c574062db 100644
--- a/doc/src/sgml/ref/create_materialized_view.sgml
+++ b/doc/src/sgml/ref/create_materialized_view.sgml
@@ -21,7 +21,7 @@ PostgreSQL documentation
<refsynopsisdiv>
<synopsis>
-CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
+CREATE [ INCREMENTAL ] MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
[ (<replaceable>column_name</replaceable> [, ...] ) ]
[ USING <replaceable class="parameter">method</replaceable> ]
[ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
@@ -60,6 +60,125 @@ CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
<title>Parameters</title>
<variablelist>
+ <varlistentry>
+ <term><literal>INCREMENTAL</literal></term>
+ <listitem>
+ <para>
+ If specified, some triggers are automatically created so that the rows
+ of the materialized view are immediately updated when base tables of the
+ materialized view are updated. In general, this allows faster update of
+ the materialized view at a price of slower update of the base tables
+ because the triggers will be invoked. We call this form of materialized
+ view as "Incrementally Maintainable Materialized View" (IMMV).
+ </para>
+ <para>
+ When <acronym>IMMV</acronym> is defined without using <command>WITH NO DATA</command>,
+ a unique index is created on the view automatically if possible. If the view
+ definition query has a GROUP BY clause, a unique index is created on the columns
+ of GROUP BY expressions. Also, if the view has DISTINCT clause, a unique index
+ is created on all columns in the target list. Otherwise, if the view contains all
+ primary key attritubes of its base tables in the target list, a unique index is
+ created on these attritubes. In other cases, no index is created.
+ </para>
+ <para>
+ There are restrictions of query definitions allowed to use this
+ option. The following are supported in query definitions for IMMV:
+ <itemizedlist>
+
+ <listitem>
+ <para>
+ Inner joins (including self-joins).
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Some built-in aggregate functions (count, sum, avg, min, max) without a HAVING
+ clause.
+ </para>
+ </listitem>
+ </itemizedlist>
+
+ Unsupported queries with this option include the following:
+
+ <itemizedlist>
+ <listitem>
+ <para>
+ Outer joins.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Sub-queries.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Aggregate functions other than built-in count, sum, avg, min and max.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ Aggregate functions with a HAVING clause.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ DISTINCT ON, WINDOW, VALUES, LIMIT and OFFSET clause.
+ </para>
+ </listitem>
+ </itemizedlist>
+
+ Other restrictions include:
+ <itemizedlist>
+
+ <listitem>
+ <para>
+ IMMVs must be based on simple base tables. It's not supported to
+ create them on top of views or materialized views.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ It is not supported to include system columns in an IMMV.
+ <programlisting>
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+ERROR: system column is not supported with IVM
+ </programlisting>
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Non-immutable functions are not supported.
+ <programlisting>
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+ERROR: functions in IMMV must be marked IMMUTABLE
+ </programlisting>
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ IMMVs do not support expressions that contains aggregates
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Logical replication does not support IMMVs.
+ </para>
+ </listitem>
+
+ </itemizedlist>
+
+ </para>
+ </listitem>
+ </varlistentry>
+
<varlistentry>
<term><literal>IF NOT EXISTS</literal></term>
<listitem>
@@ -155,7 +274,8 @@ CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
This clause specifies whether or not the materialized view should be
populated at creation time. If not, the materialized view will be
flagged as unscannable and cannot be queried until <command>REFRESH
- MATERIALIZED VIEW</command> is used.
+ MATERIALIZED VIEW</command> is used. Also, if the view is IMMV,
+ triggers for maintaining the view are not created.
</para>
</listitem>
</varlistentry>
diff --git a/doc/src/sgml/ref/refresh_materialized_view.sgml b/doc/src/sgml/ref/refresh_materialized_view.sgml
index 7a019162c3..dd894a2324 100644
--- a/doc/src/sgml/ref/refresh_materialized_view.sgml
+++ b/doc/src/sgml/ref/refresh_materialized_view.sgml
@@ -35,9 +35,13 @@ REFRESH MATERIALIZED VIEW [ CONCURRENTLY ] <replaceable class="parameter">name</
owner of the materialized view. The old contents are discarded. If
<literal>WITH DATA</literal> is specified (or defaults) the backing query
is executed to provide the new data, and the materialized view is left in a
- scannable state. If <literal>WITH NO DATA</literal> is specified no new
+ scannable state. If the view is an incrementally maintainable materialized
+ view (IMMV) and was 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 <literal>WITH NO DATA</literal> is specified no new
data is generated and the materialized view is left in an unscannable
- state.
+ state. If the view is IMMV, the triggers are dropped.
</para>
<para>
<literal>CONCURRENTLY</literal> and <literal>WITH NO DATA</literal> may not
diff --git a/doc/src/sgml/rules.sgml b/doc/src/sgml/rules.sgml
index 784c16e76e..149bb99b1c 100644
--- a/doc/src/sgml/rules.sgml
+++ b/doc/src/sgml/rules.sgml
@@ -1098,6 +1098,443 @@ SELECT word FROM words ORDER BY word <-> 'caterpiler' LIMIT 10;
</sect1>
+<sect1 id="rules-ivm">
+<title>Incremental View Maintenance</title>
+
+<indexterm zone="rules-ivm">
+ <primary>incremental view maintenance</primary>
+</indexterm>
+
+<indexterm zone="rules-ivm">
+ <primary>materialized view</primary>
+ <secondary>incremental view maintenance</secondary>
+</indexterm>
+
+<indexterm zone="rules-ivm">
+ <primary>view</primary>
+ <secondary>incremental view maintenance</secondary>
+</indexterm>
+
+<sect2 id="rules-ivm-overview">
+<title>Overview</title>
+
+<para>
+ Incremental View Maintenance (<acronym>IVM</acronym>) is a way to make
+ materialized views up-to-date in which only incremental changes are computed
+ and applied on views rather than recomputing the contents from scratch as
+ <command>REFRESH MATERIALIZED VIEW</command> does. <acronym>IVM</acronym>
+ can update materialized views more efficiently than recomputation when only
+ small parts of the view are changed.
+</para>
+
+<para>
+ There are two approaches with regard to timing of view maintenance:
+ immediate and deferred. In immediate maintenance, views are updated in the
+ same transaction that its base table is modified. In deferred maintenance,
+ views are updated after the transaction is committed, for example, when the
+ view is accessed, as a response to user command like <command>REFRESH
+ MATERIALIZED VIEW</command>, or periodically in background, and so on.
+ <productname>PostgreSQL</productname> currently implements only a kind of
+ immediate maintenance, in which materialized views are updated immediately
+ in AFTER triggers when a base table is modified.
+</para>
+
+<para>
+ To create materialized views supporting <acronym>IVM</acronym>, use the
+ <command>CREATE INCREMENTAL MATERIALIZED VIEW</command>, for example:
+<programlisting>
+CREATE <emphasis>INCREMENTAL</emphasis> MATERIALIZED VIEW mymatview AS SELECT * FROM mytab;
+</programlisting>
+ When a materialized view is created with the <literal>INCREMENTAL</literal>
+ keyword, some triggers are automatically created so that the view's contents are
+ immediately updated when its base tables are modified. We call this form
+ of materialized view an Incrementally Maintainable Materialized View
+ (<acronym>IMMV</acronym>).
+<programlisting>
+postgres=# CREATE INCREMENTAL MATERIALIZED VIEW m AS SELECT * FROM t0;
+NOTICE: could not create an index on materialized view "m" automatically
+HINT: Create an index on the materialized view for effcient incremental maintenance.
+SELECT 3
+postgres=# SELECT * FROM m;
+ i
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+postgres=# INSERT INTO t0 VALUES (4);
+INSERT 0 1
+postgres=# SELECT * FROM m; -- automatically updated
+ i
+---
+ 1
+ 2
+ 3
+ 4
+(4 rows)
+</programlisting>
+</para>
+
+<para>
+ Some <acronym>IMMV</acronym>s have hidden columns which are added
+ automatically when a materialized view is created. Their name starts
+ with <literal>__ivm_</literal> and they contain information required
+ for maintaining the <acronym>IMMV</acronym>. Such columns are not visible
+ when the <acronym>IMMV</acronym> is accessed by <literal>SELECT *</literal>
+ but are visible if the column name is explicitly specified in the target
+ list. We can also see the hidden columns in <literal>\d</literal>
+ meta-commands of <command>psql</command> commands.
+</para>
+
+<para>
+ In general, <acronym>IMMV</acronym>s allow faster updates of materialized
+ views at the price of slower updates to their base tables. Updates of
+ <acronym>IMMV</acronym> is slower because triggers will be invoked and the
+ view is updated in triggers per modification statement.
+</para>
+
+<para>
+ For example, suppose a normal materialized view defined as below:
+
+<programlisting>
+test=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm AS
+ SELECT a.aid, b.bid, a.abalance, b.bbalance
+ FROM pgbench_accounts a JOIN pgbench_branches b USING(bid);
+SELECT 10000000
+
+</programlisting>
+
+ Updating a tuple in a base table of this materialized view is rapid but the
+ <command>REFRESH MATERIALIZED VIEW</command> command on this view takes a long time:
+
+<programlisting>
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 0.990 ms
+
+test=# REFRESH MATERIALIZED VIEW mv_normal ;
+REFRESH MATERIALIZED VIEW
+Time: 33533.952 ms (00:33.534)
+</programlisting>
+</para>
+
+<para>
+ On the other hand, after creating <acronym>IMMV</acronym> with the same view
+ definition as below:
+
+<programlisting>
+test=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm AS
+ SELECT a.aid, b.bid, a.abalance, b.bbalance
+ FROM pgbench_accounts a JOIN pgbench_branches b USING(bid);
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+NOTICE: created index "mv_ivm_index" on materialized view "mv_ivm"
+</programlisting>
+
+ updating a tuple in a base table takes more than the normal view,
+ but its content is updated automatically and this is faster than the
+ <command>REFRESH MATERIALIZED VIEW</command> command.
+
+<programlisting>
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 13.068 ms
+</programlisting>
+
+</para>
+
+<para>
+ Appropriate indexes on <acronym>IMMV</acronym>s are necessary for
+ efficient <acronym>IVM</acronym> because it looks for tuples to be
+ updated in <acronym>IMMV</acronym>. If there are no indexes, it
+ will take a long time.
+</para>
+
+<para>
+ Therefore, when <acronym>IMMV</acronym> is defined, a unique index is created on the view
+ automatically if possible. If the view definition query has a GROUP BY clause, a unique
+ index is created on the columns of GROUP BY expressions. Also, if the view has DISTINCT
+ clause, a unique index is created on all columns in the target list. Otherwise, if the
+ view contains all primary key attritubes of its base tables in the target list, a unique
+ index is created on these attritubes. In other cases, no index is created.
+</para>
+
+<para>
+ In the previous example, a unique index "mv_ivm_index" is created on aid and bid
+ columns of materialized view "mv_ivm", and this enables the rapid update of the view.
+ Dropping this index make updating the view take a loger time.
+<programlisting>
+test=# DROP INDEX mv_ivm_index;
+DROP INDEX
+Time: 67.081 ms
+
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 16386.245 ms (00:16.386)
+</programlisting>
+
+</para>
+
+<para>
+ <acronym>IVM</acronym> is effective when we want to keep a materialized
+ view up-to-date and small fraction of a base table is modified
+ infrequently. Due to the overhead of immediate maintenance, <acronym>IVM</acronym>
+ 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, <acronym>IVM</acronym> is not effective and the cost of
+ maintenance can be larger than the <command>REFRESH MATERIALIZED VIEW</command>
+ command. In such situation, we can use <command>REFRESH MATERIALIZED VIEW</command>
+ and specify <literal>WITH NO DATA</literal> to disable immediate
+ maintenance before modifying a base table. After a base table modification,
+ execute the <command>REFRESH MATERIALIZED VIEW</command> (with <literal>WITH DATA</literal>)
+ command to refresh the view data and enable immediate maintenance.
+</para>
+
+</sect2>
+
+<sect2 id="rules-ivm-support">
+<title>Supported View Definitions and Restrictions</title>
+
+<para>
+ Currently, we can create <acronym>IMMV</acronym>s using inner joins, and some
+ aggregates. However, several restrictions apply to the definition of IMMV.
+</para>
+
+<sect3 id="rules-ivm-support-joins">
+<title>Joins</title>
+<para>
+ Inner joins including self-join are supported. Outer joins are not supported.
+</para>
+</sect3>
+
+<sect3 id="rules-ivm-support-aggregates">
+<title>Aggregates</title>
+<para>
+ Supported aggregate functions are <function>count</function>, <function>sum</function>,
+ <function>avg</function>, <function>min</function>, and <function>max</function>.
+ Currently, only built-in aggregate functions are supported and user defined
+ aggregates cannot be used. When a base table is modified, the new aggregated
+ values are incrementally calculated using the old aggregated values and values
+ of related hidden columns stored in <acronym>IMMV</acronym>.
+</para>
+
+<para>
+ Note that for <function>min</function> or <function>max</function>, the new values
+ could be re-calculated from base tables with regard to the affected groups when a
+ tuple containing the current minimal or maximal values are deleted from a base table.
+ Therefore, it can takes a long time to update an <acronym>IMMV</acronym> containing
+ these functions.
+</para>
+
+<para>
+ Also note that using <function>sum</function> or <function>avg</function> on
+ <type>real</type> (<type>float4</type>) type or <type>double precision</type>
+ (<type>float8</type>) type in <acronym>IMMV</acronym> is unsafe. This is
+ because aggregated values in <acronym>IMMV</acronym> can become different from
+ results calculated from base tables due to the limited precision of these types.
+ To avoid this problem, use the <type>numeric</type> type instead.
+</para>
+
+ <sect4 id="rules-ivm-restrictions-aggregates">
+ <title>Restrictions on Aggregates</title>
+ <para>
+ There are the following restrictions:
+ <itemizedlist>
+ <listitem>
+ <para>
+ If we have a <literal>GROUP BY</literal> clause, expressions specified in
+ <literal>GROUP BY</literal> must appear in the target list. This is
+ how tuples to be updated in the <acronym>IMMV</acronym> are identified.
+ These attributes are used as scan keys for searching tuples in the
+ <acronym>IMMV</acronym>, so indexes on them are required for efficient
+ <acronym>IVM</acronym>.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <literal>HAVING</literal> clause cannot be used.
+ </para>
+ </listitem>
+ </itemizedlist>
+ </para>
+ </sect4>
+</sect3>
+
+<sect3 id="rules-ivm-general-restricitons">
+<title>Other General Restrictions</title>
+<para>
+ There are other restrictions which generally apply to <acronym>IMMV</acronym>:
+ <itemizedlist>
+ <listitem>
+ <para>
+ Sub-queries cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ CTEs cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Window functions cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s must be based on simple base tables. It's not
+ supported to create them on top of views, materialized views, foreign tables, inhe.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ LIMIT and OFFSET clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s cannot contain system columns.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s cannot contain non-immutable functions.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ UNION/INTERSECT/EXCEPT clauses cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ DISTINCT ON clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ TABLESAMPLE parameter cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ inheritance parent tables cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ VALUES clause cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <literal>GROUPING SETS</literal> and <literal>FILTER</literal> clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ FOR UPDATE/SHARE cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ targetlist cannot contain columns whose name start with <literal>__ivm_</literal>.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ targetlist cannot contain expressions which contain an aggregate in it.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Logical replication is not supported, that is, even when a base table
+ at a publisher node is modified, <acronym>IMMV</acronym>s at subscriber
+ nodes are not updated.
+ </para>
+ </listitem>
+
+ </itemizedlist>
+</para>
+</sect3>
+
+</sect2>
+
+<sect2 id="rules-ivm-distinct">
+<title><literal>DISTINCT</literal></title>
+
+<para>
+ <productname>PostgreSQL</productname> supports <acronym>IMMV</acronym> with
+ <literal>DISTINCT</literal>. For example, suppose a <acronym>IMMV</acronym>
+ defined with <literal>DISTINCT</literal> on a base table containing duplicate
+ tuples. When tuples are deleted from the base table, a tuple in the view is
+ deleted if and only if the multiplicity of the tuple becomes zero. Moreover,
+ when tuples are inserted into the base table, a tuple is inserted into the
+ view only if the same tuple doesn't already exist in it.
+</para>
+
+<para>
+ Physically, an <acronym>IMMV</acronym> defined with <literal>DISTINCT</literal>
+ contains tuples after eliminating duplicates, and the multiplicity of each tuple
+ is stored in a hidden column named <literal>__ivm_count__</literal>.
+</para>
+</sect2>
+
+<sect2 id="rules-ivm-concurrent-transactions">
+<title>Concurrent Transactions</title>
+<para>
+ Suppose an <acronym>IMMV</acronym> is defined on two base tables and each
+ table was modified in different a concurrent transaction simultaneously.
+ In the transaction which was committed first, <acronym>IMMV</acronym> can
+ be updated considering only the change which happened in this transaction.
+ On the other hand, in order to update the view correctly in the transaction
+ which was committed later, we need to know the changes occurred in
+ both transactions. For this reason, <literal>ExclusiveLock</literal>
+ is held on an <acronym>IMMV</acronym> immediately after a base table is
+ modified in <literal>READ COMMITTED</literal> mode to make sure that
+ the <acronym>IMMV</acronym> is updated in the latter transaction after
+ the former transaction is committed. In <literal>REPEATABLE READ</literal>
+ or <literal>SERIALIZABLE</literal> mode, an error is raised immediately
+ if lock acquisition fails because any changes which occurred in
+ other transactions are not be visible in these modes and
+ <acronym>IMMV</acronym> cannot be updated correctly in such situations.
+ However, as an exception if the view has only one base table and
+ <command>INSERT</command> is performed on the table,
+ the lock held on thew view is <literal>RowExclusiveLock</literal>.
+</para>
+</sect2>
+
+<sect2 id="rules-ivm-rls">
+<title>Row Level Security</title>
+<para>
+ If some base tables have row level security policy, rows that are not visible
+ to the materialized view's owner are excluded from the result. In addition, such
+ rows are excluded as well when views are incrementally maintained. However, if a
+ new policy is defined or policies are changed after the materialized view was created,
+ the new policy will not be applied to the view contents. To apply the new policy,
+ you need to refresh materialized views.
+</para>
+</sect2>
+
+</sect1>
+
<sect1 id="rules-update">
<title>Rules on <command>INSERT</command>, <command>UPDATE</command>, and <command>DELETE</command></title>
diff --git a/doc/src/sgml/system-views.sgml b/doc/src/sgml/system-views.sgml
index be90edd0e2..c909b2ab91 100644
--- a/doc/src/sgml/system-views.sgml
+++ b/doc/src/sgml/system-views.sgml
@@ -1787,6 +1787,15 @@ SELECT * FROM pg_locks pl LEFT JOIN pg_prepared_xacts ppx
</para></entry>
</row>
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>isimmv</structfield> <type>bool</type>
+ </para>
+ <para>
+ True if materialized view is incrementally maintainable
+ </para></entry>
+ </row>
+
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>definition</structfield> <type>text</type>
--
2.25.1
On Mon, 4 Mar 2024 11:58:46 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:
On Tue, 23 Jan 2024 16:23:27 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:On Mon, 22 Jan 2024 13:51:08 +1100
Peter Smith <smithpb2250@gmail.com> wrote:2024-01 Commitfest.
Hi, This patch has a CF status of "Needs Review" [1], but it seems
like there was some CFbot test failure last time it was run [2].
Please have a look and post an updated version if necessary.I attached a rebased patch-set, v30.
I attached a rebased patch-set, v31.
Also, I added a comment on RelationIsIVM() macro persuggestion from jian he.
In addition, I fixed a failure reported from cfbot on FreeBSD build caused by;
WARNING: outfuncs/readfuncs failed to produce an equal rewritten parse tree
This warning was raised since I missed to modify outfuncs.c for a new field.
Regards,
Yugo Nagata
Regards,
Yugo Nagata--
Yugo NAGATA <nagata@sraoss.co.jp>
--
Yugo NAGATA <nagata@sraoss.co.jp>
Attachments:
v31-0001-Add-a-syntax-to-create-Incrementally-Maintainabl.patchtext/x-diff; name=v31-0001-Add-a-syntax-to-create-Incrementally-Maintainabl.patchDownload
From 59c733c16d44b090fda173df1498a7719a9ba88c Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:05:02 +0900
Subject: [PATCH v31 01/11] Add a syntax to create Incrementally Maintainable
Materialized Views
Allow to create Incrementally Maintainable Materialized View (IMMV)
by using INCREMENTAL option in CREATE MATERIALIZED VIEW command
as follow:
CREATE [INCREMANTAL] MATERIALIZED VIEW xxxxx AS SELECT ....;
---
src/backend/parser/gram.y | 32 +++++++++++++++++++++-----------
src/include/nodes/primnodes.h | 1 +
src/include/parser/kwlist.h | 1 +
3 files changed, 23 insertions(+), 11 deletions(-)
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index c1b0cff1c9..3a4746a22b 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -467,6 +467,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <range> OptTempTableName
%type <into> into_clause create_as_target create_mv_target
+%type <boolean> incremental
%type <defelt> createfunc_opt_item common_func_opt_item dostmt_opt_item
%type <fun_param> func_arg func_arg_with_default table_func_column aggr_arg
@@ -730,7 +731,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
HANDLER HAVING HEADER_P HOLD HOUR_P
IDENTITY_P IF_P ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IMPORT_P IN_P INCLUDE
- INCLUDING INCREMENT INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
+ INCLUDING INCREMENT INCREMENTAL INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
@@ -4732,32 +4733,34 @@ opt_with_data:
*****************************************************************************/
CreateMatViewStmt:
- CREATE OptNoLog MATERIALIZED VIEW create_mv_target AS SelectStmt opt_with_data
+ CREATE OptNoLog incremental MATERIALIZED VIEW create_mv_target AS SelectStmt opt_with_data
{
CreateTableAsStmt *ctas = makeNode(CreateTableAsStmt);
- ctas->query = $7;
- ctas->into = $5;
+ ctas->query = $8;
+ ctas->into = $6;
ctas->objtype = OBJECT_MATVIEW;
ctas->is_select_into = false;
ctas->if_not_exists = false;
/* cram additional flags into the IntoClause */
- $5->rel->relpersistence = $2;
- $5->skipData = !($8);
+ $6->rel->relpersistence = $2;
+ $6->skipData = !($9);
+ $6->ivm = $3;
$$ = (Node *) ctas;
}
- | CREATE OptNoLog MATERIALIZED VIEW IF_P NOT EXISTS create_mv_target AS SelectStmt opt_with_data
+ | CREATE OptNoLog incremental MATERIALIZED VIEW IF_P NOT EXISTS create_mv_target AS SelectStmt opt_with_data
{
CreateTableAsStmt *ctas = makeNode(CreateTableAsStmt);
- ctas->query = $10;
- ctas->into = $8;
+ ctas->query = $11;
+ ctas->into = $9;
ctas->objtype = OBJECT_MATVIEW;
ctas->is_select_into = false;
ctas->if_not_exists = true;
/* cram additional flags into the IntoClause */
- $8->rel->relpersistence = $2;
- $8->skipData = !($11);
+ $9->rel->relpersistence = $2;
+ $9->skipData = !($12);
+ $9->ivm = $3;
$$ = (Node *) ctas;
}
;
@@ -4774,9 +4777,14 @@ create_mv_target:
$$->tableSpaceName = $5;
$$->viewQuery = NULL; /* filled at analysis time */
$$->skipData = false; /* might get changed later */
+ $$->ivm = false;
}
;
+incremental: INCREMENTAL { $$ = true; }
+ | /*EMPTY*/ { $$ = false; }
+ ;
+
OptNoLog: UNLOGGED { $$ = RELPERSISTENCE_UNLOGGED; }
| /*EMPTY*/ { $$ = RELPERSISTENCE_PERMANENT; }
;
@@ -17436,6 +17444,7 @@ unreserved_keyword:
| INCLUDE
| INCLUDING
| INCREMENT
+ | INCREMENTAL
| INDENT
| INDEX
| INDEXES
@@ -18017,6 +18026,7 @@ bare_label_keyword:
| INCLUDE
| INCLUDING
| INCREMENT
+ | INCREMENTAL
| INDENT
| INDEX
| INDEXES
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index 376f67e6a5..f7bcf78cf2 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -154,6 +154,7 @@ typedef struct IntoClause
/* materialized view's SELECT query */
Node *viewQuery pg_node_attr(query_jumble_ignore);
bool skipData; /* true for WITH NO DATA */
+ bool ivm; /* true for WITH IVM */
} IntoClause;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 57514d064b..f146d7c41a 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -210,6 +210,7 @@ PG_KEYWORD("in", IN_P, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("include", INCLUDE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("including", INCLUDING, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("increment", INCREMENT, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("incremental", INCREMENTAL, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("indent", INDENT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("index", INDEX, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("indexes", INDEXES, UNRESERVED_KEYWORD, BARE_LABEL)
--
2.25.1
v31-0002-Add-relisivm-column-to-pg_class-system-catalog.patchtext/x-diff; name=v31-0002-Add-relisivm-column-to-pg_class-system-catalog.patchDownload
From 1c8c4821f46e0395e9f0d14c22a0a591c7208a39 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:07:23 +0900
Subject: [PATCH v31 02/11] Add relisivm column to pg_class system catalog
If this boolean column is true, a relations is Incrementally Maintainable
Materialized View (IMMV). This is set when IMMV is created.
Also, isimmv columns is added to pg_matviews system view.
isimmv
---
src/backend/catalog/heap.c | 1 +
src/backend/catalog/index.c | 1 +
src/backend/catalog/system_views.sql | 1 +
src/backend/utils/cache/lsyscache.c | 24 ++++++++++++++++++++++++
src/backend/utils/cache/relcache.c | 2 ++
src/include/catalog/pg_class.h | 3 +++
src/include/utils/lsyscache.h | 1 +
src/include/utils/rel.h | 6 ++++++
src/test/regress/expected/rules.out | 1 +
9 files changed, 40 insertions(+)
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index cc31909012..1d2e2228c4 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -937,6 +937,7 @@ InsertPgClassTuple(Relation pg_class_desc,
values[Anum_pg_class_relrewrite - 1] = ObjectIdGetDatum(rd_rel->relrewrite);
values[Anum_pg_class_relfrozenxid - 1] = TransactionIdGetDatum(rd_rel->relfrozenxid);
values[Anum_pg_class_relminmxid - 1] = MultiXactIdGetDatum(rd_rel->relminmxid);
+ values[Anum_pg_class_relisivm - 1] = BoolGetDatum(rd_rel->relisivm);
if (relacl != (Datum) 0)
values[Anum_pg_class_relacl - 1] = relacl;
else
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index b6a7c60e23..906ec6c088 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -1007,6 +1007,7 @@ index_create(Relation heapRelation,
indexRelation->rd_rel->relowner = heapRelation->rd_rel->relowner;
indexRelation->rd_rel->relam = accessMethodId;
indexRelation->rd_rel->relispartition = OidIsValid(parentIndexRelid);
+ indexRelation->rd_rel->relisivm = false;
/*
* store index's pg_class entry
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index 401fb35947..16c3399975 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -146,6 +146,7 @@ CREATE VIEW pg_matviews AS
T.spcname AS tablespace,
C.relhasindex AS hasindexes,
C.relispopulated AS ispopulated,
+ C.relisivm AS isimmv,
pg_get_viewdef(C.oid) AS definition
FROM pg_class C LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
LEFT JOIN pg_tablespace T ON (T.oid = C.reltablespace)
diff --git a/src/backend/utils/cache/lsyscache.c b/src/backend/utils/cache/lsyscache.c
index 26368ffcc9..01af4ad5bb 100644
--- a/src/backend/utils/cache/lsyscache.c
+++ b/src/backend/utils/cache/lsyscache.c
@@ -2020,6 +2020,30 @@ get_rel_relispartition(Oid relid)
return false;
}
+/*
+ * get_rel_relisivm
+ *
+ * Returns the relisivm flag associated with a given relation.
+ */
+bool
+get_rel_relisivm(Oid relid)
+{
+ HeapTuple tp;
+
+ tp = SearchSysCache1(RELOID, ObjectIdGetDatum(relid));
+ if (HeapTupleIsValid(tp))
+ {
+ Form_pg_class reltup = (Form_pg_class) GETSTRUCT(tp);
+ bool result;
+
+ result = reltup->relisivm;
+ ReleaseSysCache(tp);
+ return result;
+ }
+ else
+ return false;
+}
+
/*
* get_rel_tablespace
*
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 1f419c2a6d..71c0fd506c 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -1932,6 +1932,8 @@ formrdesc(const char *relationName, Oid relationReltype,
/* ... and they're always populated, too */
relation->rd_rel->relispopulated = true;
+ /* ... and they're always no ivm, too */
+ relation->rd_rel->relisivm = false;
relation->rd_rel->relreplident = REPLICA_IDENTITY_NOTHING;
relation->rd_rel->relpages = 0;
diff --git a/src/include/catalog/pg_class.h b/src/include/catalog/pg_class.h
index 0fc2c093b0..80cbee29ca 100644
--- a/src/include/catalog/pg_class.h
+++ b/src/include/catalog/pg_class.h
@@ -119,6 +119,9 @@ CATALOG(pg_class,1259,RelationRelationId) BKI_BOOTSTRAP BKI_ROWTYPE_OID(83,Relat
/* is relation a partition? */
bool relispartition BKI_DEFAULT(f);
+ /* is relation a matview with ivm? */
+ bool relisivm BKI_DEFAULT(f);
+
/* link to original rel during table rewrite; otherwise 0 */
Oid relrewrite BKI_DEFAULT(0) BKI_LOOKUP_OPT(pg_class);
diff --git a/src/include/utils/lsyscache.h b/src/include/utils/lsyscache.h
index 35a8dec2b9..93c2fcb21c 100644
--- a/src/include/utils/lsyscache.h
+++ b/src/include/utils/lsyscache.h
@@ -137,6 +137,7 @@ extern Oid get_rel_namespace(Oid relid);
extern Oid get_rel_type_id(Oid relid);
extern char get_rel_relkind(Oid relid);
extern bool get_rel_relispartition(Oid relid);
+extern bool get_rel_relisivm(Oid relid);
extern Oid get_rel_tablespace(Oid relid);
extern char get_rel_persistence(Oid relid);
extern Oid get_rel_relam(Oid relid);
diff --git a/src/include/utils/rel.h b/src/include/utils/rel.h
index f25f769af2..d3144c949f 100644
--- a/src/include/utils/rel.h
+++ b/src/include/utils/rel.h
@@ -678,6 +678,12 @@ RelationCloseSmgr(Relation relation)
*/
#define RelationIsPopulated(relation) ((relation)->rd_rel->relispopulated)
+/*
+ * RelationIsIVM
+ * True if relation is an incrementally maintainable materialized view.
+ */
+#define RelationIsIVM(relation) ((relation)->rd_rel->relisivm)
+
/*
* RelationIsAccessibleInLogicalDecoding
* True if we need to log enough information to have access via
diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out
index f53c3036a6..c6e878c3ab 100644
--- a/src/test/regress/expected/rules.out
+++ b/src/test/regress/expected/rules.out
@@ -1392,6 +1392,7 @@ pg_matviews| SELECT n.nspname AS schemaname,
t.spcname AS tablespace,
c.relhasindex AS hasindexes,
c.relispopulated AS ispopulated,
+ c.relisivm AS isimmv,
pg_get_viewdef(c.oid) AS definition
FROM ((pg_class c
LEFT JOIN pg_namespace n ON ((n.oid = c.relnamespace)))
--
2.25.1
v31-0003-Allow-to-prolong-life-span-of-transition-tables-.patchtext/x-diff; name=v31-0003-Allow-to-prolong-life-span-of-transition-tables-.patchDownload
From 3534db8daf699fd36945f70adfe0f705f2ee2087 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:09:45 +0900
Subject: [PATCH v31 03/11] Allow to prolong life span of transition tables
until transaction end
Originally, tuplestores of AFTER trigger's transition tables were
freed for each query depth. For our IVM implementation, we would like
to prolong life of the tuplestores because we have to preserve them
for a whole query assuming that some base tables might be changed
in some trigger functions.
---
src/backend/commands/trigger.c | 83 ++++++++++++++++++++++++++++++++--
src/include/commands/trigger.h | 2 +
2 files changed, 81 insertions(+), 4 deletions(-)
diff --git a/src/backend/commands/trigger.c b/src/backend/commands/trigger.c
index 84494c4b81..0424ab9a29 100644
--- a/src/backend/commands/trigger.c
+++ b/src/backend/commands/trigger.c
@@ -3729,6 +3729,10 @@ typedef struct AfterTriggerEventList
* end of the list, so it is relatively easy to discard them. The event
* list chunks themselves are stored in event_cxt.
*
+ * prolonged_tuplestored is a list of transition table tuplestores whose
+ * life are prolonged to the end of the outmost query instead of each nested
+ * query.
+ *
* query_depth is the current depth of nested AfterTriggerBeginQuery calls
* (-1 when the stack is empty).
*
@@ -3794,6 +3798,7 @@ typedef struct AfterTriggersData
SetConstraintState state; /* the active S C state */
AfterTriggerEventList events; /* deferred-event list */
MemoryContext event_cxt; /* memory context for events, if any */
+ List *prolonged_tuplestores; /* list of prolonged tuplestores */
/* per-query-level data: */
AfterTriggersQueryData *query_stack; /* array of structs shown below */
@@ -3829,6 +3834,7 @@ struct AfterTriggersTableData
bool closed; /* true when no longer OK to add tuples */
bool before_trig_done; /* did we already queue BS triggers? */
bool after_trig_done; /* did we already queue AS triggers? */
+ bool prolonged; /* are transition tables prolonged? */
AfterTriggerEventList after_trig_events; /* if so, saved list pointer */
/*
@@ -3878,6 +3884,7 @@ static void TransitionTableAddTuple(EState *estate,
TupleTableSlot *original_insert_tuple,
Tuplestorestate *tuplestore);
static void AfterTriggerFreeQuery(AfterTriggersQueryData *qs);
+static void release_or_prolong_tuplestore(Tuplestorestate *ts, bool prolonged);
static SetConstraintState SetConstraintStateCreate(int numalloc);
static SetConstraintState SetConstraintStateCopy(SetConstraintState origstate);
static SetConstraintState SetConstraintStateAddItem(SetConstraintState state,
@@ -4755,6 +4762,45 @@ afterTriggerInvokeEvents(AfterTriggerEventList *events,
}
+/*
+ * SetTransitionTablePreserved
+ *
+ * Prolong lifespan of transition tables corresponding specified relid and
+ * command type to the end of the outmost query instead of each nested query.
+ * This enables to use nested AFTER trigger's transition tables from outer
+ * query's triggers. Currently, only immediate incremental view maintenance
+ * uses this.
+ */
+void
+SetTransitionTablePreserved(Oid relid, CmdType cmdType)
+{
+ AfterTriggersTableData *table;
+ AfterTriggersQueryData *qs;
+ bool found = false;
+ ListCell *lc;
+
+ /* Check state, like AfterTriggerSaveEvent. */
+ if (afterTriggers.query_depth < 0)
+ elog(ERROR, "SetTransitionTablePreserved() called outside of query");
+
+ qs = &afterTriggers.query_stack[afterTriggers.query_depth];
+
+ foreach(lc, qs->tables)
+ {
+ table = (AfterTriggersTableData *) lfirst(lc);
+ if (table->relid == relid && table->cmdType == cmdType &&
+ table->closed)
+ {
+ table->prolonged = true;
+ found = true;
+ }
+ }
+
+ if (!found)
+ elog(ERROR,"could not find table with OID %d and command type %d", relid, cmdType);
+}
+
+
/*
* GetAfterTriggersTableData
*
@@ -4965,6 +5011,7 @@ AfterTriggerBeginXact(void)
*/
afterTriggers.firing_counter = (CommandId) 1; /* mustn't be 0 */
afterTriggers.query_depth = -1;
+ afterTriggers.prolonged_tuplestores = NIL;
/*
* Verify that there is no leftover state remaining. If these assertions
@@ -5125,19 +5172,19 @@ AfterTriggerFreeQuery(AfterTriggersQueryData *qs)
ts = table->old_upd_tuplestore;
table->old_upd_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->new_upd_tuplestore;
table->new_upd_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->old_del_tuplestore;
table->old_del_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->new_ins_tuplestore;
table->new_ins_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
if (table->storeslot)
{
TupleTableSlot *slot = table->storeslot;
@@ -5154,6 +5201,34 @@ AfterTriggerFreeQuery(AfterTriggersQueryData *qs)
*/
qs->tables = NIL;
list_free_deep(tables);
+
+ /* Release prolonged tuplestores at the end of the outmost query */
+ if (afterTriggers.query_depth == 0)
+ {
+ foreach(lc, afterTriggers.prolonged_tuplestores)
+ {
+ ts = (Tuplestorestate *) lfirst(lc);
+ if (ts)
+ tuplestore_end(ts);
+ }
+ afterTriggers.prolonged_tuplestores = NIL;
+ }
+}
+
+/*
+ * Release the tuplestore, or append it to the prolonged tuplestores list.
+ */
+static void
+release_or_prolong_tuplestore(Tuplestorestate *ts, bool prolonged)
+{
+ if (prolonged && afterTriggers.query_depth > 0)
+ {
+ MemoryContext oldcxt = MemoryContextSwitchTo(CurTransactionContext);
+ afterTriggers.prolonged_tuplestores = lappend(afterTriggers.prolonged_tuplestores, ts);
+ MemoryContextSwitchTo(oldcxt);
+ }
+ else
+ tuplestore_end(ts);
}
diff --git a/src/include/commands/trigger.h b/src/include/commands/trigger.h
index cb968d03ec..768d6e1c0b 100644
--- a/src/include/commands/trigger.h
+++ b/src/include/commands/trigger.h
@@ -265,6 +265,8 @@ extern void AfterTriggerEndSubXact(bool isCommit);
extern void AfterTriggerSetState(ConstraintsSetStmt *stmt);
extern bool AfterTriggerPendingOnRel(Oid relid);
+extern void SetTransitionTablePreserved(Oid relid, CmdType cmdType);
+
/*
* in utils/adt/ri_triggers.c
--
2.25.1
v31-0004-Add-Incremental-View-Maintenance-support-to-pg_d.patchtext/x-diff; name=v31-0004-Add-Incremental-View-Maintenance-support-to-pg_d.patchDownload
From 727d939cb9f23439fd3322942a78c60fc35f92f5 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 11 Nov 2020 17:01:25 +0900
Subject: [PATCH v31 04/11] Add Incremental View Maintenance support to pg_dump
Support CREATE INCREMENTAL MATERIALIZED VIEW syntax.
---
src/bin/pg_dump/pg_dump.c | 18 +++++++++++++++---
src/bin/pg_dump/pg_dump.h | 2 ++
src/bin/pg_dump/t/002_pg_dump.pl | 18 ++++++++++++++++++
3 files changed, 35 insertions(+), 3 deletions(-)
diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c
index b1c4c3ec7f..92a8cbf244 100644
--- a/src/bin/pg_dump/pg_dump.c
+++ b/src/bin/pg_dump/pg_dump.c
@@ -6677,6 +6677,7 @@ getTables(Archive *fout, int *numTables)
int i_relacl;
int i_acldefault;
int i_ispartition;
+ int i_isivm;
/*
* Find all the tables and table-like objects.
@@ -6779,10 +6780,17 @@ getTables(Archive *fout, int *numTables)
if (fout->remoteVersion >= 100000)
appendPQExpBufferStr(query,
- "c.relispartition AS ispartition ");
+ "c.relispartition AS ispartition, ");
else
appendPQExpBufferStr(query,
- "false AS ispartition ");
+ "false AS ispartition, ");
+
+ if (fout->remoteVersion >= 170000)
+ appendPQExpBufferStr(query,
+ "c.relisivm AS isivm ");
+ else
+ appendPQExpBufferStr(query,
+ "false AS isivm ");
/*
* Left join to pg_depend to pick up dependency info linking sequences to
@@ -6891,6 +6899,7 @@ getTables(Archive *fout, int *numTables)
i_relacl = PQfnumber(res, "relacl");
i_acldefault = PQfnumber(res, "acldefault");
i_ispartition = PQfnumber(res, "ispartition");
+ i_isivm = PQfnumber(res, "isivm");
if (dopt->lockWaitTimeout)
{
@@ -6970,6 +6979,7 @@ getTables(Archive *fout, int *numTables)
tblinfo[i].amname = pg_strdup(PQgetvalue(res, i, i_amname));
tblinfo[i].is_identity_sequence = (strcmp(PQgetvalue(res, i, i_is_identity_sequence), "t") == 0);
tblinfo[i].ispartition = (strcmp(PQgetvalue(res, i, i_ispartition), "t") == 0);
+ tblinfo[i].isivm = (strcmp(PQgetvalue(res, i, i_isivm), "t") == 0);
/* other fields were zeroed above */
@@ -16023,9 +16033,11 @@ dumpTableSchema(Archive *fout, const TableInfo *tbinfo)
binary_upgrade_set_pg_class_oids(fout, q,
tbinfo->dobj.catId.oid, false);
- appendPQExpBuffer(q, "CREATE %s%s %s",
+ appendPQExpBuffer(q, "CREATE %s%s%s %s",
tbinfo->relpersistence == RELPERSISTENCE_UNLOGGED ?
"UNLOGGED " : "",
+ tbinfo->relkind == RELKIND_MATVIEW && tbinfo->isivm ?
+ "INCREMENTAL " : "",
reltypename,
qualrelname);
diff --git a/src/bin/pg_dump/pg_dump.h b/src/bin/pg_dump/pg_dump.h
index 9bc93520b4..4e240f8832 100644
--- a/src/bin/pg_dump/pg_dump.h
+++ b/src/bin/pg_dump/pg_dump.h
@@ -325,6 +325,8 @@ typedef struct _tableInfo
int numParents; /* number of (immediate) parent tables */
struct _tableInfo **parents; /* TableInfos of immediate parents */
+ bool isivm; /* is incrementally maintainable materialized view? */
+
/*
* These fields are computed only if we decide the table is interesting
* (it's either a table to dump, or a direct parent of a dumpable table).
diff --git a/src/bin/pg_dump/t/002_pg_dump.pl b/src/bin/pg_dump/t/002_pg_dump.pl
index f0410ce6a1..a119ec8db1 100644
--- a/src/bin/pg_dump/t/002_pg_dump.pl
+++ b/src/bin/pg_dump/t/002_pg_dump.pl
@@ -2832,6 +2832,24 @@ my %tests = (
},
},
+ 'CREATE MATERIALIZED VIEW matview_ivm' => {
+ create_order => 21,
+ create_sql => 'CREATE INCREMENTAL MATERIALIZED VIEW dump_test.matview_ivm (col1) AS
+ SELECT col1 FROM dump_test.test_table;',
+ regexp => qr/^
+ \QCREATE INCREMENTAL MATERIALIZED VIEW dump_test.matview_ivm AS\E
+ \n\s+\QSELECT col1\E
+ \n\s+\QFROM dump_test.test_table\E
+ \n\s+\QWITH NO DATA;\E
+ /xm,
+ like =>
+ { %full_runs, %dump_test_schema_runs, section_pre_data => 1, },
+ unlike => {
+ exclude_dump_test_schema => 1,
+ only_dump_measurement => 1,
+ },
+ },
+
'CREATE POLICY p1 ON test_table' => {
create_order => 22,
create_sql => 'CREATE POLICY p1 ON dump_test.test_table
--
2.25.1
v31-0005-Add-Incremental-View-Maintenance-support-to-psql.patchtext/x-diff; name=v31-0005-Add-Incremental-View-Maintenance-support-to-psql.patchDownload
From 4a79294b239e10a1c7b358bbbfb58d2bd440ae64 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:21:54 +0900
Subject: [PATCH v31 05/11] Add Incremental View Maintenance support to psql
Add tab completion and meta-command output for IVM.
---
src/bin/psql/describe.c | 32 +++++++++++++++++++++++++++++++-
src/bin/psql/tab-complete.c | 14 +++++++++-----
2 files changed, 40 insertions(+), 6 deletions(-)
diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c
index 6433497bcd..df559dce42 100644
--- a/src/bin/psql/describe.c
+++ b/src/bin/psql/describe.c
@@ -1574,6 +1574,7 @@ describeOneTableDetails(const char *schemaname,
char relpersistence;
char relreplident;
char *relam;
+ bool isivm;
} tableinfo;
bool show_column_details = false;
@@ -1586,7 +1587,26 @@ describeOneTableDetails(const char *schemaname,
initPQExpBuffer(&tmpbuf);
/* Get general table info */
- if (pset.sversion >= 120000)
+ if (pset.sversion >= 170000)
+ {
+ printfPQExpBuffer(&buf,
+ "SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
+ "c.relhastriggers, c.relrowsecurity, c.relforcerowsecurity, "
+ "false AS relhasoids, c.relispartition, %s, c.reltablespace, "
+ "CASE WHEN c.reloftype = 0 THEN '' ELSE c.reloftype::pg_catalog.regtype::pg_catalog.text END, "
+ "c.relpersistence, c.relreplident, am.amname, "
+ "c.relisivm\n"
+ "FROM pg_catalog.pg_class c\n "
+ "LEFT JOIN pg_catalog.pg_class tc ON (c.reltoastrelid = tc.oid)\n"
+ "LEFT JOIN pg_catalog.pg_am am ON (c.relam = am.oid)\n"
+ "WHERE c.oid = '%s';",
+ (verbose ?
+ "pg_catalog.array_to_string(c.reloptions || "
+ "array(select 'toast.' || x from pg_catalog.unnest(tc.reloptions) x), ', ')\n"
+ : "''"),
+ oid);
+ }
+ else if (pset.sversion >= 120000)
{
printfPQExpBuffer(&buf,
"SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
@@ -1706,6 +1726,10 @@ describeOneTableDetails(const char *schemaname,
(char *) NULL : pg_strdup(PQgetvalue(res, 0, 14));
else
tableinfo.relam = NULL;
+ if (pset.sversion >= 170000)
+ tableinfo.isivm = strcmp(PQgetvalue(res, 0, 15), "t") == 0;
+ else
+ tableinfo.isivm = false;
PQclear(res);
res = NULL;
@@ -3560,6 +3584,12 @@ describeOneTableDetails(const char *schemaname,
printfPQExpBuffer(&buf, _("Access method: %s"), tableinfo.relam);
printTableAddFooter(&cont, buf.data);
}
+
+ /* Incremental view maintance info */
+ if (verbose && tableinfo.relkind == RELKIND_MATVIEW && tableinfo.isivm)
+ {
+ printTableAddFooter(&cont, _("Incremental view maintenance: yes"));
+ }
}
/* reloptions, if verbose */
diff --git a/src/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c
index f121216ddc..946d47fa1f 100644
--- a/src/bin/psql/tab-complete.c
+++ b/src/bin/psql/tab-complete.c
@@ -1245,6 +1245,7 @@ static const pgsql_thing_t words_after_create[] = {
{"FOREIGN TABLE", NULL, NULL, NULL},
{"FUNCTION", NULL, NULL, Query_for_list_of_functions},
{"GROUP", Query_for_list_of_roles},
+ {"INCREMENTAL MATERIALIZED VIEW", NULL, NULL, &Query_for_list_of_matviews, NULL, THING_NO_DROP | THING_NO_ALTER},
{"INDEX", NULL, NULL, &Query_for_list_of_indexes},
{"LANGUAGE", Query_for_list_of_languages},
{"LARGE OBJECT", NULL, NULL, NULL, NULL, THING_NO_CREATE | THING_NO_DROP},
@@ -3256,7 +3257,7 @@ psql_completion(const char *text, int start, int end)
if (HeadMatches("CREATE", "SCHEMA"))
COMPLETE_WITH("TABLE", "SEQUENCE");
else
- COMPLETE_WITH("TABLE", "SEQUENCE", "MATERIALIZED VIEW");
+ COMPLETE_WITH("TABLE", "SEQUENCE", "MATERIALIZED VIEW", "INCREMENTAL MATERIALIZED VIEW");
}
/* Complete PARTITION BY with RANGE ( or LIST ( or ... */
else if (TailMatches("PARTITION", "BY"))
@@ -3601,13 +3602,16 @@ psql_completion(const char *text, int start, int end)
COMPLETE_WITH("SELECT");
/* CREATE MATERIALIZED VIEW */
- else if (Matches("CREATE", "MATERIALIZED"))
+ else if (Matches("CREATE", "MATERIALIZED") ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED"))
COMPLETE_WITH("VIEW");
- /* Complete CREATE MATERIALIZED VIEW <name> with AS */
- else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny))
+ /* Complete CREATE MATERIALIZED VIEW <name> with AS */
+ else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny) ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED", "VIEW", MatchAny))
COMPLETE_WITH("AS");
/* Complete "CREATE MATERIALIZED VIEW <sth> AS with "SELECT" */
- else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny, "AS"))
+ else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny, "AS") ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED", "VIEW", MatchAny, "AS"))
COMPLETE_WITH("SELECT");
/* CREATE EVENT TRIGGER */
--
2.25.1
v31-0006-Add-Incremental-View-Maintenance-support.patchtext/x-diff; name=v31-0006-Add-Incremental-View-Maintenance-support.patchDownload
From 81a4c748afd4fc5ddd56ed0cdd0b607e57d93d21 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 18:59:50 +0900
Subject: [PATCH v31 06/11] Add Incremental View Maintenance support
In this implementation, AFTER triggers are used to collect
tuplestores containing transition table contents. When multiple tables
are changed, multiple AFTER triggers are invoked, then the final AFTER
trigger performs actual update of the matview. In addition, BEFORE
triggers are also used to handle global information for view
maintenance.
To calculate view deltas, we need both pre-state and post-state of base
tables. Post-update states are available in AFTER trigger, and pre-update
states can be calculated by removing inserted tuples and appending deleted
tuples. Insterted tuples are filtered using the snapshot taken before
table modiication, and deleted tuples are contained in the old transition
table.
Incrementally Maintainable Materialized Views (IMMV) can contain
duplicated tuples.
This patch also allows self-join, simultaneous updates of more than
one base table, and multiple updates of the same base table.
---
src/backend/access/transam/xact.c | 5 +
src/backend/commands/createas.c | 682 ++++++++++++++
src/backend/commands/matview.c | 1468 ++++++++++++++++++++++++++++-
src/include/catalog/pg_proc.dat | 10 +
src/include/commands/createas.h | 4 +
src/include/commands/matview.h | 9 +
6 files changed, 2143 insertions(+), 35 deletions(-)
diff --git a/src/backend/access/transam/xact.c b/src/backend/access/transam/xact.c
index df5a67e4c3..a2d5404912 100644
--- a/src/backend/access/transam/xact.c
+++ b/src/backend/access/transam/xact.c
@@ -36,6 +36,7 @@
#include "catalog/pg_enum.h"
#include "catalog/storage.h"
#include "commands/async.h"
+#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/trigger.h"
#include "common/pg_prng.h"
@@ -2860,6 +2861,7 @@ AbortTransaction(void)
AtAbort_Notify();
AtEOXact_RelationMap(false, is_parallel_worker);
AtAbort_Twophase();
+ AtAbort_IVM();
/*
* Advertise the fact that we aborted in pg_xact (assuming that we got as
@@ -5198,6 +5200,9 @@ AbortSubTransaction(void)
pgstat_progress_end_command();
UnlockBuffers();
+ /* Clean up hash entries for incremental view maintenance */
+ AtAbort_IVM();
+
/* Reset WAL record construction state */
XLogResetInsertion();
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index 62050f4dc5..04a5ee9e37 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -29,15 +29,27 @@
#include "access/tableam.h"
#include "access/xact.h"
#include "catalog/namespace.h"
+#include "catalog/index.h"
+#include "catalog/pg_constraint.h"
+#include "catalog/pg_inherits.h"
+#include "catalog/pg_trigger.h"
#include "catalog/toasting.h"
#include "commands/createas.h"
+#include "commands/defrem.h"
#include "commands/matview.h"
#include "commands/prepare.h"
#include "commands/tablecmds.h"
+#include "commands/tablespace.h"
+#include "commands/trigger.h"
#include "commands/view.h"
#include "miscadmin.h"
+#include "optimizer/optimizer.h"
+#include "optimizer/prep.h"
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
+#include "parser/parser.h"
+#include "parser/parsetree.h"
+#include "parser/parse_clause.h"
#include "rewrite/rewriteHandler.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
@@ -68,6 +80,12 @@ static bool intorel_receive(TupleTableSlot *slot, DestReceiver *self);
static void intorel_shutdown(DestReceiver *self);
static void intorel_destroy(DestReceiver *self);
+static void CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid matviewOid,
+ Relids *relids, bool ex_lock);
+static void CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock);
+static void check_ivm_restriction(Node *node);
+static bool check_ivm_restriction_walker(Node *node, void *context);
+static Bitmapset *get_primary_key_attnos_from_query(Query *query, List **constraintList);
/*
* create_ctas_internal
@@ -277,6 +295,18 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
save_nestlevel = NewGUCNestLevel();
}
+ if (is_matview && into->ivm)
+ {
+ /* check if the query is supported in IMMV definition */
+ if (contain_mutable_functions((Node *) query))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("mutable function is not supported on incrementally maintainable materialized view"),
+ errhint("functions must be marked IMMUTABLE")));
+
+ check_ivm_restriction((Node *) query);
+ }
+
if (into->skipData)
{
/*
@@ -353,6 +383,27 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
/* Restore userid and security context */
SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ if (into->ivm)
+ {
+ Oid matviewOid = address.objectId;
+ Relation matviewRel = table_open(matviewOid, NoLock);
+
+ /*
+ * Mark relisivm field, if it's a matview and into->ivm is true.
+ */
+ SetMatViewIVMState(matviewRel, true);
+
+ if (!into->skipData)
+ {
+ /* Create an index on incremental maintainable materialized view, if possible */
+ CreateIndexOnIMMV((Query *) into->viewQuery, matviewRel);
+
+ /* Create triggers on incremental maintainable materialized view */
+ CreateIvmTriggersOnBaseTables((Query *) into->viewQuery, matviewOid);
+ }
+ table_close(matviewRel, NoLock);
+ }
}
return address;
@@ -630,3 +681,634 @@ intorel_destroy(DestReceiver *self)
{
pfree(self);
}
+
+/*
+ * CreateIvmTriggersOnBaseTables -- create IVM triggers on all base tables
+ */
+void
+CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid)
+{
+ Relids relids = NULL;
+ bool ex_lock = false;
+ RangeTblEntry *rte;
+
+ /* Immediately return if we don't have any base tables. */
+ if (list_length(qry->rtable) < 1)
+ return;
+
+ /*
+ * If the view has more than one base tables, we need an exclusive lock
+ * on the view so that the view would be maintained serially to avoid
+ * the inconsistency that occurs when two base tables are modified in
+ * concurrent transactions. However, if the view has only one table,
+ * we can use a weaker lock.
+ *
+ * The type of lock should be determined here, because if we check the
+ * view definition at maintenance time, we need to acquire a weaker lock,
+ * and upgrading the lock level after this increases probability of
+ * deadlock.
+ */
+
+ rte = list_nth(qry->rtable, 0);
+ if (list_length(qry->rtable) > 1 || rte->rtekind != RTE_RELATION)
+ ex_lock = true;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, (Node *)qry, matviewOid, &relids, ex_lock);
+
+ bms_free(relids);
+}
+
+static void
+CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid matviewOid,
+ Relids *relids, bool ex_lock)
+{
+ if (node == NULL)
+ return;
+
+ /* This can recurse, so check for excessive recursion */
+ check_stack_depth();
+
+ switch (nodeTag(node))
+ {
+ case T_Query:
+ {
+ Query *query = (Query *) node;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, (Node *)query->jointree, matviewOid, relids, ex_lock);
+ }
+ break;
+
+ case T_RangeTblRef:
+ {
+ int rti = ((RangeTblRef *) node)->rtindex;
+ RangeTblEntry *rte = rt_fetch(rti, qry->rtable);
+
+ if (rte->rtekind == RTE_RELATION && !bms_is_member(rte->relid, *relids))
+ {
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_INSERT, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_DELETE, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_UPDATE, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_TRUNCATE, TRIGGER_TYPE_BEFORE, true);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_INSERT, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_DELETE, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_UPDATE, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_TRUNCATE, TRIGGER_TYPE_AFTER, true);
+
+ *relids = bms_add_member(*relids, rte->relid);
+ }
+ }
+ break;
+
+ case T_FromExpr:
+ {
+ FromExpr *f = (FromExpr *) node;
+ ListCell *l;
+
+ foreach(l, f->fromlist)
+ CreateIvmTriggersOnBaseTablesRecurse(qry, lfirst(l), matviewOid, relids, ex_lock);
+ }
+ break;
+
+ case T_JoinExpr:
+ {
+ JoinExpr *j = (JoinExpr *) node;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, j->larg, matviewOid, relids, ex_lock);
+ CreateIvmTriggersOnBaseTablesRecurse(qry, j->rarg, matviewOid, relids, ex_lock);
+ }
+ break;
+
+ default:
+ elog(ERROR, "unrecognized node type: %d", (int) nodeTag(node));
+ }
+}
+
+/*
+ * CreateIvmTrigger -- create IVM trigger on a base table
+ */
+static void
+CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock)
+{
+ ObjectAddress refaddr;
+ ObjectAddress address;
+ CreateTrigStmt *ivm_trigger;
+ List *transitionRels = NIL;
+
+ Assert(timing == TRIGGER_TYPE_BEFORE || timing == TRIGGER_TYPE_AFTER);
+
+ refaddr.classId = RelationRelationId;
+ refaddr.objectId = viewOid;
+ refaddr.objectSubId = 0;
+
+ ivm_trigger = makeNode(CreateTrigStmt);
+ ivm_trigger->relation = NULL;
+ ivm_trigger->row = false;
+
+ ivm_trigger->timing = timing;
+ ivm_trigger->events = type;
+
+ switch (type)
+ {
+ case TRIGGER_TYPE_INSERT:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_ins_before" : "IVM_trigger_ins_after");
+ break;
+ case TRIGGER_TYPE_DELETE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_del_before" : "IVM_trigger_del_after");
+ break;
+ case TRIGGER_TYPE_UPDATE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_upd_before" : "IVM_trigger_upd_after");
+ break;
+ case TRIGGER_TYPE_TRUNCATE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_truncate_before" : "IVM_trigger_truncate_after");
+ break;
+ default:
+ elog(ERROR, "unsupported trigger type");
+ }
+
+ if (timing == TRIGGER_TYPE_AFTER)
+ {
+ if (type == TRIGGER_TYPE_INSERT || type == TRIGGER_TYPE_UPDATE)
+ {
+ TriggerTransition *n = makeNode(TriggerTransition);
+ n->name = "__ivm_newtable";
+ n->isNew = true;
+ n->isTable = true;
+
+ transitionRels = lappend(transitionRels, n);
+ }
+ if (type == TRIGGER_TYPE_DELETE || type == TRIGGER_TYPE_UPDATE)
+ {
+ TriggerTransition *n = makeNode(TriggerTransition);
+ n->name = "__ivm_oldtable";
+ n->isNew = false;
+ n->isTable = true;
+
+ transitionRels = lappend(transitionRels, n);
+ }
+ }
+
+ /*
+ * XXX: When using DELETE or UPDATE, we must use exclusive lock for now
+ * because apply_old_delta(_with_count) uses ctid to identify the tuple
+ * to be deleted/deleted, but doesn't work in concurrent situations.
+ *
+ * If the view doesn't have aggregate, distinct, or tuple duplicate,
+ * then it would work even in concurrent situations. However, we don't have
+ * any way to guarantee the view has a unique key before opening the IMMV
+ * at the maintenance time because users may drop the unique index.
+ */
+
+ if (type == TRIGGER_TYPE_DELETE || type == TRIGGER_TYPE_UPDATE)
+ ex_lock = true;
+
+ ivm_trigger->funcname =
+ (timing == TRIGGER_TYPE_BEFORE ? SystemFuncName("IVM_immediate_before") : SystemFuncName("IVM_immediate_maintenance"));
+
+ ivm_trigger->columns = NIL;
+ ivm_trigger->transitionRels = transitionRels;
+ ivm_trigger->whenClause = NULL;
+ ivm_trigger->isconstraint = false;
+ ivm_trigger->deferrable = false;
+ ivm_trigger->initdeferred = false;
+ ivm_trigger->constrrel = NULL;
+ ivm_trigger->args = list_make2(
+ makeString(DatumGetPointer(DirectFunctionCall1(oidout, ObjectIdGetDatum(viewOid)))),
+ makeString(DatumGetPointer(DirectFunctionCall1(boolout, BoolGetDatum(ex_lock))))
+ );
+
+ address = CreateTrigger(ivm_trigger, NULL, relOid, InvalidOid, InvalidOid,
+ InvalidOid, InvalidOid, InvalidOid, NULL, true, false);
+
+ recordDependencyOn(&address, &refaddr, DEPENDENCY_AUTO);
+
+ /* Make changes-so-far visible */
+ CommandCounterIncrement();
+}
+
+/*
+ * check_ivm_restriction --- look for specify nodes in the query tree
+ */
+static void
+check_ivm_restriction(Node *node)
+{
+ check_ivm_restriction_walker(node, NULL);
+}
+
+static bool
+check_ivm_restriction_walker(Node *node, void *context)
+{
+ if (node == NULL)
+ return false;
+
+ /*
+ * We currently don't support Sub-Query.
+ */
+ if (IsA(node, SubPlan) || IsA(node, SubLink))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("subquery is not supported on incrementally maintainable materialized view")));
+
+ /* This can recurse, so check for excessive recursion */
+ check_stack_depth();
+
+ switch (nodeTag(node))
+ {
+ case T_Query:
+ {
+ Query *qry = (Query *)node;
+ ListCell *lc;
+ List *vars;
+
+ /* if contained CTE, return error */
+ if (qry->cteList != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("CTE is not supported on incrementally maintainable materialized view")));
+ if (qry->havingQual != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg(" HAVING clause is not supported on incrementally maintainable materialized view")));
+ if (qry->sortClause != NIL) /* There is a possibility that we don't need to return an error */
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("ORDER BY clause is not supported on incrementally maintainable materialized view")));
+ if (qry->limitOffset != NULL || qry->limitCount != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view")));
+ if (qry->distinctClause)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("DISTINCT is not supported on incrementally maintainable materialized view")));
+ if (qry->hasDistinctOn)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("DISTINCT ON is not supported on incrementally maintainable materialized view")));
+ if (qry->hasWindowFuncs)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("window functions are not supported on incrementally maintainable materialized view")));
+ if (qry->groupingSets != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUPING SETS, ROLLUP, or CUBE clauses is not supported on incrementally maintainable materialized view")));
+ if (qry->setOperations != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("UNION/INTERSECT/EXCEPT statements are not supported on incrementally maintainable materialized view")));
+ if (list_length(qry->targetList) == 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("empty target list is not supported on incrementally maintainable materialized view")));
+ if (qry->rowMarks != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view")));
+
+ /* system column restrictions */
+ vars = pull_vars_of_level((Node *) qry, 0);
+ foreach(lc, vars)
+ {
+ if (IsA(lfirst(lc), Var))
+ {
+ Var *var = (Var *) lfirst(lc);
+ /* if system column, return error */
+ if (var->varattno < 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("system column is not supported on incrementally maintainable materialized view")));
+ }
+ }
+
+ /* restrictions for rtable */
+ foreach(lc, qry->rtable)
+ {
+ RangeTblEntry *rte = (RangeTblEntry *) lfirst(lc);
+
+ if (rte->subquery)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("subquery is not supported on incrementally maintainable materialized view")));
+
+ if (rte->tablesample != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("TABLESAMPLE clause is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitioned table is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_RELATION && has_superclass(rte->relid))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_RELATION && find_inheritance_children(rte->relid, NoLock) != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("inheritance parent is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_FOREIGN_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("foreign table is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_VIEW ||
+ rte->relkind == RELKIND_MATVIEW)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view")));
+
+ if (rte->rtekind == RTE_VALUES)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("VALUES is not supported on incrementally maintainable materialized view")));
+
+ }
+
+ query_tree_walker(qry, check_ivm_restriction_walker, NULL, QTW_IGNORE_RANGE_TABLE);
+
+ break;
+ }
+ case T_TargetEntry:
+ {
+ TargetEntry *tle = (TargetEntry *)node;
+ if (isIvmName(tle->resname))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("column name %s is not supported on incrementally maintainable materialized view", tle->resname)));
+
+ expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ break;
+ }
+ case T_JoinExpr:
+ {
+ JoinExpr *joinexpr = (JoinExpr *)node;
+
+ if (joinexpr->jointype > JOIN_INNER)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("OUTER JOIN is not supported on incrementally maintainable materialized view")));
+
+ expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ }
+ break;
+ case T_Aggref:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function is not supported on incrementally maintainable materialized view")));
+ break;
+ default:
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
+ break;
+ }
+ return false;
+}
+
+/*
+ * CreateIndexOnIMMV
+ *
+ * Create a unique index on incremental maintainable materialized view.
+ * If the view definition query has a GROUP BY clause, the index is created
+ * on the columns of GROUP BY expressions. Otherwise, if the view contains
+ * all primary key attritubes of its base tables in the target list, the index
+ * is created on these attritubes. In other cases, no index is created.
+ */
+void
+CreateIndexOnIMMV(Query *query, Relation matviewRel)
+{
+ ListCell *lc;
+ IndexStmt *index;
+ ObjectAddress address;
+ List *constraintList = NIL;
+ char idxname[NAMEDATALEN];
+ List *indexoidlist = RelationGetIndexList(matviewRel);
+ ListCell *indexoidscan;
+ Bitmapset *key_attnos;
+
+ snprintf(idxname, sizeof(idxname), "%s_index", RelationGetRelationName(matviewRel));
+
+ index = makeNode(IndexStmt);
+
+ index->unique = true;
+ index->primary = false;
+ index->isconstraint = false;
+ index->deferrable = false;
+ index->initdeferred = false;
+ index->idxname = idxname;
+ index->relation =
+ makeRangeVar(get_namespace_name(RelationGetNamespace(matviewRel)),
+ pstrdup(RelationGetRelationName(matviewRel)),
+ -1);
+ index->accessMethod = DEFAULT_INDEX_TYPE;
+ index->options = NIL;
+ index->tableSpace = get_tablespace_name(matviewRel->rd_rel->reltablespace);
+ index->whereClause = NULL;
+ index->indexParams = NIL;
+ index->indexIncludingParams = NIL;
+ index->excludeOpNames = NIL;
+ index->idxcomment = NULL;
+ index->indexOid = InvalidOid;
+ index->oldNumber = InvalidRelFileNumber;
+ index->oldCreateSubid = InvalidSubTransactionId;
+ index->oldFirstRelfilelocatorSubid = InvalidSubTransactionId;
+ index->transformed = true;
+ index->concurrent = false;
+ index->if_not_exists = false;
+
+ /* create index on the base tables' primary key columns */
+ key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
+ if (key_attnos)
+ {
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ }
+ else
+ {
+ /* create no index, just notice that an appropriate index is necessary for efficient IVM */
+ ereport(NOTICE,
+ (errmsg("could not create an index on materialized view \"%s\" automatically",
+ RelationGetRelationName(matviewRel)),
+ errdetail("This target list does not have all the primary key columns. "),
+ errhint("Create an index on the materialized view for efficient incremental maintenance.")));
+ return;
+ }
+
+ /* If we have a compatible index, we don't need to create another. */
+ foreach(indexoidscan, indexoidlist)
+ {
+ Oid indexoid = lfirst_oid(indexoidscan);
+ Relation indexRel;
+ bool hasCompatibleIndex = false;
+
+ indexRel = index_open(indexoid, AccessShareLock);
+
+ if (CheckIndexCompatible(indexRel->rd_id,
+ index->accessMethod,
+ index->indexParams,
+ index->excludeOpNames,
+ false))
+ hasCompatibleIndex = true;
+
+ index_close(indexRel, AccessShareLock);
+
+ if (hasCompatibleIndex)
+ return;
+ }
+
+ address = DefineIndex(RelationGetRelid(matviewRel),
+ index,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ -1,
+ false, true, false, false, true);
+
+ ereport(NOTICE,
+ (errmsg("created index \"%s\" on materialized view \"%s\"",
+ idxname, RelationGetRelationName(matviewRel))));
+
+ /*
+ * Make dependencies so that the index is dropped if any base tables's
+ * primary key is dropped.
+ */
+ foreach(lc, constraintList)
+ {
+ Oid constraintOid = lfirst_oid(lc);
+ ObjectAddress refaddr;
+
+ refaddr.classId = ConstraintRelationId;
+ refaddr.objectId = constraintOid;
+ refaddr.objectSubId = 0;
+
+ recordDependencyOn(&address, &refaddr, DEPENDENCY_NORMAL);
+ }
+}
+
+
+/*
+ * get_primary_key_attnos_from_query
+ *
+ * Identify the columns in base tables' primary keys in the target list.
+ *
+ * Returns a Bitmapset of the column attnos of the primary key's columns of
+ * tables that used in the query. The attnos are offset by
+ * FirstLowInvalidHeapAttributeNumber as same as get_primary_key_attnos.
+ *
+ * If any table has no primary key or any primary key's columns is not in
+ * the target list, return NULL. We also return NULL if any pkey constraint
+ * is deferrable.
+ *
+ * constraintList is set to a list of the OIDs of the pkey constraints.
+ */
+static Bitmapset *
+get_primary_key_attnos_from_query(Query *query, List **constraintList)
+{
+ List *key_attnos_list = NIL;
+ ListCell *lc;
+ int i;
+ Bitmapset *keys = NULL;
+ Relids rels_in_from;
+
+ /*
+ * Collect primary key attributes from all tables used in query. The key attributes
+ * sets for each table are stored in key_attnos_list in order by RTE index.
+ */
+ foreach(lc, query->rtable)
+ {
+ RangeTblEntry *r = (RangeTblEntry*) lfirst(lc);
+ Bitmapset *key_attnos;
+ bool has_pkey = true;
+
+ /* for tables, call get_primary_key_attnos */
+ if (r->rtekind == RTE_RELATION)
+ {
+ Oid constraintOid;
+ key_attnos = get_primary_key_attnos(r->relid, false, &constraintOid);
+ *constraintList = lappend_oid(*constraintList, constraintOid);
+ has_pkey = (key_attnos != NULL);
+ }
+ /* for other RTEs, store NULL into key_attnos_list */
+ else
+ key_attnos = NULL;
+
+ /*
+ * If any table or subquery has no primary key or its pkey constraint is deferrable,
+ * we cannot get key attributes for this query, so return NULL.
+ */
+ if (!has_pkey)
+ return NULL;
+
+ key_attnos_list = lappend(key_attnos_list, key_attnos);
+ }
+
+ /* Collect key attributes appearing in the target list */
+ i = 1;
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) flatten_join_alias_vars(NULL, query, lfirst(lc));
+
+ if (IsA(tle->expr, Var))
+ {
+ Var *var = (Var*) tle->expr;
+ Bitmapset *key_attnos = list_nth(key_attnos_list, var->varno - 1);
+
+ /* check if this attribute is from a base table's primary key */
+ if (bms_is_member(var->varattno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ /*
+ * Remove found key attributes from key_attnos_list, and add this
+ * to the result list.
+ */
+ key_attnos = bms_del_member(key_attnos, var->varattno - FirstLowInvalidHeapAttributeNumber);
+ if (bms_is_empty(key_attnos))
+ {
+ key_attnos_list = list_delete_nth_cell(key_attnos_list, var->varno - 1);
+ key_attnos_list = list_insert_nth(key_attnos_list, var->varno - 1, NULL);
+ }
+ keys = bms_add_member(keys, i - FirstLowInvalidHeapAttributeNumber);
+ }
+ }
+ i++;
+ }
+
+ /* Collect RTE indexes of relations appearing in the FROM clause */
+ rels_in_from = get_relids_in_jointree((Node *) query->jointree, false, false);
+
+ /*
+ * Check if all key attributes of relations in FROM are appearing in the target
+ * list. If an attribute remains in key_attnos_list in spite of the table is used
+ * in FROM clause, the target is missing this key attribute, so we return NULL.
+ */
+ i = 1;
+ foreach(lc, key_attnos_list)
+ {
+ Bitmapset *bms = (Bitmapset *)lfirst(lc);
+ if (!bms_is_empty(bms) && bms_is_member(i, rels_in_from))
+ return NULL;
+ i++;
+ }
+
+ return keys;
+}
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index 6d09b75556..1061c37b2c 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -23,23 +23,35 @@
#include "catalog/indexing.h"
#include "catalog/namespace.h"
#include "catalog/pg_am.h"
+#include "catalog/pg_depend.h"
+#include "catalog/pg_trigger.h"
#include "catalog/pg_opclass.h"
#include "commands/cluster.h"
#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
+#include "commands/createas.h"
#include "executor/executor.h"
#include "executor/spi.h"
+#include "executor/tstoreReceiver.h"
#include "miscadmin.h"
+#include "nodes/makefuncs.h"
+#include "parser/analyze.h"
+#include "parser/parse_clause.h"
+#include "parser/parse_func.h"
+#include "parser/parse_relation.h"
#include "pgstat.h"
#include "rewrite/rewriteHandler.h"
+#include "rewrite/rowsecurity.h"
#include "storage/lmgr.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
+#include "utils/fmgroids.h"
#include "utils/lsyscache.h"
#include "utils/rel.h"
#include "utils/snapmgr.h"
#include "utils/syscache.h"
+#include "utils/typcache.h"
typedef struct
@@ -53,6 +65,52 @@ typedef struct
BulkInsertState bistate; /* bulk insert state */
} DR_transientrel;
+#define MV_INIT_QUERYHASHSIZE 16
+
+/*
+ * MV_TriggerHashEntry
+ *
+ * Hash entry for base tables on which IVM trigger is invoked
+ */
+typedef struct MV_TriggerHashEntry
+{
+ Oid matview_id; /* OID of the materialized view */
+ int before_trig_count; /* count of before triggers invoked */
+ int after_trig_count; /* count of after triggers invoked */
+
+ Snapshot snapshot; /* Snapshot just before table change */
+
+ List *tables; /* List of MV_TriggerTable */
+ bool has_old; /* tuples are deleted from any table? */
+ bool has_new; /* tuples are inserted into any table? */
+} MV_TriggerHashEntry;
+
+/*
+ * MV_TriggerTable
+ *
+ * IVM related data for tables on which the trigger is invoked.
+ */
+typedef struct MV_TriggerTable
+{
+ Oid table_id; /* OID of the modified table */
+ List *old_tuplestores; /* tuplestores for deleted tuples */
+ List *new_tuplestores; /* tuplestores for inserted tuples */
+
+ List *rte_indexes; /* List of RTE index of the modified table */
+ RangeTblEntry *original_rte; /* the original RTE saved before rewriting query */
+
+ Relation rel; /* relation of the modified table */
+ TupleTableSlot *slot; /* for checking visibility in the pre-state table */
+} MV_TriggerTable;
+
+static HTAB *mv_trigger_info = NULL;
+
+static bool in_delta_calculation = false;
+
+/* ENR name for materialized view delta */
+#define NEW_DELTA_ENRNAME "new_delta"
+#define OLD_DELTA_ENRNAME "old_delta"
+
static int matview_maintenance_depth = 0;
static void transientrel_startup(DestReceiver *self, int operation, TupleDesc typeinfo);
@@ -60,7 +118,9 @@ static bool transientrel_receive(TupleTableSlot *slot, DestReceiver *self);
static void transientrel_shutdown(DestReceiver *self);
static void transientrel_destroy(DestReceiver *self);
static uint64 refresh_matview_datafill(DestReceiver *dest, Query *query,
- const char *queryString);
+ QueryEnvironment *queryEnv,
+ TupleDesc *resultTupleDesc,
+ const char *queryString);
static char *make_temptable_name_n(char *tempname, int n);
static void refresh_by_match_merge(Oid matviewOid, Oid tempOid, Oid relowner,
int save_sec_context);
@@ -68,6 +128,37 @@ static void refresh_by_heap_swap(Oid matviewOid, Oid OIDNewHeap, char relpersist
static bool is_usable_unique_index(Relation indexRel);
static void OpenMatViewIncrementalMaintenance(void);
static void CloseMatViewIncrementalMaintenance(void);
+static Query *get_matview_query(Relation matviewRel);
+
+static Query *rewrite_query_for_preupdate_state(Query *query, List *tables,
+ ParseState *pstate, Oid matviewid);
+static void register_delta_ENRs(ParseState *pstate, Query *query, List *tables);
+static char *make_delta_enr_name(const char *prefix, Oid relid, int count);
+static RangeTblEntry *get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *table,
+ QueryEnvironment *queryEnv, Oid matviewid);
+static RangeTblEntry *replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
+ QueryEnvironment *queryEnv);
+static Query *rewrite_query_for_counting(Query *query, ParseState *pstate);
+
+static void calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
+ DestReceiver *dest_old, DestReceiver *dest_new,
+ TupleDesc *tupdesc_old, TupleDesc *tupdesc_new,
+ QueryEnvironment *queryEnv);
+static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte_index);
+
+static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
+ TupleDesc tupdesc_old, TupleDesc tupdesc_new,
+ Query *query);
+static void apply_old_delta(const char *matviewname, const char *deltaname_old,
+ List *keys);
+static void apply_new_delta(const char *matviewname, const char *deltaname_new,
+ StringInfo target_list);
+static char *get_matching_condition_string(List *keys);
+static void generate_equal(StringInfo querybuf, Oid opttype,
+ const char *leftop, const char *rightop);
+
+static void mv_InitHashTables(void);
+static void clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort);
/*
* SetMatViewPopulatedState
@@ -109,6 +200,46 @@ SetMatViewPopulatedState(Relation relation, bool newstate)
CommandCounterIncrement();
}
+/*
+ * SetMatViewIVMState
+ * Mark a materialized view as IVM, or not.
+ *
+ * NOTE: caller must be holding an appropriate lock on the relation.
+ */
+void
+SetMatViewIVMState(Relation relation, bool newstate)
+{
+ Relation pgrel;
+ HeapTuple tuple;
+
+ Assert(relation->rd_rel->relkind == RELKIND_MATVIEW);
+
+ /*
+ * Update relation's pg_class entry. Crucial side-effect: other backends
+ * (and this one too!) are sent SI message to make them rebuild relcache
+ * entries.
+ */
+ pgrel = table_open(RelationRelationId, RowExclusiveLock);
+ tuple = SearchSysCacheCopy1(RELOID,
+ ObjectIdGetDatum(RelationGetRelid(relation)));
+ if (!HeapTupleIsValid(tuple))
+ elog(ERROR, "cache lookup failed for relation %u",
+ RelationGetRelid(relation));
+
+ ((Form_pg_class) GETSTRUCT(tuple))->relisivm = newstate;
+
+ CatalogTupleUpdate(pgrel, &tuple->t_self, tuple);
+
+ heap_freetuple(tuple);
+ table_close(pgrel, RowExclusiveLock);
+
+ /*
+ * Advance command counter to make the updated pg_class row locally
+ * visible.
+ */
+ CommandCounterIncrement();
+}
+
/*
* ExecRefreshMatView -- execute a REFRESH MATERIALIZED VIEW command
*
@@ -135,8 +266,6 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
{
Oid matviewOid;
Relation matviewRel;
- RewriteRule *rule;
- List *actions;
Query *dataQuery;
Oid tableSpace;
Oid relowner;
@@ -150,6 +279,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
int save_sec_context;
int save_nestlevel;
ObjectAddress address;
+ bool oldPopulated;
/* Determine strength of lock needed. */
concurrent = stmt->concurrent;
@@ -176,6 +306,8 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
save_nestlevel = NewGUCNestLevel();
RestrictSearchPath();
+ oldPopulated = RelationIsPopulated(matviewRel);
+
/* Make sure it is a materialized view. */
if (matviewRel->rd_rel->relkind != RELKIND_MATVIEW)
ereport(ERROR,
@@ -196,32 +328,9 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
errmsg("%s and %s options cannot be used together",
"CONCURRENTLY", "WITH NO DATA")));
- /*
- * Check that everything is correct for a refresh. Problems at this point
- * are internal errors, so elog is sufficient.
- */
- if (matviewRel->rd_rel->relhasrules == false ||
- matviewRel->rd_rules->numLocks < 1)
- elog(ERROR,
- "materialized view \"%s\" is missing rewrite information",
- RelationGetRelationName(matviewRel));
-
- if (matviewRel->rd_rules->numLocks > 1)
- elog(ERROR,
- "materialized view \"%s\" has too many rules",
- RelationGetRelationName(matviewRel));
- rule = matviewRel->rd_rules->rules[0];
- if (rule->event != CMD_SELECT || !(rule->isInstead))
- elog(ERROR,
- "the rule for materialized view \"%s\" is not a SELECT INSTEAD OF rule",
- RelationGetRelationName(matviewRel));
+ dataQuery = get_matview_query(matviewRel);
- actions = rule->actions;
- if (list_length(actions) != 1)
- elog(ERROR,
- "the rule for materialized view \"%s\" is not a single action",
- RelationGetRelationName(matviewRel));
/*
* Check that there is a unique index with no WHERE clause on one or more
@@ -256,12 +365,6 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
errhint("Create a unique index with no WHERE clause on one or more columns of the materialized view.")));
}
- /*
- * The stored query was rewritten at the time of the MV definition, but
- * has not been scribbled on by the planner.
- */
- dataQuery = linitial_node(Query, actions);
-
/*
* Check for active uses of the relation in the current transaction, such
* as open scans.
@@ -289,6 +392,74 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
relpersistence = matviewRel->rd_rel->relpersistence;
}
+ /* delete IMMV triggers. */
+ if (RelationIsIVM(matviewRel) && stmt->skipData )
+ {
+ Relation tgRel;
+ Relation depRel;
+ ScanKeyData key;
+ SysScanDesc scan;
+ HeapTuple tup;
+ ObjectAddresses *immv_triggers;
+
+ immv_triggers = new_object_addresses();
+
+ tgRel = table_open(TriggerRelationId, RowExclusiveLock);
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ /* search triggers that depends on IMMV. */
+ ScanKeyInit(&key,
+ Anum_pg_depend_refobjid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(matviewOid));
+ scan = systable_beginscan(depRel, DependReferenceIndexId, true,
+ NULL, 1, &key);
+ while ((tup = systable_getnext(scan)) != NULL)
+ {
+ ObjectAddress obj;
+ Form_pg_depend foundDep = (Form_pg_depend) GETSTRUCT(tup);
+
+ if (foundDep->classid == TriggerRelationId)
+ {
+ HeapTuple tgtup;
+ ScanKeyData tgkey[1];
+ SysScanDesc tgscan;
+ Form_pg_trigger tgform;
+
+ /* Find the trigger name. */
+ ScanKeyInit(&tgkey[0],
+ Anum_pg_trigger_oid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(foundDep->objid));
+
+ tgscan = systable_beginscan(tgRel, TriggerOidIndexId, true,
+ NULL, 1, tgkey);
+ tgtup = systable_getnext(tgscan);
+ if (!HeapTupleIsValid(tgtup))
+ elog(ERROR, "could not find tuple for immv trigger %u", foundDep->objid);
+
+ tgform = (Form_pg_trigger) GETSTRUCT(tgtup);
+
+ /* If trigger is created by IMMV, delete it. */
+ if (strncmp(NameStr(tgform->tgname), "IVM_trigger_", 12) == 0)
+ {
+ obj.classId = foundDep->classid;
+ obj.objectId = foundDep->objid;
+ obj.objectSubId = foundDep->refobjsubid;
+ add_exact_object_address(&obj, immv_triggers);
+ }
+ systable_endscan(tgscan);
+ }
+ }
+ systable_endscan(scan);
+
+ performMultipleDeletions(immv_triggers, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ table_close(depRel, RowExclusiveLock);
+ table_close(tgRel, RowExclusiveLock);
+ free_object_addresses(immv_triggers);
+ }
+
/*
* Create the transient table that will receive the regenerated data. Lock
* it against access by any other process until commit (by which time it
@@ -302,7 +473,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
/* Generate the data, if wanted. */
if (!stmt->skipData)
- processed = refresh_matview_datafill(dest, dataQuery, queryString);
+ processed = refresh_matview_datafill(dest, dataQuery, NULL, NULL, queryString);
/* Make the matview match the newly generated data. */
if (concurrent)
@@ -337,6 +508,12 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
pgstat_count_heap_insert(matviewRel, processed);
}
+ if (!stmt->skipData && RelationIsIVM(matviewRel) && !oldPopulated)
+ {
+ CreateIndexOnIMMV(dataQuery, matviewRel);
+ CreateIvmTriggersOnBaseTables(dataQuery, matviewOid);
+ }
+
table_close(matviewRel, NoLock);
/* Roll back any GUC changes */
@@ -371,6 +548,8 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
*/
static uint64
refresh_matview_datafill(DestReceiver *dest, Query *query,
+ QueryEnvironment *queryEnv,
+ TupleDesc *resultTupleDesc,
const char *queryString)
{
List *rewritten;
@@ -407,7 +586,7 @@ refresh_matview_datafill(DestReceiver *dest, Query *query,
/* Create a QueryDesc, redirecting output to our tuple receiver */
queryDesc = CreateQueryDesc(plan, queryString,
GetActiveSnapshot(), InvalidSnapshot,
- dest, NULL, NULL, 0);
+ dest, NULL, queryEnv ? queryEnv: NULL, 0);
/* call ExecutorStart to prepare the plan for execution */
ExecutorStart(queryDesc, 0);
@@ -417,6 +596,9 @@ refresh_matview_datafill(DestReceiver *dest, Query *query,
processed = queryDesc->estate->es_processed;
+ if (resultTupleDesc)
+ *resultTupleDesc = CreateTupleDescCopy(queryDesc->tupDesc);
+
/* and clean up */
ExecutorFinish(queryDesc);
ExecutorEnd(queryDesc);
@@ -950,3 +1132,1219 @@ CloseMatViewIncrementalMaintenance(void)
matview_maintenance_depth--;
Assert(matview_maintenance_depth >= 0);
}
+
+/*
+ * get_matview_query - get the Query from a matview's _RETURN rule.
+ */
+static Query *
+get_matview_query(Relation matviewRel)
+{
+ RewriteRule *rule;
+ List * actions;
+
+ /*
+ * Check that everything is correct for a refresh. Problems at this point
+ * are internal errors, so elog is sufficient.
+ */
+ if (matviewRel->rd_rel->relhasrules == false ||
+ matviewRel->rd_rules->numLocks < 1)
+ elog(ERROR,
+ "materialized view \"%s\" is missing rewrite information",
+ RelationGetRelationName(matviewRel));
+
+ if (matviewRel->rd_rules->numLocks > 1)
+ elog(ERROR,
+ "materialized view \"%s\" has too many rules",
+ RelationGetRelationName(matviewRel));
+
+ rule = matviewRel->rd_rules->rules[0];
+ if (rule->event != CMD_SELECT || !(rule->isInstead))
+ elog(ERROR,
+ "the rule for materialized view \"%s\" is not a SELECT INSTEAD OF rule",
+ RelationGetRelationName(matviewRel));
+
+ actions = rule->actions;
+ if (list_length(actions) != 1)
+ elog(ERROR,
+ "the rule for materialized view \"%s\" is not a single action",
+ RelationGetRelationName(matviewRel));
+
+ /*
+ * The stored query was rewritten at the time of the MV definition, but
+ * has not been scribbled on by the planner.
+ */
+ return linitial_node(Query, actions);
+}
+
+
+/* ----------------------------------------------------
+ * Incremental View Maintenance routines
+ * ---------------------------------------------------
+ */
+
+/*
+ * IVM_immediate_before
+ *
+ * IVM trigger function invoked before base table is modified. If this is
+ * invoked firstly in the same statement, we save the transaction id and the
+ * command id at that time.
+ */
+Datum
+IVM_immediate_before(PG_FUNCTION_ARGS)
+{
+ TriggerData *trigdata = (TriggerData *) fcinfo->context;
+ char *matviewOid_text = trigdata->tg_trigger->tgargs[0];
+ char *ex_lock_text = trigdata->tg_trigger->tgargs[1];
+ Oid matviewOid;
+ MV_TriggerHashEntry *entry;
+ bool found;
+ bool ex_lock;
+
+ matviewOid = DatumGetObjectId(DirectFunctionCall1(oidin, CStringGetDatum(matviewOid_text)));
+ ex_lock = DatumGetBool(DirectFunctionCall1(boolin, CStringGetDatum(ex_lock_text)));
+
+ /* If the view has more than one tables, we have to use an exclusive lock. */
+ if (ex_lock)
+ {
+ /*
+ * Wait for concurrent transactions which update this materialized view at
+ * READ COMMITED. This is needed to see changes committed in other
+ * transactions. No wait and raise an error at REPEATABLE READ or
+ * SERIALIZABLE to prevent update anomalies of matviews.
+ * XXX: dead-lock is possible here.
+ */
+ if (!IsolationUsesXactSnapshot())
+ LockRelationOid(matviewOid, ExclusiveLock);
+ else if (!ConditionalLockRelationOid(matviewOid, ExclusiveLock))
+ {
+ /* try to throw error by name; relation could be deleted... */
+ char *relname = get_rel_name(matviewOid);
+
+ if (!relname)
+ ereport(ERROR,
+ (errcode(ERRCODE_LOCK_NOT_AVAILABLE),
+ errmsg("could not obtain lock on materialized view during incremental maintenance")));
+
+ ereport(ERROR,
+ (errcode(ERRCODE_LOCK_NOT_AVAILABLE),
+ errmsg("could not obtain lock on materialized view \"%s\" during incremental maintenance",
+ relname)));
+ }
+ }
+ else
+ LockRelationOid(matviewOid, RowExclusiveLock);
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_trigger_info)
+ mv_InitHashTables();
+
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_ENTER, &found);
+
+ /* On the first BEFORE to update the view, initialize trigger data */
+ if (!found)
+ {
+ /*
+ * Get a snapshot just before the table was modified for checking
+ * tuple visibility in the pre-update state of the table.
+ */
+ Snapshot snapshot = GetActiveSnapshot();
+
+ entry->matview_id = matviewOid;
+ entry->before_trig_count = 0;
+ entry->after_trig_count = 0;
+ entry->snapshot = RegisterSnapshot(snapshot);
+ entry->tables = NIL;
+ entry->has_old = false;
+ entry->has_new = false;
+ }
+
+ entry->before_trig_count++;
+
+ return PointerGetDatum(NULL);
+}
+
+/*
+ * IVM_immediate_maintenance
+ *
+ * IVM trigger function invoked after base table is modified.
+ * For each table, tuplestores of transition tables are collected.
+ * and after the last modification
+ */
+Datum
+IVM_immediate_maintenance(PG_FUNCTION_ARGS)
+{
+ TriggerData *trigdata = (TriggerData *) fcinfo->context;
+ Relation rel;
+ Oid relid;
+ Oid matviewOid;
+ Query *query;
+ Query *rewritten = NULL;
+ char *matviewOid_text = trigdata->tg_trigger->tgargs[0];
+ Relation matviewRel;
+ int old_depth = matview_maintenance_depth;
+
+ Oid relowner;
+ Tuplestorestate *old_tuplestore = NULL;
+ Tuplestorestate *new_tuplestore = NULL;
+ DestReceiver *dest_new = NULL, *dest_old = NULL;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ MV_TriggerHashEntry *entry;
+ MV_TriggerTable *table;
+ bool found;
+
+ ParseState *pstate;
+ QueryEnvironment *queryEnv = create_queryEnv();
+ MemoryContext oldcxt;
+ ListCell *lc;
+ int i;
+
+
+ /* Create a ParseState for rewriting the view definition query */
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ rel = trigdata->tg_relation;
+ relid = rel->rd_id;
+
+ matviewOid = DatumGetObjectId(DirectFunctionCall1(oidin, CStringGetDatum(matviewOid_text)));
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_trigger_info)
+ mv_InitHashTables();
+
+ /* get the entry for this materialized view */
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_FIND, &found);
+ Assert (found && entry != NULL);
+ entry->after_trig_count++;
+
+ /* search the entry for the modified table and create new entry if not found */
+ found = false;
+ foreach(lc, entry->tables)
+ {
+ table = (MV_TriggerTable *) lfirst(lc);
+ if (table->table_id == relid)
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ table = (MV_TriggerTable *) palloc0(sizeof(MV_TriggerTable));
+ table->table_id = relid;
+ table->old_tuplestores = NIL;
+ table->new_tuplestores = NIL;
+ table->rte_indexes = NIL;
+ table->slot = MakeSingleTupleTableSlot(RelationGetDescr(rel), table_slot_callbacks(rel));
+ table->rel = table_open(RelationGetRelid(rel), NoLock);
+ entry->tables = lappend(entry->tables, table);
+
+ MemoryContextSwitchTo(oldcxt);
+ }
+
+ /* Save the transition tables and make a request to not free immediately */
+ if (trigdata->tg_oldtable)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+ table->old_tuplestores = lappend(table->old_tuplestores, trigdata->tg_oldtable);
+ entry->has_old = true;
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (trigdata->tg_newtable)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+ table->new_tuplestores = lappend(table->new_tuplestores, trigdata->tg_newtable);
+ entry->has_new = true;
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (entry->has_new || entry->has_old)
+ {
+ CmdType cmd;
+
+ if (TRIGGER_FIRED_BY_INSERT(trigdata->tg_event))
+ cmd = CMD_INSERT;
+ else if (TRIGGER_FIRED_BY_DELETE(trigdata->tg_event))
+ cmd = CMD_DELETE;
+ else if (TRIGGER_FIRED_BY_UPDATE(trigdata->tg_event))
+ cmd = CMD_UPDATE;
+ else
+ elog(ERROR,"unsupported trigger type");
+
+ /* Prolong lifespan of transition tables to the end of the last AFTER trigger */
+ SetTransitionTablePreserved(relid, cmd);
+ }
+
+
+ /* If this is not the last AFTER trigger call, immediately exit. */
+ Assert (entry->before_trig_count >= entry->after_trig_count);
+ if (entry->before_trig_count != entry->after_trig_count)
+ return PointerGetDatum(NULL);
+
+ /*
+ * If this is the last AFTER trigger call, continue and update the view.
+ */
+
+ /*
+ * Advance command counter to make the updated base table row locally
+ * visible.
+ */
+ CommandCounterIncrement();
+
+ matviewRel = table_open(matviewOid, NoLock);
+
+ /* Make sure it is a materialized view. */
+ Assert(matviewRel->rd_rel->relkind == RELKIND_MATVIEW);
+
+ /*
+ * Get and push the latast snapshot to see any changes which is committed
+ * during waiting in other transactions at READ COMMITTED level.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /*
+ * Check for active uses of the relation in the current transaction, such
+ * as open scans.
+ *
+ * NB: We count on this to protect us against problems with refreshing the
+ * data using TABLE_INSERT_FROZEN.
+ */
+ CheckTableNotInUse(matviewRel, "refresh a materialized view incrementally");
+
+ /*
+ * Switch to the owner's userid, so that any functions are run as that
+ * user. Also arrange to make GUC variable changes local to this command.
+ * We will switch modes when we are about to execute user code.
+ */
+ relowner = matviewRel->rd_rel->relowner;
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+
+ /* get view query*/
+ query = get_matview_query(matviewRel);
+
+ /*
+ * When a base table is truncated, the view content will be empty if the
+ * view definition query does not contain an aggregate without a GROUP clause.
+ * Therefore, such views can be truncated.
+ */
+ if (TRIGGER_FIRED_BY_TRUNCATE(trigdata->tg_event))
+ {
+ ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
+ NIL, DROP_RESTRICT, false, false);
+
+ /* Clean up hash entry and delete tuplestores */
+ clean_up_IVM_hash_entry(entry, false);
+
+ /* Pop the original snapshot. */
+ PopActiveSnapshot();
+
+ table_close(matviewRel, NoLock);
+
+ /* Roll back any GUC changes */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ return PointerGetDatum(NULL);
+ }
+
+ /*
+ * rewrite query for calculating deltas
+ */
+
+ rewritten = copyObject(query);
+
+ /* Replace resnames in a target list with materialized view's attnames */
+ i = 0;
+ foreach (lc, rewritten->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
+
+ tle->resname = pstrdup(resname);
+ i++;
+ }
+
+ /* Set all tables in the query to pre-update state */
+ rewritten = rewrite_query_for_preupdate_state(rewritten, entry->tables,
+ pstate, matviewOid);
+ /* Rewrite for counting duplicated tuples */
+ rewritten = rewrite_query_for_counting(rewritten, pstate);
+
+ /* Create tuplestores to store view deltas */
+ if (entry->has_old)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ old_tuplestore = tuplestore_begin_heap(false, false, work_mem);
+ dest_old = CreateDestReceiver(DestTuplestore);
+ SetTuplestoreDestReceiverParams(dest_old,
+ old_tuplestore,
+ TopTransactionContext,
+ false,
+ NULL,
+ NULL);
+
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (entry->has_new)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ new_tuplestore = tuplestore_begin_heap(false, false, work_mem);
+ dest_new = CreateDestReceiver(DestTuplestore);
+ SetTuplestoreDestReceiverParams(dest_new,
+ new_tuplestore,
+ TopTransactionContext,
+ false,
+ NULL,
+ NULL);
+ MemoryContextSwitchTo(oldcxt);
+ }
+
+ /* for all modified tables */
+ foreach(lc, entry->tables)
+ {
+ ListCell *lc2;
+
+ table = (MV_TriggerTable *) lfirst(lc);
+
+ /* loop for self-join */
+ foreach(lc2, table->rte_indexes)
+ {
+ int rte_index = lfirst_int(lc2);
+ TupleDesc tupdesc_old;
+ TupleDesc tupdesc_new;
+
+ /* calculate delta tables */
+ calc_delta(table, rte_index, rewritten, dest_old, dest_new,
+ &tupdesc_old, &tupdesc_new, queryEnv);
+
+ /* Set the table in the query to post-update state */
+ rewritten = rewrite_query_for_postupdate_state(rewritten, table, rte_index);
+
+ PG_TRY();
+ {
+ /* apply the delta tables to the materialized view */
+ apply_delta(matviewOid, old_tuplestore, new_tuplestore,
+ tupdesc_old, tupdesc_new, query);
+ }
+ PG_CATCH();
+ {
+ matview_maintenance_depth = old_depth;
+ PG_RE_THROW();
+ }
+ PG_END_TRY();
+
+ /* clear view delta tuplestores */
+ if (old_tuplestore)
+ tuplestore_clear(old_tuplestore);
+ if (new_tuplestore)
+ tuplestore_clear(new_tuplestore);
+ }
+ }
+
+ /* Clean up hash entry and delete tuplestores */
+ clean_up_IVM_hash_entry(entry, false);
+ if (old_tuplestore)
+ {
+ dest_old->rDestroy(dest_old);
+ tuplestore_end(old_tuplestore);
+ }
+ if (new_tuplestore)
+ {
+ dest_new->rDestroy(dest_new);
+ tuplestore_end(new_tuplestore);
+ }
+
+ /* Pop the original snapshot. */
+ PopActiveSnapshot();
+
+ table_close(matviewRel, NoLock);
+
+ /* Roll back any GUC changes */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ return PointerGetDatum(NULL);
+}
+
+/*
+ * rewrite_query_for_preupdate_state
+ *
+ * Rewrite the query so that base tables' RTEs will represent "pre-update"
+ * state of tables. This is necessary to calculate view delta after multiple
+ * tables are modified.
+ */
+static Query*
+rewrite_query_for_preupdate_state(Query *query, List *tables,
+ ParseState *pstate, Oid matviewid)
+{
+ ListCell *lc;
+ int num_rte = list_length(query->rtable);
+ int i;
+
+
+ /* register delta ENRs */
+ register_delta_ENRs(pstate, query, tables);
+
+ /* XXX: Is necessary? Is this right timing? */
+ AcquireRewriteLocks(query, true, false);
+
+ i = 1;
+ foreach(lc, query->rtable)
+ {
+ RangeTblEntry *r = (RangeTblEntry*) lfirst(lc);
+
+ ListCell *lc2;
+ foreach(lc2, tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc2);
+ /*
+ * if the modified table is found then replace the original RTE with
+ * "pre-state" RTE and append its index to the list.
+ */
+ if (r->relid == table->table_id)
+ {
+ List *securityQuals;
+ List *withCheckOptions;
+ bool hasRowSecurity;
+ bool hasSubLinks;
+
+ RangeTblEntry *rte_pre = get_prestate_rte(r, table, pstate->p_queryEnv, matviewid);
+
+ /*
+ * Set a row security poslicies of the modified table to the subquery RTE which
+ * represents the pre-update state of the table.
+ */
+ get_row_security_policies(query, table->original_rte, i,
+ &securityQuals, &withCheckOptions,
+ &hasRowSecurity, &hasSubLinks);
+
+ if (hasRowSecurity)
+ {
+ query->hasRowSecurity = true;
+ rte_pre->security_barrier = true;
+ }
+ if (hasSubLinks)
+ query->hasSubLinks = true;
+
+ rte_pre->securityQuals = securityQuals;
+ lfirst(lc) = rte_pre;
+
+ table->rte_indexes = lappend_int(table->rte_indexes, i);
+ break;
+ }
+ }
+
+ /* finish the loop if we processed all RTE included in the original query */
+ if (i++ >= num_rte)
+ break;
+ }
+
+ return query;
+}
+
+/*
+ * register_delta_ENRs
+ *
+ * For all modified tables, make ENRs for their transition tables
+ * and register them to the queryEnv. ENR's RTEs are also appended
+ * into the list in query tree.
+ */
+static void
+register_delta_ENRs(ParseState *pstate, Query *query, List *tables)
+{
+ QueryEnvironment *queryEnv = pstate->p_queryEnv;
+ ListCell *lc;
+ RangeTblEntry *rte;
+
+ foreach(lc, tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc);
+ ListCell *lc2;
+ int count;
+
+ count = 0;
+ foreach(lc2, table->old_tuplestores)
+ {
+ Tuplestorestate *oldtable = (Tuplestorestate *) lfirst(lc2);
+ EphemeralNamedRelation enr =
+ palloc(sizeof(EphemeralNamedRelationData));
+ ParseNamespaceItem *nsitem;
+
+ enr->md.name = make_delta_enr_name("old", table->table_id, count);
+ enr->md.reliddesc = table->table_id;
+ enr->md.tupdesc = NULL;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(oldtable);
+ enr->reldata = oldtable;
+ register_ENR(queryEnv, enr);
+
+ nsitem = addRangeTableEntryForENR(pstate, makeRangeVar(NULL, enr->md.name, -1), true);
+ rte = nsitem->p_rte;
+
+ query->rtable = lappend(query->rtable, rte);
+
+ count++;
+ }
+
+ count = 0;
+ foreach(lc2, table->new_tuplestores)
+ {
+ Tuplestorestate *newtable = (Tuplestorestate *) lfirst(lc2);
+ EphemeralNamedRelation enr =
+ palloc(sizeof(EphemeralNamedRelationData));
+ ParseNamespaceItem *nsitem;
+
+ enr->md.name = make_delta_enr_name("new", table->table_id, count);
+ enr->md.reliddesc = table->table_id;
+ enr->md.tupdesc = NULL;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(newtable);
+ enr->reldata = newtable;
+ register_ENR(queryEnv, enr);
+
+ nsitem = addRangeTableEntryForENR(pstate, makeRangeVar(NULL, enr->md.name, -1), true);
+ rte = nsitem->p_rte;
+
+ query->rtable = lappend(query->rtable, rte);
+
+ count++;
+ }
+ }
+}
+
+#define DatumGetItemPointer(X) ((ItemPointer) DatumGetPointer(X))
+#define PG_GETARG_ITEMPOINTER(n) DatumGetItemPointer(PG_GETARG_DATUM(n))
+
+/*
+ * ivm_visible_in_prestate
+ *
+ * Check visibility of a tuple specified by the tableoid and item pointer
+ * using the snapshot taken just before the table was modified.
+ */
+Datum
+ivm_visible_in_prestate(PG_FUNCTION_ARGS)
+{
+ Oid tableoid = PG_GETARG_OID(0);
+ ItemPointer itemPtr = PG_GETARG_ITEMPOINTER(1);
+ Oid matviewOid = PG_GETARG_OID(2);
+ MV_TriggerHashEntry *entry;
+ MV_TriggerTable *table = NULL;
+ ListCell *lc;
+ bool found;
+ bool result;
+
+ if (!in_delta_calculation)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("ivm_visible_in_prestate can be called only in delta calculation")));
+
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_FIND, &found);
+ Assert (found && entry != NULL);
+
+ foreach(lc, entry->tables)
+ {
+ table = (MV_TriggerTable *) lfirst(lc);
+ if (table->table_id == tableoid)
+ break;
+ }
+
+ Assert (table != NULL);
+
+ result = table_tuple_fetch_row_version(table->rel, itemPtr, entry->snapshot, table->slot);
+
+ PG_RETURN_BOOL(result);
+}
+
+/*
+ * get_prestate_rte
+ *
+ * Rewrite RTE of the modified table to a subquery which represents
+ * "pre-state" table. The original RTE is saved in table->rte_original.
+ */
+static RangeTblEntry*
+get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *table,
+ QueryEnvironment *queryEnv, Oid matviewid)
+{
+ StringInfoData str;
+ RawStmt *raw;
+ Query *subquery;
+ Relation rel;
+ ParseState *pstate;
+ char *relname;
+ int i;
+
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ /*
+ * We can use NoLock here since AcquireRewriteLocks should
+ * have locked the relation already.
+ */
+ rel = table_open(table->table_id, NoLock);
+ relname = quote_qualified_identifier(
+ get_namespace_name(RelationGetNamespace(rel)),
+ RelationGetRelationName(rel));
+ table_close(rel, NoLock);
+
+ /*
+ * Filtering inserted row using the snapshot taken before the table
+ * is modified. ctid is required for maintaining outer join views.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str,
+ "SELECT t.* FROM %s t"
+ " WHERE pg_catalog.ivm_visible_in_prestate(t.tableoid, t.ctid ,%d::pg_catalog.oid)",
+ relname, matviewid);
+
+ /*
+ * Append deleted rows contained in old transition tables.
+ */
+ for (i = 0; i < list_length(table->old_tuplestores); i++)
+ {
+ appendStringInfo(&str, " UNION ALL ");
+ appendStringInfo(&str," SELECT * FROM %s",
+ make_delta_enr_name("old", table->table_id, i));
+ }
+
+ /* Get a subquery representing pre-state of the table */
+ raw = (RawStmt*)linitial(raw_parser(str.data, RAW_PARSE_DEFAULT));
+ subquery = transformStmt(pstate, raw->stmt);
+
+ /* save the original RTE */
+ table->original_rte = copyObject(rte);
+
+ rte->rtekind = RTE_SUBQUERY;
+ rte->subquery = subquery;
+ rte->security_barrier = false;
+
+ /* Clear fields that should not be set in a subquery RTE */
+ rte->relid = InvalidOid;
+ rte->relkind = 0;
+ rte->rellockmode = 0;
+ rte->tablesample = NULL;
+ rte->perminfoindex = 0; /* no permission checking for this RTE */
+ rte->inh = false; /* must not be set for a subquery */
+
+ return rte;
+}
+
+/*
+ * make_delta_enr_name
+ *
+ * Make a name for ENR of a transition table from the base table's oid.
+ * prefix will be "new" or "old" depending on its transition table kind..
+ */
+static char*
+make_delta_enr_name(const char *prefix, Oid relid, int count)
+{
+ char buf[NAMEDATALEN];
+ char *name;
+
+ snprintf(buf, NAMEDATALEN, "__ivm_%s_%u_%u", prefix, relid, count);
+ name = pstrdup(buf);
+
+ return name;
+}
+
+/*
+ * replace_rte_with_delta
+ *
+ * Replace RTE of the modified table with a single table delta that combine its
+ * all transition tables.
+ */
+static RangeTblEntry*
+replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
+ QueryEnvironment *queryEnv)
+{
+ Oid relid = table->table_id;
+ StringInfoData str;
+ ParseState *pstate;
+ RawStmt *raw;
+ Query *sub;
+ int num_tuplestores = list_length(is_new ? table->new_tuplestores : table->old_tuplestores);
+ int i;
+
+ /* the previous RTE must be a subquery which represents "pre-state" table */
+ Assert(rte->rtekind == RTE_SUBQUERY);
+
+ /* Create a ParseState for rewriting the view definition query */
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ initStringInfo(&str);
+
+ for (i = 0; i < num_tuplestores; i++)
+ {
+ if (i > 0)
+ appendStringInfo(&str, " UNION ALL ");
+
+ appendStringInfo(&str,
+ " SELECT * FROM %s",
+ make_delta_enr_name(is_new ? "new" : "old", relid, i));
+ }
+
+ raw = (RawStmt*)linitial(raw_parser(str.data, RAW_PARSE_DEFAULT));
+ sub = transformStmt(pstate, raw->stmt);
+
+ /*
+ * Update the subquery so that it represent the combined transition
+ * table. Note that we leave the security_barrier and securityQuals
+ * fields so that the subquery relation can be protected by the RLS
+ * policy as same as the modified table.
+ */
+ rte->rtekind = RTE_SUBQUERY;
+ rte->subquery = sub;
+
+ return rte;
+}
+
+/*
+ * rewrite_query_for_counting
+ *
+ * Rewrite query for counting duplicated tuples.
+ */
+static Query *
+rewrite_query_for_counting(Query *query, ParseState *pstate)
+{
+ TargetEntry *tle_count;
+ FuncCall *fn;
+ Node *node;
+
+ /* Add count(*) for counting distinct tuples in views */
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+ fn->agg_star = true;
+ if (!query->groupClause && !query->hasAggs)
+ query->groupClause = transformDistinctClause(NULL, &query->targetList, query->sortClause, false);
+
+ node = ParseFuncOrColumn(pstate, fn->funcname, NIL, NULL, fn, false, -1);
+
+ tle_count = makeTargetEntry((Expr *) node,
+ list_length(query->targetList) + 1,
+ pstrdup("__ivm_count__"),
+ false);
+ query->targetList = lappend(query->targetList, tle_count);
+ query->hasAggs = true;
+
+ return query;
+}
+
+/*
+ * calc_delta
+ *
+ * Calculate view deltas generated under the modification of a table specified
+ * by the RTE index.
+ */
+static void
+calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
+ DestReceiver *dest_old, DestReceiver *dest_new,
+ TupleDesc *tupdesc_old, TupleDesc *tupdesc_new,
+ QueryEnvironment *queryEnv)
+{
+ ListCell *lc = list_nth_cell(query->rtable, rte_index - 1);
+ RangeTblEntry *rte = (RangeTblEntry *) lfirst(lc);
+
+ in_delta_calculation = true;
+
+ /* Generate old delta */
+ if (list_length(table->old_tuplestores) > 0)
+ {
+ /* Replace the modified table with the old delta table and calculate the old view delta. */
+ replace_rte_with_delta(rte, table, false, queryEnv);
+ refresh_matview_datafill(dest_old, query, queryEnv, tupdesc_old, "");
+ }
+
+ /* Generate new delta */
+ if (list_length(table->new_tuplestores) > 0)
+ {
+ /* Replace the modified table with the new delta table and calculate the new view delta*/
+ replace_rte_with_delta(rte, table, true, queryEnv);
+ refresh_matview_datafill(dest_new, query, queryEnv, tupdesc_new, "");
+ }
+
+ in_delta_calculation = false;
+}
+
+/*
+ * rewrite_query_for_postupdate_state
+ *
+ * Rewrite the query so that the specified base table's RTEs will represent
+ * "post-update" state of tables. This is called after the view delta
+ * calculation due to changes on this table finishes.
+ */
+static Query*
+rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte_index)
+{
+ ListCell *lc = list_nth_cell(query->rtable, rte_index - 1);
+
+ /* Retore the original RTE */
+ lfirst(lc) = table->original_rte;
+
+ return query;
+}
+
+/*
+ * apply_delta
+ *
+ * Apply deltas to the materialized view. In outer join cases, this requires
+ * the view maintenance graph.
+ */
+static void
+apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
+ TupleDesc tupdesc_old, TupleDesc tupdesc_new,
+ Query *query)
+{
+ StringInfoData querybuf;
+ StringInfoData target_list_buf;
+ Relation matviewRel;
+ char *matviewname;
+ ListCell *lc;
+ int i;
+ List *keys = NIL;
+
+
+ /*
+ * get names of the materialized view and delta tables
+ */
+
+ matviewRel = table_open(matviewOid, NoLock);
+ matviewname = quote_qualified_identifier(get_namespace_name(RelationGetNamespace(matviewRel)),
+ RelationGetRelationName(matviewRel));
+
+ /*
+ * Build parts of the maintenance queries
+ */
+
+ initStringInfo(&querybuf);
+ initStringInfo(&target_list_buf);
+
+ /* build string of target list */
+ for (i = 0; i < matviewRel->rd_att->natts; i++)
+ {
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
+
+ if (i != 0)
+ appendStringInfo(&target_list_buf, ", ");
+ appendStringInfo(&target_list_buf, "%s", quote_qualified_identifier(NULL, resname));
+ }
+
+ i = 0;
+ foreach (lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+
+ i++;
+
+ if (tle->resjunk)
+ continue;
+
+ keys = lappend(keys, attr);
+ }
+
+ /* Start maintaining the materialized view. */
+ OpenMatViewIncrementalMaintenance();
+
+ /* Open SPI context. */
+ if (SPI_connect() != SPI_OK_CONNECT)
+ elog(ERROR, "SPI_connect failed");
+
+ /* For tuple deletion */
+ if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
+ {
+ EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ int rc;
+
+ /* convert tuplestores to ENR, and register for SPI */
+ enr->md.name = pstrdup(OLD_DELTA_ENRNAME);
+ enr->md.reliddesc = InvalidOid;
+ enr->md.tupdesc = tupdesc_old;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(old_tuplestores);
+ enr->reldata = old_tuplestores;
+
+ rc = SPI_register_relation(enr);
+ if (rc != SPI_OK_REL_REGISTER)
+ elog(ERROR, "SPI_register failed");
+
+ apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+
+ }
+ /* For tuple insertion */
+ if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
+ {
+ EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ int rc;
+
+ /* convert tuplestores to ENR, and register for SPI */
+ enr->md.name = pstrdup(NEW_DELTA_ENRNAME);
+ enr->md.reliddesc = InvalidOid;
+ enr->md.tupdesc = tupdesc_new;;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(new_tuplestores);
+ enr->reldata = new_tuplestores;
+
+ rc = SPI_register_relation(enr);
+ if (rc != SPI_OK_REL_REGISTER)
+ elog(ERROR, "SPI_register failed");
+
+ /* apply new delta */
+ apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
+ }
+
+ /* We're done maintaining the materialized view. */
+ CloseMatViewIncrementalMaintenance();
+
+ table_close(matviewRel, NoLock);
+
+ /* Close SPI context. */
+ if (SPI_finish() != SPI_OK_FINISH)
+ elog(ERROR, "SPI_finish failed");
+}
+
+/*
+ * apply_old_delta
+ *
+ * Execute a query for applying a delta table given by deltname_old
+ * which contains tuples to be deleted from to a materialized view given by
+ * matviewname. This is used when counting is not required.
+ */
+static void
+apply_old_delta(const char *matviewname, const char *deltaname_old,
+ List *keys)
+{
+ StringInfoData querybuf;
+ StringInfoData keysbuf;
+ char *match_cond;
+ ListCell *lc;
+
+ /* build WHERE condition for searching tuples to be deleted */
+ match_cond = get_matching_condition_string(keys);
+
+ /* build string of keys list */
+ initStringInfo(&keysbuf);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&keysbuf, "%s", quote_qualified_identifier("mv", resname));
+ if (lnext(keys, lc))
+ appendStringInfo(&keysbuf, ", ");
+ }
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "DELETE FROM %s WHERE ctid IN ("
+ "SELECT tid FROM (SELECT pg_catalog.row_number() over (partition by %s) AS \"__ivm_row_number__\","
+ "mv.ctid AS tid,"
+ "diff.\"__ivm_count__\""
+ "FROM %s AS mv, %s AS diff "
+ "WHERE %s) v "
+ "WHERE v.\"__ivm_row_number__\" OPERATOR(pg_catalog.<=) v.\"__ivm_count__\")",
+ matviewname,
+ keysbuf.data,
+ matviewname, deltaname_old,
+ match_cond);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
+/*
+ * apply_new_delta
+ *
+ * Execute a query for applying a delta table given by deltname_new
+ * which contains tuples to be inserted into a materialized view given by
+ * matviewname. This is used when counting is not required.
+ */
+static void
+apply_new_delta(const char *matviewname, const char *deltaname_new,
+ StringInfo target_list)
+{
+ StringInfoData querybuf;
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "INSERT INTO %s (%s) SELECT %s FROM ("
+ "SELECT diff.*, pg_catalog.generate_series(1, diff.\"__ivm_count__\")"
+ " AS __ivm_generate_series__ "
+ "FROM %s AS diff) AS v",
+ matviewname, target_list->data, target_list->data,
+ deltaname_new);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_INSERT)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
+/*
+ * get_matching_condition_string
+ *
+ * Build a predicate string for looking for a tuple with given keys.
+ */
+static char *
+get_matching_condition_string(List *keys)
+{
+ StringInfoData match_cond;
+ ListCell *lc;
+
+ /* If there is no key columns, the condition is always true. */
+ if (keys == NIL)
+ return "true";
+
+ initStringInfo(&match_cond);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ char *mv_resname = quote_qualified_identifier("mv", resname);
+ char *diff_resname = quote_qualified_identifier("diff", resname);
+ Oid typid = attr->atttypid;
+
+ /* Considering NULL values, we can not use simple = operator. */
+ appendStringInfo(&match_cond, "(");
+ generate_equal(&match_cond, typid, mv_resname, diff_resname);
+ appendStringInfo(&match_cond, " OR (%s IS NULL AND %s IS NULL))",
+ mv_resname, diff_resname);
+
+ if (lnext(keys, lc))
+ appendStringInfo(&match_cond, " AND ");
+ }
+
+ return match_cond.data;
+}
+
+/*
+ * generate_equals
+ *
+ * Generate an equality clause using given operands' default equality
+ * operator.
+ */
+static void
+generate_equal(StringInfo querybuf, Oid opttype,
+ const char *leftop, const char *rightop)
+{
+ TypeCacheEntry *typentry;
+
+ typentry = lookup_type_cache(opttype, TYPECACHE_EQ_OPR);
+ if (!OidIsValid(typentry->eq_opr))
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_FUNCTION),
+ errmsg("could not identify an equality operator for type %s",
+ format_type_be_qualified(opttype))));
+
+ generate_operator_clause(querybuf,
+ leftop, opttype,
+ typentry->eq_opr,
+ rightop, opttype);
+}
+
+/*
+ * mv_InitHashTables
+ */
+static void
+mv_InitHashTables(void)
+{
+ HASHCTL ctl;
+
+ memset(&ctl, 0, sizeof(ctl));
+ ctl.keysize = sizeof(Oid);
+ ctl.entrysize = sizeof(MV_TriggerHashEntry);
+ mv_trigger_info = hash_create("MV trigger info",
+ MV_INIT_QUERYHASHSIZE,
+ &ctl, HASH_ELEM | HASH_BLOBS);
+}
+
+/*
+ * AtAbort_IVM
+ *
+ * Clean up hash entries for all materialized views. This is called at
+ * transaction abort.
+ */
+void
+AtAbort_IVM()
+{
+ HASH_SEQ_STATUS seq;
+ MV_TriggerHashEntry *entry;
+
+ if (mv_trigger_info)
+ {
+ hash_seq_init(&seq, mv_trigger_info);
+ while ((entry = hash_seq_search(&seq)) != NULL)
+ clean_up_IVM_hash_entry(entry, true);
+ }
+ in_delta_calculation = false;
+}
+
+/*
+ * clean_up_IVM_hash_entry
+ *
+ * Clean up tuple stores and hash entries for a materialized view after its
+ * maintenance finished.
+ */
+static void
+clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort)
+{
+ bool found;
+ ListCell *lc;
+
+ foreach(lc, entry->tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc);
+
+ list_free(table->old_tuplestores);
+ list_free(table->new_tuplestores);
+ if (!is_abort)
+ {
+ ExecDropSingleTupleTableSlot(table->slot);
+ table_close(table->rel, NoLock);
+ }
+ }
+ list_free(entry->tables);
+
+ if (!is_abort)
+ UnregisterSnapshot(entry->snapshot);
+
+ hash_search(mv_trigger_info, (void *) &entry->matview_id, HASH_REMOVE, &found);
+}
+
+/*
+ * isIvmName
+ *
+ * Check if this is a IVM hidden column from the name.
+ */
+bool
+isIvmName(const char *s)
+{
+ if (s)
+ return (strncmp(s, "__ivm_", 6) == 0);
+ return false;
+}
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index 07023ee61d..cae088ede0 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -12192,4 +12192,14 @@
proargtypes => 'int2',
prosrc => 'gist_stratnum_identity' },
+# IVM
+{ oid => '786', descr => 'ivm trigger (before)',
+ proname => 'IVM_immediate_before', provolatile => 'v', prorettype => 'trigger',
+ proargtypes => '', prosrc => 'IVM_immediate_before' },
+{ oid => '787', descr => 'ivm trigger (after)',
+ proname => 'IVM_immediate_maintenance', provolatile => 'v', prorettype => 'trigger',
+ proargtypes => '', prosrc => 'IVM_immediate_maintenance' },
+{ oid => '788', descr => 'ivm filetring ',
+ proname => 'ivm_visible_in_prestate', provolatile => 's', prorettype => 'bool',
+ proargtypes => 'oid tid oid', prosrc => 'ivm_visible_in_prestate' },
]
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 94678e3834..396ad1bb4c 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -16,6 +16,7 @@
#include "catalog/objectaddress.h"
#include "nodes/params.h"
+#include "nodes/pathnodes.h"
#include "parser/parse_node.h"
#include "tcop/dest.h"
#include "utils/queryenvironment.h"
@@ -25,6 +26,9 @@ extern ObjectAddress ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *st
ParamListInfo params, QueryEnvironment *queryEnv,
QueryCompletion *qc);
+extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
+extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
+
extern int GetIntoRelEFlags(IntoClause *intoClause);
extern DestReceiver *CreateIntoRelDestReceiver(IntoClause *intoClause);
diff --git a/src/include/commands/matview.h b/src/include/commands/matview.h
index 817b2ba0b6..3257e1adff 100644
--- a/src/include/commands/matview.h
+++ b/src/include/commands/matview.h
@@ -15,6 +15,7 @@
#define MATVIEW_H
#include "catalog/objectaddress.h"
+#include "fmgr.h"
#include "nodes/params.h"
#include "nodes/parsenodes.h"
#include "tcop/dest.h"
@@ -23,6 +24,8 @@
extern void SetMatViewPopulatedState(Relation relation, bool newstate);
+extern void SetMatViewIVMState(Relation relation, bool newstate);
+
extern ObjectAddress ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
ParamListInfo params, QueryCompletion *qc);
@@ -30,4 +33,10 @@ extern DestReceiver *CreateTransientRelDestReceiver(Oid transientoid);
extern bool MatViewIncrementalMaintenanceIsEnabled(void);
+extern Datum IVM_immediate_before(PG_FUNCTION_ARGS);
+extern Datum IVM_immediate_maintenance(PG_FUNCTION_ARGS);
+extern Datum IVM_visible_in_prestate(PG_FUNCTION_ARGS);
+extern void AtAbort_IVM(void);
+extern bool isIvmName(const char *s);
+
#endif /* MATVIEW_H */
--
2.25.1
v31-0007-Add-DISTINCT-support-for-IVM.patchtext/x-diff; name=v31-0007-Add-DISTINCT-support-for-IVM.patchDownload
From c5ed89bc016b4534e8f3fddf7ccc41da8a38ebcc Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 19:08:51 +0900
Subject: [PATCH v31 07/11] Add DISTINCT support for IVM
When IMMV is created with DISTINCT, multiplicity of tuples is
counted and stored in "__ivm_count__" column, which is a hidden
column of IMMV. The value in __ivm_count__ is updated when IMMV
is maintained incrementally. A tuple in IMMV can be removed if
and only if the count becomes zero.
---
src/backend/commands/createas.c | 141 ++++++++++++++++++++------
src/backend/commands/indexcmds.c | 40 ++++++++
src/backend/commands/matview.c | 148 ++++++++++++++++++++++++++--
src/backend/commands/tablecmds.c | 9 ++
src/backend/nodes/outfuncs.c | 1 +
src/backend/nodes/readfuncs.c | 1 +
src/backend/parser/parse_relation.c | 18 +++-
src/backend/rewrite/rewriteDefine.c | 3 +-
src/include/commands/createas.h | 2 +
src/include/nodes/parsenodes.h | 2 +
10 files changed, 320 insertions(+), 45 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index 04a5ee9e37..8f2bd5203e 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -50,6 +50,7 @@
#include "parser/parser.h"
#include "parser/parsetree.h"
#include "parser/parse_clause.h"
+#include "parser/parse_func.h"
#include "rewrite/rewriteHandler.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
@@ -305,6 +306,9 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
errhint("functions must be marked IMMUTABLE")));
check_ivm_restriction((Node *) query);
+
+ /* For IMMV, we need to rewrite matview query */
+ query = rewriteQueryForIMMV(query, into->colNames);
}
if (into->skipData)
@@ -409,6 +413,49 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
return address;
}
+/*
+ * rewriteQueryForIMMV -- rewrite view definition query for IMMV
+ *
+ * count(*) is added for counting distinct tuples in views.
+ */
+Query *
+rewriteQueryForIMMV(Query *query, List *colNames)
+{
+ Query *rewritten;
+
+ Node *node;
+ ParseState *pstate = make_parsestate(NULL);
+ FuncCall *fn;
+
+ rewritten = copyObject(query);
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ /*
+ * Convert DISTINCT to GROUP BY and add count(*) for counting distinct
+ * tuples in views.
+ */
+ if (rewritten->distinctClause)
+ {
+ TargetEntry *tle;
+
+ rewritten->groupClause = transformDistinctClause(NULL, &rewritten->targetList, rewritten->sortClause, false);
+
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+ fn->agg_star = true;
+
+ node = ParseFuncOrColumn(pstate, fn->funcname, NIL, NULL, fn, false, -1);
+
+ tle = makeTargetEntry((Expr *) node,
+ list_length(rewritten->targetList) + 1,
+ pstrdup("__ivm_count__"),
+ false);
+ rewritten->targetList = lappend(rewritten->targetList, tle);
+ rewritten->hasAggs = true;
+ }
+
+ return rewritten;
+}
+
/*
* GetIntoRelEFlags --- compute executor flags needed for CREATE TABLE AS
*
@@ -532,7 +579,8 @@ intorel_startup(DestReceiver *self, int operation, TupleDesc typeinfo)
ColumnDef *col;
char *colname;
- if (lc)
+ /* Don't override hidden columns added for IVM */
+ if (lc && !isIvmName(NameStr(attribute->attname)))
{
colname = strVal(lfirst(lc));
lc = lnext(into->colNames, lc);
@@ -936,10 +984,6 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view")));
- if (qry->distinctClause)
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("DISTINCT is not supported on incrementally maintainable materialized view")));
if (qry->hasDistinctOn)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
@@ -1086,12 +1130,18 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
char idxname[NAMEDATALEN];
List *indexoidlist = RelationGetIndexList(matviewRel);
ListCell *indexoidscan;
- Bitmapset *key_attnos;
snprintf(idxname, sizeof(idxname), "%s_index", RelationGetRelationName(matviewRel));
index = makeNode(IndexStmt);
+ /*
+ * We consider null values not distinct to make sure that views with DISTINCT
+ * or GROUP BY don't contain multiple NULL rows when NULL is inserted to
+ * a base table concurrently.
+ */
+ index->nulls_not_distinct = true;
+
index->unique = true;
index->primary = false;
index->isconstraint = false;
@@ -1118,41 +1168,68 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
index->concurrent = false;
index->if_not_exists = false;
- /* create index on the base tables' primary key columns */
- key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
- if (key_attnos)
+ if (query->distinctClause)
{
+ /* create unique constraint on all columns */
foreach(lc, query->targetList)
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
-
- if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
- {
- IndexElem *iparam;
-
- iparam = makeNode(IndexElem);
- iparam->name = pstrdup(NameStr(attr->attname));
- iparam->expr = NULL;
- iparam->indexcolname = NULL;
- iparam->collation = NIL;
- iparam->opclass = NIL;
- iparam->opclassopts = NIL;
- iparam->ordering = SORTBY_DEFAULT;
- iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
- index->indexParams = lappend(index->indexParams, iparam);
- }
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
}
}
else
{
- /* create no index, just notice that an appropriate index is necessary for efficient IVM */
- ereport(NOTICE,
- (errmsg("could not create an index on materialized view \"%s\" automatically",
- RelationGetRelationName(matviewRel)),
- errdetail("This target list does not have all the primary key columns. "),
- errhint("Create an index on the materialized view for efficient incremental maintenance.")));
- return;
+ Bitmapset *key_attnos;
+
+ /* create index on the base tables' primary key columns */
+ key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
+ if (key_attnos)
+ {
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ }
+ else
+ {
+ /* create no index, just notice that an appropriate index is necessary for efficient IVM */
+ ereport(NOTICE,
+ (errmsg("could not create an index on materialized view \"%s\" automatically",
+ RelationGetRelationName(matviewRel)),
+ errdetail("This target list does not have all the primary key columns, "
+ "or this view does not contain DISTINCT clause."),
+ errhint("Create an index on the materialized view for efficient incremental maintenance.")));
+ return;
+ }
}
/* If we have a compatible index, we don't need to create another. */
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index d9016ef487..fb5265e6c3 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -41,6 +41,7 @@
#include "commands/dbcommands.h"
#include "commands/defrem.h"
#include "commands/event_trigger.h"
+#include "commands/matview.h"
#include "commands/progress.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
@@ -1132,6 +1133,45 @@ DefineIndex(Oid tableId,
safe_index = indexInfo->ii_Expressions == NIL &&
indexInfo->ii_Predicate == NIL;
+ /*
+ * We disallow unique indexes on IVM columns of IMMVs.
+ */
+ if (RelationIsIVM(rel) && stmt->unique)
+ {
+ for (int i = 0; i < indexInfo->ii_NumIndexKeyAttrs; i++)
+ {
+ AttrNumber attno = indexInfo->ii_IndexAttrNumbers[i];
+ if (attno > 0)
+ {
+ char *name = NameStr(TupleDescAttr(rel->rd_att, attno - 1)->attname);
+ if (name && isIvmName(name))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("unique index creation on IVM columns is not supported")));
+ }
+ }
+
+ if (indexInfo->ii_Expressions)
+ {
+ Bitmapset *indexattrs = NULL;
+ int varno = -1;
+
+ pull_varattnos((Node *) indexInfo->ii_Expressions, 1, &indexattrs);
+
+ while ((varno = bms_next_member(indexattrs, varno)) >= 0)
+ {
+ int attno = varno + FirstLowInvalidHeapAttributeNumber;
+ char *name = NameStr(TupleDescAttr(rel->rd_att, attno - 1)->attname);
+ if (name && isIvmName(name))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("unique index creation on IVM columns is not supported")));
+ }
+
+ }
+ }
+
+
/*
* Report index creation if appropriate (delay this till after most of the
* error checks)
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index 1061c37b2c..f2e8aa02a3 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -148,11 +148,15 @@ static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *
static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
- Query *query);
+ Query *query, bool use_count, char *count_colname);
static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
+static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
+ List *keys, const char *count_colname);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
+static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
+ List *keys, StringInfo target_list, const char* count_colname);
static char *get_matching_condition_string(List *keys);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
@@ -267,6 +271,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
Oid matviewOid;
Relation matviewRel;
Query *dataQuery;
+ Query *viewQuery;
Oid tableSpace;
Oid relowner;
Oid OIDNewHeap;
@@ -329,8 +334,13 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
"CONCURRENTLY", "WITH NO DATA")));
- dataQuery = get_matview_query(matviewRel);
+ viewQuery = get_matview_query(matviewRel);
+ /* For IMMV, we need to rewrite matview query */
+ if (!stmt->skipData && RelationIsIVM(matviewRel))
+ dataQuery = rewriteQueryForIMMV(viewQuery,NIL);
+ else
+ dataQuery = viewQuery;
/*
* Check that there is a unique index with no WHERE clause on one or more
@@ -510,8 +520,8 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
if (!stmt->skipData && RelationIsIVM(matviewRel) && !oldPopulated)
{
- CreateIndexOnIMMV(dataQuery, matviewRel);
- CreateIvmTriggersOnBaseTables(dataQuery, matviewOid);
+ CreateIndexOnIMMV(viewQuery, matviewRel);
+ CreateIvmTriggersOnBaseTables(viewQuery, matviewOid);
}
table_close(matviewRel, NoLock);
@@ -1533,6 +1543,13 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
int rte_index = lfirst_int(lc2);
TupleDesc tupdesc_old;
TupleDesc tupdesc_new;
+ bool use_count = false;
+ char *count_colname = NULL;
+
+ count_colname = pstrdup("__ivm_count__");
+
+ if (query->distinctClause)
+ use_count = true;
/* calculate delta tables */
calc_delta(table, rte_index, rewritten, dest_old, dest_new,
@@ -1545,7 +1562,8 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
{
/* apply the delta tables to the materialized view */
apply_delta(matviewOid, old_tuplestore, new_tuplestore,
- tupdesc_old, tupdesc_new, query);
+ tupdesc_old, tupdesc_new, query, use_count,
+ count_colname);
}
PG_CATCH();
{
@@ -2018,7 +2036,7 @@ rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte
static void
apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
- Query *query)
+ Query *query, bool use_count, char *count_colname)
{
StringInfoData querybuf;
StringInfoData target_list_buf;
@@ -2094,7 +2112,12 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (rc != SPI_OK_REL_REGISTER)
elog(ERROR, "SPI_register failed");
- apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+ if (use_count)
+ /* apply old delta and get rows to be recalculated */
+ apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
+ keys, count_colname);
+ else
+ apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
}
/* For tuple insertion */
@@ -2116,7 +2139,11 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_register failed");
/* apply new delta */
- apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
+ if (use_count)
+ apply_new_delta_with_count(matviewname, NEW_DELTA_ENRNAME,
+ keys, &target_list_buf, count_colname);
+ else
+ apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
}
/* We're done maintaining the materialized view. */
@@ -2129,6 +2156,51 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_finish failed");
}
+/*
+ * apply_old_delta_with_count
+ *
+ * Execute a query for applying a delta table given by deltname_old
+ * which contains tuples to be deleted from to a materialized view given by
+ * matviewname. This is used when counting is required, that is, the view
+ * has aggregate or distinct.
+ */
+static void
+apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
+ List *keys, const char *count_colname)
+{
+ StringInfoData querybuf;
+ char *match_cond;
+
+ /* build WHERE condition for searching tuples to be deleted */
+ match_cond = get_matching_condition_string(keys);
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "WITH t AS (" /* collecting tid of target tuples in the view */
+ "SELECT diff.%s, " /* count column */
+ "(diff.%s OPERATOR(pg_catalog.=) mv.%s) AS for_dlt, "
+ "mv.ctid "
+ "FROM %s AS mv, %s AS diff "
+ "WHERE %s" /* tuple matching condition */
+ "), updt AS (" /* update a tuple if this is not to be deleted */
+ "UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
+ "FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
+ ")"
+ /* delete a tuple if this is to be deleted */
+ "DELETE FROM %s AS mv USING t "
+ "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
+ count_colname,
+ count_colname, count_colname,
+ matviewname, deltaname_old,
+ match_cond,
+ matviewname, count_colname, count_colname, count_colname,
+ matviewname);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
/*
* apply_old_delta
*
@@ -2178,6 +2250,66 @@ apply_old_delta(const char *matviewname, const char *deltaname_old,
elog(ERROR, "SPI_exec failed: %s", querybuf.data);
}
+/*
+ * apply_new_delta_with_count
+ *
+ * Execute a query for applying a delta table given by deltname_new
+ * which contains tuples to be inserted into a materialized view given by
+ * matviewname. This is used when counting is required, that is, the view
+ * has aggregate or distinct. Also, when a table in EXISTS sub queries
+ * is modified.
+ */
+static void
+apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
+ List *keys, StringInfo target_list, const char* count_colname)
+{
+ StringInfoData querybuf;
+ StringInfoData returning_keys;
+ ListCell *lc;
+ char *match_cond = "";
+
+ /* build WHERE condition for searching tuples to be updated */
+ match_cond = get_matching_condition_string(keys);
+
+ /* build string of keys list */
+ initStringInfo(&returning_keys);
+ if (keys)
+ {
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&returning_keys, "%s", quote_qualified_identifier("mv", resname));
+ if (lnext(keys, lc))
+ appendStringInfo(&returning_keys, ", ");
+ }
+ }
+ else
+ appendStringInfo(&returning_keys, "NULL");
+
+ /* Search for matching tuples from the view and update if found or insert if not. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "WITH updt AS (" /* update a tuple if this exists in the view */
+ "UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.+) diff.%s "
+ "FROM %s AS diff "
+ "WHERE %s " /* tuple matching condition */
+ "RETURNING %s" /* returning keys of updated tuples */
+ ") INSERT INTO %s (%s) " /* insert a new tuple if this doesn't exist */
+ "SELECT %s FROM %s AS diff "
+ "WHERE NOT EXISTS (SELECT 1 FROM updt AS mv WHERE %s);",
+ matviewname, count_colname, count_colname, count_colname,
+ deltaname_new,
+ match_cond,
+ returning_keys.data,
+ matviewname, target_list->data,
+ target_list->data, deltaname_new,
+ match_cond);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_INSERT)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
/*
* apply_new_delta
*
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 6741e721ae..dad09b9b0b 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -56,6 +56,7 @@
#include "commands/cluster.h"
#include "commands/comment.h"
#include "commands/defrem.h"
+#include "commands/matview.h"
#include "commands/event_trigger.h"
#include "commands/sequence.h"
#include "commands/tablecmds.h"
@@ -3789,6 +3790,14 @@ renameatt_internal(Oid myrelid,
targetrelation = relation_open(myrelid, AccessExclusiveLock);
renameatt_check(myrelid, RelationGetForm(targetrelation), recursing);
+ /*
+ * Don't rename IVM columns.
+ */
+ if (RelationIsIVM(targetrelation) && isIvmName(oldattname))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("IVM column can not be renamed")));
+
/*
* if the 'recurse' flag is set then we are supposed to rename this
* attribute in all classes that inherit from 'relname' (as well as in
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 3337b77ae6..c191f70a6f 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -510,6 +510,7 @@ _outRangeTblEntry(StringInfo str, const RangeTblEntry *node)
WRITE_INT_FIELD(rellockmode);
WRITE_UINT_FIELD(perminfoindex);
WRITE_NODE_FIELD(tablesample);
+ WRITE_BOOL_FIELD(relisivm);
break;
case RTE_SUBQUERY:
WRITE_NODE_FIELD(subquery);
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index c4d01a441a..ffcab8cda2 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -361,6 +361,7 @@ _readRangeTblEntry(void)
READ_INT_FIELD(rellockmode);
READ_UINT_FIELD(perminfoindex);
READ_NODE_FIELD(tablesample);
+ READ_BOOL_FIELD(relisivm);
break;
case RTE_SUBQUERY:
READ_NODE_FIELD(subquery);
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index 427b7325db..65aecc96a7 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -36,6 +36,7 @@
#include "utils/rel.h"
#include "utils/syscache.h"
#include "utils/varlena.h"
+#include "commands/matview.h"
/*
@@ -97,7 +98,7 @@ static void expandTupleDesc(TupleDesc tupdesc, Alias *eref,
int count, int offset,
int rtindex, int sublevels_up,
int location, bool include_dropped,
- List **colnames, List **colvars);
+ List **colnames, List **colvars, bool is_ivm);
static int specialAttNum(const char *attname);
static bool rte_visible_if_lateral(ParseState *pstate, RangeTblEntry *rte);
static bool rte_visible_if_qualified(ParseState *pstate, RangeTblEntry *rte);
@@ -1503,6 +1504,7 @@ addRangeTableEntry(ParseState *pstate,
rte->inh = inh;
rte->relkind = rel->rd_rel->relkind;
rte->rellockmode = lockmode;
+ rte->relisivm = rel->rd_rel->relisivm;
/*
* Build the list of effective column names using user-supplied aliases
@@ -1588,6 +1590,7 @@ addRangeTableEntryForRelation(ParseState *pstate,
rte->inh = inh;
rte->relkind = rel->rd_rel->relkind;
rte->rellockmode = lockmode;
+ rte->relisivm = rel->rd_rel->relisivm;
/*
* Build the list of effective column names using user-supplied aliases
@@ -2752,7 +2755,7 @@ expandRTE(RangeTblEntry *rte, int rtindex, int sublevels_up,
expandTupleDesc(tupdesc, rte->eref,
rtfunc->funccolcount, atts_done,
rtindex, sublevels_up, location,
- include_dropped, colnames, colvars);
+ include_dropped, colnames, colvars, false);
}
else if (functypclass == TYPEFUNC_SCALAR)
{
@@ -3020,7 +3023,7 @@ expandRelation(Oid relid, Alias *eref, int rtindex, int sublevels_up,
expandTupleDesc(rel->rd_att, eref, rel->rd_att->natts, 0,
rtindex, sublevels_up,
location, include_dropped,
- colnames, colvars);
+ colnames, colvars, RelationIsIVM(rel));
relation_close(rel, AccessShareLock);
}
@@ -3037,7 +3040,7 @@ static void
expandTupleDesc(TupleDesc tupdesc, Alias *eref, int count, int offset,
int rtindex, int sublevels_up,
int location, bool include_dropped,
- List **colnames, List **colvars)
+ List **colnames, List **colvars, bool is_ivm)
{
ListCell *aliascell;
int varattno;
@@ -3050,6 +3053,9 @@ expandTupleDesc(TupleDesc tupdesc, Alias *eref, int count, int offset,
{
Form_pg_attribute attr = TupleDescAttr(tupdesc, varattno);
+ if (is_ivm && isIvmName(NameStr(attr->attname)) && !MatViewIncrementalMaintenanceIsEnabled())
+ continue;
+
if (attr->attisdropped)
{
if (include_dropped)
@@ -3212,6 +3218,10 @@ expandNSItemAttrs(ParseState *pstate, ParseNamespaceItem *nsitem,
Var *varnode = (Var *) lfirst(var);
TargetEntry *te;
+ /* if transform * into columnlist with IMMV, remove IVM columns */
+ if (rte->relisivm && isIvmName(label) && !MatViewIncrementalMaintenanceIsEnabled())
+ continue;
+
te = makeTargetEntry((Expr *) varnode,
(AttrNumber) pstate->p_next_resno++,
label,
diff --git a/src/backend/rewrite/rewriteDefine.c b/src/backend/rewrite/rewriteDefine.c
index 6cc9a8d8bf..5d22dbcfcf 100644
--- a/src/backend/rewrite/rewriteDefine.c
+++ b/src/backend/rewrite/rewriteDefine.c
@@ -614,7 +614,8 @@ checkRuleResultList(List *targetList, TupleDesc resultDesc, bool isSelect,
attr->atttypmod))));
}
- if (i != resultDesc->natts)
+ /* No check for materialized views since this could have special columns for IVM */
+ if ((!isSelect || requireColumnNameMatch) && i != resultDesc->natts)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
isSelect ?
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 396ad1bb4c..6b47e66bfd 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -29,6 +29,8 @@ extern ObjectAddress ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *st
extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
+extern Query *rewriteQueryForIMMV(Query *query, List *colNames);
+
extern int GetIntoRelEFlags(IntoClause *intoClause);
extern DestReceiver *CreateIntoRelDestReceiver(IntoClause *intoClause);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b89baef95d..bfa48d659e 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1089,6 +1089,8 @@ typedef struct RangeTblEntry
Index perminfoindex pg_node_attr(query_jumble_ignore);
/* sampling info, or NULL */
struct TableSampleClause *tablesample;
+ /* incrementally maintainable materialized view? */
+ bool relisivm;
/*
* Fields valid for a subquery RTE (else NULL):
--
2.25.1
v31-0008-Add-aggregates-support-in-IVM.patchtext/x-diff; name=v31-0008-Add-aggregates-support-in-IVM.patchDownload
From 64080da7d682ca8c582be60a04471400d99bae33 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 20:46:32 +0900
Subject: [PATCH v31 08/11] Add aggregates support in IVM
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit
count, sum, adn avg are supported.
As a restriction, expressions specified in GROUP BY must appear in
the target list because tuples to be updated in IMMV are identified
by using this group key. However, in the case of aggregates without
GROUP BY, there is only one tuple in the view, so keys are not uses
to identify tuples.
When creating a IMMV, in addition to __ivm_count column, some hidden
columns for each aggregate are added to the target list. For example,
names of these hidden columns are ivm_count_avg and ivm_sum_avg for
the average function, and so on.
When a base table is modified, the aggregated values and related
hidden columns are also updated as well as __ivm_count__. The
way of update depends the kind of aggregate function. Specifically,
sum and count are updated by simply adding or subtracting delta value
calculated from delta tables. avg is updated by using values of sum
and count stored in views as hidden columns and deltas calculated
from delta tables.
About aggregate functions except "count()" (sum and avg), NULLs in input
values are ignored, and the result of aggegate should be NULL when no
rows are selected. To support this specification, the numbers of non-NULL
input values are counted and stored in hidden columns. In the case of
count(), count(x) returns zero when no rows are selected, but count(*)
doesn't ignore NULL input.
---
src/backend/commands/createas.c | 265 +++++++++++++++++--
src/backend/commands/matview.c | 433 ++++++++++++++++++++++++++++++--
src/include/commands/createas.h | 1 +
3 files changed, 662 insertions(+), 37 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index 8f2bd5203e..aa8440b4e1 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -51,13 +51,19 @@
#include "parser/parsetree.h"
#include "parser/parse_clause.h"
#include "parser/parse_func.h"
+#include "parser/parse_type.h"
#include "rewrite/rewriteHandler.h"
+#include "rewrite/rewriteManip.h"
+#include "storage/smgr.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
#include "utils/lsyscache.h"
+#include "utils/regproc.h"
+#include "utils/fmgroids.h"
#include "utils/rel.h"
#include "utils/rls.h"
#include "utils/snapmgr.h"
+#include "utils/syscache.h"
typedef struct
{
@@ -71,6 +77,11 @@ typedef struct
BulkInsertState bistate; /* bulk insert state */
} DR_intorel;
+typedef struct
+{
+ bool has_agg;
+} check_ivm_restriction_context;
+
/* utility functions for CTAS definition creation */
static ObjectAddress create_ctas_internal(List *attrList, IntoClause *into);
static ObjectAddress create_ctas_nodata(List *tlist, IntoClause *into);
@@ -85,8 +96,9 @@ static void CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid mat
Relids *relids, bool ex_lock);
static void CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock);
static void check_ivm_restriction(Node *node);
-static bool check_ivm_restriction_walker(Node *node, void *context);
+static bool check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context);
static Bitmapset *get_primary_key_attnos_from_query(Query *query, List **constraintList);
+static bool check_aggregate_supports_ivm(Oid aggfnoid);
/*
* create_ctas_internal
@@ -417,6 +429,7 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
* rewriteQueryForIMMV -- rewrite view definition query for IMMV
*
* count(*) is added for counting distinct tuples in views.
+ * Also, additional hidden columns are added for aggregate values.
*/
Query *
rewriteQueryForIMMV(Query *query, List *colNames)
@@ -430,16 +443,49 @@ rewriteQueryForIMMV(Query *query, List *colNames)
rewritten = copyObject(query);
pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
- /*
- * Convert DISTINCT to GROUP BY and add count(*) for counting distinct
- * tuples in views.
- */
- if (rewritten->distinctClause)
+ /* group keys must be in targetlist */
+ if (rewritten->groupClause)
{
- TargetEntry *tle;
+ ListCell *lc;
+ foreach(lc, rewritten->groupClause)
+ {
+ SortGroupClause *scl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(scl, rewritten->targetList);
+ if (tle->resjunk)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUP BY expression not appearing in select list is not supported on incrementally maintainable materialized view")));
+ }
+ }
+ /* Convert DISTINCT to GROUP BY. count(*) will be added afterward. */
+ else if (!rewritten->hasAggs && rewritten->distinctClause)
rewritten->groupClause = transformDistinctClause(NULL, &rewritten->targetList, rewritten->sortClause, false);
+ /* Add additional columns for aggregate values */
+ if (rewritten->hasAggs)
+ {
+ ListCell *lc;
+ List *aggs = NIL;
+ AttrNumber next_resno = list_length(rewritten->targetList) + 1;
+
+ foreach(lc, rewritten->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ char *resname = (colNames == NIL || foreach_current_index(lc) >= list_length(colNames) ?
+ tle->resname : strVal(list_nth(colNames, tle->resno - 1)));
+
+ if (IsA(tle->expr, Aggref))
+ makeIvmAggColumn(pstate, (Aggref *) tle->expr, resname, &next_resno, &aggs);
+ }
+ rewritten->targetList = list_concat(rewritten->targetList, aggs);
+ }
+
+ /* Add count(*) for counting distinct tuples in views */
+ if (rewritten->distinctClause || rewritten->hasAggs)
+ {
+ TargetEntry *tle;
+
fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
fn->agg_star = true;
@@ -456,6 +502,91 @@ rewriteQueryForIMMV(Query *query, List *colNames)
return rewritten;
}
+/*
+ * makeIvmAggColumn -- make additional aggregate columns for IVM
+ *
+ * For an aggregate column specified by aggref, additional aggregate columns
+ * are added, which are used to calculate the new aggregate value in IMMV.
+ * An additional aggregate columns has a name based on resname
+ * (ex. ivm_count_resname), and resno specified by next_resno. The created
+ * columns are returned to aggs, and the resno for the next column is also
+ * returned to next_resno.
+ *
+ * Currently, an additional count() is created for aggref other than count.
+ * In addition, sum() is created for avg aggregate column.
+ */
+void
+makeIvmAggColumn(ParseState *pstate, Aggref *aggref, char *resname, AttrNumber *next_resno, List **aggs)
+{
+ TargetEntry *tle_count;
+ Node *node;
+ FuncCall *fn;
+ Const *dmy_arg = makeConst(INT4OID,
+ -1,
+ InvalidOid,
+ sizeof(int32),
+ Int32GetDatum(1),
+ false,
+ true); /* pass by value */
+ const char *aggname = get_func_name(aggref->aggfnoid);
+
+ /*
+ * For aggregate functions except count, add count() func with the same arg parameters.
+ * This count result is used for determining if the aggregate value should be NULL or not.
+ * Also, add sum() func for avg because we need to calculate an average value as sum/count.
+ *
+ * XXX: If there are same expressions explicitly in the target list, we can use this instead
+ * of adding new duplicated one.
+ */
+ if (strcmp(aggname, "count") != 0)
+ {
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+
+ /* Make a Func with a dummy arg, and then override this by the original agg's args. */
+ node = ParseFuncOrColumn(pstate, fn->funcname, list_make1(dmy_arg), NULL, fn, false, -1);
+ ((Aggref *)node)->args = aggref->args;
+
+ tle_count = makeTargetEntry((Expr *) node,
+ *next_resno,
+ pstrdup(makeObjectName("__ivm_count",resname, "_")),
+ false);
+ *aggs = lappend(*aggs, tle_count);
+ (*next_resno)++;
+ }
+ if (strcmp(aggname, "avg") == 0)
+ {
+ List *dmy_args = NIL;
+ ListCell *lc;
+ foreach(lc, aggref->aggargtypes)
+ {
+ Oid typeid = lfirst_oid(lc);
+ Type type = typeidType(typeid);
+
+ Const *con = makeConst(typeid,
+ -1,
+ typeTypeCollation(type),
+ typeLen(type),
+ (Datum) 0,
+ true,
+ typeByVal(type));
+ dmy_args = lappend(dmy_args, con);
+ ReleaseSysCache(type);
+ }
+ fn = makeFuncCall(SystemFuncName("sum"), NIL, COERCE_EXPLICIT_CALL, -1);
+
+ /* Make a Func with dummy args, and then override this by the original agg's args. */
+ node = ParseFuncOrColumn(pstate, fn->funcname, dmy_args, NULL, fn, false, -1);
+ ((Aggref *)node)->args = aggref->args;
+
+ tle_count = makeTargetEntry((Expr *) node,
+ *next_resno,
+ pstrdup(makeObjectName("__ivm_sum",resname, "_")),
+ false);
+ *aggs = lappend(*aggs, tle_count);
+ (*next_resno)++;
+ }
+}
+
/*
* GetIntoRelEFlags --- compute executor flags needed for CREATE TABLE AS
*
@@ -939,11 +1070,13 @@ CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock
static void
check_ivm_restriction(Node *node)
{
- check_ivm_restriction_walker(node, NULL);
+ check_ivm_restriction_context context = {false};
+
+ check_ivm_restriction_walker(node, &context);
}
static bool
-check_ivm_restriction_walker(Node *node, void *context)
+check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context)
{
if (node == NULL)
return false;
@@ -972,6 +1105,10 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("CTE is not supported on incrementally maintainable materialized view")));
+ if (qry->groupClause != NIL && !qry->hasAggs)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUP BY clause without aggregate is not supported on incrementally maintainable materialized view")));
if (qry->havingQual != NULL)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
@@ -1024,6 +1161,8 @@ check_ivm_restriction_walker(Node *node, void *context)
}
}
+ context->has_agg |= qry->hasAggs;
+
/* restrictions for rtable */
foreach(lc, qry->rtable)
{
@@ -1072,7 +1211,7 @@ check_ivm_restriction_walker(Node *node, void *context)
}
- query_tree_walker(qry, check_ivm_restriction_walker, NULL, QTW_IGNORE_RANGE_TABLE);
+ query_tree_walker(qry, check_ivm_restriction_walker, (void *) context, QTW_IGNORE_RANGE_TABLE);
break;
}
@@ -1083,8 +1222,12 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("column name %s is not supported on incrementally maintainable materialized view", tle->resname)));
+ if (context->has_agg && !IsA(tle->expr, Aggref) && contain_aggs_of_level((Node *) tle->expr, 0))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("expression containing an aggregate in it is not supported on incrementally maintainable materialized view")));
- expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
break;
}
case T_JoinExpr:
@@ -1096,14 +1239,36 @@ check_ivm_restriction_walker(Node *node, void *context)
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("OUTER JOIN is not supported on incrementally maintainable materialized view")));
- expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
+ break;
}
- break;
case T_Aggref:
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("aggregate function is not supported on incrementally maintainable materialized view")));
- break;
+ {
+ /* Check if this supports IVM */
+ Aggref *aggref = (Aggref *) node;
+ const char *aggname = format_procedure(aggref->aggfnoid);
+
+ if (aggref->aggfilter != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with FILTER clause is not supported on incrementally maintainable materialized view")));
+
+ if (aggref->aggdistinct != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with DISTINCT arguments is not supported on incrementally maintainable materialized view")));
+
+ if (aggref->aggorder != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with ORDER clause is not supported on incrementally maintainable materialized view")));
+
+ if (!check_aggregate_supports_ivm(aggref->aggfnoid))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function %s is not supported on incrementally maintainable materialized view", aggname)));
+ break;
+ }
default:
expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
break;
@@ -1111,6 +1276,46 @@ check_ivm_restriction_walker(Node *node, void *context)
return false;
}
+/*
+ * check_aggregate_supports_ivm
+ *
+ * Check if the given aggregate function is supporting IVM
+ */
+static bool
+check_aggregate_supports_ivm(Oid aggfnoid)
+{
+ switch (aggfnoid)
+ {
+ /* count */
+ case F_COUNT_ANY:
+ case F_COUNT_:
+
+ /* sum */
+ case F_SUM_INT8:
+ case F_SUM_INT4:
+ case F_SUM_INT2:
+ case F_SUM_FLOAT4:
+ case F_SUM_FLOAT8:
+ case F_SUM_MONEY:
+ case F_SUM_INTERVAL:
+ case F_SUM_NUMERIC:
+
+ /* avg */
+ case F_AVG_INT8:
+ case F_AVG_INT4:
+ case F_AVG_INT2:
+ case F_AVG_NUMERIC:
+ case F_AVG_FLOAT4:
+ case F_AVG_FLOAT8:
+ case F_AVG_INTERVAL:
+
+ return true;
+
+ default:
+ return false;
+ }
+}
+
/*
* CreateIndexOnIMMV
*
@@ -1168,7 +1373,29 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
index->concurrent = false;
index->if_not_exists = false;
- if (query->distinctClause)
+ if (query->groupClause)
+ {
+ /* create unique constraint on GROUP BY expression columns */
+ foreach(lc, query->groupClause)
+ {
+ SortGroupClause *scl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(scl, query->targetList);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ else if (query->distinctClause)
{
/* create unique constraint on all columns */
foreach(lc, query->targetList)
@@ -1226,7 +1453,7 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
(errmsg("could not create an index on materialized view \"%s\" automatically",
RelationGetRelationName(matviewRel)),
errdetail("This target list does not have all the primary key columns, "
- "or this view does not contain DISTINCT clause."),
+ "or this view does not contain GROUP BY or DISTINCT clause."),
errhint("Create an index on the materialized view for efficient incremental maintenance.")));
return;
}
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index f2e8aa02a3..97406b28c9 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -27,6 +27,7 @@
#include "catalog/pg_trigger.h"
#include "catalog/pg_opclass.h"
#include "commands/cluster.h"
+#include "commands/defrem.h"
#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
@@ -36,6 +37,7 @@
#include "executor/tstoreReceiver.h"
#include "miscadmin.h"
#include "nodes/makefuncs.h"
+#include "optimizer/optimizer.h"
#include "parser/analyze.h"
#include "parser/parse_clause.h"
#include "parser/parse_func.h"
@@ -107,6 +109,13 @@ static HTAB *mv_trigger_info = NULL;
static bool in_delta_calculation = false;
+/* kind of IVM operation for the view */
+typedef enum
+{
+ IVM_ADD,
+ IVM_SUB
+} IvmOp;
+
/* ENR name for materialized view delta */
#define NEW_DELTA_ENRNAME "new_delta"
#define OLD_DELTA_ENRNAME "old_delta"
@@ -138,7 +147,7 @@ static RangeTblEntry *get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *tabl
QueryEnvironment *queryEnv, Oid matviewid);
static RangeTblEntry *replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
QueryEnvironment *queryEnv);
-static Query *rewrite_query_for_counting(Query *query, ParseState *pstate);
+static Query *rewrite_query_for_counting_and_aggregates(Query *query, ParseState *pstate);
static void calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
DestReceiver *dest_old, DestReceiver *dest_new,
@@ -149,14 +158,27 @@ static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *
static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
Query *query, bool use_count, char *count_colname);
+static void append_set_clause_for_count(const char *resname, StringInfo buf_old,
+ StringInfo buf_new,StringInfo aggs_list);
+static void append_set_clause_for_sum(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list);
+static void append_set_clause_for_avg(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ const char *aggtype);
+static char *get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
+ const char* count_col, const char *castType);
+static char *get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
+ const char* count_col);
static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
- List *keys, const char *count_colname);
+ List *keys, StringInfo aggs_list, StringInfo aggs_set,
+ const char *count_colname);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
- List *keys, StringInfo target_list, const char* count_colname);
+ List *keys, StringInfo target_list, StringInfo aggs_set,
+ const char* count_colname);
static char *get_matching_condition_string(List *keys);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
@@ -1452,11 +1474,44 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
* When a base table is truncated, the view content will be empty if the
* view definition query does not contain an aggregate without a GROUP clause.
* Therefore, such views can be truncated.
+ *
+ * Aggregate views without a GROUP clause always have one row. Therefore,
+ * if a base table is truncated, the view will not be empty and will contain
+ * a row with NULL value (or 0 for count()). So, in this case, we refresh the
+ * view instead of truncating it.
*/
if (TRIGGER_FIRED_BY_TRUNCATE(trigdata->tg_event))
{
- ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
- NIL, DROP_RESTRICT, false, false);
+ if (!(query->hasAggs && query->groupClause == NIL))
+ ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
+ NIL, DROP_RESTRICT, false, false);
+ else
+ {
+ Oid OIDNewHeap;
+ DestReceiver *dest;
+ uint64 processed = 0;
+ Query *dataQuery = rewriteQueryForIMMV(query, NIL);
+ char relpersistence = matviewRel->rd_rel->relpersistence;
+
+ /*
+ * Create the transient table that will receive the regenerated data. Lock
+ * it against access by any other process until commit (by which time it
+ * will be gone).
+ */
+ OIDNewHeap = make_new_heap(matviewOid, matviewRel->rd_rel->reltablespace,
+ matviewRel->rd_rel->relam,
+ relpersistence, ExclusiveLock);
+ LockRelationOid(OIDNewHeap, AccessExclusiveLock);
+ dest = CreateTransientRelDestReceiver(OIDNewHeap);
+
+ /* Generate the data */
+ processed = refresh_matview_datafill(dest, dataQuery, NULL, NULL, "");
+ refresh_by_heap_swap(matviewOid, OIDNewHeap, relpersistence);
+
+ /* Inform cumulative stats system about our activity */
+ pgstat_count_truncate(matviewRel);
+ pgstat_count_heap_insert(matviewRel, processed);
+ }
/* Clean up hash entry and delete tuplestores */
clean_up_IVM_hash_entry(entry, false);
@@ -1496,8 +1551,8 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
/* Set all tables in the query to pre-update state */
rewritten = rewrite_query_for_preupdate_state(rewritten, entry->tables,
pstate, matviewOid);
- /* Rewrite for counting duplicated tuples */
- rewritten = rewrite_query_for_counting(rewritten, pstate);
+ /* Rewrite for counting duplicated tuples and aggregates functions*/
+ rewritten = rewrite_query_for_counting_and_aggregates(rewritten, pstate);
/* Create tuplestores to store view deltas */
if (entry->has_old)
@@ -1548,7 +1603,7 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
count_colname = pstrdup("__ivm_count__");
- if (query->distinctClause)
+ if (query->hasAggs || query->distinctClause)
use_count = true;
/* calculate delta tables */
@@ -1944,17 +1999,34 @@ replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
}
/*
- * rewrite_query_for_counting
+ * rewrite_query_for_counting_and_aggregates
*
- * Rewrite query for counting duplicated tuples.
+ * Rewrite query for counting duplicated tuples and aggregate functions.
*/
static Query *
-rewrite_query_for_counting(Query *query, ParseState *pstate)
+rewrite_query_for_counting_and_aggregates(Query *query, ParseState *pstate)
{
TargetEntry *tle_count;
FuncCall *fn;
Node *node;
+ /* For aggregate views */
+ if (query->hasAggs)
+ {
+ ListCell *lc;
+ List *aggs = NIL;
+ AttrNumber next_resno = list_length(query->targetList) + 1;
+
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+
+ if (IsA(tle->expr, Aggref))
+ makeIvmAggColumn(pstate, (Aggref *)tle->expr, tle->resname, &next_resno, &aggs);
+ }
+ query->targetList = list_concat(query->targetList, aggs);
+ }
+
/* Add count(*) for counting distinct tuples in views */
fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
fn->agg_star = true;
@@ -2027,6 +2099,8 @@ rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte
return query;
}
+#define IVM_colname(type, col) makeObjectName("__ivm_" type, col, "_")
+
/*
* apply_delta
*
@@ -2040,6 +2114,9 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
{
StringInfoData querybuf;
StringInfoData target_list_buf;
+ StringInfo aggs_list_buf = NULL;
+ StringInfo aggs_set_old = NULL;
+ StringInfo aggs_set_new = NULL;
Relation matviewRel;
char *matviewname;
ListCell *lc;
@@ -2062,6 +2139,15 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
initStringInfo(&querybuf);
initStringInfo(&target_list_buf);
+ if (query->hasAggs)
+ {
+ if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
+ aggs_set_old = makeStringInfo();
+ if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
+ aggs_set_new = makeStringInfo();
+ aggs_list_buf = makeStringInfo();
+ }
+
/* build string of target list */
for (i = 0; i < matviewRel->rd_att->natts; i++)
{
@@ -2078,13 +2164,61 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
i++;
if (tle->resjunk)
continue;
- keys = lappend(keys, attr);
+ /*
+ * For views without aggregates, all attributes are used as keys to identify a
+ * tuple in a view.
+ */
+ if (!query->hasAggs)
+ keys = lappend(keys, attr);
+
+ /* For views with aggregates, we need to build SET clause for updating aggregate
+ * values. */
+ if (query->hasAggs && IsA(tle->expr, Aggref))
+ {
+ Aggref *aggref = (Aggref *) tle->expr;
+ const char *aggname = get_func_name(aggref->aggfnoid);
+
+ /*
+ * We can use function names here because it is already checked if these
+ * can be used in IMMV by its OID at the definition time.
+ */
+
+ /* count */
+ if (!strcmp(aggname, "count"))
+ append_set_clause_for_count(resname, aggs_set_old, aggs_set_new, aggs_list_buf);
+
+ /* sum */
+ else if (!strcmp(aggname, "sum"))
+ append_set_clause_for_sum(resname, aggs_set_old, aggs_set_new, aggs_list_buf);
+
+ /* avg */
+ else if (!strcmp(aggname, "avg"))
+ append_set_clause_for_avg(resname, aggs_set_old, aggs_set_new, aggs_list_buf,
+ format_type_be(aggref->aggtype));
+
+ else
+ elog(ERROR, "unsupported aggregate function: %s", aggname);
+ }
+ }
+
+ /* If we have GROUP BY clause, we use its entries as keys. */
+ if (query->hasAggs && query->groupClause)
+ {
+ foreach (lc, query->groupClause)
+ {
+ SortGroupClause *sgcl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(sgcl, query->targetList);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ keys = lappend(keys, attr);
+ }
}
/* Start maintaining the materialized view. */
@@ -2115,7 +2249,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (use_count)
/* apply old delta and get rows to be recalculated */
apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
- keys, count_colname);
+ keys, aggs_list_buf, aggs_set_old,
+ count_colname);
else
apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
@@ -2141,7 +2276,7 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
/* apply new delta */
if (use_count)
apply_new_delta_with_count(matviewname, NEW_DELTA_ENRNAME,
- keys, &target_list_buf, count_colname);
+ keys, aggs_set_new, &target_list_buf, count_colname);
else
apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
}
@@ -2156,6 +2291,250 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_finish failed");
}
+/*
+ * append_set_clause_for_count
+ *
+ * Append SET clause string for count aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_count(const char *resname, StringInfo buf_old,
+ StringInfo buf_new,StringInfo aggs_list)
+{
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* resname = mv.resname - t.resname */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, resname, "mv", "t", NULL, NULL));
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* resname = mv.resname + diff.resname */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, resname, "mv", "diff", NULL, NULL));
+ }
+
+ appendStringInfo(aggs_list, ", %s",
+ quote_qualified_identifier("diff", resname)
+ );
+}
+
+/*
+ * append_set_clause_for_sum
+ *
+ * Append SET clause string for sum aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_sum(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list)
+{
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* sum = mv.sum - t.sum */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, resname, "mv", "t", count_col, NULL)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* sum = mv.sum + diff.sum */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, resname, "mv", "diff", count_col, NULL)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
+/*
+ * append_set_clause_for_avg
+ *
+ * Append SET clause string for avg aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_avg(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ const char *aggtype)
+{
+ char *sum_col = IVM_colname("sum", resname);
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* avg = (mv.sum - t.sum)::aggtype / (mv.count - t.count) */
+ appendStringInfo(buf_old,
+ ", %s = %s OPERATOR(pg_catalog./) %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, sum_col, "mv", "t", count_col, aggtype),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ /* sum = mv.sum - t.sum */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, sum_col),
+ get_operation_string(IVM_SUB, sum_col, "mv", "t", count_col, NULL)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* avg = (mv.sum + diff.sum)::aggtype / (mv.count + diff.count) */
+ appendStringInfo(buf_new,
+ ", %s = %s OPERATOR(pg_catalog./) %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, sum_col, "mv", "diff", count_col, aggtype),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ /* sum = mv.sum + diff.sum */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, sum_col),
+ get_operation_string(IVM_ADD, sum_col, "mv", "diff", count_col, NULL)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("sum", resname)),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
+/*
+ * get_operation_string
+ *
+ * Build a string to calculate the new aggregate values.
+ */
+static char *
+get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
+ const char* count_col, const char *castType)
+{
+ StringInfoData buf;
+ StringInfoData castString;
+ char *col1 = quote_qualified_identifier(arg1, col);
+ char *col2 = quote_qualified_identifier(arg2, col);
+ char op_char = (op == IVM_SUB ? '-' : '+');
+
+ initStringInfo(&buf);
+ initStringInfo(&castString);
+
+ if (castType)
+ appendStringInfo(&castString, "::%s", castType);
+
+ if (!count_col)
+ {
+ /*
+ * If the attributes don't have count columns then calc the result
+ * by using the operator simply.
+ */
+ appendStringInfo(&buf, "(%s OPERATOR(pg_catalog.%c) %s)%s",
+ col1, op_char, col2, castString.data);
+ }
+ else
+ {
+ /*
+ * If the attributes have count columns then consider the condition
+ * where the result becomes NULL.
+ */
+ char *null_cond = get_null_condition_string(op, arg1, arg2, count_col);
+
+ appendStringInfo(&buf,
+ "(CASE WHEN %s THEN NULL "
+ "WHEN %s IS NULL THEN %s "
+ "WHEN %s IS NULL THEN %s "
+ "ELSE (%s OPERATOR(pg_catalog.%c) %s)%s END)",
+ null_cond,
+ col1, col2,
+ col2, col1,
+ col1, op_char, col2, castString.data
+ );
+ }
+
+ return buf.data;
+}
+
+/*
+ * get_null_condition_string
+ *
+ * Build a predicate string for CASE clause to check if an aggregate value
+ * will became NULL after the given operation is applied.
+ */
+static char *
+get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
+ const char* count_col)
+{
+ StringInfoData null_cond;
+ initStringInfo(&null_cond);
+
+ switch (op)
+ {
+ case IVM_ADD:
+ appendStringInfo(&null_cond,
+ "%s OPERATOR(pg_catalog.=) 0 AND %s OPERATOR(pg_catalog.=) 0",
+ quote_qualified_identifier(arg1, count_col),
+ quote_qualified_identifier(arg2, count_col)
+ );
+ break;
+ case IVM_SUB:
+ appendStringInfo(&null_cond,
+ "%s OPERATOR(pg_catalog.=) %s",
+ quote_qualified_identifier(arg1, count_col),
+ quote_qualified_identifier(arg2, count_col)
+ );
+ break;
+ default:
+ elog(ERROR,"unknown operation");
+ }
+
+ return null_cond.data;
+}
+
+
/*
* apply_old_delta_with_count
*
@@ -2163,13 +2542,20 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
* which contains tuples to be deleted from to a materialized view given by
* matviewname. This is used when counting is required, that is, the view
* has aggregate or distinct.
+ *
+ * If the view desn't have aggregates or has GROUP BY, this requires a keys
+ * list to identify a tuple in the view. If the view has aggregates, this
+ * requires strings representing resnames of aggregates and SET clause for
+ * updating aggregate values.
*/
static void
apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
- List *keys, const char *count_colname)
+ List *keys, StringInfo aggs_list, StringInfo aggs_set,
+ const char *count_colname)
{
StringInfoData querybuf;
char *match_cond;
+ bool agg_without_groupby = (list_length(keys) == 0);
/* build WHERE condition for searching tuples to be deleted */
match_cond = get_matching_condition_string(keys);
@@ -2179,22 +2565,26 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
appendStringInfo(&querybuf,
"WITH t AS (" /* collecting tid of target tuples in the view */
"SELECT diff.%s, " /* count column */
- "(diff.%s OPERATOR(pg_catalog.=) mv.%s) AS for_dlt, "
+ "(diff.%s OPERATOR(pg_catalog.=) mv.%s AND %s) AS for_dlt, "
"mv.ctid "
+ "%s " /* aggregate columns */
"FROM %s AS mv, %s AS diff "
"WHERE %s" /* tuple matching condition */
"), updt AS (" /* update a tuple if this is not to be deleted */
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
+ "%s" /* SET clauses for aggregates */
"FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
")"
/* delete a tuple if this is to be deleted */
"DELETE FROM %s AS mv USING t "
"WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
count_colname,
- count_colname, count_colname,
+ count_colname, count_colname, (agg_without_groupby ? "false" : "true"),
+ (aggs_list != NULL ? aggs_list->data : ""),
matviewname, deltaname_old,
match_cond,
matviewname, count_colname, count_colname, count_colname,
+ (aggs_set != NULL ? aggs_set->data : ""),
matviewname);
if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
@@ -2258,10 +2648,15 @@ apply_old_delta(const char *matviewname, const char *deltaname_old,
* matviewname. This is used when counting is required, that is, the view
* has aggregate or distinct. Also, when a table in EXISTS sub queries
* is modified.
+ *
+ * If the view desn't have aggregates or has GROUP BY, this requires a keys
+ * list to identify a tuple in the view. If the view has aggregates, this
+ * requires strings representing SET clause for updating aggregate values.
*/
static void
apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
- List *keys, StringInfo target_list, const char* count_colname)
+ List *keys, StringInfo aggs_set, StringInfo target_list,
+ const char* count_colname)
{
StringInfoData querybuf;
StringInfoData returning_keys;
@@ -2292,6 +2687,7 @@ apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
appendStringInfo(&querybuf,
"WITH updt AS (" /* update a tuple if this exists in the view */
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.+) diff.%s "
+ "%s " /* SET clauses for aggregates */
"FROM %s AS diff "
"WHERE %s " /* tuple matching condition */
"RETURNING %s" /* returning keys of updated tuples */
@@ -2299,6 +2695,7 @@ apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
"SELECT %s FROM %s AS diff "
"WHERE NOT EXISTS (SELECT 1 FROM updt AS mv WHERE %s);",
matviewname, count_colname, count_colname, count_colname,
+ (aggs_set != NULL ? aggs_set->data : ""),
deltaname_new,
match_cond,
returning_keys.data,
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 6b47e66bfd..af3a5b4b27 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -30,6 +30,7 @@ extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
extern Query *rewriteQueryForIMMV(Query *query, List *colNames);
+extern void makeIvmAggColumn(ParseState *pstate, Aggref *aggref, char *resname, AttrNumber *next_resno, List **aggs);
extern int GetIntoRelEFlags(IntoClause *intoClause);
--
2.25.1
v31-0009-Add-support-for-min-max-aggregates-for-IVM.patchtext/x-diff; name=v31-0009-Add-support-for-min-max-aggregates-for-IVM.patchDownload
From 82268cb3b17c05eb1c9d018d9cbae56c4ae45c4e Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 20:58:25 +0900
Subject: [PATCH v31 09/11] Add support for min/max aggregates for IVM
Supporting min and max is more complicated than count, sum, or avg.
For an example of min, when tuples are inserted, the current min value
in the view and the min value in the inseteted tuples are compared,
then the smaller one is used as the latest min value. On the other
hand, when tuples are deleted, if the current min value in the view
equals to the min in the deleted tuples, we need re-computation the
latest min value from base tables. Otherwise, the current value in
the view remains.
---
src/backend/commands/createas.c | 45 +++
src/backend/commands/matview.c | 644 +++++++++++++++++++++++++++++++-
2 files changed, 680 insertions(+), 9 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index aa8440b4e1..7e1627ad1b 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -1309,6 +1309,51 @@ check_aggregate_supports_ivm(Oid aggfnoid)
case F_AVG_FLOAT8:
case F_AVG_INTERVAL:
+ /* min */
+ case F_MIN_ANYARRAY:
+ case F_MIN_INT8:
+ case F_MIN_INT4:
+ case F_MIN_INT2:
+ case F_MIN_OID:
+ case F_MIN_FLOAT4:
+ case F_MIN_FLOAT8:
+ case F_MIN_DATE:
+ case F_MIN_TIME:
+ case F_MIN_TIMETZ:
+ case F_MIN_MONEY:
+ case F_MIN_TIMESTAMP:
+ case F_MIN_TIMESTAMPTZ:
+ case F_MIN_INTERVAL:
+ case F_MIN_TEXT:
+ case F_MIN_NUMERIC:
+ case F_MIN_BPCHAR:
+ case F_MIN_TID:
+ case F_MIN_ANYENUM:
+ case F_MIN_INET:
+ case F_MIN_PG_LSN:
+
+ /* max */
+ case F_MAX_ANYARRAY:
+ case F_MAX_INT8:
+ case F_MAX_INT4:
+ case F_MAX_INT2:
+ case F_MAX_OID:
+ case F_MAX_FLOAT4:
+ case F_MAX_FLOAT8:
+ case F_MAX_DATE:
+ case F_MAX_TIME:
+ case F_MAX_TIMETZ:
+ case F_MAX_MONEY:
+ case F_MAX_TIMESTAMP:
+ case F_MAX_TIMESTAMPTZ:
+ case F_MAX_INTERVAL:
+ case F_MAX_TEXT:
+ case F_MAX_NUMERIC:
+ case F_MAX_BPCHAR:
+ case F_MAX_TID:
+ case F_MAX_ANYENUM:
+ case F_MAX_INET:
+ case F_MAX_PG_LSN:
return true;
default:
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index 97406b28c9..0ff5e3922b 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -69,6 +69,34 @@ typedef struct
#define MV_INIT_QUERYHASHSIZE 16
+/* MV query type codes */
+#define MV_PLAN_RECALC 1
+#define MV_PLAN_SET_VALUE 2
+
+/*
+ * MI_QueryKey
+ *
+ * The key identifying a prepared SPI plan in our query hashtable
+ */
+typedef struct MV_QueryKey
+{
+ Oid matview_id; /* OID of materialized view */
+ int32 query_type; /* query type ID, see MV_PLAN_XXX above */
+} MV_QueryKey;
+
+/*
+ * MV_QueryHashEntry
+ *
+ * Hash entry for cached plans used to maintain materialized views.
+ */
+typedef struct MV_QueryHashEntry
+{
+ MV_QueryKey key;
+ SPIPlanPtr plan;
+ SearchPathMatcher *search_path; /* search_path used for parsing
+ * and planning */
+} MV_QueryHashEntry;
+
/*
* MV_TriggerHashEntry
*
@@ -105,6 +133,7 @@ typedef struct MV_TriggerTable
TupleTableSlot *slot; /* for checking visibility in the pre-state table */
} MV_TriggerTable;
+static HTAB *mv_query_cache = NULL;
static HTAB *mv_trigger_info = NULL;
static bool in_delta_calculation = false;
@@ -165,6 +194,9 @@ static void append_set_clause_for_sum(const char *resname, StringInfo buf_old,
static void append_set_clause_for_avg(const char *resname, StringInfo buf_old,
StringInfo buf_new, StringInfo aggs_list,
const char *aggtype);
+static void append_set_clause_for_minmax(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ bool is_min);
static char *get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
const char* count_col, const char *castType);
static char *get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
@@ -173,17 +205,30 @@ static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
List *keys, StringInfo aggs_list, StringInfo aggs_set,
- const char *count_colname);
+ List *minmax_list, List *is_min_list,
+ const char *count_colname,
+ SPITupleTable **tuptable_recalc, uint64 *num_recalc);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
List *keys, StringInfo target_list, StringInfo aggs_set,
const char* count_colname);
static char *get_matching_condition_string(List *keys);
+static char *get_returning_string(List *minmax_list, List *is_min_list, List *keys);
+static char *get_minmax_recalc_condition_string(List *minmax_list, List *is_min_list);
+static char *get_select_for_recalc_string(List *keys);
+static void recalc_and_set_values(SPITupleTable *tuptable_recalc, int64 num_tuples,
+ List *namelist, List *keys, Relation matviewRel);
+static SPIPlanPtr get_plan_for_recalc(Oid matviewOid, List *namelist, List *keys, Oid *keyTypes);
+static SPIPlanPtr get_plan_for_set_values(Oid matviewOid, char *matviewname, List *namelist,
+ Oid *valTypes);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
static void mv_InitHashTables(void);
+static SPIPlanPtr mv_FetchPreparedPlan(MV_QueryKey *key);
+static void mv_HashPreparedPlan(MV_QueryKey *key, SPIPlanPtr plan);
+static void mv_BuildQueryKey(MV_QueryKey *key, Oid matview_id, int32 query_type);
static void clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort);
/*
@@ -2122,6 +2167,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
ListCell *lc;
int i;
List *keys = NIL;
+ List *minmax_list = NIL;
+ List *is_min_list = NIL;
/*
@@ -2203,6 +2250,17 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
append_set_clause_for_avg(resname, aggs_set_old, aggs_set_new, aggs_list_buf,
format_type_be(aggref->aggtype));
+ /* min/max */
+ else if (!strcmp(aggname, "min") || !strcmp(aggname, "max"))
+ {
+ bool is_min = (!strcmp(aggname, "min"));
+
+ append_set_clause_for_minmax(resname, aggs_set_old, aggs_set_new, aggs_list_buf, is_min);
+
+ /* make a resname list of min and max aggregates */
+ minmax_list = lappend(minmax_list, resname);
+ is_min_list = lappend_int(is_min_list, is_min);
+ }
else
elog(ERROR, "unsupported aggregate function: %s", aggname);
}
@@ -2232,6 +2290,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
{
EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ SPITupleTable *tuptable_recalc = NULL;
+ uint64 num_recalc;
int rc;
/* convert tuplestores to ENR, and register for SPI */
@@ -2250,10 +2310,18 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
/* apply old delta and get rows to be recalculated */
apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
keys, aggs_list_buf, aggs_set_old,
- count_colname);
+ minmax_list, is_min_list,
+ count_colname, &tuptable_recalc, &num_recalc);
else
apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+ /*
+ * If we have min or max, we might have to recalculate aggregate values from base tables
+ * on some tuples. TIDs and keys such tuples are returned as a result of the above query.
+ */
+ if (minmax_list && tuptable_recalc)
+ recalc_and_set_values(tuptable_recalc, num_recalc, minmax_list, keys, matviewRel);
+
}
/* For tuple insertion */
if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
@@ -2445,6 +2513,70 @@ append_set_clause_for_avg(const char *resname, StringInfo buf_old,
);
}
+/*
+ * append_set_clause_for_minmax
+ *
+ * Append SET clause string for min or max aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ * is_min is true if this is min, false if not.
+ */
+static void
+append_set_clause_for_minmax(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ bool is_min)
+{
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /*
+ * If the new value doesn't became NULL then use the value remaining
+ * in the view although this will be recomputated afterwords.
+ */
+ appendStringInfo(buf_old,
+ ", %s = CASE WHEN %s THEN NULL ELSE %s END",
+ quote_qualified_identifier(NULL, resname),
+ get_null_condition_string(IVM_SUB, "mv", "t", count_col),
+ quote_qualified_identifier("mv", resname)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /*
+ * min = LEAST(mv.min, diff.min)
+ * max = GREATEST(mv.max, diff.max)
+ */
+ appendStringInfo(buf_new,
+ ", %s = CASE WHEN %s THEN NULL ELSE %s(%s,%s) END",
+ quote_qualified_identifier(NULL, resname),
+ get_null_condition_string(IVM_ADD, "mv", "diff", count_col),
+
+ is_min ? "LEAST" : "GREATEST",
+ quote_qualified_identifier("mv", resname),
+ quote_qualified_identifier("diff", resname)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
/*
* get_operation_string
*
@@ -2547,19 +2679,44 @@ get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
* list to identify a tuple in the view. If the view has aggregates, this
* requires strings representing resnames of aggregates and SET clause for
* updating aggregate values.
+ *
+ * If the view has min or max aggregate, this requires a list of resnames of
+ * min/max aggregates and a list of boolean which represents which entries in
+ * minmax_list is min. These are necessary to check if we need to recalculate
+ * min or max aggregate values. In this case, this query returns TID and keys
+ * of tuples which need to be recalculated. This result and the number of rows
+ * are stored in tuptables and num_recalc repectedly.
+ *
*/
static void
apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
List *keys, StringInfo aggs_list, StringInfo aggs_set,
- const char *count_colname)
+ List *minmax_list, List *is_min_list,
+ const char *count_colname,
+ SPITupleTable **tuptable_recalc, uint64 *num_recalc)
{
StringInfoData querybuf;
char *match_cond;
+ char *updt_returning = "";
+ char *select_for_recalc = "SELECT";
bool agg_without_groupby = (list_length(keys) == 0);
+ Assert(tuptable_recalc != NULL);
+ Assert(num_recalc != NULL);
+
/* build WHERE condition for searching tuples to be deleted */
match_cond = get_matching_condition_string(keys);
+ /*
+ * We need a special RETURNING clause and SELECT statement for min/max to
+ * check which tuple needs re-calculation from base tables.
+ */
+ if (minmax_list)
+ {
+ updt_returning = get_returning_string(minmax_list, is_min_list, keys);
+ select_for_recalc = get_select_for_recalc_string(keys);
+ }
+
/* Search for matching tuples from the view and update or delete if found. */
initStringInfo(&querybuf);
appendStringInfo(&querybuf,
@@ -2574,10 +2731,11 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
"%s" /* SET clauses for aggregates */
"FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
- ")"
- /* delete a tuple if this is to be deleted */
- "DELETE FROM %s AS mv USING t "
- "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
+ "%s" /* RETURNING clause for recalc infomation */
+ "), dlt AS (" /* delete a tuple if this is to be deleted */
+ "DELETE FROM %s AS mv USING t "
+ "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt"
+ ") %s", /* SELECT returning which tuples need to be recalculated */
count_colname,
count_colname, count_colname, (agg_without_groupby ? "false" : "true"),
(aggs_list != NULL ? aggs_list->data : ""),
@@ -2585,10 +2743,25 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
match_cond,
matviewname, count_colname, count_colname, count_colname,
(aggs_set != NULL ? aggs_set->data : ""),
- matviewname);
+ updt_returning,
+ matviewname,
+ select_for_recalc);
- if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_SELECT)
elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+
+
+ /* Return tuples to be recalculated. */
+ if (minmax_list)
+ {
+ *tuptable_recalc = SPI_tuptable;
+ *num_recalc = SPI_processed;
+ }
+ else
+ {
+ *tuptable_recalc = NULL;
+ *num_recalc = 0;
+ }
}
/*
@@ -2771,6 +2944,349 @@ get_matching_condition_string(List *keys)
return match_cond.data;
}
+/*
+ * get_returning_string
+ *
+ * Build a string for RETURNING clause of UPDATE used in apply_old_delta_with_count.
+ * This clause returns ctid and a boolean value that indicates if we need to
+ * recalculate min or max value, for each updated row.
+ */
+static char *
+get_returning_string(List *minmax_list, List *is_min_list, List *keys)
+{
+ StringInfoData returning;
+ char *recalc_cond;
+ ListCell *lc;
+
+ Assert(minmax_list != NIL && is_min_list != NIL);
+ recalc_cond = get_minmax_recalc_condition_string(minmax_list, is_min_list);
+
+ initStringInfo(&returning);
+
+ appendStringInfo(&returning, "RETURNING mv.ctid AS tid, (%s) AS recalc", recalc_cond);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&returning, ", %s", quote_qualified_identifier("mv", resname));
+ }
+
+ return returning.data;
+}
+
+/*
+ * get_minmax_recalc_condition_string
+ *
+ * Build a predicate string for checking if any min/max aggregate
+ * value needs to be recalculated.
+ */
+static char *
+get_minmax_recalc_condition_string(List *minmax_list, List *is_min_list)
+{
+ StringInfoData recalc_cond;
+ ListCell *lc1, *lc2;
+
+ initStringInfo(&recalc_cond);
+
+ Assert (list_length(minmax_list) == list_length(is_min_list));
+
+ forboth (lc1, minmax_list, lc2, is_min_list)
+ {
+ char *resname = (char *) lfirst(lc1);
+ bool is_min = (bool) lfirst_int(lc2);
+ char *op_str = (is_min ? ">=" : "<=");
+
+ appendStringInfo(&recalc_cond, "%s OPERATOR(pg_catalog.%s) %s",
+ quote_qualified_identifier("mv", resname),
+ op_str,
+ quote_qualified_identifier("t", resname)
+ );
+
+ if (lnext(minmax_list, lc1))
+ appendStringInfo(&recalc_cond, " OR ");
+ }
+
+ return recalc_cond.data;
+}
+
+/*
+ * get_select_for_recalc_string
+ *
+ * Build a query to return tid and keys of tuples which need
+ * recalculation. This is used as the result of the query
+ * built by apply_old_delta.
+ */
+static char *
+get_select_for_recalc_string(List *keys)
+{
+ StringInfoData qry;
+ ListCell *lc;
+
+ initStringInfo(&qry);
+
+ appendStringInfo(&qry, "SELECT tid");
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ appendStringInfo(&qry, ", %s", NameStr(attr->attname));
+ }
+
+ appendStringInfo(&qry, " FROM updt WHERE recalc");
+
+ return qry.data;
+}
+
+/*
+ * recalc_and_set_values
+ *
+ * Recalculate tuples in a materialized from base tables and update these.
+ * The tuples which needs recalculation are specified by keys, and resnames
+ * of columns to be updated are specified by namelist. TIDs and key values
+ * are given by tuples in tuptable_recalc. Its first attribute must be TID
+ * and key values must be following this.
+ */
+static void
+recalc_and_set_values(SPITupleTable *tuptable_recalc, int64 num_tuples,
+ List *namelist, List *keys, Relation matviewRel)
+{
+ TupleDesc tupdesc_recalc = tuptable_recalc->tupdesc;
+ Oid *keyTypes = NULL, *types = NULL;
+ char *keyNulls = NULL, *nulls = NULL;
+ Datum *keyVals = NULL, *vals = NULL;
+ int num_vals = list_length(namelist);
+ int num_keys = list_length(keys);
+ uint64 i;
+ Oid matviewOid;
+ char *matviewname;
+
+ matviewOid = RelationGetRelid(matviewRel);
+ matviewname = quote_qualified_identifier(get_namespace_name(RelationGetNamespace(matviewRel)),
+ RelationGetRelationName(matviewRel));
+
+ /* If we have keys, initialize arrays for them. */
+ if (keys)
+ {
+ keyTypes = palloc(sizeof(Oid) * num_keys);
+ keyNulls = palloc(sizeof(char) * num_keys);
+ keyVals = palloc(sizeof(Datum) * num_keys);
+ /* a tuple contains keys to be recalculated and ctid to be updated*/
+ Assert(tupdesc_recalc->natts == num_keys + 1);
+
+ /* Types of key attributes */
+ for (i = 0; i < num_keys; i++)
+ keyTypes[i] = TupleDescAttr(tupdesc_recalc, i + 1)->atttypid;
+ }
+
+ /* allocate memory for all attribute names and tid */
+ types = palloc(sizeof(Oid) * (num_vals + 1));
+ nulls = palloc(sizeof(char) * (num_vals + 1));
+ vals = palloc(sizeof(Datum) * (num_vals + 1));
+
+ /* For each tuple which needs recalculation */
+ for (i = 0; i < num_tuples; i++)
+ {
+ int j;
+ bool isnull;
+ SPIPlanPtr plan;
+ SPITupleTable *tuptable_newvals;
+ TupleDesc tupdesc_newvals;
+
+ /* Set group key values as parameters if needed. */
+ if (keys)
+ {
+ for (j = 0; j < num_keys; j++)
+ {
+ keyVals[j] = SPI_getbinval(tuptable_recalc->vals[i], tupdesc_recalc, j + 2, &isnull);
+ if (isnull)
+ keyNulls[j] = 'n';
+ else
+ keyNulls[j] = ' ';
+ }
+ }
+
+ /*
+ * Get recalculated values from base tables. The result must be
+ * only one tuple thich contains the new values for specified keys.
+ */
+ plan = get_plan_for_recalc(matviewOid, namelist, keys, keyTypes);
+ if (SPI_execute_plan(plan, keyVals, keyNulls, false, 0) != SPI_OK_SELECT)
+ elog(ERROR, "SPI_execute_plan");
+ if (SPI_processed != 1)
+ elog(ERROR, "SPI_execute_plan returned zero or more than one rows");
+
+ tuptable_newvals = SPI_tuptable;
+ tupdesc_newvals = tuptable_newvals->tupdesc;
+
+ Assert(tupdesc_newvals->natts == num_vals);
+
+ /* Set the new values as parameters */
+ for (j = 0; j < tupdesc_newvals->natts; j++)
+ {
+ if (i == 0)
+ types[j] = TupleDescAttr(tupdesc_newvals, j)->atttypid;
+
+ vals[j] = SPI_getbinval(tuptable_newvals->vals[0], tupdesc_newvals, j + 1, &isnull);
+ if (isnull)
+ nulls[j] = 'n';
+ else
+ nulls[j] = ' ';
+ }
+ /* Set TID of the view tuple to be updated as a parameter */
+ types[j] = TIDOID;
+ vals[j] = SPI_getbinval(tuptable_recalc->vals[i], tupdesc_recalc, 1, &isnull);
+ nulls[j] = ' ';
+
+ /* Update the view tuple to the new values */
+ plan = get_plan_for_set_values(matviewOid, matviewname, namelist, types);
+ if (SPI_execute_plan(plan, vals, nulls, false, 0) != SPI_OK_UPDATE)
+ elog(ERROR, "SPI_execute_plan");
+ }
+}
+
+
+/*
+ * get_plan_for_recalc
+ *
+ * Create or fetch a plan for recalculating value in the view's target list
+ * from base tables using the definition query of materialized view specified
+ * by matviewOid. namelist is a list of resnames of values to be recalculated.
+ *
+ * keys is a list of keys to identify tuples to be recalculated if this is not
+ * empty. KeyTypes is an array of types of keys.
+ */
+static SPIPlanPtr
+get_plan_for_recalc(Oid matviewOid, List *namelist, List *keys, Oid *keyTypes)
+{
+ MV_QueryKey hash_key;
+ SPIPlanPtr plan;
+
+ /* Fetch or prepare a saved plan for the recalculation */
+ mv_BuildQueryKey(&hash_key, matviewOid, MV_PLAN_RECALC);
+ if ((plan = mv_FetchPreparedPlan(&hash_key)) == NULL)
+ {
+ ListCell *lc;
+ StringInfoData str;
+ char *viewdef;
+
+ /* get view definition of matview */
+ viewdef = text_to_cstring((text *) DatumGetPointer(
+ DirectFunctionCall1(pg_get_viewdef, ObjectIdGetDatum(matviewOid))));
+ /* get rid of trailing semi-colon */
+ viewdef[strlen(viewdef)-1] = '\0';
+
+ /*
+ * Build a query string for recalculating values. This is like
+ *
+ * SELECT x1, x2, x3, ... FROM ( ... view definition query ...) mv
+ * WHERE (key1, key2, ...) = ($1, $2, ...);
+ */
+
+ initStringInfo(&str);
+ appendStringInfo(&str, "SELECT ");
+ foreach (lc, namelist)
+ {
+ appendStringInfo(&str, "%s", (char *) lfirst(lc));
+ if (lnext(namelist, lc))
+ appendStringInfoString(&str, ", ");
+ }
+ appendStringInfo(&str, " FROM (%s) mv", viewdef);
+
+ if (keys)
+ {
+ int i = 1;
+ char paramname[16];
+
+ appendStringInfo(&str, " WHERE (");
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ Oid typid = attr->atttypid;
+
+ sprintf(paramname, "$%d", i);
+ appendStringInfo(&str, "(");
+ generate_equal(&str, typid, resname, paramname);
+ appendStringInfo(&str, " OR (%s IS NULL AND %s IS NULL))",
+ resname, paramname);
+
+ if (lnext(keys, lc))
+ appendStringInfoString(&str, " AND ");
+ i++;
+ }
+ appendStringInfo(&str, ")");
+ }
+ else
+ keyTypes = NULL;
+
+ plan = SPI_prepare(str.data, list_length(keys), keyTypes);
+ if (plan == NULL)
+ elog(ERROR, "SPI_prepare returned %s for %s", SPI_result_code_string(SPI_result), str.data);
+
+ SPI_keepplan(plan);
+ mv_HashPreparedPlan(&hash_key, plan);
+ }
+
+ return plan;
+}
+
+/*
+ * get_plan_for_set_values
+ *
+ * Create or fetch a plan for applying new values calculated by
+ * get_plan_for_recalc to a materialized view specified by matviewOid.
+ * matviewname is the name of the view. namelist is a list of resnames
+ * of attributes to be updated, and valTypes is an array of types of the
+ * values.
+ */
+static SPIPlanPtr
+get_plan_for_set_values(Oid matviewOid, char *matviewname, List *namelist,
+ Oid *valTypes)
+{
+ MV_QueryKey key;
+ SPIPlanPtr plan;
+
+ /* Fetch or prepare a saved plan for the real check */
+ mv_BuildQueryKey(&key, matviewOid, MV_PLAN_SET_VALUE);
+ if ((plan = mv_FetchPreparedPlan(&key)) == NULL)
+ {
+ ListCell *lc;
+ StringInfoData str;
+ int i;
+
+ /*
+ * Build a query string for applying min/max values. This is like
+ *
+ * UPDATE matviewname AS mv
+ * SET (x1, x2, x3, x4) = ($1, $2, $3, $4)
+ * WHERE ctid = $5;
+ */
+
+ initStringInfo(&str);
+ appendStringInfo(&str, "UPDATE %s AS mv SET (", matviewname);
+ foreach (lc, namelist)
+ {
+ appendStringInfo(&str, "%s", (char *) lfirst(lc));
+ if (lnext(namelist, lc))
+ appendStringInfoString(&str, ", ");
+ }
+ appendStringInfo(&str, ") = ROW(");
+
+ for (i = 1; i <= list_length(namelist); i++)
+ appendStringInfo(&str, "%s$%d", (i==1 ? "" : ", "), i);
+
+ appendStringInfo(&str, ") WHERE ctid OPERATOR(pg_catalog.=) $%d", i);
+
+ plan = SPI_prepare(str.data, list_length(namelist) + 1, valTypes);
+ if (plan == NULL)
+ elog(ERROR, "SPI_prepare returned %s for %s", SPI_result_code_string(SPI_result), str.data);
+
+ SPI_keepplan(plan);
+ mv_HashPreparedPlan(&key, plan);
+ }
+
+ return plan;
+}
+
/*
* generate_equals
*
@@ -2804,6 +3320,13 @@ mv_InitHashTables(void)
{
HASHCTL ctl;
+ memset(&ctl, 0, sizeof(ctl));
+ ctl.keysize = sizeof(MV_QueryKey);
+ ctl.entrysize = sizeof(MV_QueryHashEntry);
+ mv_query_cache = hash_create("MV query cache",
+ MV_INIT_QUERYHASHSIZE,
+ &ctl, HASH_ELEM | HASH_BLOBS);
+
memset(&ctl, 0, sizeof(ctl));
ctl.keysize = sizeof(Oid);
ctl.entrysize = sizeof(MV_TriggerHashEntry);
@@ -2812,6 +3335,109 @@ mv_InitHashTables(void)
&ctl, HASH_ELEM | HASH_BLOBS);
}
+/*
+ * mv_FetchPreparedPlan
+ */
+static SPIPlanPtr
+mv_FetchPreparedPlan(MV_QueryKey *key)
+{
+ MV_QueryHashEntry *entry;
+ SPIPlanPtr plan;
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_query_cache)
+ mv_InitHashTables();
+
+ /*
+ * Lookup for the key
+ */
+ entry = (MV_QueryHashEntry *) hash_search(mv_query_cache,
+ (void *) key,
+ HASH_FIND, NULL);
+ if (entry == NULL)
+ return NULL;
+
+ /*
+ * Check whether the plan is still valid. If it isn't, we don't want to
+ * simply rely on plancache.c to regenerate it; rather we should start
+ * from scratch and rebuild the query text too. This is to cover cases
+ * such as table/column renames. We depend on the plancache machinery to
+ * detect possible invalidations, though.
+ *
+ * CAUTION: this check is only trustworthy if the caller has already
+ * locked both materialized views and base tables.
+ *
+ * Also, check whether the search_path is still the same as when we made it.
+ * If it isn't, we need to rebuild the query text because the result of
+ * pg_ivm_get_viewdef() will change.
+ */
+ plan = entry->plan;
+ if (plan && SPI_plan_is_valid(plan) &&
+ SearchPathMatchesCurrentEnvironment(entry->search_path))
+ return plan;
+
+ /*
+ * Otherwise we might as well flush the cached plan now, to free a little
+ * memory space before we make a new one.
+ */
+ if (plan)
+ SPI_freeplan(plan);
+ if (entry->search_path)
+ pfree(entry->search_path);
+
+ entry->plan = NULL;
+ entry->search_path = NULL;
+
+ return NULL;
+}
+
+/*
+ * mv_HashPreparedPlan
+ *
+ * Add another plan to our private SPI query plan hashtable.
+ */
+static void
+mv_HashPreparedPlan(MV_QueryKey *key, SPIPlanPtr plan)
+{
+ MV_QueryHashEntry *entry;
+ bool found;
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_query_cache)
+ mv_InitHashTables();
+
+ /*
+ * Add the new plan. We might be overwriting an entry previously found
+ * invalid by mv_FetchPreparedPlan.
+ */
+ entry = (MV_QueryHashEntry *) hash_search(mv_query_cache,
+ (void *) key,
+ HASH_ENTER, &found);
+ Assert(!found || entry->plan == NULL);
+ entry->plan = plan;
+ entry->search_path = GetSearchPathMatcher(TopMemoryContext);
+}
+
+/*
+ * mv_BuildQueryKey
+ *
+ * Construct a hashtable key for a prepared SPI plan for IVM.
+ */
+static void
+mv_BuildQueryKey(MV_QueryKey *key, Oid matview_id, int32 query_type)
+{
+ /*
+ * We assume struct MV_QueryKey contains no padding bytes, else we'd need
+ * to use memset to clear them.
+ */
+ key->matview_id = matview_id;
+ key->query_type = query_type;
+}
+
/*
* AtAbort_IVM
*
--
2.25.1
v31-0010-Add-regression-tests-for-Incremental-View-Mainte.patchtext/x-diff; name=v31-0010-Add-regression-tests-for-Incremental-View-Mainte.patchDownload
From af767263ad558d47e9fefa587ebc368caa81f8f4 Mon Sep 17 00:00:00 2001
From: Takuma Hoshiai <takuma.hoshiai@gmail.com>
Date: Wed, 10 Mar 2021 11:11:13 +0900
Subject: [PATCH v31 10/11] Add regression tests for Incremental View
Maintenance
---
.../regress/expected/incremental_matview.out | 1030 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/incremental_matview.sql | 533 +++++++++
3 files changed, 1564 insertions(+), 1 deletion(-)
create mode 100644 src/test/regress/expected/incremental_matview.out
create mode 100644 src/test/regress/sql/incremental_matview.sql
diff --git a/src/test/regress/expected/incremental_matview.out b/src/test/regress/expected/incremental_matview.out
new file mode 100644
index 0000000000..8946d09f5d
--- /dev/null
+++ b/src/test/regress/expected/incremental_matview.out
@@ -0,0 +1,1030 @@
+-- create a table to use as a basis for views and materialized views in various combinations
+CREATE TABLE mv_base_a (i int, j int);
+INSERT INTO mv_base_a VALUES
+ (1,10),
+ (2,20),
+ (3,30),
+ (4,40),
+ (5,50);
+CREATE TABLE mv_base_b (i int, k int);
+INSERT INTO mv_base_b VALUES
+ (1,101),
+ (2,102),
+ (3,103),
+ (4,104);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_1 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) WITH NO DATA;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ERROR: materialized view "mv_ivm_1" has not been populated
+HINT: Use the REFRESH MATERIALIZED VIEW command.
+REFRESH MATERIALIZED VIEW mv_ivm_1;
+NOTICE: could not create an index on materialized view "mv_ivm_1" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+-- REFRESH WITH NO DATA
+BEGIN;
+CREATE FUNCTION dummy_ivm_trigger_func() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+CREATE CONSTRAINT TRIGGER dummy_ivm_trigger AFTER INSERT
+ON mv_base_a FROM mv_ivm_1 FOR EACH ROW
+EXECUTE PROCEDURE dummy_ivm_trigger_func();
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ count
+-------
+ 17
+(1 row)
+
+REFRESH MATERIALIZED VIEW mv_ivm_1 WITH NO DATA;
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+-- immediate maintenance
+BEGIN;
+INSERT INTO mv_base_b VALUES(5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+ 5 | 50 | 105
+(5 rows)
+
+UPDATE mv_base_a SET j = 0 WHERE i = 1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 0 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+ 5 | 50 | 105
+(5 rows)
+
+DELETE FROM mv_base_b WHERE (i,k) = (5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 0 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+ROLLBACK;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+-- rename of IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS SELECT DISTINCT * FROM mv_base_a;
+NOTICE: created index "mv_ivm_rename_index" on materialized view "mv_ivm_rename"
+ALTER MATERIALIZED VIEW mv_ivm_rename RENAME COLUMN __ivm_count__ TO xxx;
+ERROR: IVM column can not be renamed
+DROP MATERIALIZED VIEW mv_ivm_rename;
+-- unique index on IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_unique AS SELECT DISTINCT * FROM mv_base_a;
+NOTICE: created index "mv_ivm_unique_index" on materialized view "mv_ivm_unique"
+CREATE UNIQUE INDEX ON mv_ivm_unique(__ivm_count__);
+ERROR: unique index creation on IVM columns is not supported
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__));
+ERROR: unique index creation on IVM columns is not supported
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__ + 1));
+ERROR: unique index creation on IVM columns is not supported
+DROP MATERIALIZED VIEW mv_ivm_unique;
+-- TRUNCATE a base table in join views
+BEGIN;
+TRUNCATE mv_base_a;
+SELECT * FROM mv_ivm_1;
+ i | j | k
+---+---+---
+(0 rows)
+
+ROLLBACK;
+BEGIN;
+TRUNCATE mv_base_b;
+SELECT * FROM mv_ivm_1;
+ i | j | k
+---+---+---
+(0 rows)
+
+ROLLBACK;
+-- some query syntax
+BEGIN;
+CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql'
+ AS 'SELECT 1' IMMUTABLE;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_func AS SELECT * FROM ivm_func();
+NOTICE: could not create an index on materialized view "mv_ivm_func" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_no_tbl AS SELECT 1;
+NOTICE: could not create an index on materialized view "mv_ivm_no_tbl" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+ROLLBACK;
+-- result of materialized view have DISTINCT clause or the duplicate result.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_duplicate AS SELECT j FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_duplicate" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_distinct AS SELECT DISTINCT j FROM mv_base_a;
+NOTICE: created index "mv_ivm_distinct_index" on materialized view "mv_ivm_distinct"
+INSERT INTO mv_base_a VALUES(6,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 20
+ 30
+ 40
+ 50
+(6 rows)
+
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+ROLLBACK;
+-- support SUM(), COUNT() and AVG() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 120 | 2 | 60.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+UPDATE mv_base_a SET j = 200 WHERE (i,j) = (2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+----------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 220 | 2 | 110.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (2,200);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+ROLLBACK;
+-- support COUNT(*) aggregate function
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ i | sum | count
+---+-----+-------
+ 1 | 10 | 1
+ 2 | 20 | 1
+ 3 | 30 | 1
+ 4 | 40 | 1
+ 5 | 50 | 1
+(5 rows)
+
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ i | sum | count
+---+-----+-------
+ 1 | 10 | 1
+ 2 | 120 | 2
+ 3 | 30 | 1
+ 4 | 40 | 1
+ 5 | 50 | 1
+(5 rows)
+
+ROLLBACK;
+-- TRUNCATE a base table in aggregate views
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+TRUNCATE mv_base_a;
+SELECT sum, count FROM mv_ivm_agg;
+ sum | count
+-----+-------
+(0 rows)
+
+SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+ i | sum | count
+---+-----+-------
+(0 rows)
+
+ROLLBACK;
+-- support aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_group" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+---------------------
+ 150 | 5 | 30.0000000000000000
+(1 row)
+
+INSERT INTO mv_base_a VALUES(6,60);
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+---------------------
+ 210 | 6 | 35.0000000000000000
+(1 row)
+
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+ROLLBACK;
+-- TRUNCATE a base table in aggregate views without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_group" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+TRUNCATE mv_base_a;
+SELECT sum, count, avg FROM mv_ivm_group;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+ROLLBACK;
+-- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_avg_bug AS SELECT i, SUM(j), COUNT(j), AVG(j) FROM mv_base_A GROUP BY i;
+NOTICE: created index "mv_ivm_avg_bug_index" on materialized view "mv_ivm_avg_bug"
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+INSERT INTO mv_base_a VALUES
+ (1,0),
+ (1,0),
+ (2,30),
+ (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 3 | 3.3333333333333333
+ 2 | 80 | 3 | 26.6666666666666667
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (1,0);
+DELETE FROM mv_base_a WHERE (i,j) = (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+ROLLBACK;
+-- support MIN(), MAX() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_min_max_index" on materialized view "mv_ivm_min_max"
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 10 | 10
+ 2 | 20 | 20
+ 3 | 30 | 30
+ 4 | 40 | 40
+ 5 | 50 | 50
+(5 rows)
+
+INSERT INTO mv_base_a VALUES
+ (1,11), (1,12),
+ (2,21), (2,22),
+ (3,31), (3,32),
+ (4,41), (4,42),
+ (5,51), (5,52);
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 10 | 12
+ 2 | 20 | 22
+ 3 | 30 | 32
+ 4 | 40 | 42
+ 5 | 50 | 52
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) IN ((1,10), (2,21), (3,32));
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 11 | 12
+ 2 | 20 | 22
+ 3 | 30 | 31
+ 4 | 40 | 42
+ 5 | 50 | 52
+(5 rows)
+
+ROLLBACK;
+-- support MIN(), MAX() aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT MIN(j), MAX(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_min_max" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 10 | 50
+(1 row)
+
+INSERT INTO mv_base_a VALUES
+ (0,0), (6,60), (7,70);
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 0 | 70
+(1 row)
+
+DELETE FROM mv_base_a WHERE (i,j) IN ((0,0), (7,70));
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 10 | 60
+(1 row)
+
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ |
+(1 row)
+
+ROLLBACK;
+-- Test MIN/MAX after search_path change
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min AS SELECT MIN(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_min" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 10
+(1 row)
+
+CREATE SCHEMA myschema;
+GRANT ALL ON SCHEMA myschema TO public;
+CREATE TABLE myschema.mv_base_a (j int);
+INSERT INTO myschema.mv_base_a VALUES (1);
+DELETE FROM mv_base_a WHERE (i,j) = (1,10);
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 20
+(1 row)
+
+SET search_path TO myschema,public,pg_catalog;
+DELETE FROM public.mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 30
+(1 row)
+
+ROLLBACK;
+-- aggregate views with column names specified
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ a | sum
+---+------
+ 1 | 110
+ 2 | 2200
+ 3 | 300
+ 4 | 40
+ 5 | 50
+(5 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ a | b
+---+------
+ 1 | 110
+ 2 | 2200
+ 3 | 300
+ 4 | 40
+ 5 | 50
+(5 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b,c) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+ERROR: too many column names were specified
+ROLLBACK;
+-- support self join view and multiple change on the same table
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_self(v1, v2) AS
+ SELECT t1.v, t2.v FROM base_t AS t1 JOIN base_t AS t2 ON t1.i = t2.i;
+NOTICE: could not create an index on materialized view "mv_self" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+----+----
+ 10 | 10
+ 20 | 20
+ 30 | 30
+(3 rows)
+
+INSERT INTO base_t VALUES (4,40);
+DELETE FROM base_t WHERE i = 1;
+UPDATE base_t SET v = v*10 WHERE i=2;
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+-----+-----
+ 30 | 30
+ 40 | 40
+ 200 | 200
+(3 rows)
+
+WITH
+ ins_t1 AS (INSERT INTO base_t VALUES (5,50) RETURNING 1),
+ ins_t2 AS (INSERT INTO base_t VALUES (6,60) RETURNING 1),
+ upd_t AS (UPDATE base_t SET v = v + 100 RETURNING 1),
+ dlt_t AS (DELETE FROM base_t WHERE i IN (4,5) RETURNING 1)
+SELECT NULL;
+ ?column?
+----------
+
+(1 row)
+
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+-----+-----
+ 50 | 50
+ 60 | 60
+ 130 | 130
+ 300 | 300
+(4 rows)
+
+--- with sub-transactions
+SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,70);
+RELEASE SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,77);
+SELECT * FROM mv_self ORDER BY v1, v2;
+ v1 | v2
+-----+-----
+ 50 | 50
+ 60 | 60
+ 70 | 70
+ 70 | 77
+ 77 | 70
+ 77 | 77
+ 130 | 130
+ 300 | 300
+(8 rows)
+
+ROLLBACK;
+-- support simultaneous table changes
+BEGIN;
+CREATE TABLE base_r (i int, v int);
+CREATE TABLE base_s (i int, v int);
+INSERT INTO base_r VALUES (1, 10), (2, 20), (3, 30);
+INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300);
+CREATE INCREMENTAL MATERIALIZED VIEW mv(v1, v2) AS
+ SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i);
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY v1;
+ v1 | v2
+----+-----
+ 10 | 100
+ 20 | 200
+ 30 | 300
+(3 rows)
+
+WITH
+ ins_r AS (INSERT INTO base_r VALUES (1,11) RETURNING 1),
+ ins_r2 AS (INSERT INTO base_r VALUES (3,33) RETURNING 1),
+ ins_s AS (INSERT INTO base_s VALUES (2,222) RETURNING 1),
+ upd_r AS (UPDATE base_r SET v = v + 1000 WHERE i = 2 RETURNING 1),
+ dlt_s AS (DELETE FROM base_s WHERE i = 3 RETURNING 1)
+SELECT NULL;
+ ?column?
+----------
+
+(1 row)
+
+SELECT * FROM mv ORDER BY v1;
+ v1 | v2
+------+-----
+ 10 | 100
+ 11 | 100
+ 1020 | 200
+ 1020 | 222
+(4 rows)
+
+ROLLBACK;
+-- support foreign reference constraints
+BEGIN;
+CREATE TABLE ri1 (i int PRIMARY KEY);
+CREATE TABLE ri2 (i int PRIMARY KEY REFERENCES ri1(i) ON UPDATE CASCADE ON DELETE CASCADE, v int);
+INSERT INTO ri1 VALUES (1),(2),(3);
+INSERT INTO ri2 VALUES (1),(2),(3);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ri(i1, i2) AS
+ SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i);
+NOTICE: created index "mv_ri_index" on materialized view "mv_ri"
+SELECT * FROM mv_ri ORDER BY i1;
+ i1 | i2
+----+----
+ 1 | 1
+ 2 | 2
+ 3 | 3
+(3 rows)
+
+UPDATE ri1 SET i=10 where i=1;
+DELETE FROM ri1 WHERE i=2;
+SELECT * FROM mv_ri ORDER BY i2;
+ i1 | i2
+----+----
+ 3 | 3
+ 10 | 10
+(2 rows)
+
+ROLLBACK;
+-- views including NULL
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1,10),(2, NULL);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY i;
+ i | v
+---+----
+ 1 | 10
+ 2 |
+(2 rows)
+
+UPDATE base_t SET v = 20 WHERE i = 2;
+SELECT * FROM mv ORDER BY i;
+ i | v
+---+----
+ 1 | 10
+ 2 | 20
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY i;
+ i
+---
+(0 rows)
+
+INSERT INTO base_t VALUES (1),(NULL);
+SELECT * FROM mv ORDER BY i;
+ i
+---
+ 1
+
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, sum(v) FROM base_t GROUP BY i;
+NOTICE: created index "mv_index" on materialized view "mv"
+SELECT * FROM mv ORDER BY i;
+ i | sum
+---+-----
+ 1 | 30
+ | 3
+(2 rows)
+
+UPDATE base_t SET v = v * 10;
+SELECT * FROM mv ORDER BY i;
+ i | sum
+---+-----
+ 1 | 300
+ | 30
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, min(v), max(v) FROM base_t GROUP BY i;
+NOTICE: created index "mv_index" on materialized view "mv"
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 1 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 1;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 3;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 5;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 4
+(1 row)
+
+ROLLBACK;
+-- IMMV containing user defined type
+BEGIN;
+CREATE TYPE mytype;
+CREATE FUNCTION mytype_in(cstring)
+ RETURNS mytype AS 'int4in'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+NOTICE: return type mytype is only a shell
+CREATE FUNCTION mytype_out(mytype)
+ RETURNS cstring AS 'int4out'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+NOTICE: argument type mytype is only a shell
+CREATE TYPE mytype (
+ LIKE = int4,
+ INPUT = mytype_in,
+ OUTPUT = mytype_out
+);
+CREATE FUNCTION mytype_eq(mytype, mytype)
+ RETURNS bool AS 'int4eq'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_lt(mytype, mytype)
+ RETURNS bool AS 'int4lt'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_cmp(mytype, mytype)
+ RETURNS integer AS 'btint4cmp'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE OPERATOR = (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_eq);
+CREATE OPERATOR < (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_lt);
+CREATE OPERATOR CLASS mytype_ops
+ DEFAULT FOR TYPE mytype USING btree AS
+ OPERATOR 1 <,
+ OPERATOR 3 = ,
+ FUNCTION 1 mytype_cmp(mytype,mytype);
+CREATE TABLE t_mytype (x mytype);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_mytype AS
+ SELECT * FROM t_mytype;
+NOTICE: could not create an index on materialized view "mv_mytype" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+INSERT INTO t_mytype VALUES ('1'::mytype);
+SELECT * FROM mv_mytype;
+ x
+---
+ 1
+(1 row)
+
+ROLLBACK;
+-- outer join is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv(a,b) AS SELECT a.i, b.i FROM mv_base_a a LEFT JOIN mv_base_b b ON a.i=b.i;
+ERROR: OUTER JOIN is not supported on incrementally maintainable materialized view
+-- CTE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS
+ WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i;
+ERROR: CTE is not supported on incrementally maintainable materialized view
+-- contain system column
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm01 AS SELECT i,j,xmin FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT i,j,xmin::text AS x_min FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm06 AS SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+-- contain subquery
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm03 AS SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 );
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT * FROM mv_base_b) b WHERE a.i = b.i;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm05 AS SELECT i,j, (SELECT k FROM mv_base_b b WHERE a.i = b.i) FROM mv_base_a a;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+-- contain ORDER BY
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) ORDER BY i,j,k;
+ERROR: ORDER BY clause is not supported on incrementally maintainable materialized view
+-- contain HAVING
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) GROUP BY i,j,k HAVING SUM(i) > 5;
+ERROR: HAVING clause is not supported on incrementally maintainable materialized view
+-- contain view or materialized view
+CREATE VIEW b_view AS SELECT i,k FROM mv_base_b;
+CREATE MATERIALIZED VIEW b_mview AS SELECT i,k FROM mv_base_b;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT a.i,a.j FROM mv_base_a a,b_view b WHERE a.i = b.i;
+ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT a.i,a.j FROM mv_base_a a,b_mview b WHERE a.i = b.i;
+ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm09 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) b WHERE a.i = b.i;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm10 AS SELECT a.i,a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) OR a.i > 5;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+-- contain mutable functions
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+ERROR: mutable function is not supported on incrementally maintainable materialized view
+HINT: functions must be marked IMMUTABLE
+-- LIMIT/OFFSET is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm13 AS SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5;
+ERROR: LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view
+-- DISTINCT ON is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm14 AS SELECT DISTINCT ON(i) i, j FROM mv_base_a;
+ERROR: DISTINCT ON is not supported on incrementally maintainable materialized view
+-- TABLESAMPLE clause is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm15 AS SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50);
+ERROR: TABLESAMPLE clause is not supported on incrementally maintainable materialized view
+-- window functions are not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm16 AS SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a;
+ERROR: window functions are not supported on incrementally maintainable materialized view
+-- aggregate function with some options is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm17 AS SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a;
+ERROR: aggregate function with FILTER clause is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm18 AS SELECT COUNT(DISTINCT i) FROM mv_base_a;
+ERROR: aggregate function with DISTINCT arguments is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm19 AS SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a;
+ERROR: aggregate function with ORDER clause is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm20 AS SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),());
+ERROR: GROUPING SETS, ROLLUP, or CUBE clauses is not supported on incrementally maintainable materialized view
+-- inheritance parent is not supported
+BEGIN;
+CREATE TABLE parent (i int, v int);
+CREATE TABLE child_a(options text) INHERITS(parent);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm21 AS SELECT * FROM parent;
+ERROR: inheritance parent is not supported on incrementally maintainable materialized view
+ROLLBACK;
+-- UNION statement is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm22 AS SELECT i,j FROM mv_base_a UNION ALL SELECT i,k FROM mv_base_b;;
+ERROR: UNION/INTERSECT/EXCEPT statements are not supported on incrementally maintainable materialized view
+-- empty target list is not allowed with IVM
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm25 AS SELECT FROM mv_base_a;
+ERROR: empty target list is not supported on incrementally maintainable materialized view
+-- FOR UPDATE/SHARE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm26 AS SELECT i,j FROM mv_base_a FOR UPDATE;
+ERROR: FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view
+-- tartget list cannot contain ivm column that start with '__ivm'
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm28 AS SELECT i AS "__ivm_count__" FROM mv_base_a;
+ERROR: column name __ivm_count__ is not supported on incrementally maintainable materialized view
+-- expressions specified in GROUP BY must appear in the target list.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm29 AS SELECT COUNT(i) FROM mv_base_a GROUP BY i;
+ERROR: GROUP BY expression not appearing in select list is not supported on incrementally maintainable materialized view
+-- experssions containing an aggregate is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm30 AS SELECT sum(i)*0.5 FROM mv_base_a;
+ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm31 AS SELECT sum(i)/sum(j) FROM mv_base_a;
+ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view
+-- VALUES is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_only_values1 AS values(1);
+ERROR: VALUES is not supported on incrementally maintainable materialized view
+-- views containing base tables with Row Level Security
+DROP USER IF EXISTS ivm_admin;
+NOTICE: role "ivm_admin" does not exist, skipping
+DROP USER IF EXISTS ivm_user;
+NOTICE: role "ivm_user" does not exist, skipping
+CREATE USER ivm_admin;
+CREATE USER ivm_user;
+--- create a table with RLS
+SET SESSION AUTHORIZATION ivm_admin;
+CREATE TABLE rls_tbl(id int, data text, owner name);
+INSERT INTO rls_tbl VALUES
+ (1,'foo','ivm_user'),
+ (2,'bar','postgres');
+CREATE TABLE num_tbl(id int, num text);
+INSERT INTO num_tbl VALUES
+ (1,'one'),
+ (2,'two'),
+ (3,'three'),
+ (4,'four'),
+ (5,'five'),
+ (6,'six');
+--- Users can access only their own rows
+CREATE POLICY rls_tbl_policy ON rls_tbl FOR SELECT TO PUBLIC USING(owner = current_user);
+ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
+GRANT ALL on rls_tbl TO PUBLIC;
+GRANT ALL on num_tbl TO PUBLIC;
+--- create a view owned by ivm_user
+SET SESSION AUTHORIZATION ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls AS SELECT * FROM rls_tbl;
+NOTICE: could not create an index on materialized view "ivm_rls" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+------+----------
+ 1 | foo | ivm_user
+(1 row)
+
+RESET SESSION AUTHORIZATION;
+--- inserts rows owned by different users
+INSERT INTO rls_tbl VALUES
+ (3,'baz','ivm_user'),
+ (4,'qux','postgres');
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+------+----------
+ 1 | foo | ivm_user
+ 3 | baz | ivm_user
+(2 rows)
+
+--- combination of diffent kinds of commands
+WITH
+ i AS (INSERT INTO rls_tbl VALUES(5,'quux','postgres'), (6,'corge','ivm_user')),
+ u AS (UPDATE rls_tbl SET owner = 'postgres' WHERE id = 1),
+ u2 AS (UPDATE rls_tbl SET owner = 'ivm_user' WHERE id = 2)
+SELECT;
+--
+(1 row)
+
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+-------+----------
+ 2 | bar | ivm_user
+ 3 | baz | ivm_user
+ 6 | corge | ivm_user
+(3 rows)
+
+---
+SET SESSION AUTHORIZATION ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls2 AS SELECT * FROM rls_tbl JOIN num_tbl USING(id);
+NOTICE: could not create an index on materialized view "ivm_rls2" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+RESET SESSION AUTHORIZATION;
+WITH
+ x AS (UPDATE rls_tbl SET data = data || '_2' where id in (3,4)),
+ y AS (UPDATE num_tbl SET num = num || '_2' where id in (3,4))
+SELECT;
+--
+(1 row)
+
+SELECT * FROM ivm_rls2 ORDER BY 1,2,3;
+ id | data | owner | num
+----+-------+----------+---------
+ 2 | bar | ivm_user | two
+ 3 | baz_2 | ivm_user | three_2
+ 6 | corge | ivm_user | six
+(3 rows)
+
+-- automatic index creation
+CREATE TABLE base_a (i int primary key, j int);
+CREATE TABLE base_b (i int primary key, j int);
+--- group by: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx1 AS SELECT i, sum(j) FROM base_a GROUP BY i;
+NOTICE: created index "mv_idx1_index" on materialized view "mv_idx1"
+--- distinct: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx2 AS SELECT DISTINCT j FROM base_a;
+NOTICE: created index "mv_idx2_index" on materialized view "mv_idx2"
+--- with all pkey columns: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx3(i_a, i_b) AS SELECT a.i, b.i FROM base_a a, base_b b;
+NOTICE: created index "mv_idx3_index" on materialized view "mv_idx3"
+--- missing some pkey columns: no index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx4 AS SELECT j FROM base_a;
+NOTICE: could not create an index on materialized view "mv_idx4" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx5 AS SELECT a.i, b.j FROM base_a a, base_b b;
+NOTICE: could not create an index on materialized view "mv_idx5" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+-- cleanup
+DROP TABLE rls_tbl CASCADE;
+NOTICE: drop cascades to 2 other objects
+DETAIL: drop cascades to materialized view ivm_rls
+drop cascades to materialized view ivm_rls2
+DROP TABLE num_tbl CASCADE;
+DROP USER ivm_user;
+DROP USER ivm_admin;
+DROP TABLE mv_base_b CASCADE;
+NOTICE: drop cascades to 3 other objects
+DETAIL: drop cascades to materialized view mv_ivm_1
+drop cascades to view b_view
+drop cascades to materialized view b_mview
+DROP TABLE mv_base_a CASCADE;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 5ac6e871f5..64c910af65 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -78,7 +78,7 @@ test: brin_bloom brin_multi
# psql depends on create_am
# amutils depends on geometry, create_index_spgist, hash_index, brin
# ----------
-test: create_table_like alter_generic alter_operator misc async dbsize merge misc_functions sysviews tsrf tid tidscan tidrangescan collate.utf8 collate.icu.utf8 incremental_sort create_role without_overlaps
+test: create_table_like alter_generic alter_operator misc async dbsize merge misc_functions sysviews tsrf tid tidscan tidrangescan collate.utf8 collate.icu.utf8 incremental_sort create_role without_overlaps incremental_matview
# collate.linux.utf8 and collate.icu.utf8 tests cannot be run in parallel with each other
test: rules psql psql_crosstab amutils stats_ext collate.linux.utf8 collate.windows.win1252
diff --git a/src/test/regress/sql/incremental_matview.sql b/src/test/regress/sql/incremental_matview.sql
new file mode 100644
index 0000000000..82686f9324
--- /dev/null
+++ b/src/test/regress/sql/incremental_matview.sql
@@ -0,0 +1,533 @@
+-- create a table to use as a basis for views and materialized views in various combinations
+CREATE TABLE mv_base_a (i int, j int);
+INSERT INTO mv_base_a VALUES
+ (1,10),
+ (2,20),
+ (3,30),
+ (4,40),
+ (5,50);
+CREATE TABLE mv_base_b (i int, k int);
+INSERT INTO mv_base_b VALUES
+ (1,101),
+ (2,102),
+ (3,103),
+ (4,104);
+
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_1 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) WITH NO DATA;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+REFRESH MATERIALIZED VIEW mv_ivm_1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+
+-- REFRESH WITH NO DATA
+BEGIN;
+CREATE FUNCTION dummy_ivm_trigger_func() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+
+CREATE CONSTRAINT TRIGGER dummy_ivm_trigger AFTER INSERT
+ON mv_base_a FROM mv_ivm_1 FOR EACH ROW
+EXECUTE PROCEDURE dummy_ivm_trigger_func();
+
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+
+REFRESH MATERIALIZED VIEW mv_ivm_1 WITH NO DATA;
+
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ROLLBACK;
+
+-- immediate maintenance
+BEGIN;
+INSERT INTO mv_base_b VALUES(5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+UPDATE mv_base_a SET j = 0 WHERE i = 1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+DELETE FROM mv_base_b WHERE (i,k) = (5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ROLLBACK;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+
+-- rename of IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS SELECT DISTINCT * FROM mv_base_a;
+ALTER MATERIALIZED VIEW mv_ivm_rename RENAME COLUMN __ivm_count__ TO xxx;
+DROP MATERIALIZED VIEW mv_ivm_rename;
+
+-- unique index on IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_unique AS SELECT DISTINCT * FROM mv_base_a;
+CREATE UNIQUE INDEX ON mv_ivm_unique(__ivm_count__);
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__));
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__ + 1));
+DROP MATERIALIZED VIEW mv_ivm_unique;
+
+-- TRUNCATE a base table in join views
+BEGIN;
+TRUNCATE mv_base_a;
+SELECT * FROM mv_ivm_1;
+ROLLBACK;
+
+BEGIN;
+TRUNCATE mv_base_b;
+SELECT * FROM mv_ivm_1;
+ROLLBACK;
+
+-- some query syntax
+BEGIN;
+CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql'
+ AS 'SELECT 1' IMMUTABLE;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_func AS SELECT * FROM ivm_func();
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_no_tbl AS SELECT 1;
+ROLLBACK;
+
+-- result of materialized view have DISTINCT clause or the duplicate result.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_duplicate AS SELECT j FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_distinct AS SELECT DISTINCT j FROM mv_base_a;
+INSERT INTO mv_base_a VALUES(6,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+DELETE FROM mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ROLLBACK;
+
+-- support SUM(), COUNT() and AVG() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+UPDATE mv_base_a SET j = 200 WHERE (i,j) = (2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+DELETE FROM mv_base_a WHERE (i,j) = (2,200);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ROLLBACK;
+
+-- support COUNT(*) aggregate function
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ROLLBACK;
+
+-- TRUNCATE a base table in aggregate views
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+TRUNCATE mv_base_a;
+SELECT sum, count FROM mv_ivm_agg;
+SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+ROLLBACK;
+
+-- support aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+INSERT INTO mv_base_a VALUES(6,60);
+SELECT * FROM mv_ivm_group ORDER BY 1;
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ROLLBACK;
+
+-- TRUNCATE a base table in aggregate views without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+TRUNCATE mv_base_a;
+SELECT sum, count, avg FROM mv_ivm_group;
+SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+ROLLBACK;
+
+-- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_avg_bug AS SELECT i, SUM(j), COUNT(j), AVG(j) FROM mv_base_A GROUP BY i;
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES
+ (1,0),
+ (1,0),
+ (2,30),
+ (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+DELETE FROM mv_base_a WHERE (i,j) = (1,0);
+DELETE FROM mv_base_a WHERE (i,j) = (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ROLLBACK;
+
+-- support MIN(), MAX() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES
+ (1,11), (1,12),
+ (2,21), (2,22),
+ (3,31), (3,32),
+ (4,41), (4,42),
+ (5,51), (5,52);
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+DELETE FROM mv_base_a WHERE (i,j) IN ((1,10), (2,21), (3,32));
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ROLLBACK;
+
+-- support MIN(), MAX() aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT MIN(j), MAX(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+INSERT INTO mv_base_a VALUES
+ (0,0), (6,60), (7,70);
+SELECT * FROM mv_ivm_min_max;
+DELETE FROM mv_base_a WHERE (i,j) IN ((0,0), (7,70));
+SELECT * FROM mv_ivm_min_max;
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+ROLLBACK;
+
+-- Test MIN/MAX after search_path change
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min AS SELECT MIN(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_min;
+
+CREATE SCHEMA myschema;
+GRANT ALL ON SCHEMA myschema TO public;
+CREATE TABLE myschema.mv_base_a (j int);
+INSERT INTO myschema.mv_base_a VALUES (1);
+
+DELETE FROM mv_base_a WHERE (i,j) = (1,10);
+SELECT * FROM mv_ivm_min;
+
+SET search_path TO myschema,public,pg_catalog;
+DELETE FROM public.mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_min;
+ROLLBACK;
+
+-- aggregate views with column names specified
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b,c) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+ROLLBACK;
+
+-- support self join view and multiple change on the same table
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_self(v1, v2) AS
+ SELECT t1.v, t2.v FROM base_t AS t1 JOIN base_t AS t2 ON t1.i = t2.i;
+SELECT * FROM mv_self ORDER BY v1;
+INSERT INTO base_t VALUES (4,40);
+DELETE FROM base_t WHERE i = 1;
+UPDATE base_t SET v = v*10 WHERE i=2;
+SELECT * FROM mv_self ORDER BY v1;
+WITH
+ ins_t1 AS (INSERT INTO base_t VALUES (5,50) RETURNING 1),
+ ins_t2 AS (INSERT INTO base_t VALUES (6,60) RETURNING 1),
+ upd_t AS (UPDATE base_t SET v = v + 100 RETURNING 1),
+ dlt_t AS (DELETE FROM base_t WHERE i IN (4,5) RETURNING 1)
+SELECT NULL;
+SELECT * FROM mv_self ORDER BY v1;
+
+--- with sub-transactions
+SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,70);
+RELEASE SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,77);
+SELECT * FROM mv_self ORDER BY v1, v2;
+
+ROLLBACK;
+
+-- support simultaneous table changes
+BEGIN;
+CREATE TABLE base_r (i int, v int);
+CREATE TABLE base_s (i int, v int);
+INSERT INTO base_r VALUES (1, 10), (2, 20), (3, 30);
+INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300);
+CREATE INCREMENTAL MATERIALIZED VIEW mv(v1, v2) AS
+ SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i);
+SELECT * FROM mv ORDER BY v1;
+WITH
+ ins_r AS (INSERT INTO base_r VALUES (1,11) RETURNING 1),
+ ins_r2 AS (INSERT INTO base_r VALUES (3,33) RETURNING 1),
+ ins_s AS (INSERT INTO base_s VALUES (2,222) RETURNING 1),
+ upd_r AS (UPDATE base_r SET v = v + 1000 WHERE i = 2 RETURNING 1),
+ dlt_s AS (DELETE FROM base_s WHERE i = 3 RETURNING 1)
+SELECT NULL;
+SELECT * FROM mv ORDER BY v1;
+ROLLBACK;
+
+-- support foreign reference constraints
+BEGIN;
+CREATE TABLE ri1 (i int PRIMARY KEY);
+CREATE TABLE ri2 (i int PRIMARY KEY REFERENCES ri1(i) ON UPDATE CASCADE ON DELETE CASCADE, v int);
+INSERT INTO ri1 VALUES (1),(2),(3);
+INSERT INTO ri2 VALUES (1),(2),(3);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ri(i1, i2) AS
+ SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i);
+SELECT * FROM mv_ri ORDER BY i1;
+UPDATE ri1 SET i=10 where i=1;
+DELETE FROM ri1 WHERE i=2;
+SELECT * FROM mv_ri ORDER BY i2;
+ROLLBACK;
+
+-- views including NULL
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1,10),(2, NULL);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+SELECT * FROM mv ORDER BY i;
+UPDATE base_t SET v = 20 WHERE i = 2;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+SELECT * FROM mv ORDER BY i;
+INSERT INTO base_t VALUES (1),(NULL);
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, sum(v) FROM base_t GROUP BY i;
+SELECT * FROM mv ORDER BY i;
+UPDATE base_t SET v = v * 10;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, min(v), max(v) FROM base_t GROUP BY i;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 1;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 3;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 5;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+-- IMMV containing user defined type
+BEGIN;
+
+CREATE TYPE mytype;
+CREATE FUNCTION mytype_in(cstring)
+ RETURNS mytype AS 'int4in'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_out(mytype)
+ RETURNS cstring AS 'int4out'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE TYPE mytype (
+ LIKE = int4,
+ INPUT = mytype_in,
+ OUTPUT = mytype_out
+);
+
+CREATE FUNCTION mytype_eq(mytype, mytype)
+ RETURNS bool AS 'int4eq'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_lt(mytype, mytype)
+ RETURNS bool AS 'int4lt'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_cmp(mytype, mytype)
+ RETURNS integer AS 'btint4cmp'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+
+CREATE OPERATOR = (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_eq);
+CREATE OPERATOR < (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_lt);
+
+CREATE OPERATOR CLASS mytype_ops
+ DEFAULT FOR TYPE mytype USING btree AS
+ OPERATOR 1 <,
+ OPERATOR 3 = ,
+ FUNCTION 1 mytype_cmp(mytype,mytype);
+
+CREATE TABLE t_mytype (x mytype);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_mytype AS
+ SELECT * FROM t_mytype;
+INSERT INTO t_mytype VALUES ('1'::mytype);
+SELECT * FROM mv_mytype;
+
+ROLLBACK;
+
+-- outer join is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv(a,b) AS SELECT a.i, b.i FROM mv_base_a a LEFT JOIN mv_base_b b ON a.i=b.i;
+-- CTE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS
+ WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i;
+-- contain system column
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm01 AS SELECT i,j,xmin FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT i,j,xmin::text AS x_min FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm06 AS SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a;
+-- contain subquery
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm03 AS SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 );
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT * FROM mv_base_b) b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm05 AS SELECT i,j, (SELECT k FROM mv_base_b b WHERE a.i = b.i) FROM mv_base_a a;
+-- contain ORDER BY
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) ORDER BY i,j,k;
+-- contain HAVING
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) GROUP BY i,j,k HAVING SUM(i) > 5;
+
+-- contain view or materialized view
+CREATE VIEW b_view AS SELECT i,k FROM mv_base_b;
+CREATE MATERIALIZED VIEW b_mview AS SELECT i,k FROM mv_base_b;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT a.i,a.j FROM mv_base_a a,b_view b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT a.i,a.j FROM mv_base_a a,b_mview b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm09 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm10 AS SELECT a.i,a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) OR a.i > 5;
+
+-- contain mutable functions
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+
+-- LIMIT/OFFSET is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm13 AS SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5;
+
+-- DISTINCT ON is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm14 AS SELECT DISTINCT ON(i) i, j FROM mv_base_a;
+
+-- TABLESAMPLE clause is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm15 AS SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50);
+
+-- window functions are not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm16 AS SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a;
+
+-- aggregate function with some options is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm17 AS SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm18 AS SELECT COUNT(DISTINCT i) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm19 AS SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm20 AS SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),());
+
+-- inheritance parent is not supported
+BEGIN;
+CREATE TABLE parent (i int, v int);
+CREATE TABLE child_a(options text) INHERITS(parent);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm21 AS SELECT * FROM parent;
+ROLLBACK;
+
+-- UNION statement is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm22 AS SELECT i,j FROM mv_base_a UNION ALL SELECT i,k FROM mv_base_b;;
+
+-- empty target list is not allowed with IVM
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm25 AS SELECT FROM mv_base_a;
+
+-- FOR UPDATE/SHARE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm26 AS SELECT i,j FROM mv_base_a FOR UPDATE;
+
+-- tartget list cannot contain ivm column that start with '__ivm'
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm28 AS SELECT i AS "__ivm_count__" FROM mv_base_a;
+
+-- expressions specified in GROUP BY must appear in the target list.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm29 AS SELECT COUNT(i) FROM mv_base_a GROUP BY i;
+
+-- experssions containing an aggregate is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm30 AS SELECT sum(i)*0.5 FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm31 AS SELECT sum(i)/sum(j) FROM mv_base_a;
+
+-- VALUES is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_only_values1 AS values(1);
+
+-- views containing base tables with Row Level Security
+DROP USER IF EXISTS ivm_admin;
+DROP USER IF EXISTS ivm_user;
+CREATE USER ivm_admin;
+CREATE USER ivm_user;
+
+--- create a table with RLS
+SET SESSION AUTHORIZATION ivm_admin;
+CREATE TABLE rls_tbl(id int, data text, owner name);
+INSERT INTO rls_tbl VALUES
+ (1,'foo','ivm_user'),
+ (2,'bar','postgres');
+CREATE TABLE num_tbl(id int, num text);
+INSERT INTO num_tbl VALUES
+ (1,'one'),
+ (2,'two'),
+ (3,'three'),
+ (4,'four'),
+ (5,'five'),
+ (6,'six');
+
+--- Users can access only their own rows
+CREATE POLICY rls_tbl_policy ON rls_tbl FOR SELECT TO PUBLIC USING(owner = current_user);
+ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
+GRANT ALL on rls_tbl TO PUBLIC;
+GRANT ALL on num_tbl TO PUBLIC;
+
+--- create a view owned by ivm_user
+SET SESSION AUTHORIZATION ivm_user;
+
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls AS SELECT * FROM rls_tbl;
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+RESET SESSION AUTHORIZATION;
+
+--- inserts rows owned by different users
+INSERT INTO rls_tbl VALUES
+ (3,'baz','ivm_user'),
+ (4,'qux','postgres');
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+
+--- combination of diffent kinds of commands
+WITH
+ i AS (INSERT INTO rls_tbl VALUES(5,'quux','postgres'), (6,'corge','ivm_user')),
+ u AS (UPDATE rls_tbl SET owner = 'postgres' WHERE id = 1),
+ u2 AS (UPDATE rls_tbl SET owner = 'ivm_user' WHERE id = 2)
+SELECT;
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+
+---
+SET SESSION AUTHORIZATION ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls2 AS SELECT * FROM rls_tbl JOIN num_tbl USING(id);
+RESET SESSION AUTHORIZATION;
+
+WITH
+ x AS (UPDATE rls_tbl SET data = data || '_2' where id in (3,4)),
+ y AS (UPDATE num_tbl SET num = num || '_2' where id in (3,4))
+SELECT;
+SELECT * FROM ivm_rls2 ORDER BY 1,2,3;
+
+-- automatic index creation
+CREATE TABLE base_a (i int primary key, j int);
+CREATE TABLE base_b (i int primary key, j int);
+
+--- group by: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx1 AS SELECT i, sum(j) FROM base_a GROUP BY i;
+
+--- distinct: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx2 AS SELECT DISTINCT j FROM base_a;
+
+--- with all pkey columns: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx3(i_a, i_b) AS SELECT a.i, b.i FROM base_a a, base_b b;
+
+--- missing some pkey columns: no index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx4 AS SELECT j FROM base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx5 AS SELECT a.i, b.j FROM base_a a, base_b b;
+
+-- cleanup
+
+DROP TABLE rls_tbl CASCADE;
+DROP TABLE num_tbl CASCADE;
+DROP USER ivm_user;
+DROP USER ivm_admin;
+
+DROP TABLE mv_base_b CASCADE;
+DROP TABLE mv_base_a CASCADE;
--
2.25.1
v31-0011-Add-documentations-about-Incremental-View-Mainte.patchtext/x-diff; name=v31-0011-Add-documentations-about-Incremental-View-Mainte.patchDownload
From 63b74f140dc2da34e04f3f9e6afe14c19a505ee1 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:25:34 +0900
Subject: [PATCH v31 11/11] Add documentations about Incremental View
Maintenance
---
doc/src/sgml/catalogs.sgml | 9 +
.../sgml/ref/create_materialized_view.sgml | 124 ++++-
.../sgml/ref/refresh_materialized_view.sgml | 8 +-
doc/src/sgml/rules.sgml | 437 ++++++++++++++++++
doc/src/sgml/system-views.sgml | 9 +
5 files changed, 583 insertions(+), 4 deletions(-)
diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index 096ddab481..d4255f1015 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -2231,6 +2231,15 @@ SCRAM-SHA-256$<replaceable><iteration count></replaceable>:<replaceable>&l
</para></entry>
</row>
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>relisivm</structfield> <type>bool</type>
+ </para>
+ <para>
+ True if relation is incrementally maintainable materialized view
+ </para></entry>
+ </row>
+
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>relrewrite</structfield> <type>oid</type>
diff --git a/doc/src/sgml/ref/create_materialized_view.sgml b/doc/src/sgml/ref/create_materialized_view.sgml
index 0d2fea2b97..8c574062db 100644
--- a/doc/src/sgml/ref/create_materialized_view.sgml
+++ b/doc/src/sgml/ref/create_materialized_view.sgml
@@ -21,7 +21,7 @@ PostgreSQL documentation
<refsynopsisdiv>
<synopsis>
-CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
+CREATE [ INCREMENTAL ] MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
[ (<replaceable>column_name</replaceable> [, ...] ) ]
[ USING <replaceable class="parameter">method</replaceable> ]
[ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
@@ -60,6 +60,125 @@ CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
<title>Parameters</title>
<variablelist>
+ <varlistentry>
+ <term><literal>INCREMENTAL</literal></term>
+ <listitem>
+ <para>
+ If specified, some triggers are automatically created so that the rows
+ of the materialized view are immediately updated when base tables of the
+ materialized view are updated. In general, this allows faster update of
+ the materialized view at a price of slower update of the base tables
+ because the triggers will be invoked. We call this form of materialized
+ view as "Incrementally Maintainable Materialized View" (IMMV).
+ </para>
+ <para>
+ When <acronym>IMMV</acronym> is defined without using <command>WITH NO DATA</command>,
+ a unique index is created on the view automatically if possible. If the view
+ definition query has a GROUP BY clause, a unique index is created on the columns
+ of GROUP BY expressions. Also, if the view has DISTINCT clause, a unique index
+ is created on all columns in the target list. Otherwise, if the view contains all
+ primary key attritubes of its base tables in the target list, a unique index is
+ created on these attritubes. In other cases, no index is created.
+ </para>
+ <para>
+ There are restrictions of query definitions allowed to use this
+ option. The following are supported in query definitions for IMMV:
+ <itemizedlist>
+
+ <listitem>
+ <para>
+ Inner joins (including self-joins).
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Some built-in aggregate functions (count, sum, avg, min, max) without a HAVING
+ clause.
+ </para>
+ </listitem>
+ </itemizedlist>
+
+ Unsupported queries with this option include the following:
+
+ <itemizedlist>
+ <listitem>
+ <para>
+ Outer joins.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Sub-queries.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Aggregate functions other than built-in count, sum, avg, min and max.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ Aggregate functions with a HAVING clause.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ DISTINCT ON, WINDOW, VALUES, LIMIT and OFFSET clause.
+ </para>
+ </listitem>
+ </itemizedlist>
+
+ Other restrictions include:
+ <itemizedlist>
+
+ <listitem>
+ <para>
+ IMMVs must be based on simple base tables. It's not supported to
+ create them on top of views or materialized views.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ It is not supported to include system columns in an IMMV.
+ <programlisting>
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+ERROR: system column is not supported with IVM
+ </programlisting>
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Non-immutable functions are not supported.
+ <programlisting>
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+ERROR: functions in IMMV must be marked IMMUTABLE
+ </programlisting>
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ IMMVs do not support expressions that contains aggregates
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Logical replication does not support IMMVs.
+ </para>
+ </listitem>
+
+ </itemizedlist>
+
+ </para>
+ </listitem>
+ </varlistentry>
+
<varlistentry>
<term><literal>IF NOT EXISTS</literal></term>
<listitem>
@@ -155,7 +274,8 @@ CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
This clause specifies whether or not the materialized view should be
populated at creation time. If not, the materialized view will be
flagged as unscannable and cannot be queried until <command>REFRESH
- MATERIALIZED VIEW</command> is used.
+ MATERIALIZED VIEW</command> is used. Also, if the view is IMMV,
+ triggers for maintaining the view are not created.
</para>
</listitem>
</varlistentry>
diff --git a/doc/src/sgml/ref/refresh_materialized_view.sgml b/doc/src/sgml/ref/refresh_materialized_view.sgml
index 8ed43ade80..a4d729bdf0 100644
--- a/doc/src/sgml/ref/refresh_materialized_view.sgml
+++ b/doc/src/sgml/ref/refresh_materialized_view.sgml
@@ -36,9 +36,13 @@ REFRESH MATERIALIZED VIEW [ CONCURRENTLY ] <replaceable class="parameter">name</
privilege on the materialized view. The old contents are discarded. If
<literal>WITH DATA</literal> is specified (or defaults) the backing query
is executed to provide the new data, and the materialized view is left in a
- scannable state. If <literal>WITH NO DATA</literal> is specified no new
+ scannable state. If the view is an incrementally maintainable materialized
+ view (IMMV) and was 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 <literal>WITH NO DATA</literal> is specified no new
data is generated and the materialized view is left in an unscannable
- state.
+ state. If the view is IMMV, the triggers are dropped.
</para>
<para>
<literal>CONCURRENTLY</literal> and <literal>WITH NO DATA</literal> may not
diff --git a/doc/src/sgml/rules.sgml b/doc/src/sgml/rules.sgml
index 7a928bd7b9..73597ea7a5 100644
--- a/doc/src/sgml/rules.sgml
+++ b/doc/src/sgml/rules.sgml
@@ -1100,6 +1100,443 @@ SELECT word FROM words ORDER BY word <-> 'caterpiler' LIMIT 10;
</sect1>
+<sect1 id="rules-ivm">
+<title>Incremental View Maintenance</title>
+
+<indexterm zone="rules-ivm">
+ <primary>incremental view maintenance</primary>
+</indexterm>
+
+<indexterm zone="rules-ivm">
+ <primary>materialized view</primary>
+ <secondary>incremental view maintenance</secondary>
+</indexterm>
+
+<indexterm zone="rules-ivm">
+ <primary>view</primary>
+ <secondary>incremental view maintenance</secondary>
+</indexterm>
+
+<sect2 id="rules-ivm-overview">
+<title>Overview</title>
+
+<para>
+ Incremental View Maintenance (<acronym>IVM</acronym>) is a way to make
+ materialized views up-to-date in which only incremental changes are computed
+ and applied on views rather than recomputing the contents from scratch as
+ <command>REFRESH MATERIALIZED VIEW</command> does. <acronym>IVM</acronym>
+ can update materialized views more efficiently than recomputation when only
+ small parts of the view are changed.
+</para>
+
+<para>
+ There are two approaches with regard to timing of view maintenance:
+ immediate and deferred. In immediate maintenance, views are updated in the
+ same transaction that its base table is modified. In deferred maintenance,
+ views are updated after the transaction is committed, for example, when the
+ view is accessed, as a response to user command like <command>REFRESH
+ MATERIALIZED VIEW</command>, or periodically in background, and so on.
+ <productname>PostgreSQL</productname> currently implements only a kind of
+ immediate maintenance, in which materialized views are updated immediately
+ in AFTER triggers when a base table is modified.
+</para>
+
+<para>
+ To create materialized views supporting <acronym>IVM</acronym>, use the
+ <command>CREATE INCREMENTAL MATERIALIZED VIEW</command>, for example:
+<programlisting>
+CREATE <emphasis>INCREMENTAL</emphasis> MATERIALIZED VIEW mymatview AS SELECT * FROM mytab;
+</programlisting>
+ When a materialized view is created with the <literal>INCREMENTAL</literal>
+ keyword, some triggers are automatically created so that the view's contents are
+ immediately updated when its base tables are modified. We call this form
+ of materialized view an Incrementally Maintainable Materialized View
+ (<acronym>IMMV</acronym>).
+<programlisting>
+postgres=# CREATE INCREMENTAL MATERIALIZED VIEW m AS SELECT * FROM t0;
+NOTICE: could not create an index on materialized view "m" automatically
+HINT: Create an index on the materialized view for effcient incremental maintenance.
+SELECT 3
+postgres=# SELECT * FROM m;
+ i
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+postgres=# INSERT INTO t0 VALUES (4);
+INSERT 0 1
+postgres=# SELECT * FROM m; -- automatically updated
+ i
+---
+ 1
+ 2
+ 3
+ 4
+(4 rows)
+</programlisting>
+</para>
+
+<para>
+ Some <acronym>IMMV</acronym>s have hidden columns which are added
+ automatically when a materialized view is created. Their name starts
+ with <literal>__ivm_</literal> and they contain information required
+ for maintaining the <acronym>IMMV</acronym>. Such columns are not visible
+ when the <acronym>IMMV</acronym> is accessed by <literal>SELECT *</literal>
+ but are visible if the column name is explicitly specified in the target
+ list. We can also see the hidden columns in <literal>\d</literal>
+ meta-commands of <command>psql</command> commands.
+</para>
+
+<para>
+ In general, <acronym>IMMV</acronym>s allow faster updates of materialized
+ views at the price of slower updates to their base tables. Updates of
+ <acronym>IMMV</acronym> is slower because triggers will be invoked and the
+ view is updated in triggers per modification statement.
+</para>
+
+<para>
+ For example, suppose a normal materialized view defined as below:
+
+<programlisting>
+test=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm AS
+ SELECT a.aid, b.bid, a.abalance, b.bbalance
+ FROM pgbench_accounts a JOIN pgbench_branches b USING(bid);
+SELECT 10000000
+
+</programlisting>
+
+ Updating a tuple in a base table of this materialized view is rapid but the
+ <command>REFRESH MATERIALIZED VIEW</command> command on this view takes a long time:
+
+<programlisting>
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 0.990 ms
+
+test=# REFRESH MATERIALIZED VIEW mv_normal ;
+REFRESH MATERIALIZED VIEW
+Time: 33533.952 ms (00:33.534)
+</programlisting>
+</para>
+
+<para>
+ On the other hand, after creating <acronym>IMMV</acronym> with the same view
+ definition as below:
+
+<programlisting>
+test=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm AS
+ SELECT a.aid, b.bid, a.abalance, b.bbalance
+ FROM pgbench_accounts a JOIN pgbench_branches b USING(bid);
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+NOTICE: created index "mv_ivm_index" on materialized view "mv_ivm"
+</programlisting>
+
+ updating a tuple in a base table takes more than the normal view,
+ but its content is updated automatically and this is faster than the
+ <command>REFRESH MATERIALIZED VIEW</command> command.
+
+<programlisting>
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 13.068 ms
+</programlisting>
+
+</para>
+
+<para>
+ Appropriate indexes on <acronym>IMMV</acronym>s are necessary for
+ efficient <acronym>IVM</acronym> because it looks for tuples to be
+ updated in <acronym>IMMV</acronym>. If there are no indexes, it
+ will take a long time.
+</para>
+
+<para>
+ Therefore, when <acronym>IMMV</acronym> is defined, a unique index is created on the view
+ automatically if possible. If the view definition query has a GROUP BY clause, a unique
+ index is created on the columns of GROUP BY expressions. Also, if the view has DISTINCT
+ clause, a unique index is created on all columns in the target list. Otherwise, if the
+ view contains all primary key attritubes of its base tables in the target list, a unique
+ index is created on these attritubes. In other cases, no index is created.
+</para>
+
+<para>
+ In the previous example, a unique index "mv_ivm_index" is created on aid and bid
+ columns of materialized view "mv_ivm", and this enables the rapid update of the view.
+ Dropping this index make updating the view take a loger time.
+<programlisting>
+test=# DROP INDEX mv_ivm_index;
+DROP INDEX
+Time: 67.081 ms
+
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 16386.245 ms (00:16.386)
+</programlisting>
+
+</para>
+
+<para>
+ <acronym>IVM</acronym> is effective when we want to keep a materialized
+ view up-to-date and small fraction of a base table is modified
+ infrequently. Due to the overhead of immediate maintenance, <acronym>IVM</acronym>
+ 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, <acronym>IVM</acronym> is not effective and the cost of
+ maintenance can be larger than the <command>REFRESH MATERIALIZED VIEW</command>
+ command. In such situation, we can use <command>REFRESH MATERIALIZED VIEW</command>
+ and specify <literal>WITH NO DATA</literal> to disable immediate
+ maintenance before modifying a base table. After a base table modification,
+ execute the <command>REFRESH MATERIALIZED VIEW</command> (with <literal>WITH DATA</literal>)
+ command to refresh the view data and enable immediate maintenance.
+</para>
+
+</sect2>
+
+<sect2 id="rules-ivm-support">
+<title>Supported View Definitions and Restrictions</title>
+
+<para>
+ Currently, we can create <acronym>IMMV</acronym>s using inner joins, and some
+ aggregates. However, several restrictions apply to the definition of IMMV.
+</para>
+
+<sect3 id="rules-ivm-support-joins">
+<title>Joins</title>
+<para>
+ Inner joins including self-join are supported. Outer joins are not supported.
+</para>
+</sect3>
+
+<sect3 id="rules-ivm-support-aggregates">
+<title>Aggregates</title>
+<para>
+ Supported aggregate functions are <function>count</function>, <function>sum</function>,
+ <function>avg</function>, <function>min</function>, and <function>max</function>.
+ Currently, only built-in aggregate functions are supported and user defined
+ aggregates cannot be used. When a base table is modified, the new aggregated
+ values are incrementally calculated using the old aggregated values and values
+ of related hidden columns stored in <acronym>IMMV</acronym>.
+</para>
+
+<para>
+ Note that for <function>min</function> or <function>max</function>, the new values
+ could be re-calculated from base tables with regard to the affected groups when a
+ tuple containing the current minimal or maximal values are deleted from a base table.
+ Therefore, it can takes a long time to update an <acronym>IMMV</acronym> containing
+ these functions.
+</para>
+
+<para>
+ Also note that using <function>sum</function> or <function>avg</function> on
+ <type>real</type> (<type>float4</type>) type or <type>double precision</type>
+ (<type>float8</type>) type in <acronym>IMMV</acronym> is unsafe. This is
+ because aggregated values in <acronym>IMMV</acronym> can become different from
+ results calculated from base tables due to the limited precision of these types.
+ To avoid this problem, use the <type>numeric</type> type instead.
+</para>
+
+ <sect4 id="rules-ivm-restrictions-aggregates">
+ <title>Restrictions on Aggregates</title>
+ <para>
+ There are the following restrictions:
+ <itemizedlist>
+ <listitem>
+ <para>
+ If we have a <literal>GROUP BY</literal> clause, expressions specified in
+ <literal>GROUP BY</literal> must appear in the target list. This is
+ how tuples to be updated in the <acronym>IMMV</acronym> are identified.
+ These attributes are used as scan keys for searching tuples in the
+ <acronym>IMMV</acronym>, so indexes on them are required for efficient
+ <acronym>IVM</acronym>.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <literal>HAVING</literal> clause cannot be used.
+ </para>
+ </listitem>
+ </itemizedlist>
+ </para>
+ </sect4>
+</sect3>
+
+<sect3 id="rules-ivm-general-restricitons">
+<title>Other General Restrictions</title>
+<para>
+ There are other restrictions which generally apply to <acronym>IMMV</acronym>:
+ <itemizedlist>
+ <listitem>
+ <para>
+ Sub-queries cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ CTEs cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Window functions cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s must be based on simple base tables. It's not
+ supported to create them on top of views, materialized views, foreign tables, inhe.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ LIMIT and OFFSET clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s cannot contain system columns.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s cannot contain non-immutable functions.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ UNION/INTERSECT/EXCEPT clauses cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ DISTINCT ON clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ TABLESAMPLE parameter cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ inheritance parent tables cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ VALUES clause cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <literal>GROUPING SETS</literal> and <literal>FILTER</literal> clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ FOR UPDATE/SHARE cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ targetlist cannot contain columns whose name start with <literal>__ivm_</literal>.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ targetlist cannot contain expressions which contain an aggregate in it.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Logical replication is not supported, that is, even when a base table
+ at a publisher node is modified, <acronym>IMMV</acronym>s at subscriber
+ nodes are not updated.
+ </para>
+ </listitem>
+
+ </itemizedlist>
+</para>
+</sect3>
+
+</sect2>
+
+<sect2 id="rules-ivm-distinct">
+<title><literal>DISTINCT</literal></title>
+
+<para>
+ <productname>PostgreSQL</productname> supports <acronym>IMMV</acronym> with
+ <literal>DISTINCT</literal>. For example, suppose a <acronym>IMMV</acronym>
+ defined with <literal>DISTINCT</literal> on a base table containing duplicate
+ tuples. When tuples are deleted from the base table, a tuple in the view is
+ deleted if and only if the multiplicity of the tuple becomes zero. Moreover,
+ when tuples are inserted into the base table, a tuple is inserted into the
+ view only if the same tuple doesn't already exist in it.
+</para>
+
+<para>
+ Physically, an <acronym>IMMV</acronym> defined with <literal>DISTINCT</literal>
+ contains tuples after eliminating duplicates, and the multiplicity of each tuple
+ is stored in a hidden column named <literal>__ivm_count__</literal>.
+</para>
+</sect2>
+
+<sect2 id="rules-ivm-concurrent-transactions">
+<title>Concurrent Transactions</title>
+<para>
+ Suppose an <acronym>IMMV</acronym> is defined on two base tables and each
+ table was modified in different a concurrent transaction simultaneously.
+ In the transaction which was committed first, <acronym>IMMV</acronym> can
+ be updated considering only the change which happened in this transaction.
+ On the other hand, in order to update the view correctly in the transaction
+ which was committed later, we need to know the changes occurred in
+ both transactions. For this reason, <literal>ExclusiveLock</literal>
+ is held on an <acronym>IMMV</acronym> immediately after a base table is
+ modified in <literal>READ COMMITTED</literal> mode to make sure that
+ the <acronym>IMMV</acronym> is updated in the latter transaction after
+ the former transaction is committed. In <literal>REPEATABLE READ</literal>
+ or <literal>SERIALIZABLE</literal> mode, an error is raised immediately
+ if lock acquisition fails because any changes which occurred in
+ other transactions are not be visible in these modes and
+ <acronym>IMMV</acronym> cannot be updated correctly in such situations.
+ However, as an exception if the view has only one base table and
+ <command>INSERT</command> is performed on the table,
+ the lock held on thew view is <literal>RowExclusiveLock</literal>.
+</para>
+</sect2>
+
+<sect2 id="rules-ivm-rls">
+<title>Row Level Security</title>
+<para>
+ If some base tables have row level security policy, rows that are not visible
+ to the materialized view's owner are excluded from the result. In addition, such
+ rows are excluded as well when views are incrementally maintained. However, if a
+ new policy is defined or policies are changed after the materialized view was created,
+ the new policy will not be applied to the view contents. To apply the new policy,
+ you need to refresh materialized views.
+</para>
+</sect2>
+
+</sect1>
+
<sect1 id="rules-update">
<title>Rules on <command>INSERT</command>, <command>UPDATE</command>, and <command>DELETE</command></title>
diff --git a/doc/src/sgml/system-views.sgml b/doc/src/sgml/system-views.sgml
index 3c8dca8ca3..da22606213 100644
--- a/doc/src/sgml/system-views.sgml
+++ b/doc/src/sgml/system-views.sgml
@@ -1787,6 +1787,15 @@ SELECT * FROM pg_locks pl LEFT JOIN pg_prepared_xacts ppx
</para></entry>
</row>
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>isimmv</structfield> <type>bool</type>
+ </para>
+ <para>
+ True if materialized view is incrementally maintainable
+ </para></entry>
+ </row>
+
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>definition</structfield> <type>text</type>
--
2.25.1
On Fri, 29 Mar 2024 23:47:00 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:
On Mon, 4 Mar 2024 11:58:46 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:On Tue, 23 Jan 2024 16:23:27 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:On Mon, 22 Jan 2024 13:51:08 +1100
Peter Smith <smithpb2250@gmail.com> wrote:2024-01 Commitfest.
Hi, This patch has a CF status of "Needs Review" [1], but it seems
like there was some CFbot test failure last time it was run [2].
Please have a look and post an updated version if necessary.I attached a rebased patch-set, v30.
I attached a rebased patch-set, v31.
Also, I added a comment on RelationIsIVM() macro persuggestion from jian he.
In addition, I fixed a failure reported from cfbot on FreeBSD build caused by;WARNING: outfuncs/readfuncs failed to produce an equal rewritten parse tree
This warning was raised since I missed to modify outfuncs.c for a new field.
I found cfbot on FreeBSD still reported a failure due to
ENFORCE_REGRESSION_TEST_NAME_RESTRICTIONS because the regression test used
wrong role names. Attached is a fixed version, v32.
Regards,
Yugo Nagata
Regards,
Yugo NagataRegards,
Yugo Nagata--
Yugo NAGATA <nagata@sraoss.co.jp>--
Yugo NAGATA <nagata@sraoss.co.jp>
--
Yugo NAGATA <nagata@sraoss.co.jp>
Attachments:
v32-0001-Add-a-syntax-to-create-Incrementally-Maintainabl.patchtext/x-diff; name=v32-0001-Add-a-syntax-to-create-Incrementally-Maintainabl.patchDownload
From 11b1448c12af8d4a4dac9f99d4a71331db6936e8 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:05:02 +0900
Subject: [PATCH v32 01/11] Add a syntax to create Incrementally Maintainable
Materialized Views
Allow to create Incrementally Maintainable Materialized View (IMMV)
by using INCREMENTAL option in CREATE MATERIALIZED VIEW command
as follow:
CREATE [INCREMANTAL] MATERIALIZED VIEW xxxxx AS SELECT ....;
---
src/backend/parser/gram.y | 32 +++++++++++++++++++++-----------
src/include/nodes/primnodes.h | 1 +
src/include/parser/kwlist.h | 1 +
3 files changed, 23 insertions(+), 11 deletions(-)
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index 682748eb4b..91df005a19 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -468,6 +468,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <range> OptTempTableName
%type <into> into_clause create_as_target create_mv_target
+%type <boolean> incremental
%type <defelt> createfunc_opt_item common_func_opt_item dostmt_opt_item
%type <fun_param> func_arg func_arg_with_default table_func_column aggr_arg
@@ -732,7 +733,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
HANDLER HAVING HEADER_P HOLD HOUR_P
IDENTITY_P IF_P ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IMPORT_P IN_P INCLUDE
- INCLUDING INCREMENT INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
+ INCLUDING INCREMENT INCREMENTAL INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
@@ -4734,32 +4735,34 @@ opt_with_data:
*****************************************************************************/
CreateMatViewStmt:
- CREATE OptNoLog MATERIALIZED VIEW create_mv_target AS SelectStmt opt_with_data
+ CREATE OptNoLog incremental MATERIALIZED VIEW create_mv_target AS SelectStmt opt_with_data
{
CreateTableAsStmt *ctas = makeNode(CreateTableAsStmt);
- ctas->query = $7;
- ctas->into = $5;
+ ctas->query = $8;
+ ctas->into = $6;
ctas->objtype = OBJECT_MATVIEW;
ctas->is_select_into = false;
ctas->if_not_exists = false;
/* cram additional flags into the IntoClause */
- $5->rel->relpersistence = $2;
- $5->skipData = !($8);
+ $6->rel->relpersistence = $2;
+ $6->skipData = !($9);
+ $6->ivm = $3;
$$ = (Node *) ctas;
}
- | CREATE OptNoLog MATERIALIZED VIEW IF_P NOT EXISTS create_mv_target AS SelectStmt opt_with_data
+ | CREATE OptNoLog incremental MATERIALIZED VIEW IF_P NOT EXISTS create_mv_target AS SelectStmt opt_with_data
{
CreateTableAsStmt *ctas = makeNode(CreateTableAsStmt);
- ctas->query = $10;
- ctas->into = $8;
+ ctas->query = $11;
+ ctas->into = $9;
ctas->objtype = OBJECT_MATVIEW;
ctas->is_select_into = false;
ctas->if_not_exists = true;
/* cram additional flags into the IntoClause */
- $8->rel->relpersistence = $2;
- $8->skipData = !($11);
+ $9->rel->relpersistence = $2;
+ $9->skipData = !($12);
+ $9->ivm = $3;
$$ = (Node *) ctas;
}
;
@@ -4776,9 +4779,14 @@ create_mv_target:
$$->tableSpaceName = $5;
$$->viewQuery = NULL; /* filled at analysis time */
$$->skipData = false; /* might get changed later */
+ $$->ivm = false;
}
;
+incremental: INCREMENTAL { $$ = true; }
+ | /*EMPTY*/ { $$ = false; }
+ ;
+
OptNoLog: UNLOGGED { $$ = RELPERSISTENCE_UNLOGGED; }
| /*EMPTY*/ { $$ = RELPERSISTENCE_PERMANENT; }
;
@@ -17454,6 +17462,7 @@ unreserved_keyword:
| INCLUDE
| INCLUDING
| INCREMENT
+ | INCREMENTAL
| INDENT
| INDEX
| INDEXES
@@ -18037,6 +18046,7 @@ bare_label_keyword:
| INCLUDE
| INCLUDING
| INCREMENT
+ | INCREMENTAL
| INDENT
| INDEX
| INDEXES
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index aa727e722c..9d0ba29a2a 100644
--- a/src/include/nodes/primnodes.h
+++ b/src/include/nodes/primnodes.h
@@ -154,6 +154,7 @@ typedef struct IntoClause
/* materialized view's SELECT query */
Node *viewQuery pg_node_attr(query_jumble_ignore);
bool skipData; /* true for WITH NO DATA */
+ bool ivm; /* true for WITH IVM */
} IntoClause;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index 6c959e85d5..94c4a3de1a 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -210,6 +210,7 @@ PG_KEYWORD("in", IN_P, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("include", INCLUDE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("including", INCLUDING, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("increment", INCREMENT, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("incremental", INCREMENTAL, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("indent", INDENT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("index", INDEX, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("indexes", INDEXES, UNRESERVED_KEYWORD, BARE_LABEL)
--
2.25.1
v32-0002-Add-relisivm-column-to-pg_class-system-catalog.patchtext/x-diff; name=v32-0002-Add-relisivm-column-to-pg_class-system-catalog.patchDownload
From 3fd73c0580a761a13938fe3787b33431db0a2759 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:07:23 +0900
Subject: [PATCH v32 02/11] Add relisivm column to pg_class system catalog
If this boolean column is true, a relations is Incrementally Maintainable
Materialized View (IMMV). This is set when IMMV is created.
Also, isimmv columns is added to pg_matviews system view.
isimmv
---
src/backend/catalog/heap.c | 1 +
src/backend/catalog/index.c | 1 +
src/backend/catalog/system_views.sql | 1 +
src/backend/utils/cache/lsyscache.c | 24 ++++++++++++++++++++++++
src/backend/utils/cache/relcache.c | 2 ++
src/include/catalog/pg_class.h | 3 +++
src/include/utils/lsyscache.h | 1 +
src/include/utils/rel.h | 6 ++++++
src/test/regress/expected/rules.out | 1 +
9 files changed, 40 insertions(+)
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index cc31909012..1d2e2228c4 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -937,6 +937,7 @@ InsertPgClassTuple(Relation pg_class_desc,
values[Anum_pg_class_relrewrite - 1] = ObjectIdGetDatum(rd_rel->relrewrite);
values[Anum_pg_class_relfrozenxid - 1] = TransactionIdGetDatum(rd_rel->relfrozenxid);
values[Anum_pg_class_relminmxid - 1] = MultiXactIdGetDatum(rd_rel->relminmxid);
+ values[Anum_pg_class_relisivm - 1] = BoolGetDatum(rd_rel->relisivm);
if (relacl != (Datum) 0)
values[Anum_pg_class_relacl - 1] = relacl;
else
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index b6a7c60e23..906ec6c088 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -1007,6 +1007,7 @@ index_create(Relation heapRelation,
indexRelation->rd_rel->relowner = heapRelation->rd_rel->relowner;
indexRelation->rd_rel->relam = accessMethodId;
indexRelation->rd_rel->relispartition = OidIsValid(parentIndexRelid);
+ indexRelation->rd_rel->relisivm = false;
/*
* store index's pg_class entry
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index 401fb35947..16c3399975 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -146,6 +146,7 @@ CREATE VIEW pg_matviews AS
T.spcname AS tablespace,
C.relhasindex AS hasindexes,
C.relispopulated AS ispopulated,
+ C.relisivm AS isimmv,
pg_get_viewdef(C.oid) AS definition
FROM pg_class C LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
LEFT JOIN pg_tablespace T ON (T.oid = C.reltablespace)
diff --git a/src/backend/utils/cache/lsyscache.c b/src/backend/utils/cache/lsyscache.c
index 26368ffcc9..01af4ad5bb 100644
--- a/src/backend/utils/cache/lsyscache.c
+++ b/src/backend/utils/cache/lsyscache.c
@@ -2020,6 +2020,30 @@ get_rel_relispartition(Oid relid)
return false;
}
+/*
+ * get_rel_relisivm
+ *
+ * Returns the relisivm flag associated with a given relation.
+ */
+bool
+get_rel_relisivm(Oid relid)
+{
+ HeapTuple tp;
+
+ tp = SearchSysCache1(RELOID, ObjectIdGetDatum(relid));
+ if (HeapTupleIsValid(tp))
+ {
+ Form_pg_class reltup = (Form_pg_class) GETSTRUCT(tp);
+ bool result;
+
+ result = reltup->relisivm;
+ ReleaseSysCache(tp);
+ return result;
+ }
+ else
+ return false;
+}
+
/*
* get_rel_tablespace
*
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 039c0d3eef..c64b9e7bf5 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -1936,6 +1936,8 @@ formrdesc(const char *relationName, Oid relationReltype,
/* ... and they're always populated, too */
relation->rd_rel->relispopulated = true;
+ /* ... and they're always no ivm, too */
+ relation->rd_rel->relisivm = false;
relation->rd_rel->relreplident = REPLICA_IDENTITY_NOTHING;
relation->rd_rel->relpages = 0;
diff --git a/src/include/catalog/pg_class.h b/src/include/catalog/pg_class.h
index 0fc2c093b0..80cbee29ca 100644
--- a/src/include/catalog/pg_class.h
+++ b/src/include/catalog/pg_class.h
@@ -119,6 +119,9 @@ CATALOG(pg_class,1259,RelationRelationId) BKI_BOOTSTRAP BKI_ROWTYPE_OID(83,Relat
/* is relation a partition? */
bool relispartition BKI_DEFAULT(f);
+ /* is relation a matview with ivm? */
+ bool relisivm BKI_DEFAULT(f);
+
/* link to original rel during table rewrite; otherwise 0 */
Oid relrewrite BKI_DEFAULT(0) BKI_LOOKUP_OPT(pg_class);
diff --git a/src/include/utils/lsyscache.h b/src/include/utils/lsyscache.h
index 35a8dec2b9..93c2fcb21c 100644
--- a/src/include/utils/lsyscache.h
+++ b/src/include/utils/lsyscache.h
@@ -137,6 +137,7 @@ extern Oid get_rel_namespace(Oid relid);
extern Oid get_rel_type_id(Oid relid);
extern char get_rel_relkind(Oid relid);
extern bool get_rel_relispartition(Oid relid);
+extern bool get_rel_relisivm(Oid relid);
extern Oid get_rel_tablespace(Oid relid);
extern char get_rel_persistence(Oid relid);
extern Oid get_rel_relam(Oid relid);
diff --git a/src/include/utils/rel.h b/src/include/utils/rel.h
index f25f769af2..d3144c949f 100644
--- a/src/include/utils/rel.h
+++ b/src/include/utils/rel.h
@@ -678,6 +678,12 @@ RelationCloseSmgr(Relation relation)
*/
#define RelationIsPopulated(relation) ((relation)->rd_rel->relispopulated)
+/*
+ * RelationIsIVM
+ * True if relation is an incrementally maintainable materialized view.
+ */
+#define RelationIsIVM(relation) ((relation)->rd_rel->relisivm)
+
/*
* RelationIsAccessibleInLogicalDecoding
* True if we need to log enough information to have access via
diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out
index 5e45ce64f7..04c54482a1 100644
--- a/src/test/regress/expected/rules.out
+++ b/src/test/regress/expected/rules.out
@@ -1392,6 +1392,7 @@ pg_matviews| SELECT n.nspname AS schemaname,
t.spcname AS tablespace,
c.relhasindex AS hasindexes,
c.relispopulated AS ispopulated,
+ c.relisivm AS isimmv,
pg_get_viewdef(c.oid) AS definition
FROM ((pg_class c
LEFT JOIN pg_namespace n ON ((n.oid = c.relnamespace)))
--
2.25.1
v32-0003-Allow-to-prolong-life-span-of-transition-tables-.patchtext/x-diff; name=v32-0003-Allow-to-prolong-life-span-of-transition-tables-.patchDownload
From 272c51927e05fcff4fa46623a012f2e25ad6885f Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:09:45 +0900
Subject: [PATCH v32 03/11] Allow to prolong life span of transition tables
until transaction end
Originally, tuplestores of AFTER trigger's transition tables were
freed for each query depth. For our IVM implementation, we would like
to prolong life of the tuplestores because we have to preserve them
for a whole query assuming that some base tables might be changed
in some trigger functions.
---
src/backend/commands/trigger.c | 83 ++++++++++++++++++++++++++++++++--
src/include/commands/trigger.h | 2 +
2 files changed, 81 insertions(+), 4 deletions(-)
diff --git a/src/backend/commands/trigger.c b/src/backend/commands/trigger.c
index 84494c4b81..0424ab9a29 100644
--- a/src/backend/commands/trigger.c
+++ b/src/backend/commands/trigger.c
@@ -3729,6 +3729,10 @@ typedef struct AfterTriggerEventList
* end of the list, so it is relatively easy to discard them. The event
* list chunks themselves are stored in event_cxt.
*
+ * prolonged_tuplestored is a list of transition table tuplestores whose
+ * life are prolonged to the end of the outmost query instead of each nested
+ * query.
+ *
* query_depth is the current depth of nested AfterTriggerBeginQuery calls
* (-1 when the stack is empty).
*
@@ -3794,6 +3798,7 @@ typedef struct AfterTriggersData
SetConstraintState state; /* the active S C state */
AfterTriggerEventList events; /* deferred-event list */
MemoryContext event_cxt; /* memory context for events, if any */
+ List *prolonged_tuplestores; /* list of prolonged tuplestores */
/* per-query-level data: */
AfterTriggersQueryData *query_stack; /* array of structs shown below */
@@ -3829,6 +3834,7 @@ struct AfterTriggersTableData
bool closed; /* true when no longer OK to add tuples */
bool before_trig_done; /* did we already queue BS triggers? */
bool after_trig_done; /* did we already queue AS triggers? */
+ bool prolonged; /* are transition tables prolonged? */
AfterTriggerEventList after_trig_events; /* if so, saved list pointer */
/*
@@ -3878,6 +3884,7 @@ static void TransitionTableAddTuple(EState *estate,
TupleTableSlot *original_insert_tuple,
Tuplestorestate *tuplestore);
static void AfterTriggerFreeQuery(AfterTriggersQueryData *qs);
+static void release_or_prolong_tuplestore(Tuplestorestate *ts, bool prolonged);
static SetConstraintState SetConstraintStateCreate(int numalloc);
static SetConstraintState SetConstraintStateCopy(SetConstraintState origstate);
static SetConstraintState SetConstraintStateAddItem(SetConstraintState state,
@@ -4755,6 +4762,45 @@ afterTriggerInvokeEvents(AfterTriggerEventList *events,
}
+/*
+ * SetTransitionTablePreserved
+ *
+ * Prolong lifespan of transition tables corresponding specified relid and
+ * command type to the end of the outmost query instead of each nested query.
+ * This enables to use nested AFTER trigger's transition tables from outer
+ * query's triggers. Currently, only immediate incremental view maintenance
+ * uses this.
+ */
+void
+SetTransitionTablePreserved(Oid relid, CmdType cmdType)
+{
+ AfterTriggersTableData *table;
+ AfterTriggersQueryData *qs;
+ bool found = false;
+ ListCell *lc;
+
+ /* Check state, like AfterTriggerSaveEvent. */
+ if (afterTriggers.query_depth < 0)
+ elog(ERROR, "SetTransitionTablePreserved() called outside of query");
+
+ qs = &afterTriggers.query_stack[afterTriggers.query_depth];
+
+ foreach(lc, qs->tables)
+ {
+ table = (AfterTriggersTableData *) lfirst(lc);
+ if (table->relid == relid && table->cmdType == cmdType &&
+ table->closed)
+ {
+ table->prolonged = true;
+ found = true;
+ }
+ }
+
+ if (!found)
+ elog(ERROR,"could not find table with OID %d and command type %d", relid, cmdType);
+}
+
+
/*
* GetAfterTriggersTableData
*
@@ -4965,6 +5011,7 @@ AfterTriggerBeginXact(void)
*/
afterTriggers.firing_counter = (CommandId) 1; /* mustn't be 0 */
afterTriggers.query_depth = -1;
+ afterTriggers.prolonged_tuplestores = NIL;
/*
* Verify that there is no leftover state remaining. If these assertions
@@ -5125,19 +5172,19 @@ AfterTriggerFreeQuery(AfterTriggersQueryData *qs)
ts = table->old_upd_tuplestore;
table->old_upd_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->new_upd_tuplestore;
table->new_upd_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->old_del_tuplestore;
table->old_del_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->new_ins_tuplestore;
table->new_ins_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
if (table->storeslot)
{
TupleTableSlot *slot = table->storeslot;
@@ -5154,6 +5201,34 @@ AfterTriggerFreeQuery(AfterTriggersQueryData *qs)
*/
qs->tables = NIL;
list_free_deep(tables);
+
+ /* Release prolonged tuplestores at the end of the outmost query */
+ if (afterTriggers.query_depth == 0)
+ {
+ foreach(lc, afterTriggers.prolonged_tuplestores)
+ {
+ ts = (Tuplestorestate *) lfirst(lc);
+ if (ts)
+ tuplestore_end(ts);
+ }
+ afterTriggers.prolonged_tuplestores = NIL;
+ }
+}
+
+/*
+ * Release the tuplestore, or append it to the prolonged tuplestores list.
+ */
+static void
+release_or_prolong_tuplestore(Tuplestorestate *ts, bool prolonged)
+{
+ if (prolonged && afterTriggers.query_depth > 0)
+ {
+ MemoryContext oldcxt = MemoryContextSwitchTo(CurTransactionContext);
+ afterTriggers.prolonged_tuplestores = lappend(afterTriggers.prolonged_tuplestores, ts);
+ MemoryContextSwitchTo(oldcxt);
+ }
+ else
+ tuplestore_end(ts);
}
diff --git a/src/include/commands/trigger.h b/src/include/commands/trigger.h
index cb968d03ec..768d6e1c0b 100644
--- a/src/include/commands/trigger.h
+++ b/src/include/commands/trigger.h
@@ -265,6 +265,8 @@ extern void AfterTriggerEndSubXact(bool isCommit);
extern void AfterTriggerSetState(ConstraintsSetStmt *stmt);
extern bool AfterTriggerPendingOnRel(Oid relid);
+extern void SetTransitionTablePreserved(Oid relid, CmdType cmdType);
+
/*
* in utils/adt/ri_triggers.c
--
2.25.1
v32-0004-Add-Incremental-View-Maintenance-support-to-pg_d.patchtext/x-diff; name=v32-0004-Add-Incremental-View-Maintenance-support-to-pg_d.patchDownload
From 4112539570be8b6333b22f3869a296d5c6abaec3 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 11 Nov 2020 17:01:25 +0900
Subject: [PATCH v32 04/11] Add Incremental View Maintenance support to pg_dump
Support CREATE INCREMENTAL MATERIALIZED VIEW syntax.
---
src/bin/pg_dump/pg_dump.c | 18 +++++++++++++++---
src/bin/pg_dump/pg_dump.h | 2 ++
src/bin/pg_dump/t/002_pg_dump.pl | 18 ++++++++++++++++++
3 files changed, 35 insertions(+), 3 deletions(-)
diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c
index b1c4c3ec7f..92a8cbf244 100644
--- a/src/bin/pg_dump/pg_dump.c
+++ b/src/bin/pg_dump/pg_dump.c
@@ -6677,6 +6677,7 @@ getTables(Archive *fout, int *numTables)
int i_relacl;
int i_acldefault;
int i_ispartition;
+ int i_isivm;
/*
* Find all the tables and table-like objects.
@@ -6779,10 +6780,17 @@ getTables(Archive *fout, int *numTables)
if (fout->remoteVersion >= 100000)
appendPQExpBufferStr(query,
- "c.relispartition AS ispartition ");
+ "c.relispartition AS ispartition, ");
else
appendPQExpBufferStr(query,
- "false AS ispartition ");
+ "false AS ispartition, ");
+
+ if (fout->remoteVersion >= 170000)
+ appendPQExpBufferStr(query,
+ "c.relisivm AS isivm ");
+ else
+ appendPQExpBufferStr(query,
+ "false AS isivm ");
/*
* Left join to pg_depend to pick up dependency info linking sequences to
@@ -6891,6 +6899,7 @@ getTables(Archive *fout, int *numTables)
i_relacl = PQfnumber(res, "relacl");
i_acldefault = PQfnumber(res, "acldefault");
i_ispartition = PQfnumber(res, "ispartition");
+ i_isivm = PQfnumber(res, "isivm");
if (dopt->lockWaitTimeout)
{
@@ -6970,6 +6979,7 @@ getTables(Archive *fout, int *numTables)
tblinfo[i].amname = pg_strdup(PQgetvalue(res, i, i_amname));
tblinfo[i].is_identity_sequence = (strcmp(PQgetvalue(res, i, i_is_identity_sequence), "t") == 0);
tblinfo[i].ispartition = (strcmp(PQgetvalue(res, i, i_ispartition), "t") == 0);
+ tblinfo[i].isivm = (strcmp(PQgetvalue(res, i, i_isivm), "t") == 0);
/* other fields were zeroed above */
@@ -16023,9 +16033,11 @@ dumpTableSchema(Archive *fout, const TableInfo *tbinfo)
binary_upgrade_set_pg_class_oids(fout, q,
tbinfo->dobj.catId.oid, false);
- appendPQExpBuffer(q, "CREATE %s%s %s",
+ appendPQExpBuffer(q, "CREATE %s%s%s %s",
tbinfo->relpersistence == RELPERSISTENCE_UNLOGGED ?
"UNLOGGED " : "",
+ tbinfo->relkind == RELKIND_MATVIEW && tbinfo->isivm ?
+ "INCREMENTAL " : "",
reltypename,
qualrelname);
diff --git a/src/bin/pg_dump/pg_dump.h b/src/bin/pg_dump/pg_dump.h
index 9bc93520b4..4e240f8832 100644
--- a/src/bin/pg_dump/pg_dump.h
+++ b/src/bin/pg_dump/pg_dump.h
@@ -325,6 +325,8 @@ typedef struct _tableInfo
int numParents; /* number of (immediate) parent tables */
struct _tableInfo **parents; /* TableInfos of immediate parents */
+ bool isivm; /* is incrementally maintainable materialized view? */
+
/*
* These fields are computed only if we decide the table is interesting
* (it's either a table to dump, or a direct parent of a dumpable table).
diff --git a/src/bin/pg_dump/t/002_pg_dump.pl b/src/bin/pg_dump/t/002_pg_dump.pl
index f0410ce6a1..a119ec8db1 100644
--- a/src/bin/pg_dump/t/002_pg_dump.pl
+++ b/src/bin/pg_dump/t/002_pg_dump.pl
@@ -2832,6 +2832,24 @@ my %tests = (
},
},
+ 'CREATE MATERIALIZED VIEW matview_ivm' => {
+ create_order => 21,
+ create_sql => 'CREATE INCREMENTAL MATERIALIZED VIEW dump_test.matview_ivm (col1) AS
+ SELECT col1 FROM dump_test.test_table;',
+ regexp => qr/^
+ \QCREATE INCREMENTAL MATERIALIZED VIEW dump_test.matview_ivm AS\E
+ \n\s+\QSELECT col1\E
+ \n\s+\QFROM dump_test.test_table\E
+ \n\s+\QWITH NO DATA;\E
+ /xm,
+ like =>
+ { %full_runs, %dump_test_schema_runs, section_pre_data => 1, },
+ unlike => {
+ exclude_dump_test_schema => 1,
+ only_dump_measurement => 1,
+ },
+ },
+
'CREATE POLICY p1 ON test_table' => {
create_order => 22,
create_sql => 'CREATE POLICY p1 ON dump_test.test_table
--
2.25.1
v32-0005-Add-Incremental-View-Maintenance-support-to-psql.patchtext/x-diff; name=v32-0005-Add-Incremental-View-Maintenance-support-to-psql.patchDownload
From c9116f11af79ceae8630bd1270a2409950473b37 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:21:54 +0900
Subject: [PATCH v32 05/11] Add Incremental View Maintenance support to psql
Add tab completion and meta-command output for IVM.
---
src/bin/psql/describe.c | 32 +++++++++++++++++++++++++++++++-
src/bin/psql/tab-complete.c | 14 +++++++++-----
2 files changed, 40 insertions(+), 6 deletions(-)
diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c
index 6433497bcd..df559dce42 100644
--- a/src/bin/psql/describe.c
+++ b/src/bin/psql/describe.c
@@ -1574,6 +1574,7 @@ describeOneTableDetails(const char *schemaname,
char relpersistence;
char relreplident;
char *relam;
+ bool isivm;
} tableinfo;
bool show_column_details = false;
@@ -1586,7 +1587,26 @@ describeOneTableDetails(const char *schemaname,
initPQExpBuffer(&tmpbuf);
/* Get general table info */
- if (pset.sversion >= 120000)
+ if (pset.sversion >= 170000)
+ {
+ printfPQExpBuffer(&buf,
+ "SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
+ "c.relhastriggers, c.relrowsecurity, c.relforcerowsecurity, "
+ "false AS relhasoids, c.relispartition, %s, c.reltablespace, "
+ "CASE WHEN c.reloftype = 0 THEN '' ELSE c.reloftype::pg_catalog.regtype::pg_catalog.text END, "
+ "c.relpersistence, c.relreplident, am.amname, "
+ "c.relisivm\n"
+ "FROM pg_catalog.pg_class c\n "
+ "LEFT JOIN pg_catalog.pg_class tc ON (c.reltoastrelid = tc.oid)\n"
+ "LEFT JOIN pg_catalog.pg_am am ON (c.relam = am.oid)\n"
+ "WHERE c.oid = '%s';",
+ (verbose ?
+ "pg_catalog.array_to_string(c.reloptions || "
+ "array(select 'toast.' || x from pg_catalog.unnest(tc.reloptions) x), ', ')\n"
+ : "''"),
+ oid);
+ }
+ else if (pset.sversion >= 120000)
{
printfPQExpBuffer(&buf,
"SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
@@ -1706,6 +1726,10 @@ describeOneTableDetails(const char *schemaname,
(char *) NULL : pg_strdup(PQgetvalue(res, 0, 14));
else
tableinfo.relam = NULL;
+ if (pset.sversion >= 170000)
+ tableinfo.isivm = strcmp(PQgetvalue(res, 0, 15), "t") == 0;
+ else
+ tableinfo.isivm = false;
PQclear(res);
res = NULL;
@@ -3560,6 +3584,12 @@ describeOneTableDetails(const char *schemaname,
printfPQExpBuffer(&buf, _("Access method: %s"), tableinfo.relam);
printTableAddFooter(&cont, buf.data);
}
+
+ /* Incremental view maintance info */
+ if (verbose && tableinfo.relkind == RELKIND_MATVIEW && tableinfo.isivm)
+ {
+ printTableAddFooter(&cont, _("Incremental view maintenance: yes"));
+ }
}
/* reloptions, if verbose */
diff --git a/src/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c
index fc6865fc70..456d042f09 100644
--- a/src/bin/psql/tab-complete.c
+++ b/src/bin/psql/tab-complete.c
@@ -1245,6 +1245,7 @@ static const pgsql_thing_t words_after_create[] = {
{"FOREIGN TABLE", NULL, NULL, NULL},
{"FUNCTION", NULL, NULL, Query_for_list_of_functions},
{"GROUP", Query_for_list_of_roles},
+ {"INCREMENTAL MATERIALIZED VIEW", NULL, NULL, &Query_for_list_of_matviews, NULL, THING_NO_DROP | THING_NO_ALTER},
{"INDEX", NULL, NULL, &Query_for_list_of_indexes},
{"LANGUAGE", Query_for_list_of_languages},
{"LARGE OBJECT", NULL, NULL, NULL, NULL, THING_NO_CREATE | THING_NO_DROP},
@@ -3256,7 +3257,7 @@ psql_completion(const char *text, int start, int end)
if (HeadMatches("CREATE", "SCHEMA"))
COMPLETE_WITH("TABLE", "SEQUENCE");
else
- COMPLETE_WITH("TABLE", "SEQUENCE", "MATERIALIZED VIEW");
+ COMPLETE_WITH("TABLE", "SEQUENCE", "MATERIALIZED VIEW", "INCREMENTAL MATERIALIZED VIEW");
}
/* Complete PARTITION BY with RANGE ( or LIST ( or ... */
else if (TailMatches("PARTITION", "BY"))
@@ -3601,13 +3602,16 @@ psql_completion(const char *text, int start, int end)
COMPLETE_WITH("SELECT");
/* CREATE MATERIALIZED VIEW */
- else if (Matches("CREATE", "MATERIALIZED"))
+ else if (Matches("CREATE", "MATERIALIZED") ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED"))
COMPLETE_WITH("VIEW");
- /* Complete CREATE MATERIALIZED VIEW <name> with AS */
- else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny))
+ /* Complete CREATE MATERIALIZED VIEW <name> with AS */
+ else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny) ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED", "VIEW", MatchAny))
COMPLETE_WITH("AS");
/* Complete "CREATE MATERIALIZED VIEW <sth> AS with "SELECT" */
- else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny, "AS"))
+ else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny, "AS") ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED", "VIEW", MatchAny, "AS"))
COMPLETE_WITH("SELECT");
/* CREATE EVENT TRIGGER */
--
2.25.1
v32-0006-Add-Incremental-View-Maintenance-support.patchtext/x-diff; name=v32-0006-Add-Incremental-View-Maintenance-support.patchDownload
From 288bc9406dc15f106c9781311d6c0a96d394a528 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 18:59:50 +0900
Subject: [PATCH v32 06/11] Add Incremental View Maintenance support
In this implementation, AFTER triggers are used to collect
tuplestores containing transition table contents. When multiple tables
are changed, multiple AFTER triggers are invoked, then the final AFTER
trigger performs actual update of the matview. In addition, BEFORE
triggers are also used to handle global information for view
maintenance.
To calculate view deltas, we need both pre-state and post-state of base
tables. Post-update states are available in AFTER trigger, and pre-update
states can be calculated by removing inserted tuples and appending deleted
tuples. Insterted tuples are filtered using the snapshot taken before
table modiication, and deleted tuples are contained in the old transition
table.
Incrementally Maintainable Materialized Views (IMMV) can contain
duplicated tuples.
This patch also allows self-join, simultaneous updates of more than
one base table, and multiple updates of the same base table.
---
src/backend/access/transam/xact.c | 5 +
src/backend/commands/createas.c | 682 ++++++++++++++
src/backend/commands/matview.c | 1468 ++++++++++++++++++++++++++++-
src/include/catalog/pg_proc.dat | 10 +
src/include/commands/createas.h | 4 +
src/include/commands/matview.h | 9 +
6 files changed, 2143 insertions(+), 35 deletions(-)
diff --git a/src/backend/access/transam/xact.c b/src/backend/access/transam/xact.c
index df5a67e4c3..a2d5404912 100644
--- a/src/backend/access/transam/xact.c
+++ b/src/backend/access/transam/xact.c
@@ -36,6 +36,7 @@
#include "catalog/pg_enum.h"
#include "catalog/storage.h"
#include "commands/async.h"
+#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/trigger.h"
#include "common/pg_prng.h"
@@ -2860,6 +2861,7 @@ AbortTransaction(void)
AtAbort_Notify();
AtEOXact_RelationMap(false, is_parallel_worker);
AtAbort_Twophase();
+ AtAbort_IVM();
/*
* Advertise the fact that we aborted in pg_xact (assuming that we got as
@@ -5198,6 +5200,9 @@ AbortSubTransaction(void)
pgstat_progress_end_command();
UnlockBuffers();
+ /* Clean up hash entries for incremental view maintenance */
+ AtAbort_IVM();
+
/* Reset WAL record construction state */
XLogResetInsertion();
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index afd3dace07..e9846c8d0f 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -29,15 +29,27 @@
#include "access/tableam.h"
#include "access/xact.h"
#include "catalog/namespace.h"
+#include "catalog/index.h"
+#include "catalog/pg_constraint.h"
+#include "catalog/pg_inherits.h"
+#include "catalog/pg_trigger.h"
#include "catalog/toasting.h"
#include "commands/createas.h"
+#include "commands/defrem.h"
#include "commands/matview.h"
#include "commands/prepare.h"
#include "commands/tablecmds.h"
+#include "commands/tablespace.h"
+#include "commands/trigger.h"
#include "commands/view.h"
#include "miscadmin.h"
+#include "optimizer/optimizer.h"
+#include "optimizer/prep.h"
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
+#include "parser/parser.h"
+#include "parser/parsetree.h"
+#include "parser/parse_clause.h"
#include "rewrite/rewriteHandler.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
@@ -68,6 +80,12 @@ static bool intorel_receive(TupleTableSlot *slot, DestReceiver *self);
static void intorel_shutdown(DestReceiver *self);
static void intorel_destroy(DestReceiver *self);
+static void CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid matviewOid,
+ Relids *relids, bool ex_lock);
+static void CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock);
+static void check_ivm_restriction(Node *node);
+static bool check_ivm_restriction_walker(Node *node, void *context);
+static Bitmapset *get_primary_key_attnos_from_query(Query *query, List **constraintList);
/*
* create_ctas_internal
@@ -277,6 +295,18 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
save_nestlevel = NewGUCNestLevel();
}
+ if (is_matview && into->ivm)
+ {
+ /* check if the query is supported in IMMV definition */
+ if (contain_mutable_functions((Node *) query))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("mutable function is not supported on incrementally maintainable materialized view"),
+ errhint("functions must be marked IMMUTABLE")));
+
+ check_ivm_restriction((Node *) query);
+ }
+
if (into->skipData)
{
/*
@@ -353,6 +383,27 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
/* Restore userid and security context */
SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ if (into->ivm)
+ {
+ Oid matviewOid = address.objectId;
+ Relation matviewRel = table_open(matviewOid, NoLock);
+
+ /*
+ * Mark relisivm field, if it's a matview and into->ivm is true.
+ */
+ SetMatViewIVMState(matviewRel, true);
+
+ if (!into->skipData)
+ {
+ /* Create an index on incremental maintainable materialized view, if possible */
+ CreateIndexOnIMMV((Query *) into->viewQuery, matviewRel);
+
+ /* Create triggers on incremental maintainable materialized view */
+ CreateIvmTriggersOnBaseTables((Query *) into->viewQuery, matviewOid);
+ }
+ table_close(matviewRel, NoLock);
+ }
}
return address;
@@ -632,3 +683,634 @@ intorel_destroy(DestReceiver *self)
{
pfree(self);
}
+
+/*
+ * CreateIvmTriggersOnBaseTables -- create IVM triggers on all base tables
+ */
+void
+CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid)
+{
+ Relids relids = NULL;
+ bool ex_lock = false;
+ RangeTblEntry *rte;
+
+ /* Immediately return if we don't have any base tables. */
+ if (list_length(qry->rtable) < 1)
+ return;
+
+ /*
+ * If the view has more than one base tables, we need an exclusive lock
+ * on the view so that the view would be maintained serially to avoid
+ * the inconsistency that occurs when two base tables are modified in
+ * concurrent transactions. However, if the view has only one table,
+ * we can use a weaker lock.
+ *
+ * The type of lock should be determined here, because if we check the
+ * view definition at maintenance time, we need to acquire a weaker lock,
+ * and upgrading the lock level after this increases probability of
+ * deadlock.
+ */
+
+ rte = list_nth(qry->rtable, 0);
+ if (list_length(qry->rtable) > 1 || rte->rtekind != RTE_RELATION)
+ ex_lock = true;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, (Node *)qry, matviewOid, &relids, ex_lock);
+
+ bms_free(relids);
+}
+
+static void
+CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid matviewOid,
+ Relids *relids, bool ex_lock)
+{
+ if (node == NULL)
+ return;
+
+ /* This can recurse, so check for excessive recursion */
+ check_stack_depth();
+
+ switch (nodeTag(node))
+ {
+ case T_Query:
+ {
+ Query *query = (Query *) node;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, (Node *)query->jointree, matviewOid, relids, ex_lock);
+ }
+ break;
+
+ case T_RangeTblRef:
+ {
+ int rti = ((RangeTblRef *) node)->rtindex;
+ RangeTblEntry *rte = rt_fetch(rti, qry->rtable);
+
+ if (rte->rtekind == RTE_RELATION && !bms_is_member(rte->relid, *relids))
+ {
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_INSERT, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_DELETE, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_UPDATE, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_TRUNCATE, TRIGGER_TYPE_BEFORE, true);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_INSERT, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_DELETE, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_UPDATE, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_TRUNCATE, TRIGGER_TYPE_AFTER, true);
+
+ *relids = bms_add_member(*relids, rte->relid);
+ }
+ }
+ break;
+
+ case T_FromExpr:
+ {
+ FromExpr *f = (FromExpr *) node;
+ ListCell *l;
+
+ foreach(l, f->fromlist)
+ CreateIvmTriggersOnBaseTablesRecurse(qry, lfirst(l), matviewOid, relids, ex_lock);
+ }
+ break;
+
+ case T_JoinExpr:
+ {
+ JoinExpr *j = (JoinExpr *) node;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, j->larg, matviewOid, relids, ex_lock);
+ CreateIvmTriggersOnBaseTablesRecurse(qry, j->rarg, matviewOid, relids, ex_lock);
+ }
+ break;
+
+ default:
+ elog(ERROR, "unrecognized node type: %d", (int) nodeTag(node));
+ }
+}
+
+/*
+ * CreateIvmTrigger -- create IVM trigger on a base table
+ */
+static void
+CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock)
+{
+ ObjectAddress refaddr;
+ ObjectAddress address;
+ CreateTrigStmt *ivm_trigger;
+ List *transitionRels = NIL;
+
+ Assert(timing == TRIGGER_TYPE_BEFORE || timing == TRIGGER_TYPE_AFTER);
+
+ refaddr.classId = RelationRelationId;
+ refaddr.objectId = viewOid;
+ refaddr.objectSubId = 0;
+
+ ivm_trigger = makeNode(CreateTrigStmt);
+ ivm_trigger->relation = NULL;
+ ivm_trigger->row = false;
+
+ ivm_trigger->timing = timing;
+ ivm_trigger->events = type;
+
+ switch (type)
+ {
+ case TRIGGER_TYPE_INSERT:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_ins_before" : "IVM_trigger_ins_after");
+ break;
+ case TRIGGER_TYPE_DELETE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_del_before" : "IVM_trigger_del_after");
+ break;
+ case TRIGGER_TYPE_UPDATE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_upd_before" : "IVM_trigger_upd_after");
+ break;
+ case TRIGGER_TYPE_TRUNCATE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_truncate_before" : "IVM_trigger_truncate_after");
+ break;
+ default:
+ elog(ERROR, "unsupported trigger type");
+ }
+
+ if (timing == TRIGGER_TYPE_AFTER)
+ {
+ if (type == TRIGGER_TYPE_INSERT || type == TRIGGER_TYPE_UPDATE)
+ {
+ TriggerTransition *n = makeNode(TriggerTransition);
+ n->name = "__ivm_newtable";
+ n->isNew = true;
+ n->isTable = true;
+
+ transitionRels = lappend(transitionRels, n);
+ }
+ if (type == TRIGGER_TYPE_DELETE || type == TRIGGER_TYPE_UPDATE)
+ {
+ TriggerTransition *n = makeNode(TriggerTransition);
+ n->name = "__ivm_oldtable";
+ n->isNew = false;
+ n->isTable = true;
+
+ transitionRels = lappend(transitionRels, n);
+ }
+ }
+
+ /*
+ * XXX: When using DELETE or UPDATE, we must use exclusive lock for now
+ * because apply_old_delta(_with_count) uses ctid to identify the tuple
+ * to be deleted/deleted, but doesn't work in concurrent situations.
+ *
+ * If the view doesn't have aggregate, distinct, or tuple duplicate,
+ * then it would work even in concurrent situations. However, we don't have
+ * any way to guarantee the view has a unique key before opening the IMMV
+ * at the maintenance time because users may drop the unique index.
+ */
+
+ if (type == TRIGGER_TYPE_DELETE || type == TRIGGER_TYPE_UPDATE)
+ ex_lock = true;
+
+ ivm_trigger->funcname =
+ (timing == TRIGGER_TYPE_BEFORE ? SystemFuncName("IVM_immediate_before") : SystemFuncName("IVM_immediate_maintenance"));
+
+ ivm_trigger->columns = NIL;
+ ivm_trigger->transitionRels = transitionRels;
+ ivm_trigger->whenClause = NULL;
+ ivm_trigger->isconstraint = false;
+ ivm_trigger->deferrable = false;
+ ivm_trigger->initdeferred = false;
+ ivm_trigger->constrrel = NULL;
+ ivm_trigger->args = list_make2(
+ makeString(DatumGetPointer(DirectFunctionCall1(oidout, ObjectIdGetDatum(viewOid)))),
+ makeString(DatumGetPointer(DirectFunctionCall1(boolout, BoolGetDatum(ex_lock))))
+ );
+
+ address = CreateTrigger(ivm_trigger, NULL, relOid, InvalidOid, InvalidOid,
+ InvalidOid, InvalidOid, InvalidOid, NULL, true, false);
+
+ recordDependencyOn(&address, &refaddr, DEPENDENCY_AUTO);
+
+ /* Make changes-so-far visible */
+ CommandCounterIncrement();
+}
+
+/*
+ * check_ivm_restriction --- look for specify nodes in the query tree
+ */
+static void
+check_ivm_restriction(Node *node)
+{
+ check_ivm_restriction_walker(node, NULL);
+}
+
+static bool
+check_ivm_restriction_walker(Node *node, void *context)
+{
+ if (node == NULL)
+ return false;
+
+ /*
+ * We currently don't support Sub-Query.
+ */
+ if (IsA(node, SubPlan) || IsA(node, SubLink))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("subquery is not supported on incrementally maintainable materialized view")));
+
+ /* This can recurse, so check for excessive recursion */
+ check_stack_depth();
+
+ switch (nodeTag(node))
+ {
+ case T_Query:
+ {
+ Query *qry = (Query *)node;
+ ListCell *lc;
+ List *vars;
+
+ /* if contained CTE, return error */
+ if (qry->cteList != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("CTE is not supported on incrementally maintainable materialized view")));
+ if (qry->havingQual != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg(" HAVING clause is not supported on incrementally maintainable materialized view")));
+ if (qry->sortClause != NIL) /* There is a possibility that we don't need to return an error */
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("ORDER BY clause is not supported on incrementally maintainable materialized view")));
+ if (qry->limitOffset != NULL || qry->limitCount != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view")));
+ if (qry->distinctClause)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("DISTINCT is not supported on incrementally maintainable materialized view")));
+ if (qry->hasDistinctOn)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("DISTINCT ON is not supported on incrementally maintainable materialized view")));
+ if (qry->hasWindowFuncs)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("window functions are not supported on incrementally maintainable materialized view")));
+ if (qry->groupingSets != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUPING SETS, ROLLUP, or CUBE clauses is not supported on incrementally maintainable materialized view")));
+ if (qry->setOperations != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("UNION/INTERSECT/EXCEPT statements are not supported on incrementally maintainable materialized view")));
+ if (list_length(qry->targetList) == 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("empty target list is not supported on incrementally maintainable materialized view")));
+ if (qry->rowMarks != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view")));
+
+ /* system column restrictions */
+ vars = pull_vars_of_level((Node *) qry, 0);
+ foreach(lc, vars)
+ {
+ if (IsA(lfirst(lc), Var))
+ {
+ Var *var = (Var *) lfirst(lc);
+ /* if system column, return error */
+ if (var->varattno < 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("system column is not supported on incrementally maintainable materialized view")));
+ }
+ }
+
+ /* restrictions for rtable */
+ foreach(lc, qry->rtable)
+ {
+ RangeTblEntry *rte = (RangeTblEntry *) lfirst(lc);
+
+ if (rte->subquery)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("subquery is not supported on incrementally maintainable materialized view")));
+
+ if (rte->tablesample != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("TABLESAMPLE clause is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitioned table is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_RELATION && has_superclass(rte->relid))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_RELATION && find_inheritance_children(rte->relid, NoLock) != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("inheritance parent is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_FOREIGN_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("foreign table is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_VIEW ||
+ rte->relkind == RELKIND_MATVIEW)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view")));
+
+ if (rte->rtekind == RTE_VALUES)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("VALUES is not supported on incrementally maintainable materialized view")));
+
+ }
+
+ query_tree_walker(qry, check_ivm_restriction_walker, NULL, QTW_IGNORE_RANGE_TABLE);
+
+ break;
+ }
+ case T_TargetEntry:
+ {
+ TargetEntry *tle = (TargetEntry *)node;
+ if (isIvmName(tle->resname))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("column name %s is not supported on incrementally maintainable materialized view", tle->resname)));
+
+ expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ break;
+ }
+ case T_JoinExpr:
+ {
+ JoinExpr *joinexpr = (JoinExpr *)node;
+
+ if (joinexpr->jointype > JOIN_INNER)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("OUTER JOIN is not supported on incrementally maintainable materialized view")));
+
+ expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ }
+ break;
+ case T_Aggref:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function is not supported on incrementally maintainable materialized view")));
+ break;
+ default:
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
+ break;
+ }
+ return false;
+}
+
+/*
+ * CreateIndexOnIMMV
+ *
+ * Create a unique index on incremental maintainable materialized view.
+ * If the view definition query has a GROUP BY clause, the index is created
+ * on the columns of GROUP BY expressions. Otherwise, if the view contains
+ * all primary key attritubes of its base tables in the target list, the index
+ * is created on these attritubes. In other cases, no index is created.
+ */
+void
+CreateIndexOnIMMV(Query *query, Relation matviewRel)
+{
+ ListCell *lc;
+ IndexStmt *index;
+ ObjectAddress address;
+ List *constraintList = NIL;
+ char idxname[NAMEDATALEN];
+ List *indexoidlist = RelationGetIndexList(matviewRel);
+ ListCell *indexoidscan;
+ Bitmapset *key_attnos;
+
+ snprintf(idxname, sizeof(idxname), "%s_index", RelationGetRelationName(matviewRel));
+
+ index = makeNode(IndexStmt);
+
+ index->unique = true;
+ index->primary = false;
+ index->isconstraint = false;
+ index->deferrable = false;
+ index->initdeferred = false;
+ index->idxname = idxname;
+ index->relation =
+ makeRangeVar(get_namespace_name(RelationGetNamespace(matviewRel)),
+ pstrdup(RelationGetRelationName(matviewRel)),
+ -1);
+ index->accessMethod = DEFAULT_INDEX_TYPE;
+ index->options = NIL;
+ index->tableSpace = get_tablespace_name(matviewRel->rd_rel->reltablespace);
+ index->whereClause = NULL;
+ index->indexParams = NIL;
+ index->indexIncludingParams = NIL;
+ index->excludeOpNames = NIL;
+ index->idxcomment = NULL;
+ index->indexOid = InvalidOid;
+ index->oldNumber = InvalidRelFileNumber;
+ index->oldCreateSubid = InvalidSubTransactionId;
+ index->oldFirstRelfilelocatorSubid = InvalidSubTransactionId;
+ index->transformed = true;
+ index->concurrent = false;
+ index->if_not_exists = false;
+
+ /* create index on the base tables' primary key columns */
+ key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
+ if (key_attnos)
+ {
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ }
+ else
+ {
+ /* create no index, just notice that an appropriate index is necessary for efficient IVM */
+ ereport(NOTICE,
+ (errmsg("could not create an index on materialized view \"%s\" automatically",
+ RelationGetRelationName(matviewRel)),
+ errdetail("This target list does not have all the primary key columns. "),
+ errhint("Create an index on the materialized view for efficient incremental maintenance.")));
+ return;
+ }
+
+ /* If we have a compatible index, we don't need to create another. */
+ foreach(indexoidscan, indexoidlist)
+ {
+ Oid indexoid = lfirst_oid(indexoidscan);
+ Relation indexRel;
+ bool hasCompatibleIndex = false;
+
+ indexRel = index_open(indexoid, AccessShareLock);
+
+ if (CheckIndexCompatible(indexRel->rd_id,
+ index->accessMethod,
+ index->indexParams,
+ index->excludeOpNames,
+ false))
+ hasCompatibleIndex = true;
+
+ index_close(indexRel, AccessShareLock);
+
+ if (hasCompatibleIndex)
+ return;
+ }
+
+ address = DefineIndex(RelationGetRelid(matviewRel),
+ index,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ -1,
+ false, true, false, false, true);
+
+ ereport(NOTICE,
+ (errmsg("created index \"%s\" on materialized view \"%s\"",
+ idxname, RelationGetRelationName(matviewRel))));
+
+ /*
+ * Make dependencies so that the index is dropped if any base tables's
+ * primary key is dropped.
+ */
+ foreach(lc, constraintList)
+ {
+ Oid constraintOid = lfirst_oid(lc);
+ ObjectAddress refaddr;
+
+ refaddr.classId = ConstraintRelationId;
+ refaddr.objectId = constraintOid;
+ refaddr.objectSubId = 0;
+
+ recordDependencyOn(&address, &refaddr, DEPENDENCY_NORMAL);
+ }
+}
+
+
+/*
+ * get_primary_key_attnos_from_query
+ *
+ * Identify the columns in base tables' primary keys in the target list.
+ *
+ * Returns a Bitmapset of the column attnos of the primary key's columns of
+ * tables that used in the query. The attnos are offset by
+ * FirstLowInvalidHeapAttributeNumber as same as get_primary_key_attnos.
+ *
+ * If any table has no primary key or any primary key's columns is not in
+ * the target list, return NULL. We also return NULL if any pkey constraint
+ * is deferrable.
+ *
+ * constraintList is set to a list of the OIDs of the pkey constraints.
+ */
+static Bitmapset *
+get_primary_key_attnos_from_query(Query *query, List **constraintList)
+{
+ List *key_attnos_list = NIL;
+ ListCell *lc;
+ int i;
+ Bitmapset *keys = NULL;
+ Relids rels_in_from;
+
+ /*
+ * Collect primary key attributes from all tables used in query. The key attributes
+ * sets for each table are stored in key_attnos_list in order by RTE index.
+ */
+ foreach(lc, query->rtable)
+ {
+ RangeTblEntry *r = (RangeTblEntry*) lfirst(lc);
+ Bitmapset *key_attnos;
+ bool has_pkey = true;
+
+ /* for tables, call get_primary_key_attnos */
+ if (r->rtekind == RTE_RELATION)
+ {
+ Oid constraintOid;
+ key_attnos = get_primary_key_attnos(r->relid, false, &constraintOid);
+ *constraintList = lappend_oid(*constraintList, constraintOid);
+ has_pkey = (key_attnos != NULL);
+ }
+ /* for other RTEs, store NULL into key_attnos_list */
+ else
+ key_attnos = NULL;
+
+ /*
+ * If any table or subquery has no primary key or its pkey constraint is deferrable,
+ * we cannot get key attributes for this query, so return NULL.
+ */
+ if (!has_pkey)
+ return NULL;
+
+ key_attnos_list = lappend(key_attnos_list, key_attnos);
+ }
+
+ /* Collect key attributes appearing in the target list */
+ i = 1;
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) flatten_join_alias_vars(NULL, query, lfirst(lc));
+
+ if (IsA(tle->expr, Var))
+ {
+ Var *var = (Var*) tle->expr;
+ Bitmapset *key_attnos = list_nth(key_attnos_list, var->varno - 1);
+
+ /* check if this attribute is from a base table's primary key */
+ if (bms_is_member(var->varattno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ /*
+ * Remove found key attributes from key_attnos_list, and add this
+ * to the result list.
+ */
+ key_attnos = bms_del_member(key_attnos, var->varattno - FirstLowInvalidHeapAttributeNumber);
+ if (bms_is_empty(key_attnos))
+ {
+ key_attnos_list = list_delete_nth_cell(key_attnos_list, var->varno - 1);
+ key_attnos_list = list_insert_nth(key_attnos_list, var->varno - 1, NULL);
+ }
+ keys = bms_add_member(keys, i - FirstLowInvalidHeapAttributeNumber);
+ }
+ }
+ i++;
+ }
+
+ /* Collect RTE indexes of relations appearing in the FROM clause */
+ rels_in_from = get_relids_in_jointree((Node *) query->jointree, false, false);
+
+ /*
+ * Check if all key attributes of relations in FROM are appearing in the target
+ * list. If an attribute remains in key_attnos_list in spite of the table is used
+ * in FROM clause, the target is missing this key attribute, so we return NULL.
+ */
+ i = 1;
+ foreach(lc, key_attnos_list)
+ {
+ Bitmapset *bms = (Bitmapset *)lfirst(lc);
+ if (!bms_is_empty(bms) && bms_is_member(i, rels_in_from))
+ return NULL;
+ i++;
+ }
+
+ return keys;
+}
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index 9ec13d0984..78a5dd1df9 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -23,23 +23,35 @@
#include "catalog/indexing.h"
#include "catalog/namespace.h"
#include "catalog/pg_am.h"
+#include "catalog/pg_depend.h"
+#include "catalog/pg_trigger.h"
#include "catalog/pg_opclass.h"
#include "commands/cluster.h"
#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
+#include "commands/createas.h"
#include "executor/executor.h"
#include "executor/spi.h"
+#include "executor/tstoreReceiver.h"
#include "miscadmin.h"
+#include "nodes/makefuncs.h"
+#include "parser/analyze.h"
+#include "parser/parse_clause.h"
+#include "parser/parse_func.h"
+#include "parser/parse_relation.h"
#include "pgstat.h"
#include "rewrite/rewriteHandler.h"
+#include "rewrite/rowsecurity.h"
#include "storage/lmgr.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
+#include "utils/fmgroids.h"
#include "utils/lsyscache.h"
#include "utils/rel.h"
#include "utils/snapmgr.h"
#include "utils/syscache.h"
+#include "utils/typcache.h"
typedef struct
@@ -53,6 +65,52 @@ typedef struct
BulkInsertState bistate; /* bulk insert state */
} DR_transientrel;
+#define MV_INIT_QUERYHASHSIZE 16
+
+/*
+ * MV_TriggerHashEntry
+ *
+ * Hash entry for base tables on which IVM trigger is invoked
+ */
+typedef struct MV_TriggerHashEntry
+{
+ Oid matview_id; /* OID of the materialized view */
+ int before_trig_count; /* count of before triggers invoked */
+ int after_trig_count; /* count of after triggers invoked */
+
+ Snapshot snapshot; /* Snapshot just before table change */
+
+ List *tables; /* List of MV_TriggerTable */
+ bool has_old; /* tuples are deleted from any table? */
+ bool has_new; /* tuples are inserted into any table? */
+} MV_TriggerHashEntry;
+
+/*
+ * MV_TriggerTable
+ *
+ * IVM related data for tables on which the trigger is invoked.
+ */
+typedef struct MV_TriggerTable
+{
+ Oid table_id; /* OID of the modified table */
+ List *old_tuplestores; /* tuplestores for deleted tuples */
+ List *new_tuplestores; /* tuplestores for inserted tuples */
+
+ List *rte_indexes; /* List of RTE index of the modified table */
+ RangeTblEntry *original_rte; /* the original RTE saved before rewriting query */
+
+ Relation rel; /* relation of the modified table */
+ TupleTableSlot *slot; /* for checking visibility in the pre-state table */
+} MV_TriggerTable;
+
+static HTAB *mv_trigger_info = NULL;
+
+static bool in_delta_calculation = false;
+
+/* ENR name for materialized view delta */
+#define NEW_DELTA_ENRNAME "new_delta"
+#define OLD_DELTA_ENRNAME "old_delta"
+
static int matview_maintenance_depth = 0;
static void transientrel_startup(DestReceiver *self, int operation, TupleDesc typeinfo);
@@ -60,7 +118,9 @@ static bool transientrel_receive(TupleTableSlot *slot, DestReceiver *self);
static void transientrel_shutdown(DestReceiver *self);
static void transientrel_destroy(DestReceiver *self);
static uint64 refresh_matview_datafill(DestReceiver *dest, Query *query,
- const char *queryString);
+ QueryEnvironment *queryEnv,
+ TupleDesc *resultTupleDesc,
+ const char *queryString);
static char *make_temptable_name_n(char *tempname, int n);
static void refresh_by_match_merge(Oid matviewOid, Oid tempOid, Oid relowner,
int save_sec_context);
@@ -68,6 +128,37 @@ static void refresh_by_heap_swap(Oid matviewOid, Oid OIDNewHeap, char relpersist
static bool is_usable_unique_index(Relation indexRel);
static void OpenMatViewIncrementalMaintenance(void);
static void CloseMatViewIncrementalMaintenance(void);
+static Query *get_matview_query(Relation matviewRel);
+
+static Query *rewrite_query_for_preupdate_state(Query *query, List *tables,
+ ParseState *pstate, Oid matviewid);
+static void register_delta_ENRs(ParseState *pstate, Query *query, List *tables);
+static char *make_delta_enr_name(const char *prefix, Oid relid, int count);
+static RangeTblEntry *get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *table,
+ QueryEnvironment *queryEnv, Oid matviewid);
+static RangeTblEntry *replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
+ QueryEnvironment *queryEnv);
+static Query *rewrite_query_for_counting(Query *query, ParseState *pstate);
+
+static void calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
+ DestReceiver *dest_old, DestReceiver *dest_new,
+ TupleDesc *tupdesc_old, TupleDesc *tupdesc_new,
+ QueryEnvironment *queryEnv);
+static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte_index);
+
+static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
+ TupleDesc tupdesc_old, TupleDesc tupdesc_new,
+ Query *query);
+static void apply_old_delta(const char *matviewname, const char *deltaname_old,
+ List *keys);
+static void apply_new_delta(const char *matviewname, const char *deltaname_new,
+ StringInfo target_list);
+static char *get_matching_condition_string(List *keys);
+static void generate_equal(StringInfo querybuf, Oid opttype,
+ const char *leftop, const char *rightop);
+
+static void mv_InitHashTables(void);
+static void clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort);
/*
* SetMatViewPopulatedState
@@ -109,6 +200,46 @@ SetMatViewPopulatedState(Relation relation, bool newstate)
CommandCounterIncrement();
}
+/*
+ * SetMatViewIVMState
+ * Mark a materialized view as IVM, or not.
+ *
+ * NOTE: caller must be holding an appropriate lock on the relation.
+ */
+void
+SetMatViewIVMState(Relation relation, bool newstate)
+{
+ Relation pgrel;
+ HeapTuple tuple;
+
+ Assert(relation->rd_rel->relkind == RELKIND_MATVIEW);
+
+ /*
+ * Update relation's pg_class entry. Crucial side-effect: other backends
+ * (and this one too!) are sent SI message to make them rebuild relcache
+ * entries.
+ */
+ pgrel = table_open(RelationRelationId, RowExclusiveLock);
+ tuple = SearchSysCacheCopy1(RELOID,
+ ObjectIdGetDatum(RelationGetRelid(relation)));
+ if (!HeapTupleIsValid(tuple))
+ elog(ERROR, "cache lookup failed for relation %u",
+ RelationGetRelid(relation));
+
+ ((Form_pg_class) GETSTRUCT(tuple))->relisivm = newstate;
+
+ CatalogTupleUpdate(pgrel, &tuple->t_self, tuple);
+
+ heap_freetuple(tuple);
+ table_close(pgrel, RowExclusiveLock);
+
+ /*
+ * Advance command counter to make the updated pg_class row locally
+ * visible.
+ */
+ CommandCounterIncrement();
+}
+
/*
* ExecRefreshMatView -- execute a REFRESH MATERIALIZED VIEW command
*
@@ -135,8 +266,6 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
{
Oid matviewOid;
Relation matviewRel;
- RewriteRule *rule;
- List *actions;
Query *dataQuery;
Oid tableSpace;
Oid relowner;
@@ -150,6 +279,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
int save_sec_context;
int save_nestlevel;
ObjectAddress address;
+ bool oldPopulated;
/* Determine strength of lock needed. */
concurrent = stmt->concurrent;
@@ -176,6 +306,8 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
save_nestlevel = NewGUCNestLevel();
RestrictSearchPath();
+ oldPopulated = RelationIsPopulated(matviewRel);
+
/* Make sure it is a materialized view. */
if (matviewRel->rd_rel->relkind != RELKIND_MATVIEW)
ereport(ERROR,
@@ -196,32 +328,9 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
errmsg("%s and %s options cannot be used together",
"CONCURRENTLY", "WITH NO DATA")));
- /*
- * Check that everything is correct for a refresh. Problems at this point
- * are internal errors, so elog is sufficient.
- */
- if (matviewRel->rd_rel->relhasrules == false ||
- matviewRel->rd_rules->numLocks < 1)
- elog(ERROR,
- "materialized view \"%s\" is missing rewrite information",
- RelationGetRelationName(matviewRel));
-
- if (matviewRel->rd_rules->numLocks > 1)
- elog(ERROR,
- "materialized view \"%s\" has too many rules",
- RelationGetRelationName(matviewRel));
- rule = matviewRel->rd_rules->rules[0];
- if (rule->event != CMD_SELECT || !(rule->isInstead))
- elog(ERROR,
- "the rule for materialized view \"%s\" is not a SELECT INSTEAD OF rule",
- RelationGetRelationName(matviewRel));
+ dataQuery = get_matview_query(matviewRel);
- actions = rule->actions;
- if (list_length(actions) != 1)
- elog(ERROR,
- "the rule for materialized view \"%s\" is not a single action",
- RelationGetRelationName(matviewRel));
/*
* Check that there is a unique index with no WHERE clause on one or more
@@ -256,12 +365,6 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
errhint("Create a unique index with no WHERE clause on one or more columns of the materialized view.")));
}
- /*
- * The stored query was rewritten at the time of the MV definition, but
- * has not been scribbled on by the planner.
- */
- dataQuery = linitial_node(Query, actions);
-
/*
* Check for active uses of the relation in the current transaction, such
* as open scans.
@@ -289,6 +392,74 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
relpersistence = matviewRel->rd_rel->relpersistence;
}
+ /* delete IMMV triggers. */
+ if (RelationIsIVM(matviewRel) && stmt->skipData )
+ {
+ Relation tgRel;
+ Relation depRel;
+ ScanKeyData key;
+ SysScanDesc scan;
+ HeapTuple tup;
+ ObjectAddresses *immv_triggers;
+
+ immv_triggers = new_object_addresses();
+
+ tgRel = table_open(TriggerRelationId, RowExclusiveLock);
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ /* search triggers that depends on IMMV. */
+ ScanKeyInit(&key,
+ Anum_pg_depend_refobjid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(matviewOid));
+ scan = systable_beginscan(depRel, DependReferenceIndexId, true,
+ NULL, 1, &key);
+ while ((tup = systable_getnext(scan)) != NULL)
+ {
+ ObjectAddress obj;
+ Form_pg_depend foundDep = (Form_pg_depend) GETSTRUCT(tup);
+
+ if (foundDep->classid == TriggerRelationId)
+ {
+ HeapTuple tgtup;
+ ScanKeyData tgkey[1];
+ SysScanDesc tgscan;
+ Form_pg_trigger tgform;
+
+ /* Find the trigger name. */
+ ScanKeyInit(&tgkey[0],
+ Anum_pg_trigger_oid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(foundDep->objid));
+
+ tgscan = systable_beginscan(tgRel, TriggerOidIndexId, true,
+ NULL, 1, tgkey);
+ tgtup = systable_getnext(tgscan);
+ if (!HeapTupleIsValid(tgtup))
+ elog(ERROR, "could not find tuple for immv trigger %u", foundDep->objid);
+
+ tgform = (Form_pg_trigger) GETSTRUCT(tgtup);
+
+ /* If trigger is created by IMMV, delete it. */
+ if (strncmp(NameStr(tgform->tgname), "IVM_trigger_", 12) == 0)
+ {
+ obj.classId = foundDep->classid;
+ obj.objectId = foundDep->objid;
+ obj.objectSubId = foundDep->refobjsubid;
+ add_exact_object_address(&obj, immv_triggers);
+ }
+ systable_endscan(tgscan);
+ }
+ }
+ systable_endscan(scan);
+
+ performMultipleDeletions(immv_triggers, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ table_close(depRel, RowExclusiveLock);
+ table_close(tgRel, RowExclusiveLock);
+ free_object_addresses(immv_triggers);
+ }
+
/*
* Create the transient table that will receive the regenerated data. Lock
* it against access by any other process until commit (by which time it
@@ -302,7 +473,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
/* Generate the data, if wanted. */
if (!stmt->skipData)
- processed = refresh_matview_datafill(dest, dataQuery, queryString);
+ processed = refresh_matview_datafill(dest, dataQuery, NULL, NULL, queryString);
/* Make the matview match the newly generated data. */
if (concurrent)
@@ -337,6 +508,12 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
pgstat_count_heap_insert(matviewRel, processed);
}
+ if (!stmt->skipData && RelationIsIVM(matviewRel) && !oldPopulated)
+ {
+ CreateIndexOnIMMV(dataQuery, matviewRel);
+ CreateIvmTriggersOnBaseTables(dataQuery, matviewOid);
+ }
+
table_close(matviewRel, NoLock);
/* Roll back any GUC changes */
@@ -371,6 +548,8 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
*/
static uint64
refresh_matview_datafill(DestReceiver *dest, Query *query,
+ QueryEnvironment *queryEnv,
+ TupleDesc *resultTupleDesc,
const char *queryString)
{
List *rewritten;
@@ -407,7 +586,7 @@ refresh_matview_datafill(DestReceiver *dest, Query *query,
/* Create a QueryDesc, redirecting output to our tuple receiver */
queryDesc = CreateQueryDesc(plan, queryString,
GetActiveSnapshot(), InvalidSnapshot,
- dest, NULL, NULL, 0);
+ dest, NULL, queryEnv ? queryEnv: NULL, 0);
/* call ExecutorStart to prepare the plan for execution */
ExecutorStart(queryDesc, 0);
@@ -417,6 +596,9 @@ refresh_matview_datafill(DestReceiver *dest, Query *query,
processed = queryDesc->estate->es_processed;
+ if (resultTupleDesc)
+ *resultTupleDesc = CreateTupleDescCopy(queryDesc->tupDesc);
+
/* and clean up */
ExecutorFinish(queryDesc);
ExecutorEnd(queryDesc);
@@ -952,3 +1134,1219 @@ CloseMatViewIncrementalMaintenance(void)
matview_maintenance_depth--;
Assert(matview_maintenance_depth >= 0);
}
+
+/*
+ * get_matview_query - get the Query from a matview's _RETURN rule.
+ */
+static Query *
+get_matview_query(Relation matviewRel)
+{
+ RewriteRule *rule;
+ List * actions;
+
+ /*
+ * Check that everything is correct for a refresh. Problems at this point
+ * are internal errors, so elog is sufficient.
+ */
+ if (matviewRel->rd_rel->relhasrules == false ||
+ matviewRel->rd_rules->numLocks < 1)
+ elog(ERROR,
+ "materialized view \"%s\" is missing rewrite information",
+ RelationGetRelationName(matviewRel));
+
+ if (matviewRel->rd_rules->numLocks > 1)
+ elog(ERROR,
+ "materialized view \"%s\" has too many rules",
+ RelationGetRelationName(matviewRel));
+
+ rule = matviewRel->rd_rules->rules[0];
+ if (rule->event != CMD_SELECT || !(rule->isInstead))
+ elog(ERROR,
+ "the rule for materialized view \"%s\" is not a SELECT INSTEAD OF rule",
+ RelationGetRelationName(matviewRel));
+
+ actions = rule->actions;
+ if (list_length(actions) != 1)
+ elog(ERROR,
+ "the rule for materialized view \"%s\" is not a single action",
+ RelationGetRelationName(matviewRel));
+
+ /*
+ * The stored query was rewritten at the time of the MV definition, but
+ * has not been scribbled on by the planner.
+ */
+ return linitial_node(Query, actions);
+}
+
+
+/* ----------------------------------------------------
+ * Incremental View Maintenance routines
+ * ---------------------------------------------------
+ */
+
+/*
+ * IVM_immediate_before
+ *
+ * IVM trigger function invoked before base table is modified. If this is
+ * invoked firstly in the same statement, we save the transaction id and the
+ * command id at that time.
+ */
+Datum
+IVM_immediate_before(PG_FUNCTION_ARGS)
+{
+ TriggerData *trigdata = (TriggerData *) fcinfo->context;
+ char *matviewOid_text = trigdata->tg_trigger->tgargs[0];
+ char *ex_lock_text = trigdata->tg_trigger->tgargs[1];
+ Oid matviewOid;
+ MV_TriggerHashEntry *entry;
+ bool found;
+ bool ex_lock;
+
+ matviewOid = DatumGetObjectId(DirectFunctionCall1(oidin, CStringGetDatum(matviewOid_text)));
+ ex_lock = DatumGetBool(DirectFunctionCall1(boolin, CStringGetDatum(ex_lock_text)));
+
+ /* If the view has more than one tables, we have to use an exclusive lock. */
+ if (ex_lock)
+ {
+ /*
+ * Wait for concurrent transactions which update this materialized view at
+ * READ COMMITED. This is needed to see changes committed in other
+ * transactions. No wait and raise an error at REPEATABLE READ or
+ * SERIALIZABLE to prevent update anomalies of matviews.
+ * XXX: dead-lock is possible here.
+ */
+ if (!IsolationUsesXactSnapshot())
+ LockRelationOid(matviewOid, ExclusiveLock);
+ else if (!ConditionalLockRelationOid(matviewOid, ExclusiveLock))
+ {
+ /* try to throw error by name; relation could be deleted... */
+ char *relname = get_rel_name(matviewOid);
+
+ if (!relname)
+ ereport(ERROR,
+ (errcode(ERRCODE_LOCK_NOT_AVAILABLE),
+ errmsg("could not obtain lock on materialized view during incremental maintenance")));
+
+ ereport(ERROR,
+ (errcode(ERRCODE_LOCK_NOT_AVAILABLE),
+ errmsg("could not obtain lock on materialized view \"%s\" during incremental maintenance",
+ relname)));
+ }
+ }
+ else
+ LockRelationOid(matviewOid, RowExclusiveLock);
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_trigger_info)
+ mv_InitHashTables();
+
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_ENTER, &found);
+
+ /* On the first BEFORE to update the view, initialize trigger data */
+ if (!found)
+ {
+ /*
+ * Get a snapshot just before the table was modified for checking
+ * tuple visibility in the pre-update state of the table.
+ */
+ Snapshot snapshot = GetActiveSnapshot();
+
+ entry->matview_id = matviewOid;
+ entry->before_trig_count = 0;
+ entry->after_trig_count = 0;
+ entry->snapshot = RegisterSnapshot(snapshot);
+ entry->tables = NIL;
+ entry->has_old = false;
+ entry->has_new = false;
+ }
+
+ entry->before_trig_count++;
+
+ return PointerGetDatum(NULL);
+}
+
+/*
+ * IVM_immediate_maintenance
+ *
+ * IVM trigger function invoked after base table is modified.
+ * For each table, tuplestores of transition tables are collected.
+ * and after the last modification
+ */
+Datum
+IVM_immediate_maintenance(PG_FUNCTION_ARGS)
+{
+ TriggerData *trigdata = (TriggerData *) fcinfo->context;
+ Relation rel;
+ Oid relid;
+ Oid matviewOid;
+ Query *query;
+ Query *rewritten = NULL;
+ char *matviewOid_text = trigdata->tg_trigger->tgargs[0];
+ Relation matviewRel;
+ int old_depth = matview_maintenance_depth;
+
+ Oid relowner;
+ Tuplestorestate *old_tuplestore = NULL;
+ Tuplestorestate *new_tuplestore = NULL;
+ DestReceiver *dest_new = NULL, *dest_old = NULL;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ MV_TriggerHashEntry *entry;
+ MV_TriggerTable *table;
+ bool found;
+
+ ParseState *pstate;
+ QueryEnvironment *queryEnv = create_queryEnv();
+ MemoryContext oldcxt;
+ ListCell *lc;
+ int i;
+
+
+ /* Create a ParseState for rewriting the view definition query */
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ rel = trigdata->tg_relation;
+ relid = rel->rd_id;
+
+ matviewOid = DatumGetObjectId(DirectFunctionCall1(oidin, CStringGetDatum(matviewOid_text)));
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_trigger_info)
+ mv_InitHashTables();
+
+ /* get the entry for this materialized view */
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_FIND, &found);
+ Assert (found && entry != NULL);
+ entry->after_trig_count++;
+
+ /* search the entry for the modified table and create new entry if not found */
+ found = false;
+ foreach(lc, entry->tables)
+ {
+ table = (MV_TriggerTable *) lfirst(lc);
+ if (table->table_id == relid)
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ table = (MV_TriggerTable *) palloc0(sizeof(MV_TriggerTable));
+ table->table_id = relid;
+ table->old_tuplestores = NIL;
+ table->new_tuplestores = NIL;
+ table->rte_indexes = NIL;
+ table->slot = MakeSingleTupleTableSlot(RelationGetDescr(rel), table_slot_callbacks(rel));
+ table->rel = table_open(RelationGetRelid(rel), NoLock);
+ entry->tables = lappend(entry->tables, table);
+
+ MemoryContextSwitchTo(oldcxt);
+ }
+
+ /* Save the transition tables and make a request to not free immediately */
+ if (trigdata->tg_oldtable)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+ table->old_tuplestores = lappend(table->old_tuplestores, trigdata->tg_oldtable);
+ entry->has_old = true;
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (trigdata->tg_newtable)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+ table->new_tuplestores = lappend(table->new_tuplestores, trigdata->tg_newtable);
+ entry->has_new = true;
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (entry->has_new || entry->has_old)
+ {
+ CmdType cmd;
+
+ if (TRIGGER_FIRED_BY_INSERT(trigdata->tg_event))
+ cmd = CMD_INSERT;
+ else if (TRIGGER_FIRED_BY_DELETE(trigdata->tg_event))
+ cmd = CMD_DELETE;
+ else if (TRIGGER_FIRED_BY_UPDATE(trigdata->tg_event))
+ cmd = CMD_UPDATE;
+ else
+ elog(ERROR,"unsupported trigger type");
+
+ /* Prolong lifespan of transition tables to the end of the last AFTER trigger */
+ SetTransitionTablePreserved(relid, cmd);
+ }
+
+
+ /* If this is not the last AFTER trigger call, immediately exit. */
+ Assert (entry->before_trig_count >= entry->after_trig_count);
+ if (entry->before_trig_count != entry->after_trig_count)
+ return PointerGetDatum(NULL);
+
+ /*
+ * If this is the last AFTER trigger call, continue and update the view.
+ */
+
+ /*
+ * Advance command counter to make the updated base table row locally
+ * visible.
+ */
+ CommandCounterIncrement();
+
+ matviewRel = table_open(matviewOid, NoLock);
+
+ /* Make sure it is a materialized view. */
+ Assert(matviewRel->rd_rel->relkind == RELKIND_MATVIEW);
+
+ /*
+ * Get and push the latast snapshot to see any changes which is committed
+ * during waiting in other transactions at READ COMMITTED level.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /*
+ * Check for active uses of the relation in the current transaction, such
+ * as open scans.
+ *
+ * NB: We count on this to protect us against problems with refreshing the
+ * data using TABLE_INSERT_FROZEN.
+ */
+ CheckTableNotInUse(matviewRel, "refresh a materialized view incrementally");
+
+ /*
+ * Switch to the owner's userid, so that any functions are run as that
+ * user. Also arrange to make GUC variable changes local to this command.
+ * We will switch modes when we are about to execute user code.
+ */
+ relowner = matviewRel->rd_rel->relowner;
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+
+ /* get view query*/
+ query = get_matview_query(matviewRel);
+
+ /*
+ * When a base table is truncated, the view content will be empty if the
+ * view definition query does not contain an aggregate without a GROUP clause.
+ * Therefore, such views can be truncated.
+ */
+ if (TRIGGER_FIRED_BY_TRUNCATE(trigdata->tg_event))
+ {
+ ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
+ NIL, DROP_RESTRICT, false, false);
+
+ /* Clean up hash entry and delete tuplestores */
+ clean_up_IVM_hash_entry(entry, false);
+
+ /* Pop the original snapshot. */
+ PopActiveSnapshot();
+
+ table_close(matviewRel, NoLock);
+
+ /* Roll back any GUC changes */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ return PointerGetDatum(NULL);
+ }
+
+ /*
+ * rewrite query for calculating deltas
+ */
+
+ rewritten = copyObject(query);
+
+ /* Replace resnames in a target list with materialized view's attnames */
+ i = 0;
+ foreach (lc, rewritten->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
+
+ tle->resname = pstrdup(resname);
+ i++;
+ }
+
+ /* Set all tables in the query to pre-update state */
+ rewritten = rewrite_query_for_preupdate_state(rewritten, entry->tables,
+ pstate, matviewOid);
+ /* Rewrite for counting duplicated tuples */
+ rewritten = rewrite_query_for_counting(rewritten, pstate);
+
+ /* Create tuplestores to store view deltas */
+ if (entry->has_old)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ old_tuplestore = tuplestore_begin_heap(false, false, work_mem);
+ dest_old = CreateDestReceiver(DestTuplestore);
+ SetTuplestoreDestReceiverParams(dest_old,
+ old_tuplestore,
+ TopTransactionContext,
+ false,
+ NULL,
+ NULL);
+
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (entry->has_new)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ new_tuplestore = tuplestore_begin_heap(false, false, work_mem);
+ dest_new = CreateDestReceiver(DestTuplestore);
+ SetTuplestoreDestReceiverParams(dest_new,
+ new_tuplestore,
+ TopTransactionContext,
+ false,
+ NULL,
+ NULL);
+ MemoryContextSwitchTo(oldcxt);
+ }
+
+ /* for all modified tables */
+ foreach(lc, entry->tables)
+ {
+ ListCell *lc2;
+
+ table = (MV_TriggerTable *) lfirst(lc);
+
+ /* loop for self-join */
+ foreach(lc2, table->rte_indexes)
+ {
+ int rte_index = lfirst_int(lc2);
+ TupleDesc tupdesc_old;
+ TupleDesc tupdesc_new;
+
+ /* calculate delta tables */
+ calc_delta(table, rte_index, rewritten, dest_old, dest_new,
+ &tupdesc_old, &tupdesc_new, queryEnv);
+
+ /* Set the table in the query to post-update state */
+ rewritten = rewrite_query_for_postupdate_state(rewritten, table, rte_index);
+
+ PG_TRY();
+ {
+ /* apply the delta tables to the materialized view */
+ apply_delta(matviewOid, old_tuplestore, new_tuplestore,
+ tupdesc_old, tupdesc_new, query);
+ }
+ PG_CATCH();
+ {
+ matview_maintenance_depth = old_depth;
+ PG_RE_THROW();
+ }
+ PG_END_TRY();
+
+ /* clear view delta tuplestores */
+ if (old_tuplestore)
+ tuplestore_clear(old_tuplestore);
+ if (new_tuplestore)
+ tuplestore_clear(new_tuplestore);
+ }
+ }
+
+ /* Clean up hash entry and delete tuplestores */
+ clean_up_IVM_hash_entry(entry, false);
+ if (old_tuplestore)
+ {
+ dest_old->rDestroy(dest_old);
+ tuplestore_end(old_tuplestore);
+ }
+ if (new_tuplestore)
+ {
+ dest_new->rDestroy(dest_new);
+ tuplestore_end(new_tuplestore);
+ }
+
+ /* Pop the original snapshot. */
+ PopActiveSnapshot();
+
+ table_close(matviewRel, NoLock);
+
+ /* Roll back any GUC changes */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ return PointerGetDatum(NULL);
+}
+
+/*
+ * rewrite_query_for_preupdate_state
+ *
+ * Rewrite the query so that base tables' RTEs will represent "pre-update"
+ * state of tables. This is necessary to calculate view delta after multiple
+ * tables are modified.
+ */
+static Query*
+rewrite_query_for_preupdate_state(Query *query, List *tables,
+ ParseState *pstate, Oid matviewid)
+{
+ ListCell *lc;
+ int num_rte = list_length(query->rtable);
+ int i;
+
+
+ /* register delta ENRs */
+ register_delta_ENRs(pstate, query, tables);
+
+ /* XXX: Is necessary? Is this right timing? */
+ AcquireRewriteLocks(query, true, false);
+
+ i = 1;
+ foreach(lc, query->rtable)
+ {
+ RangeTblEntry *r = (RangeTblEntry*) lfirst(lc);
+
+ ListCell *lc2;
+ foreach(lc2, tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc2);
+ /*
+ * if the modified table is found then replace the original RTE with
+ * "pre-state" RTE and append its index to the list.
+ */
+ if (r->relid == table->table_id)
+ {
+ List *securityQuals;
+ List *withCheckOptions;
+ bool hasRowSecurity;
+ bool hasSubLinks;
+
+ RangeTblEntry *rte_pre = get_prestate_rte(r, table, pstate->p_queryEnv, matviewid);
+
+ /*
+ * Set a row security poslicies of the modified table to the subquery RTE which
+ * represents the pre-update state of the table.
+ */
+ get_row_security_policies(query, table->original_rte, i,
+ &securityQuals, &withCheckOptions,
+ &hasRowSecurity, &hasSubLinks);
+
+ if (hasRowSecurity)
+ {
+ query->hasRowSecurity = true;
+ rte_pre->security_barrier = true;
+ }
+ if (hasSubLinks)
+ query->hasSubLinks = true;
+
+ rte_pre->securityQuals = securityQuals;
+ lfirst(lc) = rte_pre;
+
+ table->rte_indexes = lappend_int(table->rte_indexes, i);
+ break;
+ }
+ }
+
+ /* finish the loop if we processed all RTE included in the original query */
+ if (i++ >= num_rte)
+ break;
+ }
+
+ return query;
+}
+
+/*
+ * register_delta_ENRs
+ *
+ * For all modified tables, make ENRs for their transition tables
+ * and register them to the queryEnv. ENR's RTEs are also appended
+ * into the list in query tree.
+ */
+static void
+register_delta_ENRs(ParseState *pstate, Query *query, List *tables)
+{
+ QueryEnvironment *queryEnv = pstate->p_queryEnv;
+ ListCell *lc;
+ RangeTblEntry *rte;
+
+ foreach(lc, tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc);
+ ListCell *lc2;
+ int count;
+
+ count = 0;
+ foreach(lc2, table->old_tuplestores)
+ {
+ Tuplestorestate *oldtable = (Tuplestorestate *) lfirst(lc2);
+ EphemeralNamedRelation enr =
+ palloc(sizeof(EphemeralNamedRelationData));
+ ParseNamespaceItem *nsitem;
+
+ enr->md.name = make_delta_enr_name("old", table->table_id, count);
+ enr->md.reliddesc = table->table_id;
+ enr->md.tupdesc = NULL;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(oldtable);
+ enr->reldata = oldtable;
+ register_ENR(queryEnv, enr);
+
+ nsitem = addRangeTableEntryForENR(pstate, makeRangeVar(NULL, enr->md.name, -1), true);
+ rte = nsitem->p_rte;
+
+ query->rtable = lappend(query->rtable, rte);
+
+ count++;
+ }
+
+ count = 0;
+ foreach(lc2, table->new_tuplestores)
+ {
+ Tuplestorestate *newtable = (Tuplestorestate *) lfirst(lc2);
+ EphemeralNamedRelation enr =
+ palloc(sizeof(EphemeralNamedRelationData));
+ ParseNamespaceItem *nsitem;
+
+ enr->md.name = make_delta_enr_name("new", table->table_id, count);
+ enr->md.reliddesc = table->table_id;
+ enr->md.tupdesc = NULL;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(newtable);
+ enr->reldata = newtable;
+ register_ENR(queryEnv, enr);
+
+ nsitem = addRangeTableEntryForENR(pstate, makeRangeVar(NULL, enr->md.name, -1), true);
+ rte = nsitem->p_rte;
+
+ query->rtable = lappend(query->rtable, rte);
+
+ count++;
+ }
+ }
+}
+
+#define DatumGetItemPointer(X) ((ItemPointer) DatumGetPointer(X))
+#define PG_GETARG_ITEMPOINTER(n) DatumGetItemPointer(PG_GETARG_DATUM(n))
+
+/*
+ * ivm_visible_in_prestate
+ *
+ * Check visibility of a tuple specified by the tableoid and item pointer
+ * using the snapshot taken just before the table was modified.
+ */
+Datum
+ivm_visible_in_prestate(PG_FUNCTION_ARGS)
+{
+ Oid tableoid = PG_GETARG_OID(0);
+ ItemPointer itemPtr = PG_GETARG_ITEMPOINTER(1);
+ Oid matviewOid = PG_GETARG_OID(2);
+ MV_TriggerHashEntry *entry;
+ MV_TriggerTable *table = NULL;
+ ListCell *lc;
+ bool found;
+ bool result;
+
+ if (!in_delta_calculation)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("ivm_visible_in_prestate can be called only in delta calculation")));
+
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_FIND, &found);
+ Assert (found && entry != NULL);
+
+ foreach(lc, entry->tables)
+ {
+ table = (MV_TriggerTable *) lfirst(lc);
+ if (table->table_id == tableoid)
+ break;
+ }
+
+ Assert (table != NULL);
+
+ result = table_tuple_fetch_row_version(table->rel, itemPtr, entry->snapshot, table->slot);
+
+ PG_RETURN_BOOL(result);
+}
+
+/*
+ * get_prestate_rte
+ *
+ * Rewrite RTE of the modified table to a subquery which represents
+ * "pre-state" table. The original RTE is saved in table->rte_original.
+ */
+static RangeTblEntry*
+get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *table,
+ QueryEnvironment *queryEnv, Oid matviewid)
+{
+ StringInfoData str;
+ RawStmt *raw;
+ Query *subquery;
+ Relation rel;
+ ParseState *pstate;
+ char *relname;
+ int i;
+
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ /*
+ * We can use NoLock here since AcquireRewriteLocks should
+ * have locked the relation already.
+ */
+ rel = table_open(table->table_id, NoLock);
+ relname = quote_qualified_identifier(
+ get_namespace_name(RelationGetNamespace(rel)),
+ RelationGetRelationName(rel));
+ table_close(rel, NoLock);
+
+ /*
+ * Filtering inserted row using the snapshot taken before the table
+ * is modified. ctid is required for maintaining outer join views.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str,
+ "SELECT t.* FROM %s t"
+ " WHERE pg_catalog.ivm_visible_in_prestate(t.tableoid, t.ctid ,%d::pg_catalog.oid)",
+ relname, matviewid);
+
+ /*
+ * Append deleted rows contained in old transition tables.
+ */
+ for (i = 0; i < list_length(table->old_tuplestores); i++)
+ {
+ appendStringInfo(&str, " UNION ALL ");
+ appendStringInfo(&str," SELECT * FROM %s",
+ make_delta_enr_name("old", table->table_id, i));
+ }
+
+ /* Get a subquery representing pre-state of the table */
+ raw = (RawStmt*)linitial(raw_parser(str.data, RAW_PARSE_DEFAULT));
+ subquery = transformStmt(pstate, raw->stmt);
+
+ /* save the original RTE */
+ table->original_rte = copyObject(rte);
+
+ rte->rtekind = RTE_SUBQUERY;
+ rte->subquery = subquery;
+ rte->security_barrier = false;
+
+ /* Clear fields that should not be set in a subquery RTE */
+ rte->relid = InvalidOid;
+ rte->relkind = 0;
+ rte->rellockmode = 0;
+ rte->tablesample = NULL;
+ rte->perminfoindex = 0; /* no permission checking for this RTE */
+ rte->inh = false; /* must not be set for a subquery */
+
+ return rte;
+}
+
+/*
+ * make_delta_enr_name
+ *
+ * Make a name for ENR of a transition table from the base table's oid.
+ * prefix will be "new" or "old" depending on its transition table kind..
+ */
+static char*
+make_delta_enr_name(const char *prefix, Oid relid, int count)
+{
+ char buf[NAMEDATALEN];
+ char *name;
+
+ snprintf(buf, NAMEDATALEN, "__ivm_%s_%u_%u", prefix, relid, count);
+ name = pstrdup(buf);
+
+ return name;
+}
+
+/*
+ * replace_rte_with_delta
+ *
+ * Replace RTE of the modified table with a single table delta that combine its
+ * all transition tables.
+ */
+static RangeTblEntry*
+replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
+ QueryEnvironment *queryEnv)
+{
+ Oid relid = table->table_id;
+ StringInfoData str;
+ ParseState *pstate;
+ RawStmt *raw;
+ Query *sub;
+ int num_tuplestores = list_length(is_new ? table->new_tuplestores : table->old_tuplestores);
+ int i;
+
+ /* the previous RTE must be a subquery which represents "pre-state" table */
+ Assert(rte->rtekind == RTE_SUBQUERY);
+
+ /* Create a ParseState for rewriting the view definition query */
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ initStringInfo(&str);
+
+ for (i = 0; i < num_tuplestores; i++)
+ {
+ if (i > 0)
+ appendStringInfo(&str, " UNION ALL ");
+
+ appendStringInfo(&str,
+ " SELECT * FROM %s",
+ make_delta_enr_name(is_new ? "new" : "old", relid, i));
+ }
+
+ raw = (RawStmt*)linitial(raw_parser(str.data, RAW_PARSE_DEFAULT));
+ sub = transformStmt(pstate, raw->stmt);
+
+ /*
+ * Update the subquery so that it represent the combined transition
+ * table. Note that we leave the security_barrier and securityQuals
+ * fields so that the subquery relation can be protected by the RLS
+ * policy as same as the modified table.
+ */
+ rte->rtekind = RTE_SUBQUERY;
+ rte->subquery = sub;
+
+ return rte;
+}
+
+/*
+ * rewrite_query_for_counting
+ *
+ * Rewrite query for counting duplicated tuples.
+ */
+static Query *
+rewrite_query_for_counting(Query *query, ParseState *pstate)
+{
+ TargetEntry *tle_count;
+ FuncCall *fn;
+ Node *node;
+
+ /* Add count(*) for counting distinct tuples in views */
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+ fn->agg_star = true;
+ if (!query->groupClause && !query->hasAggs)
+ query->groupClause = transformDistinctClause(NULL, &query->targetList, query->sortClause, false);
+
+ node = ParseFuncOrColumn(pstate, fn->funcname, NIL, NULL, fn, false, -1);
+
+ tle_count = makeTargetEntry((Expr *) node,
+ list_length(query->targetList) + 1,
+ pstrdup("__ivm_count__"),
+ false);
+ query->targetList = lappend(query->targetList, tle_count);
+ query->hasAggs = true;
+
+ return query;
+}
+
+/*
+ * calc_delta
+ *
+ * Calculate view deltas generated under the modification of a table specified
+ * by the RTE index.
+ */
+static void
+calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
+ DestReceiver *dest_old, DestReceiver *dest_new,
+ TupleDesc *tupdesc_old, TupleDesc *tupdesc_new,
+ QueryEnvironment *queryEnv)
+{
+ ListCell *lc = list_nth_cell(query->rtable, rte_index - 1);
+ RangeTblEntry *rte = (RangeTblEntry *) lfirst(lc);
+
+ in_delta_calculation = true;
+
+ /* Generate old delta */
+ if (list_length(table->old_tuplestores) > 0)
+ {
+ /* Replace the modified table with the old delta table and calculate the old view delta. */
+ replace_rte_with_delta(rte, table, false, queryEnv);
+ refresh_matview_datafill(dest_old, query, queryEnv, tupdesc_old, "");
+ }
+
+ /* Generate new delta */
+ if (list_length(table->new_tuplestores) > 0)
+ {
+ /* Replace the modified table with the new delta table and calculate the new view delta*/
+ replace_rte_with_delta(rte, table, true, queryEnv);
+ refresh_matview_datafill(dest_new, query, queryEnv, tupdesc_new, "");
+ }
+
+ in_delta_calculation = false;
+}
+
+/*
+ * rewrite_query_for_postupdate_state
+ *
+ * Rewrite the query so that the specified base table's RTEs will represent
+ * "post-update" state of tables. This is called after the view delta
+ * calculation due to changes on this table finishes.
+ */
+static Query*
+rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte_index)
+{
+ ListCell *lc = list_nth_cell(query->rtable, rte_index - 1);
+
+ /* Retore the original RTE */
+ lfirst(lc) = table->original_rte;
+
+ return query;
+}
+
+/*
+ * apply_delta
+ *
+ * Apply deltas to the materialized view. In outer join cases, this requires
+ * the view maintenance graph.
+ */
+static void
+apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
+ TupleDesc tupdesc_old, TupleDesc tupdesc_new,
+ Query *query)
+{
+ StringInfoData querybuf;
+ StringInfoData target_list_buf;
+ Relation matviewRel;
+ char *matviewname;
+ ListCell *lc;
+ int i;
+ List *keys = NIL;
+
+
+ /*
+ * get names of the materialized view and delta tables
+ */
+
+ matviewRel = table_open(matviewOid, NoLock);
+ matviewname = quote_qualified_identifier(get_namespace_name(RelationGetNamespace(matviewRel)),
+ RelationGetRelationName(matviewRel));
+
+ /*
+ * Build parts of the maintenance queries
+ */
+
+ initStringInfo(&querybuf);
+ initStringInfo(&target_list_buf);
+
+ /* build string of target list */
+ for (i = 0; i < matviewRel->rd_att->natts; i++)
+ {
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
+
+ if (i != 0)
+ appendStringInfo(&target_list_buf, ", ");
+ appendStringInfo(&target_list_buf, "%s", quote_qualified_identifier(NULL, resname));
+ }
+
+ i = 0;
+ foreach (lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+
+ i++;
+
+ if (tle->resjunk)
+ continue;
+
+ keys = lappend(keys, attr);
+ }
+
+ /* Start maintaining the materialized view. */
+ OpenMatViewIncrementalMaintenance();
+
+ /* Open SPI context. */
+ if (SPI_connect() != SPI_OK_CONNECT)
+ elog(ERROR, "SPI_connect failed");
+
+ /* For tuple deletion */
+ if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
+ {
+ EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ int rc;
+
+ /* convert tuplestores to ENR, and register for SPI */
+ enr->md.name = pstrdup(OLD_DELTA_ENRNAME);
+ enr->md.reliddesc = InvalidOid;
+ enr->md.tupdesc = tupdesc_old;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(old_tuplestores);
+ enr->reldata = old_tuplestores;
+
+ rc = SPI_register_relation(enr);
+ if (rc != SPI_OK_REL_REGISTER)
+ elog(ERROR, "SPI_register failed");
+
+ apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+
+ }
+ /* For tuple insertion */
+ if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
+ {
+ EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ int rc;
+
+ /* convert tuplestores to ENR, and register for SPI */
+ enr->md.name = pstrdup(NEW_DELTA_ENRNAME);
+ enr->md.reliddesc = InvalidOid;
+ enr->md.tupdesc = tupdesc_new;;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(new_tuplestores);
+ enr->reldata = new_tuplestores;
+
+ rc = SPI_register_relation(enr);
+ if (rc != SPI_OK_REL_REGISTER)
+ elog(ERROR, "SPI_register failed");
+
+ /* apply new delta */
+ apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
+ }
+
+ /* We're done maintaining the materialized view. */
+ CloseMatViewIncrementalMaintenance();
+
+ table_close(matviewRel, NoLock);
+
+ /* Close SPI context. */
+ if (SPI_finish() != SPI_OK_FINISH)
+ elog(ERROR, "SPI_finish failed");
+}
+
+/*
+ * apply_old_delta
+ *
+ * Execute a query for applying a delta table given by deltname_old
+ * which contains tuples to be deleted from to a materialized view given by
+ * matviewname. This is used when counting is not required.
+ */
+static void
+apply_old_delta(const char *matviewname, const char *deltaname_old,
+ List *keys)
+{
+ StringInfoData querybuf;
+ StringInfoData keysbuf;
+ char *match_cond;
+ ListCell *lc;
+
+ /* build WHERE condition for searching tuples to be deleted */
+ match_cond = get_matching_condition_string(keys);
+
+ /* build string of keys list */
+ initStringInfo(&keysbuf);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&keysbuf, "%s", quote_qualified_identifier("mv", resname));
+ if (lnext(keys, lc))
+ appendStringInfo(&keysbuf, ", ");
+ }
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "DELETE FROM %s WHERE ctid IN ("
+ "SELECT tid FROM (SELECT pg_catalog.row_number() over (partition by %s) AS \"__ivm_row_number__\","
+ "mv.ctid AS tid,"
+ "diff.\"__ivm_count__\""
+ "FROM %s AS mv, %s AS diff "
+ "WHERE %s) v "
+ "WHERE v.\"__ivm_row_number__\" OPERATOR(pg_catalog.<=) v.\"__ivm_count__\")",
+ matviewname,
+ keysbuf.data,
+ matviewname, deltaname_old,
+ match_cond);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
+/*
+ * apply_new_delta
+ *
+ * Execute a query for applying a delta table given by deltname_new
+ * which contains tuples to be inserted into a materialized view given by
+ * matviewname. This is used when counting is not required.
+ */
+static void
+apply_new_delta(const char *matviewname, const char *deltaname_new,
+ StringInfo target_list)
+{
+ StringInfoData querybuf;
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "INSERT INTO %s (%s) SELECT %s FROM ("
+ "SELECT diff.*, pg_catalog.generate_series(1, diff.\"__ivm_count__\")"
+ " AS __ivm_generate_series__ "
+ "FROM %s AS diff) AS v",
+ matviewname, target_list->data, target_list->data,
+ deltaname_new);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_INSERT)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
+/*
+ * get_matching_condition_string
+ *
+ * Build a predicate string for looking for a tuple with given keys.
+ */
+static char *
+get_matching_condition_string(List *keys)
+{
+ StringInfoData match_cond;
+ ListCell *lc;
+
+ /* If there is no key columns, the condition is always true. */
+ if (keys == NIL)
+ return "true";
+
+ initStringInfo(&match_cond);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ char *mv_resname = quote_qualified_identifier("mv", resname);
+ char *diff_resname = quote_qualified_identifier("diff", resname);
+ Oid typid = attr->atttypid;
+
+ /* Considering NULL values, we can not use simple = operator. */
+ appendStringInfo(&match_cond, "(");
+ generate_equal(&match_cond, typid, mv_resname, diff_resname);
+ appendStringInfo(&match_cond, " OR (%s IS NULL AND %s IS NULL))",
+ mv_resname, diff_resname);
+
+ if (lnext(keys, lc))
+ appendStringInfo(&match_cond, " AND ");
+ }
+
+ return match_cond.data;
+}
+
+/*
+ * generate_equals
+ *
+ * Generate an equality clause using given operands' default equality
+ * operator.
+ */
+static void
+generate_equal(StringInfo querybuf, Oid opttype,
+ const char *leftop, const char *rightop)
+{
+ TypeCacheEntry *typentry;
+
+ typentry = lookup_type_cache(opttype, TYPECACHE_EQ_OPR);
+ if (!OidIsValid(typentry->eq_opr))
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_FUNCTION),
+ errmsg("could not identify an equality operator for type %s",
+ format_type_be_qualified(opttype))));
+
+ generate_operator_clause(querybuf,
+ leftop, opttype,
+ typentry->eq_opr,
+ rightop, opttype);
+}
+
+/*
+ * mv_InitHashTables
+ */
+static void
+mv_InitHashTables(void)
+{
+ HASHCTL ctl;
+
+ memset(&ctl, 0, sizeof(ctl));
+ ctl.keysize = sizeof(Oid);
+ ctl.entrysize = sizeof(MV_TriggerHashEntry);
+ mv_trigger_info = hash_create("MV trigger info",
+ MV_INIT_QUERYHASHSIZE,
+ &ctl, HASH_ELEM | HASH_BLOBS);
+}
+
+/*
+ * AtAbort_IVM
+ *
+ * Clean up hash entries for all materialized views. This is called at
+ * transaction abort.
+ */
+void
+AtAbort_IVM()
+{
+ HASH_SEQ_STATUS seq;
+ MV_TriggerHashEntry *entry;
+
+ if (mv_trigger_info)
+ {
+ hash_seq_init(&seq, mv_trigger_info);
+ while ((entry = hash_seq_search(&seq)) != NULL)
+ clean_up_IVM_hash_entry(entry, true);
+ }
+ in_delta_calculation = false;
+}
+
+/*
+ * clean_up_IVM_hash_entry
+ *
+ * Clean up tuple stores and hash entries for a materialized view after its
+ * maintenance finished.
+ */
+static void
+clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort)
+{
+ bool found;
+ ListCell *lc;
+
+ foreach(lc, entry->tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc);
+
+ list_free(table->old_tuplestores);
+ list_free(table->new_tuplestores);
+ if (!is_abort)
+ {
+ ExecDropSingleTupleTableSlot(table->slot);
+ table_close(table->rel, NoLock);
+ }
+ }
+ list_free(entry->tables);
+
+ if (!is_abort)
+ UnregisterSnapshot(entry->snapshot);
+
+ hash_search(mv_trigger_info, (void *) &entry->matview_id, HASH_REMOVE, &found);
+}
+
+/*
+ * isIvmName
+ *
+ * Check if this is a IVM hidden column from the name.
+ */
+bool
+isIvmName(const char *s)
+{
+ if (s)
+ return (strncmp(s, "__ivm_", 6) == 0);
+ return false;
+}
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index 134e3b22fd..8b1a87c934 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -12195,4 +12195,14 @@
proargtypes => 'int2',
prosrc => 'gist_stratnum_identity' },
+# IVM
+{ oid => '786', descr => 'ivm trigger (before)',
+ proname => 'IVM_immediate_before', provolatile => 'v', prorettype => 'trigger',
+ proargtypes => '', prosrc => 'IVM_immediate_before' },
+{ oid => '787', descr => 'ivm trigger (after)',
+ proname => 'IVM_immediate_maintenance', provolatile => 'v', prorettype => 'trigger',
+ proargtypes => '', prosrc => 'IVM_immediate_maintenance' },
+{ oid => '788', descr => 'ivm filetring ',
+ proname => 'ivm_visible_in_prestate', provolatile => 's', prorettype => 'bool',
+ proargtypes => 'oid tid oid', prosrc => 'ivm_visible_in_prestate' },
]
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 94678e3834..396ad1bb4c 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -16,6 +16,7 @@
#include "catalog/objectaddress.h"
#include "nodes/params.h"
+#include "nodes/pathnodes.h"
#include "parser/parse_node.h"
#include "tcop/dest.h"
#include "utils/queryenvironment.h"
@@ -25,6 +26,9 @@ extern ObjectAddress ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *st
ParamListInfo params, QueryEnvironment *queryEnv,
QueryCompletion *qc);
+extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
+extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
+
extern int GetIntoRelEFlags(IntoClause *intoClause);
extern DestReceiver *CreateIntoRelDestReceiver(IntoClause *intoClause);
diff --git a/src/include/commands/matview.h b/src/include/commands/matview.h
index 817b2ba0b6..3257e1adff 100644
--- a/src/include/commands/matview.h
+++ b/src/include/commands/matview.h
@@ -15,6 +15,7 @@
#define MATVIEW_H
#include "catalog/objectaddress.h"
+#include "fmgr.h"
#include "nodes/params.h"
#include "nodes/parsenodes.h"
#include "tcop/dest.h"
@@ -23,6 +24,8 @@
extern void SetMatViewPopulatedState(Relation relation, bool newstate);
+extern void SetMatViewIVMState(Relation relation, bool newstate);
+
extern ObjectAddress ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
ParamListInfo params, QueryCompletion *qc);
@@ -30,4 +33,10 @@ extern DestReceiver *CreateTransientRelDestReceiver(Oid transientoid);
extern bool MatViewIncrementalMaintenanceIsEnabled(void);
+extern Datum IVM_immediate_before(PG_FUNCTION_ARGS);
+extern Datum IVM_immediate_maintenance(PG_FUNCTION_ARGS);
+extern Datum IVM_visible_in_prestate(PG_FUNCTION_ARGS);
+extern void AtAbort_IVM(void);
+extern bool isIvmName(const char *s);
+
#endif /* MATVIEW_H */
--
2.25.1
v32-0007-Add-DISTINCT-support-for-IVM.patchtext/x-diff; name=v32-0007-Add-DISTINCT-support-for-IVM.patchDownload
From 4c633d185e3efd342bb92a176a37d50c59a94e03 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 19:08:51 +0900
Subject: [PATCH v32 07/11] Add DISTINCT support for IVM
When IMMV is created with DISTINCT, multiplicity of tuples is
counted and stored in "__ivm_count__" column, which is a hidden
column of IMMV. The value in __ivm_count__ is updated when IMMV
is maintained incrementally. A tuple in IMMV can be removed if
and only if the count becomes zero.
---
src/backend/commands/createas.c | 141 ++++++++++++++++++++------
src/backend/commands/indexcmds.c | 40 ++++++++
src/backend/commands/matview.c | 148 ++++++++++++++++++++++++++--
src/backend/commands/tablecmds.c | 9 ++
src/backend/nodes/outfuncs.c | 1 +
src/backend/nodes/readfuncs.c | 1 +
src/backend/parser/parse_relation.c | 18 +++-
src/backend/rewrite/rewriteDefine.c | 3 +-
src/include/commands/createas.h | 2 +
src/include/nodes/parsenodes.h | 2 +
10 files changed, 320 insertions(+), 45 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index e9846c8d0f..299c5a133c 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -50,6 +50,7 @@
#include "parser/parser.h"
#include "parser/parsetree.h"
#include "parser/parse_clause.h"
+#include "parser/parse_func.h"
#include "rewrite/rewriteHandler.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
@@ -305,6 +306,9 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
errhint("functions must be marked IMMUTABLE")));
check_ivm_restriction((Node *) query);
+
+ /* For IMMV, we need to rewrite matview query */
+ query = rewriteQueryForIMMV(query, into->colNames);
}
if (into->skipData)
@@ -409,6 +413,49 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
return address;
}
+/*
+ * rewriteQueryForIMMV -- rewrite view definition query for IMMV
+ *
+ * count(*) is added for counting distinct tuples in views.
+ */
+Query *
+rewriteQueryForIMMV(Query *query, List *colNames)
+{
+ Query *rewritten;
+
+ Node *node;
+ ParseState *pstate = make_parsestate(NULL);
+ FuncCall *fn;
+
+ rewritten = copyObject(query);
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ /*
+ * Convert DISTINCT to GROUP BY and add count(*) for counting distinct
+ * tuples in views.
+ */
+ if (rewritten->distinctClause)
+ {
+ TargetEntry *tle;
+
+ rewritten->groupClause = transformDistinctClause(NULL, &rewritten->targetList, rewritten->sortClause, false);
+
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+ fn->agg_star = true;
+
+ node = ParseFuncOrColumn(pstate, fn->funcname, NIL, NULL, fn, false, -1);
+
+ tle = makeTargetEntry((Expr *) node,
+ list_length(rewritten->targetList) + 1,
+ pstrdup("__ivm_count__"),
+ false);
+ rewritten->targetList = lappend(rewritten->targetList, tle);
+ rewritten->hasAggs = true;
+ }
+
+ return rewritten;
+}
+
/*
* GetIntoRelEFlags --- compute executor flags needed for CREATE TABLE AS
*
@@ -532,7 +579,8 @@ intorel_startup(DestReceiver *self, int operation, TupleDesc typeinfo)
ColumnDef *col;
char *colname;
- if (lc)
+ /* Don't override hidden columns added for IVM */
+ if (lc && !isIvmName(NameStr(attribute->attname)))
{
colname = strVal(lfirst(lc));
lc = lnext(into->colNames, lc);
@@ -938,10 +986,6 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view")));
- if (qry->distinctClause)
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("DISTINCT is not supported on incrementally maintainable materialized view")));
if (qry->hasDistinctOn)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
@@ -1088,12 +1132,18 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
char idxname[NAMEDATALEN];
List *indexoidlist = RelationGetIndexList(matviewRel);
ListCell *indexoidscan;
- Bitmapset *key_attnos;
snprintf(idxname, sizeof(idxname), "%s_index", RelationGetRelationName(matviewRel));
index = makeNode(IndexStmt);
+ /*
+ * We consider null values not distinct to make sure that views with DISTINCT
+ * or GROUP BY don't contain multiple NULL rows when NULL is inserted to
+ * a base table concurrently.
+ */
+ index->nulls_not_distinct = true;
+
index->unique = true;
index->primary = false;
index->isconstraint = false;
@@ -1120,41 +1170,68 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
index->concurrent = false;
index->if_not_exists = false;
- /* create index on the base tables' primary key columns */
- key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
- if (key_attnos)
+ if (query->distinctClause)
{
+ /* create unique constraint on all columns */
foreach(lc, query->targetList)
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
-
- if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
- {
- IndexElem *iparam;
-
- iparam = makeNode(IndexElem);
- iparam->name = pstrdup(NameStr(attr->attname));
- iparam->expr = NULL;
- iparam->indexcolname = NULL;
- iparam->collation = NIL;
- iparam->opclass = NIL;
- iparam->opclassopts = NIL;
- iparam->ordering = SORTBY_DEFAULT;
- iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
- index->indexParams = lappend(index->indexParams, iparam);
- }
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
}
}
else
{
- /* create no index, just notice that an appropriate index is necessary for efficient IVM */
- ereport(NOTICE,
- (errmsg("could not create an index on materialized view \"%s\" automatically",
- RelationGetRelationName(matviewRel)),
- errdetail("This target list does not have all the primary key columns. "),
- errhint("Create an index on the materialized view for efficient incremental maintenance.")));
- return;
+ Bitmapset *key_attnos;
+
+ /* create index on the base tables' primary key columns */
+ key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
+ if (key_attnos)
+ {
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ }
+ else
+ {
+ /* create no index, just notice that an appropriate index is necessary for efficient IVM */
+ ereport(NOTICE,
+ (errmsg("could not create an index on materialized view \"%s\" automatically",
+ RelationGetRelationName(matviewRel)),
+ errdetail("This target list does not have all the primary key columns, "
+ "or this view does not contain DISTINCT clause."),
+ errhint("Create an index on the materialized view for efficient incremental maintenance.")));
+ return;
+ }
}
/* If we have a compatible index, we don't need to create another. */
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index d9016ef487..fb5265e6c3 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -41,6 +41,7 @@
#include "commands/dbcommands.h"
#include "commands/defrem.h"
#include "commands/event_trigger.h"
+#include "commands/matview.h"
#include "commands/progress.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
@@ -1132,6 +1133,45 @@ DefineIndex(Oid tableId,
safe_index = indexInfo->ii_Expressions == NIL &&
indexInfo->ii_Predicate == NIL;
+ /*
+ * We disallow unique indexes on IVM columns of IMMVs.
+ */
+ if (RelationIsIVM(rel) && stmt->unique)
+ {
+ for (int i = 0; i < indexInfo->ii_NumIndexKeyAttrs; i++)
+ {
+ AttrNumber attno = indexInfo->ii_IndexAttrNumbers[i];
+ if (attno > 0)
+ {
+ char *name = NameStr(TupleDescAttr(rel->rd_att, attno - 1)->attname);
+ if (name && isIvmName(name))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("unique index creation on IVM columns is not supported")));
+ }
+ }
+
+ if (indexInfo->ii_Expressions)
+ {
+ Bitmapset *indexattrs = NULL;
+ int varno = -1;
+
+ pull_varattnos((Node *) indexInfo->ii_Expressions, 1, &indexattrs);
+
+ while ((varno = bms_next_member(indexattrs, varno)) >= 0)
+ {
+ int attno = varno + FirstLowInvalidHeapAttributeNumber;
+ char *name = NameStr(TupleDescAttr(rel->rd_att, attno - 1)->attname);
+ if (name && isIvmName(name))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("unique index creation on IVM columns is not supported")));
+ }
+
+ }
+ }
+
+
/*
* Report index creation if appropriate (delay this till after most of the
* error checks)
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index 78a5dd1df9..0064e10966 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -148,11 +148,15 @@ static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *
static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
- Query *query);
+ Query *query, bool use_count, char *count_colname);
static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
+static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
+ List *keys, const char *count_colname);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
+static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
+ List *keys, StringInfo target_list, const char* count_colname);
static char *get_matching_condition_string(List *keys);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
@@ -267,6 +271,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
Oid matviewOid;
Relation matviewRel;
Query *dataQuery;
+ Query *viewQuery;
Oid tableSpace;
Oid relowner;
Oid OIDNewHeap;
@@ -329,8 +334,13 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
"CONCURRENTLY", "WITH NO DATA")));
- dataQuery = get_matview_query(matviewRel);
+ viewQuery = get_matview_query(matviewRel);
+ /* For IMMV, we need to rewrite matview query */
+ if (!stmt->skipData && RelationIsIVM(matviewRel))
+ dataQuery = rewriteQueryForIMMV(viewQuery,NIL);
+ else
+ dataQuery = viewQuery;
/*
* Check that there is a unique index with no WHERE clause on one or more
@@ -510,8 +520,8 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
if (!stmt->skipData && RelationIsIVM(matviewRel) && !oldPopulated)
{
- CreateIndexOnIMMV(dataQuery, matviewRel);
- CreateIvmTriggersOnBaseTables(dataQuery, matviewOid);
+ CreateIndexOnIMMV(viewQuery, matviewRel);
+ CreateIvmTriggersOnBaseTables(viewQuery, matviewOid);
}
table_close(matviewRel, NoLock);
@@ -1535,6 +1545,13 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
int rte_index = lfirst_int(lc2);
TupleDesc tupdesc_old;
TupleDesc tupdesc_new;
+ bool use_count = false;
+ char *count_colname = NULL;
+
+ count_colname = pstrdup("__ivm_count__");
+
+ if (query->distinctClause)
+ use_count = true;
/* calculate delta tables */
calc_delta(table, rte_index, rewritten, dest_old, dest_new,
@@ -1547,7 +1564,8 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
{
/* apply the delta tables to the materialized view */
apply_delta(matviewOid, old_tuplestore, new_tuplestore,
- tupdesc_old, tupdesc_new, query);
+ tupdesc_old, tupdesc_new, query, use_count,
+ count_colname);
}
PG_CATCH();
{
@@ -2020,7 +2038,7 @@ rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte
static void
apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
- Query *query)
+ Query *query, bool use_count, char *count_colname)
{
StringInfoData querybuf;
StringInfoData target_list_buf;
@@ -2096,7 +2114,12 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (rc != SPI_OK_REL_REGISTER)
elog(ERROR, "SPI_register failed");
- apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+ if (use_count)
+ /* apply old delta and get rows to be recalculated */
+ apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
+ keys, count_colname);
+ else
+ apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
}
/* For tuple insertion */
@@ -2118,7 +2141,11 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_register failed");
/* apply new delta */
- apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
+ if (use_count)
+ apply_new_delta_with_count(matviewname, NEW_DELTA_ENRNAME,
+ keys, &target_list_buf, count_colname);
+ else
+ apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
}
/* We're done maintaining the materialized view. */
@@ -2131,6 +2158,51 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_finish failed");
}
+/*
+ * apply_old_delta_with_count
+ *
+ * Execute a query for applying a delta table given by deltname_old
+ * which contains tuples to be deleted from to a materialized view given by
+ * matviewname. This is used when counting is required, that is, the view
+ * has aggregate or distinct.
+ */
+static void
+apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
+ List *keys, const char *count_colname)
+{
+ StringInfoData querybuf;
+ char *match_cond;
+
+ /* build WHERE condition for searching tuples to be deleted */
+ match_cond = get_matching_condition_string(keys);
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "WITH t AS (" /* collecting tid of target tuples in the view */
+ "SELECT diff.%s, " /* count column */
+ "(diff.%s OPERATOR(pg_catalog.=) mv.%s) AS for_dlt, "
+ "mv.ctid "
+ "FROM %s AS mv, %s AS diff "
+ "WHERE %s" /* tuple matching condition */
+ "), updt AS (" /* update a tuple if this is not to be deleted */
+ "UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
+ "FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
+ ")"
+ /* delete a tuple if this is to be deleted */
+ "DELETE FROM %s AS mv USING t "
+ "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
+ count_colname,
+ count_colname, count_colname,
+ matviewname, deltaname_old,
+ match_cond,
+ matviewname, count_colname, count_colname, count_colname,
+ matviewname);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
/*
* apply_old_delta
*
@@ -2180,6 +2252,66 @@ apply_old_delta(const char *matviewname, const char *deltaname_old,
elog(ERROR, "SPI_exec failed: %s", querybuf.data);
}
+/*
+ * apply_new_delta_with_count
+ *
+ * Execute a query for applying a delta table given by deltname_new
+ * which contains tuples to be inserted into a materialized view given by
+ * matviewname. This is used when counting is required, that is, the view
+ * has aggregate or distinct. Also, when a table in EXISTS sub queries
+ * is modified.
+ */
+static void
+apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
+ List *keys, StringInfo target_list, const char* count_colname)
+{
+ StringInfoData querybuf;
+ StringInfoData returning_keys;
+ ListCell *lc;
+ char *match_cond = "";
+
+ /* build WHERE condition for searching tuples to be updated */
+ match_cond = get_matching_condition_string(keys);
+
+ /* build string of keys list */
+ initStringInfo(&returning_keys);
+ if (keys)
+ {
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&returning_keys, "%s", quote_qualified_identifier("mv", resname));
+ if (lnext(keys, lc))
+ appendStringInfo(&returning_keys, ", ");
+ }
+ }
+ else
+ appendStringInfo(&returning_keys, "NULL");
+
+ /* Search for matching tuples from the view and update if found or insert if not. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "WITH updt AS (" /* update a tuple if this exists in the view */
+ "UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.+) diff.%s "
+ "FROM %s AS diff "
+ "WHERE %s " /* tuple matching condition */
+ "RETURNING %s" /* returning keys of updated tuples */
+ ") INSERT INTO %s (%s) " /* insert a new tuple if this doesn't exist */
+ "SELECT %s FROM %s AS diff "
+ "WHERE NOT EXISTS (SELECT 1 FROM updt AS mv WHERE %s);",
+ matviewname, count_colname, count_colname, count_colname,
+ deltaname_new,
+ match_cond,
+ returning_keys.data,
+ matviewname, target_list->data,
+ target_list->data, deltaname_new,
+ match_cond);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_INSERT)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
/*
* apply_new_delta
*
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index a28f405e27..12b5b5df64 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -56,6 +56,7 @@
#include "commands/cluster.h"
#include "commands/comment.h"
#include "commands/defrem.h"
+#include "commands/matview.h"
#include "commands/event_trigger.h"
#include "commands/sequence.h"
#include "commands/tablecmds.h"
@@ -3797,6 +3798,14 @@ renameatt_internal(Oid myrelid,
targetrelation = relation_open(myrelid, AccessExclusiveLock);
renameatt_check(myrelid, RelationGetForm(targetrelation), recursing);
+ /*
+ * Don't rename IVM columns.
+ */
+ if (RelationIsIVM(targetrelation) && isIvmName(oldattname))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("IVM column can not be renamed")));
+
/*
* if the 'recurse' flag is set then we are supposed to rename this
* attribute in all classes that inherit from 'relname' (as well as in
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 3337b77ae6..c191f70a6f 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -510,6 +510,7 @@ _outRangeTblEntry(StringInfo str, const RangeTblEntry *node)
WRITE_INT_FIELD(rellockmode);
WRITE_UINT_FIELD(perminfoindex);
WRITE_NODE_FIELD(tablesample);
+ WRITE_BOOL_FIELD(relisivm);
break;
case RTE_SUBQUERY:
WRITE_NODE_FIELD(subquery);
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index c4d01a441a..ffcab8cda2 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -361,6 +361,7 @@ _readRangeTblEntry(void)
READ_INT_FIELD(rellockmode);
READ_UINT_FIELD(perminfoindex);
READ_NODE_FIELD(tablesample);
+ READ_BOOL_FIELD(relisivm);
break;
case RTE_SUBQUERY:
READ_NODE_FIELD(subquery);
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index 427b7325db..65aecc96a7 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -36,6 +36,7 @@
#include "utils/rel.h"
#include "utils/syscache.h"
#include "utils/varlena.h"
+#include "commands/matview.h"
/*
@@ -97,7 +98,7 @@ static void expandTupleDesc(TupleDesc tupdesc, Alias *eref,
int count, int offset,
int rtindex, int sublevels_up,
int location, bool include_dropped,
- List **colnames, List **colvars);
+ List **colnames, List **colvars, bool is_ivm);
static int specialAttNum(const char *attname);
static bool rte_visible_if_lateral(ParseState *pstate, RangeTblEntry *rte);
static bool rte_visible_if_qualified(ParseState *pstate, RangeTblEntry *rte);
@@ -1503,6 +1504,7 @@ addRangeTableEntry(ParseState *pstate,
rte->inh = inh;
rte->relkind = rel->rd_rel->relkind;
rte->rellockmode = lockmode;
+ rte->relisivm = rel->rd_rel->relisivm;
/*
* Build the list of effective column names using user-supplied aliases
@@ -1588,6 +1590,7 @@ addRangeTableEntryForRelation(ParseState *pstate,
rte->inh = inh;
rte->relkind = rel->rd_rel->relkind;
rte->rellockmode = lockmode;
+ rte->relisivm = rel->rd_rel->relisivm;
/*
* Build the list of effective column names using user-supplied aliases
@@ -2752,7 +2755,7 @@ expandRTE(RangeTblEntry *rte, int rtindex, int sublevels_up,
expandTupleDesc(tupdesc, rte->eref,
rtfunc->funccolcount, atts_done,
rtindex, sublevels_up, location,
- include_dropped, colnames, colvars);
+ include_dropped, colnames, colvars, false);
}
else if (functypclass == TYPEFUNC_SCALAR)
{
@@ -3020,7 +3023,7 @@ expandRelation(Oid relid, Alias *eref, int rtindex, int sublevels_up,
expandTupleDesc(rel->rd_att, eref, rel->rd_att->natts, 0,
rtindex, sublevels_up,
location, include_dropped,
- colnames, colvars);
+ colnames, colvars, RelationIsIVM(rel));
relation_close(rel, AccessShareLock);
}
@@ -3037,7 +3040,7 @@ static void
expandTupleDesc(TupleDesc tupdesc, Alias *eref, int count, int offset,
int rtindex, int sublevels_up,
int location, bool include_dropped,
- List **colnames, List **colvars)
+ List **colnames, List **colvars, bool is_ivm)
{
ListCell *aliascell;
int varattno;
@@ -3050,6 +3053,9 @@ expandTupleDesc(TupleDesc tupdesc, Alias *eref, int count, int offset,
{
Form_pg_attribute attr = TupleDescAttr(tupdesc, varattno);
+ if (is_ivm && isIvmName(NameStr(attr->attname)) && !MatViewIncrementalMaintenanceIsEnabled())
+ continue;
+
if (attr->attisdropped)
{
if (include_dropped)
@@ -3212,6 +3218,10 @@ expandNSItemAttrs(ParseState *pstate, ParseNamespaceItem *nsitem,
Var *varnode = (Var *) lfirst(var);
TargetEntry *te;
+ /* if transform * into columnlist with IMMV, remove IVM columns */
+ if (rte->relisivm && isIvmName(label) && !MatViewIncrementalMaintenanceIsEnabled())
+ continue;
+
te = makeTargetEntry((Expr *) varnode,
(AttrNumber) pstate->p_next_resno++,
label,
diff --git a/src/backend/rewrite/rewriteDefine.c b/src/backend/rewrite/rewriteDefine.c
index 6cc9a8d8bf..5d22dbcfcf 100644
--- a/src/backend/rewrite/rewriteDefine.c
+++ b/src/backend/rewrite/rewriteDefine.c
@@ -614,7 +614,8 @@ checkRuleResultList(List *targetList, TupleDesc resultDesc, bool isSelect,
attr->atttypmod))));
}
- if (i != resultDesc->natts)
+ /* No check for materialized views since this could have special columns for IVM */
+ if ((!isSelect || requireColumnNameMatch) && i != resultDesc->natts)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
isSelect ?
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 396ad1bb4c..6b47e66bfd 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -29,6 +29,8 @@ extern ObjectAddress ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *st
extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
+extern Query *rewriteQueryForIMMV(Query *query, List *colNames);
+
extern int GetIntoRelEFlags(IntoClause *intoClause);
extern DestReceiver *CreateIntoRelDestReceiver(IntoClause *intoClause);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index a690ebc6e5..2e96bce175 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1090,6 +1090,8 @@ typedef struct RangeTblEntry
Index perminfoindex pg_node_attr(query_jumble_ignore);
/* sampling info, or NULL */
struct TableSampleClause *tablesample;
+ /* incrementally maintainable materialized view? */
+ bool relisivm;
/*
* Fields valid for a subquery RTE (else NULL):
--
2.25.1
v32-0008-Add-aggregates-support-in-IVM.patchtext/x-diff; name=v32-0008-Add-aggregates-support-in-IVM.patchDownload
From 4538041ee46c4f6f8779c47cb435563e7a10acba Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 20:46:32 +0900
Subject: [PATCH v32 08/11] Add aggregates support in IVM
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit
count, sum, adn avg are supported.
As a restriction, expressions specified in GROUP BY must appear in
the target list because tuples to be updated in IMMV are identified
by using this group key. However, in the case of aggregates without
GROUP BY, there is only one tuple in the view, so keys are not uses
to identify tuples.
When creating a IMMV, in addition to __ivm_count column, some hidden
columns for each aggregate are added to the target list. For example,
names of these hidden columns are ivm_count_avg and ivm_sum_avg for
the average function, and so on.
When a base table is modified, the aggregated values and related
hidden columns are also updated as well as __ivm_count__. The
way of update depends the kind of aggregate function. Specifically,
sum and count are updated by simply adding or subtracting delta value
calculated from delta tables. avg is updated by using values of sum
and count stored in views as hidden columns and deltas calculated
from delta tables.
About aggregate functions except "count()" (sum and avg), NULLs in input
values are ignored, and the result of aggegate should be NULL when no
rows are selected. To support this specification, the numbers of non-NULL
input values are counted and stored in hidden columns. In the case of
count(), count(x) returns zero when no rows are selected, but count(*)
doesn't ignore NULL input.
---
src/backend/commands/createas.c | 265 +++++++++++++++++--
src/backend/commands/matview.c | 433 ++++++++++++++++++++++++++++++--
src/include/commands/createas.h | 1 +
3 files changed, 662 insertions(+), 37 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index 299c5a133c..ecec93ec1c 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -51,13 +51,19 @@
#include "parser/parsetree.h"
#include "parser/parse_clause.h"
#include "parser/parse_func.h"
+#include "parser/parse_type.h"
#include "rewrite/rewriteHandler.h"
+#include "rewrite/rewriteManip.h"
+#include "storage/smgr.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
#include "utils/lsyscache.h"
+#include "utils/regproc.h"
+#include "utils/fmgroids.h"
#include "utils/rel.h"
#include "utils/rls.h"
#include "utils/snapmgr.h"
+#include "utils/syscache.h"
typedef struct
{
@@ -71,6 +77,11 @@ typedef struct
BulkInsertState bistate; /* bulk insert state */
} DR_intorel;
+typedef struct
+{
+ bool has_agg;
+} check_ivm_restriction_context;
+
/* utility functions for CTAS definition creation */
static ObjectAddress create_ctas_internal(List *attrList, IntoClause *into);
static ObjectAddress create_ctas_nodata(List *tlist, IntoClause *into);
@@ -85,8 +96,9 @@ static void CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid mat
Relids *relids, bool ex_lock);
static void CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock);
static void check_ivm_restriction(Node *node);
-static bool check_ivm_restriction_walker(Node *node, void *context);
+static bool check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context);
static Bitmapset *get_primary_key_attnos_from_query(Query *query, List **constraintList);
+static bool check_aggregate_supports_ivm(Oid aggfnoid);
/*
* create_ctas_internal
@@ -417,6 +429,7 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
* rewriteQueryForIMMV -- rewrite view definition query for IMMV
*
* count(*) is added for counting distinct tuples in views.
+ * Also, additional hidden columns are added for aggregate values.
*/
Query *
rewriteQueryForIMMV(Query *query, List *colNames)
@@ -430,16 +443,49 @@ rewriteQueryForIMMV(Query *query, List *colNames)
rewritten = copyObject(query);
pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
- /*
- * Convert DISTINCT to GROUP BY and add count(*) for counting distinct
- * tuples in views.
- */
- if (rewritten->distinctClause)
+ /* group keys must be in targetlist */
+ if (rewritten->groupClause)
{
- TargetEntry *tle;
+ ListCell *lc;
+ foreach(lc, rewritten->groupClause)
+ {
+ SortGroupClause *scl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(scl, rewritten->targetList);
+ if (tle->resjunk)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUP BY expression not appearing in select list is not supported on incrementally maintainable materialized view")));
+ }
+ }
+ /* Convert DISTINCT to GROUP BY. count(*) will be added afterward. */
+ else if (!rewritten->hasAggs && rewritten->distinctClause)
rewritten->groupClause = transformDistinctClause(NULL, &rewritten->targetList, rewritten->sortClause, false);
+ /* Add additional columns for aggregate values */
+ if (rewritten->hasAggs)
+ {
+ ListCell *lc;
+ List *aggs = NIL;
+ AttrNumber next_resno = list_length(rewritten->targetList) + 1;
+
+ foreach(lc, rewritten->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ char *resname = (colNames == NIL || foreach_current_index(lc) >= list_length(colNames) ?
+ tle->resname : strVal(list_nth(colNames, tle->resno - 1)));
+
+ if (IsA(tle->expr, Aggref))
+ makeIvmAggColumn(pstate, (Aggref *) tle->expr, resname, &next_resno, &aggs);
+ }
+ rewritten->targetList = list_concat(rewritten->targetList, aggs);
+ }
+
+ /* Add count(*) for counting distinct tuples in views */
+ if (rewritten->distinctClause || rewritten->hasAggs)
+ {
+ TargetEntry *tle;
+
fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
fn->agg_star = true;
@@ -456,6 +502,91 @@ rewriteQueryForIMMV(Query *query, List *colNames)
return rewritten;
}
+/*
+ * makeIvmAggColumn -- make additional aggregate columns for IVM
+ *
+ * For an aggregate column specified by aggref, additional aggregate columns
+ * are added, which are used to calculate the new aggregate value in IMMV.
+ * An additional aggregate columns has a name based on resname
+ * (ex. ivm_count_resname), and resno specified by next_resno. The created
+ * columns are returned to aggs, and the resno for the next column is also
+ * returned to next_resno.
+ *
+ * Currently, an additional count() is created for aggref other than count.
+ * In addition, sum() is created for avg aggregate column.
+ */
+void
+makeIvmAggColumn(ParseState *pstate, Aggref *aggref, char *resname, AttrNumber *next_resno, List **aggs)
+{
+ TargetEntry *tle_count;
+ Node *node;
+ FuncCall *fn;
+ Const *dmy_arg = makeConst(INT4OID,
+ -1,
+ InvalidOid,
+ sizeof(int32),
+ Int32GetDatum(1),
+ false,
+ true); /* pass by value */
+ const char *aggname = get_func_name(aggref->aggfnoid);
+
+ /*
+ * For aggregate functions except count, add count() func with the same arg parameters.
+ * This count result is used for determining if the aggregate value should be NULL or not.
+ * Also, add sum() func for avg because we need to calculate an average value as sum/count.
+ *
+ * XXX: If there are same expressions explicitly in the target list, we can use this instead
+ * of adding new duplicated one.
+ */
+ if (strcmp(aggname, "count") != 0)
+ {
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+
+ /* Make a Func with a dummy arg, and then override this by the original agg's args. */
+ node = ParseFuncOrColumn(pstate, fn->funcname, list_make1(dmy_arg), NULL, fn, false, -1);
+ ((Aggref *)node)->args = aggref->args;
+
+ tle_count = makeTargetEntry((Expr *) node,
+ *next_resno,
+ pstrdup(makeObjectName("__ivm_count",resname, "_")),
+ false);
+ *aggs = lappend(*aggs, tle_count);
+ (*next_resno)++;
+ }
+ if (strcmp(aggname, "avg") == 0)
+ {
+ List *dmy_args = NIL;
+ ListCell *lc;
+ foreach(lc, aggref->aggargtypes)
+ {
+ Oid typeid = lfirst_oid(lc);
+ Type type = typeidType(typeid);
+
+ Const *con = makeConst(typeid,
+ -1,
+ typeTypeCollation(type),
+ typeLen(type),
+ (Datum) 0,
+ true,
+ typeByVal(type));
+ dmy_args = lappend(dmy_args, con);
+ ReleaseSysCache(type);
+ }
+ fn = makeFuncCall(SystemFuncName("sum"), NIL, COERCE_EXPLICIT_CALL, -1);
+
+ /* Make a Func with dummy args, and then override this by the original agg's args. */
+ node = ParseFuncOrColumn(pstate, fn->funcname, dmy_args, NULL, fn, false, -1);
+ ((Aggref *)node)->args = aggref->args;
+
+ tle_count = makeTargetEntry((Expr *) node,
+ *next_resno,
+ pstrdup(makeObjectName("__ivm_sum",resname, "_")),
+ false);
+ *aggs = lappend(*aggs, tle_count);
+ (*next_resno)++;
+ }
+}
+
/*
* GetIntoRelEFlags --- compute executor flags needed for CREATE TABLE AS
*
@@ -941,11 +1072,13 @@ CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock
static void
check_ivm_restriction(Node *node)
{
- check_ivm_restriction_walker(node, NULL);
+ check_ivm_restriction_context context = {false};
+
+ check_ivm_restriction_walker(node, &context);
}
static bool
-check_ivm_restriction_walker(Node *node, void *context)
+check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context)
{
if (node == NULL)
return false;
@@ -974,6 +1107,10 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("CTE is not supported on incrementally maintainable materialized view")));
+ if (qry->groupClause != NIL && !qry->hasAggs)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUP BY clause without aggregate is not supported on incrementally maintainable materialized view")));
if (qry->havingQual != NULL)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
@@ -1026,6 +1163,8 @@ check_ivm_restriction_walker(Node *node, void *context)
}
}
+ context->has_agg |= qry->hasAggs;
+
/* restrictions for rtable */
foreach(lc, qry->rtable)
{
@@ -1074,7 +1213,7 @@ check_ivm_restriction_walker(Node *node, void *context)
}
- query_tree_walker(qry, check_ivm_restriction_walker, NULL, QTW_IGNORE_RANGE_TABLE);
+ query_tree_walker(qry, check_ivm_restriction_walker, (void *) context, QTW_IGNORE_RANGE_TABLE);
break;
}
@@ -1085,8 +1224,12 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("column name %s is not supported on incrementally maintainable materialized view", tle->resname)));
+ if (context->has_agg && !IsA(tle->expr, Aggref) && contain_aggs_of_level((Node *) tle->expr, 0))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("expression containing an aggregate in it is not supported on incrementally maintainable materialized view")));
- expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
break;
}
case T_JoinExpr:
@@ -1098,14 +1241,36 @@ check_ivm_restriction_walker(Node *node, void *context)
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("OUTER JOIN is not supported on incrementally maintainable materialized view")));
- expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
+ break;
}
- break;
case T_Aggref:
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("aggregate function is not supported on incrementally maintainable materialized view")));
- break;
+ {
+ /* Check if this supports IVM */
+ Aggref *aggref = (Aggref *) node;
+ const char *aggname = format_procedure(aggref->aggfnoid);
+
+ if (aggref->aggfilter != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with FILTER clause is not supported on incrementally maintainable materialized view")));
+
+ if (aggref->aggdistinct != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with DISTINCT arguments is not supported on incrementally maintainable materialized view")));
+
+ if (aggref->aggorder != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with ORDER clause is not supported on incrementally maintainable materialized view")));
+
+ if (!check_aggregate_supports_ivm(aggref->aggfnoid))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function %s is not supported on incrementally maintainable materialized view", aggname)));
+ break;
+ }
default:
expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
break;
@@ -1113,6 +1278,46 @@ check_ivm_restriction_walker(Node *node, void *context)
return false;
}
+/*
+ * check_aggregate_supports_ivm
+ *
+ * Check if the given aggregate function is supporting IVM
+ */
+static bool
+check_aggregate_supports_ivm(Oid aggfnoid)
+{
+ switch (aggfnoid)
+ {
+ /* count */
+ case F_COUNT_ANY:
+ case F_COUNT_:
+
+ /* sum */
+ case F_SUM_INT8:
+ case F_SUM_INT4:
+ case F_SUM_INT2:
+ case F_SUM_FLOAT4:
+ case F_SUM_FLOAT8:
+ case F_SUM_MONEY:
+ case F_SUM_INTERVAL:
+ case F_SUM_NUMERIC:
+
+ /* avg */
+ case F_AVG_INT8:
+ case F_AVG_INT4:
+ case F_AVG_INT2:
+ case F_AVG_NUMERIC:
+ case F_AVG_FLOAT4:
+ case F_AVG_FLOAT8:
+ case F_AVG_INTERVAL:
+
+ return true;
+
+ default:
+ return false;
+ }
+}
+
/*
* CreateIndexOnIMMV
*
@@ -1170,7 +1375,29 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
index->concurrent = false;
index->if_not_exists = false;
- if (query->distinctClause)
+ if (query->groupClause)
+ {
+ /* create unique constraint on GROUP BY expression columns */
+ foreach(lc, query->groupClause)
+ {
+ SortGroupClause *scl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(scl, query->targetList);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ else if (query->distinctClause)
{
/* create unique constraint on all columns */
foreach(lc, query->targetList)
@@ -1228,7 +1455,7 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
(errmsg("could not create an index on materialized view \"%s\" automatically",
RelationGetRelationName(matviewRel)),
errdetail("This target list does not have all the primary key columns, "
- "or this view does not contain DISTINCT clause."),
+ "or this view does not contain GROUP BY or DISTINCT clause."),
errhint("Create an index on the materialized view for efficient incremental maintenance.")));
return;
}
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index 0064e10966..b7f6c3831b 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -27,6 +27,7 @@
#include "catalog/pg_trigger.h"
#include "catalog/pg_opclass.h"
#include "commands/cluster.h"
+#include "commands/defrem.h"
#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
@@ -36,6 +37,7 @@
#include "executor/tstoreReceiver.h"
#include "miscadmin.h"
#include "nodes/makefuncs.h"
+#include "optimizer/optimizer.h"
#include "parser/analyze.h"
#include "parser/parse_clause.h"
#include "parser/parse_func.h"
@@ -107,6 +109,13 @@ static HTAB *mv_trigger_info = NULL;
static bool in_delta_calculation = false;
+/* kind of IVM operation for the view */
+typedef enum
+{
+ IVM_ADD,
+ IVM_SUB
+} IvmOp;
+
/* ENR name for materialized view delta */
#define NEW_DELTA_ENRNAME "new_delta"
#define OLD_DELTA_ENRNAME "old_delta"
@@ -138,7 +147,7 @@ static RangeTblEntry *get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *tabl
QueryEnvironment *queryEnv, Oid matviewid);
static RangeTblEntry *replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
QueryEnvironment *queryEnv);
-static Query *rewrite_query_for_counting(Query *query, ParseState *pstate);
+static Query *rewrite_query_for_counting_and_aggregates(Query *query, ParseState *pstate);
static void calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
DestReceiver *dest_old, DestReceiver *dest_new,
@@ -149,14 +158,27 @@ static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *
static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
Query *query, bool use_count, char *count_colname);
+static void append_set_clause_for_count(const char *resname, StringInfo buf_old,
+ StringInfo buf_new,StringInfo aggs_list);
+static void append_set_clause_for_sum(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list);
+static void append_set_clause_for_avg(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ const char *aggtype);
+static char *get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
+ const char* count_col, const char *castType);
+static char *get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
+ const char* count_col);
static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
- List *keys, const char *count_colname);
+ List *keys, StringInfo aggs_list, StringInfo aggs_set,
+ const char *count_colname);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
- List *keys, StringInfo target_list, const char* count_colname);
+ List *keys, StringInfo target_list, StringInfo aggs_set,
+ const char* count_colname);
static char *get_matching_condition_string(List *keys);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
@@ -1454,11 +1476,44 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
* When a base table is truncated, the view content will be empty if the
* view definition query does not contain an aggregate without a GROUP clause.
* Therefore, such views can be truncated.
+ *
+ * Aggregate views without a GROUP clause always have one row. Therefore,
+ * if a base table is truncated, the view will not be empty and will contain
+ * a row with NULL value (or 0 for count()). So, in this case, we refresh the
+ * view instead of truncating it.
*/
if (TRIGGER_FIRED_BY_TRUNCATE(trigdata->tg_event))
{
- ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
- NIL, DROP_RESTRICT, false, false);
+ if (!(query->hasAggs && query->groupClause == NIL))
+ ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
+ NIL, DROP_RESTRICT, false, false);
+ else
+ {
+ Oid OIDNewHeap;
+ DestReceiver *dest;
+ uint64 processed = 0;
+ Query *dataQuery = rewriteQueryForIMMV(query, NIL);
+ char relpersistence = matviewRel->rd_rel->relpersistence;
+
+ /*
+ * Create the transient table that will receive the regenerated data. Lock
+ * it against access by any other process until commit (by which time it
+ * will be gone).
+ */
+ OIDNewHeap = make_new_heap(matviewOid, matviewRel->rd_rel->reltablespace,
+ matviewRel->rd_rel->relam,
+ relpersistence, ExclusiveLock);
+ LockRelationOid(OIDNewHeap, AccessExclusiveLock);
+ dest = CreateTransientRelDestReceiver(OIDNewHeap);
+
+ /* Generate the data */
+ processed = refresh_matview_datafill(dest, dataQuery, NULL, NULL, "");
+ refresh_by_heap_swap(matviewOid, OIDNewHeap, relpersistence);
+
+ /* Inform cumulative stats system about our activity */
+ pgstat_count_truncate(matviewRel);
+ pgstat_count_heap_insert(matviewRel, processed);
+ }
/* Clean up hash entry and delete tuplestores */
clean_up_IVM_hash_entry(entry, false);
@@ -1498,8 +1553,8 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
/* Set all tables in the query to pre-update state */
rewritten = rewrite_query_for_preupdate_state(rewritten, entry->tables,
pstate, matviewOid);
- /* Rewrite for counting duplicated tuples */
- rewritten = rewrite_query_for_counting(rewritten, pstate);
+ /* Rewrite for counting duplicated tuples and aggregates functions*/
+ rewritten = rewrite_query_for_counting_and_aggregates(rewritten, pstate);
/* Create tuplestores to store view deltas */
if (entry->has_old)
@@ -1550,7 +1605,7 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
count_colname = pstrdup("__ivm_count__");
- if (query->distinctClause)
+ if (query->hasAggs || query->distinctClause)
use_count = true;
/* calculate delta tables */
@@ -1946,17 +2001,34 @@ replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
}
/*
- * rewrite_query_for_counting
+ * rewrite_query_for_counting_and_aggregates
*
- * Rewrite query for counting duplicated tuples.
+ * Rewrite query for counting duplicated tuples and aggregate functions.
*/
static Query *
-rewrite_query_for_counting(Query *query, ParseState *pstate)
+rewrite_query_for_counting_and_aggregates(Query *query, ParseState *pstate)
{
TargetEntry *tle_count;
FuncCall *fn;
Node *node;
+ /* For aggregate views */
+ if (query->hasAggs)
+ {
+ ListCell *lc;
+ List *aggs = NIL;
+ AttrNumber next_resno = list_length(query->targetList) + 1;
+
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+
+ if (IsA(tle->expr, Aggref))
+ makeIvmAggColumn(pstate, (Aggref *)tle->expr, tle->resname, &next_resno, &aggs);
+ }
+ query->targetList = list_concat(query->targetList, aggs);
+ }
+
/* Add count(*) for counting distinct tuples in views */
fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
fn->agg_star = true;
@@ -2029,6 +2101,8 @@ rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte
return query;
}
+#define IVM_colname(type, col) makeObjectName("__ivm_" type, col, "_")
+
/*
* apply_delta
*
@@ -2042,6 +2116,9 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
{
StringInfoData querybuf;
StringInfoData target_list_buf;
+ StringInfo aggs_list_buf = NULL;
+ StringInfo aggs_set_old = NULL;
+ StringInfo aggs_set_new = NULL;
Relation matviewRel;
char *matviewname;
ListCell *lc;
@@ -2064,6 +2141,15 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
initStringInfo(&querybuf);
initStringInfo(&target_list_buf);
+ if (query->hasAggs)
+ {
+ if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
+ aggs_set_old = makeStringInfo();
+ if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
+ aggs_set_new = makeStringInfo();
+ aggs_list_buf = makeStringInfo();
+ }
+
/* build string of target list */
for (i = 0; i < matviewRel->rd_att->natts; i++)
{
@@ -2080,13 +2166,61 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
i++;
if (tle->resjunk)
continue;
- keys = lappend(keys, attr);
+ /*
+ * For views without aggregates, all attributes are used as keys to identify a
+ * tuple in a view.
+ */
+ if (!query->hasAggs)
+ keys = lappend(keys, attr);
+
+ /* For views with aggregates, we need to build SET clause for updating aggregate
+ * values. */
+ if (query->hasAggs && IsA(tle->expr, Aggref))
+ {
+ Aggref *aggref = (Aggref *) tle->expr;
+ const char *aggname = get_func_name(aggref->aggfnoid);
+
+ /*
+ * We can use function names here because it is already checked if these
+ * can be used in IMMV by its OID at the definition time.
+ */
+
+ /* count */
+ if (!strcmp(aggname, "count"))
+ append_set_clause_for_count(resname, aggs_set_old, aggs_set_new, aggs_list_buf);
+
+ /* sum */
+ else if (!strcmp(aggname, "sum"))
+ append_set_clause_for_sum(resname, aggs_set_old, aggs_set_new, aggs_list_buf);
+
+ /* avg */
+ else if (!strcmp(aggname, "avg"))
+ append_set_clause_for_avg(resname, aggs_set_old, aggs_set_new, aggs_list_buf,
+ format_type_be(aggref->aggtype));
+
+ else
+ elog(ERROR, "unsupported aggregate function: %s", aggname);
+ }
+ }
+
+ /* If we have GROUP BY clause, we use its entries as keys. */
+ if (query->hasAggs && query->groupClause)
+ {
+ foreach (lc, query->groupClause)
+ {
+ SortGroupClause *sgcl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(sgcl, query->targetList);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ keys = lappend(keys, attr);
+ }
}
/* Start maintaining the materialized view. */
@@ -2117,7 +2251,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (use_count)
/* apply old delta and get rows to be recalculated */
apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
- keys, count_colname);
+ keys, aggs_list_buf, aggs_set_old,
+ count_colname);
else
apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
@@ -2143,7 +2278,7 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
/* apply new delta */
if (use_count)
apply_new_delta_with_count(matviewname, NEW_DELTA_ENRNAME,
- keys, &target_list_buf, count_colname);
+ keys, aggs_set_new, &target_list_buf, count_colname);
else
apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
}
@@ -2158,6 +2293,250 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_finish failed");
}
+/*
+ * append_set_clause_for_count
+ *
+ * Append SET clause string for count aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_count(const char *resname, StringInfo buf_old,
+ StringInfo buf_new,StringInfo aggs_list)
+{
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* resname = mv.resname - t.resname */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, resname, "mv", "t", NULL, NULL));
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* resname = mv.resname + diff.resname */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, resname, "mv", "diff", NULL, NULL));
+ }
+
+ appendStringInfo(aggs_list, ", %s",
+ quote_qualified_identifier("diff", resname)
+ );
+}
+
+/*
+ * append_set_clause_for_sum
+ *
+ * Append SET clause string for sum aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_sum(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list)
+{
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* sum = mv.sum - t.sum */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, resname, "mv", "t", count_col, NULL)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* sum = mv.sum + diff.sum */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, resname, "mv", "diff", count_col, NULL)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
+/*
+ * append_set_clause_for_avg
+ *
+ * Append SET clause string for avg aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_avg(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ const char *aggtype)
+{
+ char *sum_col = IVM_colname("sum", resname);
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* avg = (mv.sum - t.sum)::aggtype / (mv.count - t.count) */
+ appendStringInfo(buf_old,
+ ", %s = %s OPERATOR(pg_catalog./) %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, sum_col, "mv", "t", count_col, aggtype),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ /* sum = mv.sum - t.sum */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, sum_col),
+ get_operation_string(IVM_SUB, sum_col, "mv", "t", count_col, NULL)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* avg = (mv.sum + diff.sum)::aggtype / (mv.count + diff.count) */
+ appendStringInfo(buf_new,
+ ", %s = %s OPERATOR(pg_catalog./) %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, sum_col, "mv", "diff", count_col, aggtype),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ /* sum = mv.sum + diff.sum */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, sum_col),
+ get_operation_string(IVM_ADD, sum_col, "mv", "diff", count_col, NULL)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("sum", resname)),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
+/*
+ * get_operation_string
+ *
+ * Build a string to calculate the new aggregate values.
+ */
+static char *
+get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
+ const char* count_col, const char *castType)
+{
+ StringInfoData buf;
+ StringInfoData castString;
+ char *col1 = quote_qualified_identifier(arg1, col);
+ char *col2 = quote_qualified_identifier(arg2, col);
+ char op_char = (op == IVM_SUB ? '-' : '+');
+
+ initStringInfo(&buf);
+ initStringInfo(&castString);
+
+ if (castType)
+ appendStringInfo(&castString, "::%s", castType);
+
+ if (!count_col)
+ {
+ /*
+ * If the attributes don't have count columns then calc the result
+ * by using the operator simply.
+ */
+ appendStringInfo(&buf, "(%s OPERATOR(pg_catalog.%c) %s)%s",
+ col1, op_char, col2, castString.data);
+ }
+ else
+ {
+ /*
+ * If the attributes have count columns then consider the condition
+ * where the result becomes NULL.
+ */
+ char *null_cond = get_null_condition_string(op, arg1, arg2, count_col);
+
+ appendStringInfo(&buf,
+ "(CASE WHEN %s THEN NULL "
+ "WHEN %s IS NULL THEN %s "
+ "WHEN %s IS NULL THEN %s "
+ "ELSE (%s OPERATOR(pg_catalog.%c) %s)%s END)",
+ null_cond,
+ col1, col2,
+ col2, col1,
+ col1, op_char, col2, castString.data
+ );
+ }
+
+ return buf.data;
+}
+
+/*
+ * get_null_condition_string
+ *
+ * Build a predicate string for CASE clause to check if an aggregate value
+ * will became NULL after the given operation is applied.
+ */
+static char *
+get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
+ const char* count_col)
+{
+ StringInfoData null_cond;
+ initStringInfo(&null_cond);
+
+ switch (op)
+ {
+ case IVM_ADD:
+ appendStringInfo(&null_cond,
+ "%s OPERATOR(pg_catalog.=) 0 AND %s OPERATOR(pg_catalog.=) 0",
+ quote_qualified_identifier(arg1, count_col),
+ quote_qualified_identifier(arg2, count_col)
+ );
+ break;
+ case IVM_SUB:
+ appendStringInfo(&null_cond,
+ "%s OPERATOR(pg_catalog.=) %s",
+ quote_qualified_identifier(arg1, count_col),
+ quote_qualified_identifier(arg2, count_col)
+ );
+ break;
+ default:
+ elog(ERROR,"unknown operation");
+ }
+
+ return null_cond.data;
+}
+
+
/*
* apply_old_delta_with_count
*
@@ -2165,13 +2544,20 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
* which contains tuples to be deleted from to a materialized view given by
* matviewname. This is used when counting is required, that is, the view
* has aggregate or distinct.
+ *
+ * If the view desn't have aggregates or has GROUP BY, this requires a keys
+ * list to identify a tuple in the view. If the view has aggregates, this
+ * requires strings representing resnames of aggregates and SET clause for
+ * updating aggregate values.
*/
static void
apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
- List *keys, const char *count_colname)
+ List *keys, StringInfo aggs_list, StringInfo aggs_set,
+ const char *count_colname)
{
StringInfoData querybuf;
char *match_cond;
+ bool agg_without_groupby = (list_length(keys) == 0);
/* build WHERE condition for searching tuples to be deleted */
match_cond = get_matching_condition_string(keys);
@@ -2181,22 +2567,26 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
appendStringInfo(&querybuf,
"WITH t AS (" /* collecting tid of target tuples in the view */
"SELECT diff.%s, " /* count column */
- "(diff.%s OPERATOR(pg_catalog.=) mv.%s) AS for_dlt, "
+ "(diff.%s OPERATOR(pg_catalog.=) mv.%s AND %s) AS for_dlt, "
"mv.ctid "
+ "%s " /* aggregate columns */
"FROM %s AS mv, %s AS diff "
"WHERE %s" /* tuple matching condition */
"), updt AS (" /* update a tuple if this is not to be deleted */
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
+ "%s" /* SET clauses for aggregates */
"FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
")"
/* delete a tuple if this is to be deleted */
"DELETE FROM %s AS mv USING t "
"WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
count_colname,
- count_colname, count_colname,
+ count_colname, count_colname, (agg_without_groupby ? "false" : "true"),
+ (aggs_list != NULL ? aggs_list->data : ""),
matviewname, deltaname_old,
match_cond,
matviewname, count_colname, count_colname, count_colname,
+ (aggs_set != NULL ? aggs_set->data : ""),
matviewname);
if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
@@ -2260,10 +2650,15 @@ apply_old_delta(const char *matviewname, const char *deltaname_old,
* matviewname. This is used when counting is required, that is, the view
* has aggregate or distinct. Also, when a table in EXISTS sub queries
* is modified.
+ *
+ * If the view desn't have aggregates or has GROUP BY, this requires a keys
+ * list to identify a tuple in the view. If the view has aggregates, this
+ * requires strings representing SET clause for updating aggregate values.
*/
static void
apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
- List *keys, StringInfo target_list, const char* count_colname)
+ List *keys, StringInfo aggs_set, StringInfo target_list,
+ const char* count_colname)
{
StringInfoData querybuf;
StringInfoData returning_keys;
@@ -2294,6 +2689,7 @@ apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
appendStringInfo(&querybuf,
"WITH updt AS (" /* update a tuple if this exists in the view */
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.+) diff.%s "
+ "%s " /* SET clauses for aggregates */
"FROM %s AS diff "
"WHERE %s " /* tuple matching condition */
"RETURNING %s" /* returning keys of updated tuples */
@@ -2301,6 +2697,7 @@ apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
"SELECT %s FROM %s AS diff "
"WHERE NOT EXISTS (SELECT 1 FROM updt AS mv WHERE %s);",
matviewname, count_colname, count_colname, count_colname,
+ (aggs_set != NULL ? aggs_set->data : ""),
deltaname_new,
match_cond,
returning_keys.data,
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 6b47e66bfd..af3a5b4b27 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -30,6 +30,7 @@ extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
extern Query *rewriteQueryForIMMV(Query *query, List *colNames);
+extern void makeIvmAggColumn(ParseState *pstate, Aggref *aggref, char *resname, AttrNumber *next_resno, List **aggs);
extern int GetIntoRelEFlags(IntoClause *intoClause);
--
2.25.1
v32-0009-Add-support-for-min-max-aggregates-for-IVM.patchtext/x-diff; name=v32-0009-Add-support-for-min-max-aggregates-for-IVM.patchDownload
From 54b24003c7e61c42330f4f8d069d2960f8929440 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 20:58:25 +0900
Subject: [PATCH v32 09/11] Add support for min/max aggregates for IVM
Supporting min and max is more complicated than count, sum, or avg.
For an example of min, when tuples are inserted, the current min value
in the view and the min value in the inseteted tuples are compared,
then the smaller one is used as the latest min value. On the other
hand, when tuples are deleted, if the current min value in the view
equals to the min in the deleted tuples, we need re-computation the
latest min value from base tables. Otherwise, the current value in
the view remains.
---
src/backend/commands/createas.c | 45 +++
src/backend/commands/matview.c | 644 +++++++++++++++++++++++++++++++-
2 files changed, 680 insertions(+), 9 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index ecec93ec1c..d3cf3df5a7 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -1311,6 +1311,51 @@ check_aggregate_supports_ivm(Oid aggfnoid)
case F_AVG_FLOAT8:
case F_AVG_INTERVAL:
+ /* min */
+ case F_MIN_ANYARRAY:
+ case F_MIN_INT8:
+ case F_MIN_INT4:
+ case F_MIN_INT2:
+ case F_MIN_OID:
+ case F_MIN_FLOAT4:
+ case F_MIN_FLOAT8:
+ case F_MIN_DATE:
+ case F_MIN_TIME:
+ case F_MIN_TIMETZ:
+ case F_MIN_MONEY:
+ case F_MIN_TIMESTAMP:
+ case F_MIN_TIMESTAMPTZ:
+ case F_MIN_INTERVAL:
+ case F_MIN_TEXT:
+ case F_MIN_NUMERIC:
+ case F_MIN_BPCHAR:
+ case F_MIN_TID:
+ case F_MIN_ANYENUM:
+ case F_MIN_INET:
+ case F_MIN_PG_LSN:
+
+ /* max */
+ case F_MAX_ANYARRAY:
+ case F_MAX_INT8:
+ case F_MAX_INT4:
+ case F_MAX_INT2:
+ case F_MAX_OID:
+ case F_MAX_FLOAT4:
+ case F_MAX_FLOAT8:
+ case F_MAX_DATE:
+ case F_MAX_TIME:
+ case F_MAX_TIMETZ:
+ case F_MAX_MONEY:
+ case F_MAX_TIMESTAMP:
+ case F_MAX_TIMESTAMPTZ:
+ case F_MAX_INTERVAL:
+ case F_MAX_TEXT:
+ case F_MAX_NUMERIC:
+ case F_MAX_BPCHAR:
+ case F_MAX_TID:
+ case F_MAX_ANYENUM:
+ case F_MAX_INET:
+ case F_MAX_PG_LSN:
return true;
default:
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index b7f6c3831b..42ff0ed98f 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -69,6 +69,34 @@ typedef struct
#define MV_INIT_QUERYHASHSIZE 16
+/* MV query type codes */
+#define MV_PLAN_RECALC 1
+#define MV_PLAN_SET_VALUE 2
+
+/*
+ * MI_QueryKey
+ *
+ * The key identifying a prepared SPI plan in our query hashtable
+ */
+typedef struct MV_QueryKey
+{
+ Oid matview_id; /* OID of materialized view */
+ int32 query_type; /* query type ID, see MV_PLAN_XXX above */
+} MV_QueryKey;
+
+/*
+ * MV_QueryHashEntry
+ *
+ * Hash entry for cached plans used to maintain materialized views.
+ */
+typedef struct MV_QueryHashEntry
+{
+ MV_QueryKey key;
+ SPIPlanPtr plan;
+ SearchPathMatcher *search_path; /* search_path used for parsing
+ * and planning */
+} MV_QueryHashEntry;
+
/*
* MV_TriggerHashEntry
*
@@ -105,6 +133,7 @@ typedef struct MV_TriggerTable
TupleTableSlot *slot; /* for checking visibility in the pre-state table */
} MV_TriggerTable;
+static HTAB *mv_query_cache = NULL;
static HTAB *mv_trigger_info = NULL;
static bool in_delta_calculation = false;
@@ -165,6 +194,9 @@ static void append_set_clause_for_sum(const char *resname, StringInfo buf_old,
static void append_set_clause_for_avg(const char *resname, StringInfo buf_old,
StringInfo buf_new, StringInfo aggs_list,
const char *aggtype);
+static void append_set_clause_for_minmax(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ bool is_min);
static char *get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
const char* count_col, const char *castType);
static char *get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
@@ -173,17 +205,30 @@ static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
List *keys, StringInfo aggs_list, StringInfo aggs_set,
- const char *count_colname);
+ List *minmax_list, List *is_min_list,
+ const char *count_colname,
+ SPITupleTable **tuptable_recalc, uint64 *num_recalc);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
List *keys, StringInfo target_list, StringInfo aggs_set,
const char* count_colname);
static char *get_matching_condition_string(List *keys);
+static char *get_returning_string(List *minmax_list, List *is_min_list, List *keys);
+static char *get_minmax_recalc_condition_string(List *minmax_list, List *is_min_list);
+static char *get_select_for_recalc_string(List *keys);
+static void recalc_and_set_values(SPITupleTable *tuptable_recalc, int64 num_tuples,
+ List *namelist, List *keys, Relation matviewRel);
+static SPIPlanPtr get_plan_for_recalc(Oid matviewOid, List *namelist, List *keys, Oid *keyTypes);
+static SPIPlanPtr get_plan_for_set_values(Oid matviewOid, char *matviewname, List *namelist,
+ Oid *valTypes);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
static void mv_InitHashTables(void);
+static SPIPlanPtr mv_FetchPreparedPlan(MV_QueryKey *key);
+static void mv_HashPreparedPlan(MV_QueryKey *key, SPIPlanPtr plan);
+static void mv_BuildQueryKey(MV_QueryKey *key, Oid matview_id, int32 query_type);
static void clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort);
/*
@@ -2124,6 +2169,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
ListCell *lc;
int i;
List *keys = NIL;
+ List *minmax_list = NIL;
+ List *is_min_list = NIL;
/*
@@ -2205,6 +2252,17 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
append_set_clause_for_avg(resname, aggs_set_old, aggs_set_new, aggs_list_buf,
format_type_be(aggref->aggtype));
+ /* min/max */
+ else if (!strcmp(aggname, "min") || !strcmp(aggname, "max"))
+ {
+ bool is_min = (!strcmp(aggname, "min"));
+
+ append_set_clause_for_minmax(resname, aggs_set_old, aggs_set_new, aggs_list_buf, is_min);
+
+ /* make a resname list of min and max aggregates */
+ minmax_list = lappend(minmax_list, resname);
+ is_min_list = lappend_int(is_min_list, is_min);
+ }
else
elog(ERROR, "unsupported aggregate function: %s", aggname);
}
@@ -2234,6 +2292,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
{
EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ SPITupleTable *tuptable_recalc = NULL;
+ uint64 num_recalc;
int rc;
/* convert tuplestores to ENR, and register for SPI */
@@ -2252,10 +2312,18 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
/* apply old delta and get rows to be recalculated */
apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
keys, aggs_list_buf, aggs_set_old,
- count_colname);
+ minmax_list, is_min_list,
+ count_colname, &tuptable_recalc, &num_recalc);
else
apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+ /*
+ * If we have min or max, we might have to recalculate aggregate values from base tables
+ * on some tuples. TIDs and keys such tuples are returned as a result of the above query.
+ */
+ if (minmax_list && tuptable_recalc)
+ recalc_and_set_values(tuptable_recalc, num_recalc, minmax_list, keys, matviewRel);
+
}
/* For tuple insertion */
if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
@@ -2447,6 +2515,70 @@ append_set_clause_for_avg(const char *resname, StringInfo buf_old,
);
}
+/*
+ * append_set_clause_for_minmax
+ *
+ * Append SET clause string for min or max aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ * is_min is true if this is min, false if not.
+ */
+static void
+append_set_clause_for_minmax(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ bool is_min)
+{
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /*
+ * If the new value doesn't became NULL then use the value remaining
+ * in the view although this will be recomputated afterwords.
+ */
+ appendStringInfo(buf_old,
+ ", %s = CASE WHEN %s THEN NULL ELSE %s END",
+ quote_qualified_identifier(NULL, resname),
+ get_null_condition_string(IVM_SUB, "mv", "t", count_col),
+ quote_qualified_identifier("mv", resname)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /*
+ * min = LEAST(mv.min, diff.min)
+ * max = GREATEST(mv.max, diff.max)
+ */
+ appendStringInfo(buf_new,
+ ", %s = CASE WHEN %s THEN NULL ELSE %s(%s,%s) END",
+ quote_qualified_identifier(NULL, resname),
+ get_null_condition_string(IVM_ADD, "mv", "diff", count_col),
+
+ is_min ? "LEAST" : "GREATEST",
+ quote_qualified_identifier("mv", resname),
+ quote_qualified_identifier("diff", resname)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
/*
* get_operation_string
*
@@ -2549,19 +2681,44 @@ get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
* list to identify a tuple in the view. If the view has aggregates, this
* requires strings representing resnames of aggregates and SET clause for
* updating aggregate values.
+ *
+ * If the view has min or max aggregate, this requires a list of resnames of
+ * min/max aggregates and a list of boolean which represents which entries in
+ * minmax_list is min. These are necessary to check if we need to recalculate
+ * min or max aggregate values. In this case, this query returns TID and keys
+ * of tuples which need to be recalculated. This result and the number of rows
+ * are stored in tuptables and num_recalc repectedly.
+ *
*/
static void
apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
List *keys, StringInfo aggs_list, StringInfo aggs_set,
- const char *count_colname)
+ List *minmax_list, List *is_min_list,
+ const char *count_colname,
+ SPITupleTable **tuptable_recalc, uint64 *num_recalc)
{
StringInfoData querybuf;
char *match_cond;
+ char *updt_returning = "";
+ char *select_for_recalc = "SELECT";
bool agg_without_groupby = (list_length(keys) == 0);
+ Assert(tuptable_recalc != NULL);
+ Assert(num_recalc != NULL);
+
/* build WHERE condition for searching tuples to be deleted */
match_cond = get_matching_condition_string(keys);
+ /*
+ * We need a special RETURNING clause and SELECT statement for min/max to
+ * check which tuple needs re-calculation from base tables.
+ */
+ if (minmax_list)
+ {
+ updt_returning = get_returning_string(minmax_list, is_min_list, keys);
+ select_for_recalc = get_select_for_recalc_string(keys);
+ }
+
/* Search for matching tuples from the view and update or delete if found. */
initStringInfo(&querybuf);
appendStringInfo(&querybuf,
@@ -2576,10 +2733,11 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
"%s" /* SET clauses for aggregates */
"FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
- ")"
- /* delete a tuple if this is to be deleted */
- "DELETE FROM %s AS mv USING t "
- "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
+ "%s" /* RETURNING clause for recalc infomation */
+ "), dlt AS (" /* delete a tuple if this is to be deleted */
+ "DELETE FROM %s AS mv USING t "
+ "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt"
+ ") %s", /* SELECT returning which tuples need to be recalculated */
count_colname,
count_colname, count_colname, (agg_without_groupby ? "false" : "true"),
(aggs_list != NULL ? aggs_list->data : ""),
@@ -2587,10 +2745,25 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
match_cond,
matviewname, count_colname, count_colname, count_colname,
(aggs_set != NULL ? aggs_set->data : ""),
- matviewname);
+ updt_returning,
+ matviewname,
+ select_for_recalc);
- if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_SELECT)
elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+
+
+ /* Return tuples to be recalculated. */
+ if (minmax_list)
+ {
+ *tuptable_recalc = SPI_tuptable;
+ *num_recalc = SPI_processed;
+ }
+ else
+ {
+ *tuptable_recalc = NULL;
+ *num_recalc = 0;
+ }
}
/*
@@ -2773,6 +2946,349 @@ get_matching_condition_string(List *keys)
return match_cond.data;
}
+/*
+ * get_returning_string
+ *
+ * Build a string for RETURNING clause of UPDATE used in apply_old_delta_with_count.
+ * This clause returns ctid and a boolean value that indicates if we need to
+ * recalculate min or max value, for each updated row.
+ */
+static char *
+get_returning_string(List *minmax_list, List *is_min_list, List *keys)
+{
+ StringInfoData returning;
+ char *recalc_cond;
+ ListCell *lc;
+
+ Assert(minmax_list != NIL && is_min_list != NIL);
+ recalc_cond = get_minmax_recalc_condition_string(minmax_list, is_min_list);
+
+ initStringInfo(&returning);
+
+ appendStringInfo(&returning, "RETURNING mv.ctid AS tid, (%s) AS recalc", recalc_cond);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&returning, ", %s", quote_qualified_identifier("mv", resname));
+ }
+
+ return returning.data;
+}
+
+/*
+ * get_minmax_recalc_condition_string
+ *
+ * Build a predicate string for checking if any min/max aggregate
+ * value needs to be recalculated.
+ */
+static char *
+get_minmax_recalc_condition_string(List *minmax_list, List *is_min_list)
+{
+ StringInfoData recalc_cond;
+ ListCell *lc1, *lc2;
+
+ initStringInfo(&recalc_cond);
+
+ Assert (list_length(minmax_list) == list_length(is_min_list));
+
+ forboth (lc1, minmax_list, lc2, is_min_list)
+ {
+ char *resname = (char *) lfirst(lc1);
+ bool is_min = (bool) lfirst_int(lc2);
+ char *op_str = (is_min ? ">=" : "<=");
+
+ appendStringInfo(&recalc_cond, "%s OPERATOR(pg_catalog.%s) %s",
+ quote_qualified_identifier("mv", resname),
+ op_str,
+ quote_qualified_identifier("t", resname)
+ );
+
+ if (lnext(minmax_list, lc1))
+ appendStringInfo(&recalc_cond, " OR ");
+ }
+
+ return recalc_cond.data;
+}
+
+/*
+ * get_select_for_recalc_string
+ *
+ * Build a query to return tid and keys of tuples which need
+ * recalculation. This is used as the result of the query
+ * built by apply_old_delta.
+ */
+static char *
+get_select_for_recalc_string(List *keys)
+{
+ StringInfoData qry;
+ ListCell *lc;
+
+ initStringInfo(&qry);
+
+ appendStringInfo(&qry, "SELECT tid");
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ appendStringInfo(&qry, ", %s", NameStr(attr->attname));
+ }
+
+ appendStringInfo(&qry, " FROM updt WHERE recalc");
+
+ return qry.data;
+}
+
+/*
+ * recalc_and_set_values
+ *
+ * Recalculate tuples in a materialized from base tables and update these.
+ * The tuples which needs recalculation are specified by keys, and resnames
+ * of columns to be updated are specified by namelist. TIDs and key values
+ * are given by tuples in tuptable_recalc. Its first attribute must be TID
+ * and key values must be following this.
+ */
+static void
+recalc_and_set_values(SPITupleTable *tuptable_recalc, int64 num_tuples,
+ List *namelist, List *keys, Relation matviewRel)
+{
+ TupleDesc tupdesc_recalc = tuptable_recalc->tupdesc;
+ Oid *keyTypes = NULL, *types = NULL;
+ char *keyNulls = NULL, *nulls = NULL;
+ Datum *keyVals = NULL, *vals = NULL;
+ int num_vals = list_length(namelist);
+ int num_keys = list_length(keys);
+ uint64 i;
+ Oid matviewOid;
+ char *matviewname;
+
+ matviewOid = RelationGetRelid(matviewRel);
+ matviewname = quote_qualified_identifier(get_namespace_name(RelationGetNamespace(matviewRel)),
+ RelationGetRelationName(matviewRel));
+
+ /* If we have keys, initialize arrays for them. */
+ if (keys)
+ {
+ keyTypes = palloc(sizeof(Oid) * num_keys);
+ keyNulls = palloc(sizeof(char) * num_keys);
+ keyVals = palloc(sizeof(Datum) * num_keys);
+ /* a tuple contains keys to be recalculated and ctid to be updated*/
+ Assert(tupdesc_recalc->natts == num_keys + 1);
+
+ /* Types of key attributes */
+ for (i = 0; i < num_keys; i++)
+ keyTypes[i] = TupleDescAttr(tupdesc_recalc, i + 1)->atttypid;
+ }
+
+ /* allocate memory for all attribute names and tid */
+ types = palloc(sizeof(Oid) * (num_vals + 1));
+ nulls = palloc(sizeof(char) * (num_vals + 1));
+ vals = palloc(sizeof(Datum) * (num_vals + 1));
+
+ /* For each tuple which needs recalculation */
+ for (i = 0; i < num_tuples; i++)
+ {
+ int j;
+ bool isnull;
+ SPIPlanPtr plan;
+ SPITupleTable *tuptable_newvals;
+ TupleDesc tupdesc_newvals;
+
+ /* Set group key values as parameters if needed. */
+ if (keys)
+ {
+ for (j = 0; j < num_keys; j++)
+ {
+ keyVals[j] = SPI_getbinval(tuptable_recalc->vals[i], tupdesc_recalc, j + 2, &isnull);
+ if (isnull)
+ keyNulls[j] = 'n';
+ else
+ keyNulls[j] = ' ';
+ }
+ }
+
+ /*
+ * Get recalculated values from base tables. The result must be
+ * only one tuple thich contains the new values for specified keys.
+ */
+ plan = get_plan_for_recalc(matviewOid, namelist, keys, keyTypes);
+ if (SPI_execute_plan(plan, keyVals, keyNulls, false, 0) != SPI_OK_SELECT)
+ elog(ERROR, "SPI_execute_plan");
+ if (SPI_processed != 1)
+ elog(ERROR, "SPI_execute_plan returned zero or more than one rows");
+
+ tuptable_newvals = SPI_tuptable;
+ tupdesc_newvals = tuptable_newvals->tupdesc;
+
+ Assert(tupdesc_newvals->natts == num_vals);
+
+ /* Set the new values as parameters */
+ for (j = 0; j < tupdesc_newvals->natts; j++)
+ {
+ if (i == 0)
+ types[j] = TupleDescAttr(tupdesc_newvals, j)->atttypid;
+
+ vals[j] = SPI_getbinval(tuptable_newvals->vals[0], tupdesc_newvals, j + 1, &isnull);
+ if (isnull)
+ nulls[j] = 'n';
+ else
+ nulls[j] = ' ';
+ }
+ /* Set TID of the view tuple to be updated as a parameter */
+ types[j] = TIDOID;
+ vals[j] = SPI_getbinval(tuptable_recalc->vals[i], tupdesc_recalc, 1, &isnull);
+ nulls[j] = ' ';
+
+ /* Update the view tuple to the new values */
+ plan = get_plan_for_set_values(matviewOid, matviewname, namelist, types);
+ if (SPI_execute_plan(plan, vals, nulls, false, 0) != SPI_OK_UPDATE)
+ elog(ERROR, "SPI_execute_plan");
+ }
+}
+
+
+/*
+ * get_plan_for_recalc
+ *
+ * Create or fetch a plan for recalculating value in the view's target list
+ * from base tables using the definition query of materialized view specified
+ * by matviewOid. namelist is a list of resnames of values to be recalculated.
+ *
+ * keys is a list of keys to identify tuples to be recalculated if this is not
+ * empty. KeyTypes is an array of types of keys.
+ */
+static SPIPlanPtr
+get_plan_for_recalc(Oid matviewOid, List *namelist, List *keys, Oid *keyTypes)
+{
+ MV_QueryKey hash_key;
+ SPIPlanPtr plan;
+
+ /* Fetch or prepare a saved plan for the recalculation */
+ mv_BuildQueryKey(&hash_key, matviewOid, MV_PLAN_RECALC);
+ if ((plan = mv_FetchPreparedPlan(&hash_key)) == NULL)
+ {
+ ListCell *lc;
+ StringInfoData str;
+ char *viewdef;
+
+ /* get view definition of matview */
+ viewdef = text_to_cstring((text *) DatumGetPointer(
+ DirectFunctionCall1(pg_get_viewdef, ObjectIdGetDatum(matviewOid))));
+ /* get rid of trailing semi-colon */
+ viewdef[strlen(viewdef)-1] = '\0';
+
+ /*
+ * Build a query string for recalculating values. This is like
+ *
+ * SELECT x1, x2, x3, ... FROM ( ... view definition query ...) mv
+ * WHERE (key1, key2, ...) = ($1, $2, ...);
+ */
+
+ initStringInfo(&str);
+ appendStringInfo(&str, "SELECT ");
+ foreach (lc, namelist)
+ {
+ appendStringInfo(&str, "%s", (char *) lfirst(lc));
+ if (lnext(namelist, lc))
+ appendStringInfoString(&str, ", ");
+ }
+ appendStringInfo(&str, " FROM (%s) mv", viewdef);
+
+ if (keys)
+ {
+ int i = 1;
+ char paramname[16];
+
+ appendStringInfo(&str, " WHERE (");
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ Oid typid = attr->atttypid;
+
+ sprintf(paramname, "$%d", i);
+ appendStringInfo(&str, "(");
+ generate_equal(&str, typid, resname, paramname);
+ appendStringInfo(&str, " OR (%s IS NULL AND %s IS NULL))",
+ resname, paramname);
+
+ if (lnext(keys, lc))
+ appendStringInfoString(&str, " AND ");
+ i++;
+ }
+ appendStringInfo(&str, ")");
+ }
+ else
+ keyTypes = NULL;
+
+ plan = SPI_prepare(str.data, list_length(keys), keyTypes);
+ if (plan == NULL)
+ elog(ERROR, "SPI_prepare returned %s for %s", SPI_result_code_string(SPI_result), str.data);
+
+ SPI_keepplan(plan);
+ mv_HashPreparedPlan(&hash_key, plan);
+ }
+
+ return plan;
+}
+
+/*
+ * get_plan_for_set_values
+ *
+ * Create or fetch a plan for applying new values calculated by
+ * get_plan_for_recalc to a materialized view specified by matviewOid.
+ * matviewname is the name of the view. namelist is a list of resnames
+ * of attributes to be updated, and valTypes is an array of types of the
+ * values.
+ */
+static SPIPlanPtr
+get_plan_for_set_values(Oid matviewOid, char *matviewname, List *namelist,
+ Oid *valTypes)
+{
+ MV_QueryKey key;
+ SPIPlanPtr plan;
+
+ /* Fetch or prepare a saved plan for the real check */
+ mv_BuildQueryKey(&key, matviewOid, MV_PLAN_SET_VALUE);
+ if ((plan = mv_FetchPreparedPlan(&key)) == NULL)
+ {
+ ListCell *lc;
+ StringInfoData str;
+ int i;
+
+ /*
+ * Build a query string for applying min/max values. This is like
+ *
+ * UPDATE matviewname AS mv
+ * SET (x1, x2, x3, x4) = ($1, $2, $3, $4)
+ * WHERE ctid = $5;
+ */
+
+ initStringInfo(&str);
+ appendStringInfo(&str, "UPDATE %s AS mv SET (", matviewname);
+ foreach (lc, namelist)
+ {
+ appendStringInfo(&str, "%s", (char *) lfirst(lc));
+ if (lnext(namelist, lc))
+ appendStringInfoString(&str, ", ");
+ }
+ appendStringInfo(&str, ") = ROW(");
+
+ for (i = 1; i <= list_length(namelist); i++)
+ appendStringInfo(&str, "%s$%d", (i==1 ? "" : ", "), i);
+
+ appendStringInfo(&str, ") WHERE ctid OPERATOR(pg_catalog.=) $%d", i);
+
+ plan = SPI_prepare(str.data, list_length(namelist) + 1, valTypes);
+ if (plan == NULL)
+ elog(ERROR, "SPI_prepare returned %s for %s", SPI_result_code_string(SPI_result), str.data);
+
+ SPI_keepplan(plan);
+ mv_HashPreparedPlan(&key, plan);
+ }
+
+ return plan;
+}
+
/*
* generate_equals
*
@@ -2806,6 +3322,13 @@ mv_InitHashTables(void)
{
HASHCTL ctl;
+ memset(&ctl, 0, sizeof(ctl));
+ ctl.keysize = sizeof(MV_QueryKey);
+ ctl.entrysize = sizeof(MV_QueryHashEntry);
+ mv_query_cache = hash_create("MV query cache",
+ MV_INIT_QUERYHASHSIZE,
+ &ctl, HASH_ELEM | HASH_BLOBS);
+
memset(&ctl, 0, sizeof(ctl));
ctl.keysize = sizeof(Oid);
ctl.entrysize = sizeof(MV_TriggerHashEntry);
@@ -2814,6 +3337,109 @@ mv_InitHashTables(void)
&ctl, HASH_ELEM | HASH_BLOBS);
}
+/*
+ * mv_FetchPreparedPlan
+ */
+static SPIPlanPtr
+mv_FetchPreparedPlan(MV_QueryKey *key)
+{
+ MV_QueryHashEntry *entry;
+ SPIPlanPtr plan;
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_query_cache)
+ mv_InitHashTables();
+
+ /*
+ * Lookup for the key
+ */
+ entry = (MV_QueryHashEntry *) hash_search(mv_query_cache,
+ (void *) key,
+ HASH_FIND, NULL);
+ if (entry == NULL)
+ return NULL;
+
+ /*
+ * Check whether the plan is still valid. If it isn't, we don't want to
+ * simply rely on plancache.c to regenerate it; rather we should start
+ * from scratch and rebuild the query text too. This is to cover cases
+ * such as table/column renames. We depend on the plancache machinery to
+ * detect possible invalidations, though.
+ *
+ * CAUTION: this check is only trustworthy if the caller has already
+ * locked both materialized views and base tables.
+ *
+ * Also, check whether the search_path is still the same as when we made it.
+ * If it isn't, we need to rebuild the query text because the result of
+ * pg_ivm_get_viewdef() will change.
+ */
+ plan = entry->plan;
+ if (plan && SPI_plan_is_valid(plan) &&
+ SearchPathMatchesCurrentEnvironment(entry->search_path))
+ return plan;
+
+ /*
+ * Otherwise we might as well flush the cached plan now, to free a little
+ * memory space before we make a new one.
+ */
+ if (plan)
+ SPI_freeplan(plan);
+ if (entry->search_path)
+ pfree(entry->search_path);
+
+ entry->plan = NULL;
+ entry->search_path = NULL;
+
+ return NULL;
+}
+
+/*
+ * mv_HashPreparedPlan
+ *
+ * Add another plan to our private SPI query plan hashtable.
+ */
+static void
+mv_HashPreparedPlan(MV_QueryKey *key, SPIPlanPtr plan)
+{
+ MV_QueryHashEntry *entry;
+ bool found;
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_query_cache)
+ mv_InitHashTables();
+
+ /*
+ * Add the new plan. We might be overwriting an entry previously found
+ * invalid by mv_FetchPreparedPlan.
+ */
+ entry = (MV_QueryHashEntry *) hash_search(mv_query_cache,
+ (void *) key,
+ HASH_ENTER, &found);
+ Assert(!found || entry->plan == NULL);
+ entry->plan = plan;
+ entry->search_path = GetSearchPathMatcher(TopMemoryContext);
+}
+
+/*
+ * mv_BuildQueryKey
+ *
+ * Construct a hashtable key for a prepared SPI plan for IVM.
+ */
+static void
+mv_BuildQueryKey(MV_QueryKey *key, Oid matview_id, int32 query_type)
+{
+ /*
+ * We assume struct MV_QueryKey contains no padding bytes, else we'd need
+ * to use memset to clear them.
+ */
+ key->matview_id = matview_id;
+ key->query_type = query_type;
+}
+
/*
* AtAbort_IVM
*
--
2.25.1
v32-0010-Add-regression-tests-for-Incremental-View-Mainte.patchtext/x-diff; name=v32-0010-Add-regression-tests-for-Incremental-View-Mainte.patchDownload
From a9fb7f9dc48b3cbfeb943759852b80baea1278da Mon Sep 17 00:00:00 2001
From: Takuma Hoshiai <takuma.hoshiai@gmail.com>
Date: Wed, 10 Mar 2021 11:11:13 +0900
Subject: [PATCH v32 10/11] Add regression tests for Incremental View
Maintenance
---
.../regress/expected/incremental_matview.out | 1030 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/incremental_matview.sql | 533 +++++++++
3 files changed, 1564 insertions(+), 1 deletion(-)
create mode 100644 src/test/regress/expected/incremental_matview.out
create mode 100644 src/test/regress/sql/incremental_matview.sql
diff --git a/src/test/regress/expected/incremental_matview.out b/src/test/regress/expected/incremental_matview.out
new file mode 100644
index 0000000000..d65896425e
--- /dev/null
+++ b/src/test/regress/expected/incremental_matview.out
@@ -0,0 +1,1030 @@
+-- create a table to use as a basis for views and materialized views in various combinations
+CREATE TABLE mv_base_a (i int, j int);
+INSERT INTO mv_base_a VALUES
+ (1,10),
+ (2,20),
+ (3,30),
+ (4,40),
+ (5,50);
+CREATE TABLE mv_base_b (i int, k int);
+INSERT INTO mv_base_b VALUES
+ (1,101),
+ (2,102),
+ (3,103),
+ (4,104);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_1 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) WITH NO DATA;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ERROR: materialized view "mv_ivm_1" has not been populated
+HINT: Use the REFRESH MATERIALIZED VIEW command.
+REFRESH MATERIALIZED VIEW mv_ivm_1;
+NOTICE: could not create an index on materialized view "mv_ivm_1" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+-- REFRESH WITH NO DATA
+BEGIN;
+CREATE FUNCTION dummy_ivm_trigger_func() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+CREATE CONSTRAINT TRIGGER dummy_ivm_trigger AFTER INSERT
+ON mv_base_a FROM mv_ivm_1 FOR EACH ROW
+EXECUTE PROCEDURE dummy_ivm_trigger_func();
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ count
+-------
+ 17
+(1 row)
+
+REFRESH MATERIALIZED VIEW mv_ivm_1 WITH NO DATA;
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+-- immediate maintenance
+BEGIN;
+INSERT INTO mv_base_b VALUES(5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+ 5 | 50 | 105
+(5 rows)
+
+UPDATE mv_base_a SET j = 0 WHERE i = 1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 0 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+ 5 | 50 | 105
+(5 rows)
+
+DELETE FROM mv_base_b WHERE (i,k) = (5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 0 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+ROLLBACK;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+-- rename of IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS SELECT DISTINCT * FROM mv_base_a;
+NOTICE: created index "mv_ivm_rename_index" on materialized view "mv_ivm_rename"
+ALTER MATERIALIZED VIEW mv_ivm_rename RENAME COLUMN __ivm_count__ TO xxx;
+ERROR: IVM column can not be renamed
+DROP MATERIALIZED VIEW mv_ivm_rename;
+-- unique index on IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_unique AS SELECT DISTINCT * FROM mv_base_a;
+NOTICE: created index "mv_ivm_unique_index" on materialized view "mv_ivm_unique"
+CREATE UNIQUE INDEX ON mv_ivm_unique(__ivm_count__);
+ERROR: unique index creation on IVM columns is not supported
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__));
+ERROR: unique index creation on IVM columns is not supported
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__ + 1));
+ERROR: unique index creation on IVM columns is not supported
+DROP MATERIALIZED VIEW mv_ivm_unique;
+-- TRUNCATE a base table in join views
+BEGIN;
+TRUNCATE mv_base_a;
+SELECT * FROM mv_ivm_1;
+ i | j | k
+---+---+---
+(0 rows)
+
+ROLLBACK;
+BEGIN;
+TRUNCATE mv_base_b;
+SELECT * FROM mv_ivm_1;
+ i | j | k
+---+---+---
+(0 rows)
+
+ROLLBACK;
+-- some query syntax
+BEGIN;
+CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql'
+ AS 'SELECT 1' IMMUTABLE;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_func AS SELECT * FROM ivm_func();
+NOTICE: could not create an index on materialized view "mv_ivm_func" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_no_tbl AS SELECT 1;
+NOTICE: could not create an index on materialized view "mv_ivm_no_tbl" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+ROLLBACK;
+-- result of materialized view have DISTINCT clause or the duplicate result.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_duplicate AS SELECT j FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_duplicate" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_distinct AS SELECT DISTINCT j FROM mv_base_a;
+NOTICE: created index "mv_ivm_distinct_index" on materialized view "mv_ivm_distinct"
+INSERT INTO mv_base_a VALUES(6,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 20
+ 30
+ 40
+ 50
+(6 rows)
+
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+ROLLBACK;
+-- support SUM(), COUNT() and AVG() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 120 | 2 | 60.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+UPDATE mv_base_a SET j = 200 WHERE (i,j) = (2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+----------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 220 | 2 | 110.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (2,200);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+ROLLBACK;
+-- support COUNT(*) aggregate function
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ i | sum | count
+---+-----+-------
+ 1 | 10 | 1
+ 2 | 20 | 1
+ 3 | 30 | 1
+ 4 | 40 | 1
+ 5 | 50 | 1
+(5 rows)
+
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ i | sum | count
+---+-----+-------
+ 1 | 10 | 1
+ 2 | 120 | 2
+ 3 | 30 | 1
+ 4 | 40 | 1
+ 5 | 50 | 1
+(5 rows)
+
+ROLLBACK;
+-- TRUNCATE a base table in aggregate views
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+TRUNCATE mv_base_a;
+SELECT sum, count FROM mv_ivm_agg;
+ sum | count
+-----+-------
+(0 rows)
+
+SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+ i | sum | count
+---+-----+-------
+(0 rows)
+
+ROLLBACK;
+-- support aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_group" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+---------------------
+ 150 | 5 | 30.0000000000000000
+(1 row)
+
+INSERT INTO mv_base_a VALUES(6,60);
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+---------------------
+ 210 | 6 | 35.0000000000000000
+(1 row)
+
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+ROLLBACK;
+-- TRUNCATE a base table in aggregate views without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_group" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+TRUNCATE mv_base_a;
+SELECT sum, count, avg FROM mv_ivm_group;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+ROLLBACK;
+-- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_avg_bug AS SELECT i, SUM(j), COUNT(j), AVG(j) FROM mv_base_A GROUP BY i;
+NOTICE: created index "mv_ivm_avg_bug_index" on materialized view "mv_ivm_avg_bug"
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+INSERT INTO mv_base_a VALUES
+ (1,0),
+ (1,0),
+ (2,30),
+ (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 3 | 3.3333333333333333
+ 2 | 80 | 3 | 26.6666666666666667
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (1,0);
+DELETE FROM mv_base_a WHERE (i,j) = (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+ROLLBACK;
+-- support MIN(), MAX() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_min_max_index" on materialized view "mv_ivm_min_max"
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 10 | 10
+ 2 | 20 | 20
+ 3 | 30 | 30
+ 4 | 40 | 40
+ 5 | 50 | 50
+(5 rows)
+
+INSERT INTO mv_base_a VALUES
+ (1,11), (1,12),
+ (2,21), (2,22),
+ (3,31), (3,32),
+ (4,41), (4,42),
+ (5,51), (5,52);
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 10 | 12
+ 2 | 20 | 22
+ 3 | 30 | 32
+ 4 | 40 | 42
+ 5 | 50 | 52
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) IN ((1,10), (2,21), (3,32));
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 11 | 12
+ 2 | 20 | 22
+ 3 | 30 | 31
+ 4 | 40 | 42
+ 5 | 50 | 52
+(5 rows)
+
+ROLLBACK;
+-- support MIN(), MAX() aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT MIN(j), MAX(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_min_max" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 10 | 50
+(1 row)
+
+INSERT INTO mv_base_a VALUES
+ (0,0), (6,60), (7,70);
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 0 | 70
+(1 row)
+
+DELETE FROM mv_base_a WHERE (i,j) IN ((0,0), (7,70));
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 10 | 60
+(1 row)
+
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ |
+(1 row)
+
+ROLLBACK;
+-- Test MIN/MAX after search_path change
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min AS SELECT MIN(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_min" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 10
+(1 row)
+
+CREATE SCHEMA myschema;
+GRANT ALL ON SCHEMA myschema TO public;
+CREATE TABLE myschema.mv_base_a (j int);
+INSERT INTO myschema.mv_base_a VALUES (1);
+DELETE FROM mv_base_a WHERE (i,j) = (1,10);
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 20
+(1 row)
+
+SET search_path TO myschema,public,pg_catalog;
+DELETE FROM public.mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 30
+(1 row)
+
+ROLLBACK;
+-- aggregate views with column names specified
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ a | sum
+---+------
+ 1 | 110
+ 2 | 2200
+ 3 | 300
+ 4 | 40
+ 5 | 50
+(5 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ a | b
+---+------
+ 1 | 110
+ 2 | 2200
+ 3 | 300
+ 4 | 40
+ 5 | 50
+(5 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b,c) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+ERROR: too many column names were specified
+ROLLBACK;
+-- support self join view and multiple change on the same table
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_self(v1, v2) AS
+ SELECT t1.v, t2.v FROM base_t AS t1 JOIN base_t AS t2 ON t1.i = t2.i;
+NOTICE: could not create an index on materialized view "mv_self" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+----+----
+ 10 | 10
+ 20 | 20
+ 30 | 30
+(3 rows)
+
+INSERT INTO base_t VALUES (4,40);
+DELETE FROM base_t WHERE i = 1;
+UPDATE base_t SET v = v*10 WHERE i=2;
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+-----+-----
+ 30 | 30
+ 40 | 40
+ 200 | 200
+(3 rows)
+
+WITH
+ ins_t1 AS (INSERT INTO base_t VALUES (5,50) RETURNING 1),
+ ins_t2 AS (INSERT INTO base_t VALUES (6,60) RETURNING 1),
+ upd_t AS (UPDATE base_t SET v = v + 100 RETURNING 1),
+ dlt_t AS (DELETE FROM base_t WHERE i IN (4,5) RETURNING 1)
+SELECT NULL;
+ ?column?
+----------
+
+(1 row)
+
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+-----+-----
+ 50 | 50
+ 60 | 60
+ 130 | 130
+ 300 | 300
+(4 rows)
+
+--- with sub-transactions
+SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,70);
+RELEASE SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,77);
+SELECT * FROM mv_self ORDER BY v1, v2;
+ v1 | v2
+-----+-----
+ 50 | 50
+ 60 | 60
+ 70 | 70
+ 70 | 77
+ 77 | 70
+ 77 | 77
+ 130 | 130
+ 300 | 300
+(8 rows)
+
+ROLLBACK;
+-- support simultaneous table changes
+BEGIN;
+CREATE TABLE base_r (i int, v int);
+CREATE TABLE base_s (i int, v int);
+INSERT INTO base_r VALUES (1, 10), (2, 20), (3, 30);
+INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300);
+CREATE INCREMENTAL MATERIALIZED VIEW mv(v1, v2) AS
+ SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i);
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY v1;
+ v1 | v2
+----+-----
+ 10 | 100
+ 20 | 200
+ 30 | 300
+(3 rows)
+
+WITH
+ ins_r AS (INSERT INTO base_r VALUES (1,11) RETURNING 1),
+ ins_r2 AS (INSERT INTO base_r VALUES (3,33) RETURNING 1),
+ ins_s AS (INSERT INTO base_s VALUES (2,222) RETURNING 1),
+ upd_r AS (UPDATE base_r SET v = v + 1000 WHERE i = 2 RETURNING 1),
+ dlt_s AS (DELETE FROM base_s WHERE i = 3 RETURNING 1)
+SELECT NULL;
+ ?column?
+----------
+
+(1 row)
+
+SELECT * FROM mv ORDER BY v1;
+ v1 | v2
+------+-----
+ 10 | 100
+ 11 | 100
+ 1020 | 200
+ 1020 | 222
+(4 rows)
+
+ROLLBACK;
+-- support foreign reference constraints
+BEGIN;
+CREATE TABLE ri1 (i int PRIMARY KEY);
+CREATE TABLE ri2 (i int PRIMARY KEY REFERENCES ri1(i) ON UPDATE CASCADE ON DELETE CASCADE, v int);
+INSERT INTO ri1 VALUES (1),(2),(3);
+INSERT INTO ri2 VALUES (1),(2),(3);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ri(i1, i2) AS
+ SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i);
+NOTICE: created index "mv_ri_index" on materialized view "mv_ri"
+SELECT * FROM mv_ri ORDER BY i1;
+ i1 | i2
+----+----
+ 1 | 1
+ 2 | 2
+ 3 | 3
+(3 rows)
+
+UPDATE ri1 SET i=10 where i=1;
+DELETE FROM ri1 WHERE i=2;
+SELECT * FROM mv_ri ORDER BY i2;
+ i1 | i2
+----+----
+ 3 | 3
+ 10 | 10
+(2 rows)
+
+ROLLBACK;
+-- views including NULL
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1,10),(2, NULL);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY i;
+ i | v
+---+----
+ 1 | 10
+ 2 |
+(2 rows)
+
+UPDATE base_t SET v = 20 WHERE i = 2;
+SELECT * FROM mv ORDER BY i;
+ i | v
+---+----
+ 1 | 10
+ 2 | 20
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY i;
+ i
+---
+(0 rows)
+
+INSERT INTO base_t VALUES (1),(NULL);
+SELECT * FROM mv ORDER BY i;
+ i
+---
+ 1
+
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, sum(v) FROM base_t GROUP BY i;
+NOTICE: created index "mv_index" on materialized view "mv"
+SELECT * FROM mv ORDER BY i;
+ i | sum
+---+-----
+ 1 | 30
+ | 3
+(2 rows)
+
+UPDATE base_t SET v = v * 10;
+SELECT * FROM mv ORDER BY i;
+ i | sum
+---+-----
+ 1 | 300
+ | 30
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, min(v), max(v) FROM base_t GROUP BY i;
+NOTICE: created index "mv_index" on materialized view "mv"
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 1 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 1;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 3;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 5;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 4
+(1 row)
+
+ROLLBACK;
+-- IMMV containing user defined type
+BEGIN;
+CREATE TYPE mytype;
+CREATE FUNCTION mytype_in(cstring)
+ RETURNS mytype AS 'int4in'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+NOTICE: return type mytype is only a shell
+CREATE FUNCTION mytype_out(mytype)
+ RETURNS cstring AS 'int4out'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+NOTICE: argument type mytype is only a shell
+CREATE TYPE mytype (
+ LIKE = int4,
+ INPUT = mytype_in,
+ OUTPUT = mytype_out
+);
+CREATE FUNCTION mytype_eq(mytype, mytype)
+ RETURNS bool AS 'int4eq'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_lt(mytype, mytype)
+ RETURNS bool AS 'int4lt'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_cmp(mytype, mytype)
+ RETURNS integer AS 'btint4cmp'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE OPERATOR = (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_eq);
+CREATE OPERATOR < (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_lt);
+CREATE OPERATOR CLASS mytype_ops
+ DEFAULT FOR TYPE mytype USING btree AS
+ OPERATOR 1 <,
+ OPERATOR 3 = ,
+ FUNCTION 1 mytype_cmp(mytype,mytype);
+CREATE TABLE t_mytype (x mytype);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_mytype AS
+ SELECT * FROM t_mytype;
+NOTICE: could not create an index on materialized view "mv_mytype" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+INSERT INTO t_mytype VALUES ('1'::mytype);
+SELECT * FROM mv_mytype;
+ x
+---
+ 1
+(1 row)
+
+ROLLBACK;
+-- outer join is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv(a,b) AS SELECT a.i, b.i FROM mv_base_a a LEFT JOIN mv_base_b b ON a.i=b.i;
+ERROR: OUTER JOIN is not supported on incrementally maintainable materialized view
+-- CTE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS
+ WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i;
+ERROR: CTE is not supported on incrementally maintainable materialized view
+-- contain system column
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm01 AS SELECT i,j,xmin FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT i,j,xmin::text AS x_min FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm06 AS SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+-- contain subquery
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm03 AS SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 );
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT * FROM mv_base_b) b WHERE a.i = b.i;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm05 AS SELECT i,j, (SELECT k FROM mv_base_b b WHERE a.i = b.i) FROM mv_base_a a;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+-- contain ORDER BY
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) ORDER BY i,j,k;
+ERROR: ORDER BY clause is not supported on incrementally maintainable materialized view
+-- contain HAVING
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) GROUP BY i,j,k HAVING SUM(i) > 5;
+ERROR: HAVING clause is not supported on incrementally maintainable materialized view
+-- contain view or materialized view
+CREATE VIEW b_view AS SELECT i,k FROM mv_base_b;
+CREATE MATERIALIZED VIEW b_mview AS SELECT i,k FROM mv_base_b;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT a.i,a.j FROM mv_base_a a,b_view b WHERE a.i = b.i;
+ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT a.i,a.j FROM mv_base_a a,b_mview b WHERE a.i = b.i;
+ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm09 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) b WHERE a.i = b.i;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm10 AS SELECT a.i,a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) OR a.i > 5;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+-- contain mutable functions
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+ERROR: mutable function is not supported on incrementally maintainable materialized view
+HINT: functions must be marked IMMUTABLE
+-- LIMIT/OFFSET is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm13 AS SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5;
+ERROR: LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view
+-- DISTINCT ON is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm14 AS SELECT DISTINCT ON(i) i, j FROM mv_base_a;
+ERROR: DISTINCT ON is not supported on incrementally maintainable materialized view
+-- TABLESAMPLE clause is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm15 AS SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50);
+ERROR: TABLESAMPLE clause is not supported on incrementally maintainable materialized view
+-- window functions are not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm16 AS SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a;
+ERROR: window functions are not supported on incrementally maintainable materialized view
+-- aggregate function with some options is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm17 AS SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a;
+ERROR: aggregate function with FILTER clause is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm18 AS SELECT COUNT(DISTINCT i) FROM mv_base_a;
+ERROR: aggregate function with DISTINCT arguments is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm19 AS SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a;
+ERROR: aggregate function with ORDER clause is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm20 AS SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),());
+ERROR: GROUPING SETS, ROLLUP, or CUBE clauses is not supported on incrementally maintainable materialized view
+-- inheritance parent is not supported
+BEGIN;
+CREATE TABLE parent (i int, v int);
+CREATE TABLE child_a(options text) INHERITS(parent);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm21 AS SELECT * FROM parent;
+ERROR: inheritance parent is not supported on incrementally maintainable materialized view
+ROLLBACK;
+-- UNION statement is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm22 AS SELECT i,j FROM mv_base_a UNION ALL SELECT i,k FROM mv_base_b;;
+ERROR: UNION/INTERSECT/EXCEPT statements are not supported on incrementally maintainable materialized view
+-- empty target list is not allowed with IVM
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm25 AS SELECT FROM mv_base_a;
+ERROR: empty target list is not supported on incrementally maintainable materialized view
+-- FOR UPDATE/SHARE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm26 AS SELECT i,j FROM mv_base_a FOR UPDATE;
+ERROR: FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view
+-- tartget list cannot contain ivm column that start with '__ivm'
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm28 AS SELECT i AS "__ivm_count__" FROM mv_base_a;
+ERROR: column name __ivm_count__ is not supported on incrementally maintainable materialized view
+-- expressions specified in GROUP BY must appear in the target list.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm29 AS SELECT COUNT(i) FROM mv_base_a GROUP BY i;
+ERROR: GROUP BY expression not appearing in select list is not supported on incrementally maintainable materialized view
+-- experssions containing an aggregate is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm30 AS SELECT sum(i)*0.5 FROM mv_base_a;
+ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm31 AS SELECT sum(i)/sum(j) FROM mv_base_a;
+ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view
+-- VALUES is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_only_values1 AS values(1);
+ERROR: VALUES is not supported on incrementally maintainable materialized view
+-- views containing base tables with Row Level Security
+DROP USER IF EXISTS regress_ivm_admin;
+NOTICE: role "regress_ivm_admin" does not exist, skipping
+DROP USER IF EXISTS regress_ivm_user;
+NOTICE: role "regress_ivm_user" does not exist, skipping
+CREATE USER regress_ivm_admin;
+CREATE USER regress_ivm_user;
+--- create a table with RLS
+SET SESSION AUTHORIZATION regress_ivm_admin;
+CREATE TABLE rls_tbl(id int, data text, owner name);
+INSERT INTO rls_tbl VALUES
+ (1,'foo','regress_ivm_user'),
+ (2,'bar','postgres');
+CREATE TABLE num_tbl(id int, num text);
+INSERT INTO num_tbl VALUES
+ (1,'one'),
+ (2,'two'),
+ (3,'three'),
+ (4,'four'),
+ (5,'five'),
+ (6,'six');
+--- Users can access only their own rows
+CREATE POLICY rls_tbl_policy ON rls_tbl FOR SELECT TO PUBLIC USING(owner = current_user);
+ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
+GRANT ALL on rls_tbl TO PUBLIC;
+GRANT ALL on num_tbl TO PUBLIC;
+--- create a view owned by regress_ivm_user
+SET SESSION AUTHORIZATION regress_ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls AS SELECT * FROM rls_tbl;
+NOTICE: could not create an index on materialized view "ivm_rls" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+------+------------------
+ 1 | foo | regress_ivm_user
+(1 row)
+
+RESET SESSION AUTHORIZATION;
+--- inserts rows owned by different users
+INSERT INTO rls_tbl VALUES
+ (3,'baz','regress_ivm_user'),
+ (4,'qux','postgres');
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+------+------------------
+ 1 | foo | regress_ivm_user
+ 3 | baz | regress_ivm_user
+(2 rows)
+
+--- combination of diffent kinds of commands
+WITH
+ i AS (INSERT INTO rls_tbl VALUES(5,'quux','postgres'), (6,'corge','regress_ivm_user')),
+ u AS (UPDATE rls_tbl SET owner = 'postgres' WHERE id = 1),
+ u2 AS (UPDATE rls_tbl SET owner = 'regress_ivm_user' WHERE id = 2)
+SELECT;
+--
+(1 row)
+
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+-------+------------------
+ 2 | bar | regress_ivm_user
+ 3 | baz | regress_ivm_user
+ 6 | corge | regress_ivm_user
+(3 rows)
+
+---
+SET SESSION AUTHORIZATION regress_ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls2 AS SELECT * FROM rls_tbl JOIN num_tbl USING(id);
+NOTICE: could not create an index on materialized view "ivm_rls2" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+RESET SESSION AUTHORIZATION;
+WITH
+ x AS (UPDATE rls_tbl SET data = data || '_2' where id in (3,4)),
+ y AS (UPDATE num_tbl SET num = num || '_2' where id in (3,4))
+SELECT;
+--
+(1 row)
+
+SELECT * FROM ivm_rls2 ORDER BY 1,2,3;
+ id | data | owner | num
+----+-------+------------------+---------
+ 2 | bar | regress_ivm_user | two
+ 3 | baz_2 | regress_ivm_user | three_2
+ 6 | corge | regress_ivm_user | six
+(3 rows)
+
+-- automatic index creation
+CREATE TABLE base_a (i int primary key, j int);
+CREATE TABLE base_b (i int primary key, j int);
+--- group by: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx1 AS SELECT i, sum(j) FROM base_a GROUP BY i;
+NOTICE: created index "mv_idx1_index" on materialized view "mv_idx1"
+--- distinct: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx2 AS SELECT DISTINCT j FROM base_a;
+NOTICE: created index "mv_idx2_index" on materialized view "mv_idx2"
+--- with all pkey columns: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx3(i_a, i_b) AS SELECT a.i, b.i FROM base_a a, base_b b;
+NOTICE: created index "mv_idx3_index" on materialized view "mv_idx3"
+--- missing some pkey columns: no index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx4 AS SELECT j FROM base_a;
+NOTICE: could not create an index on materialized view "mv_idx4" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx5 AS SELECT a.i, b.j FROM base_a a, base_b b;
+NOTICE: could not create an index on materialized view "mv_idx5" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+-- cleanup
+DROP TABLE rls_tbl CASCADE;
+NOTICE: drop cascades to 2 other objects
+DETAIL: drop cascades to materialized view ivm_rls
+drop cascades to materialized view ivm_rls2
+DROP TABLE num_tbl CASCADE;
+DROP USER regress_ivm_user;
+DROP USER regress_ivm_admin;
+DROP TABLE mv_base_b CASCADE;
+NOTICE: drop cascades to 3 other objects
+DETAIL: drop cascades to materialized view mv_ivm_1
+drop cascades to view b_view
+drop cascades to materialized view b_mview
+DROP TABLE mv_base_a CASCADE;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 5ac6e871f5..64c910af65 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -78,7 +78,7 @@ test: brin_bloom brin_multi
# psql depends on create_am
# amutils depends on geometry, create_index_spgist, hash_index, brin
# ----------
-test: create_table_like alter_generic alter_operator misc async dbsize merge misc_functions sysviews tsrf tid tidscan tidrangescan collate.utf8 collate.icu.utf8 incremental_sort create_role without_overlaps
+test: create_table_like alter_generic alter_operator misc async dbsize merge misc_functions sysviews tsrf tid tidscan tidrangescan collate.utf8 collate.icu.utf8 incremental_sort create_role without_overlaps incremental_matview
# collate.linux.utf8 and collate.icu.utf8 tests cannot be run in parallel with each other
test: rules psql psql_crosstab amutils stats_ext collate.linux.utf8 collate.windows.win1252
diff --git a/src/test/regress/sql/incremental_matview.sql b/src/test/regress/sql/incremental_matview.sql
new file mode 100644
index 0000000000..90116edff8
--- /dev/null
+++ b/src/test/regress/sql/incremental_matview.sql
@@ -0,0 +1,533 @@
+-- create a table to use as a basis for views and materialized views in various combinations
+CREATE TABLE mv_base_a (i int, j int);
+INSERT INTO mv_base_a VALUES
+ (1,10),
+ (2,20),
+ (3,30),
+ (4,40),
+ (5,50);
+CREATE TABLE mv_base_b (i int, k int);
+INSERT INTO mv_base_b VALUES
+ (1,101),
+ (2,102),
+ (3,103),
+ (4,104);
+
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_1 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) WITH NO DATA;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+REFRESH MATERIALIZED VIEW mv_ivm_1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+
+-- REFRESH WITH NO DATA
+BEGIN;
+CREATE FUNCTION dummy_ivm_trigger_func() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+
+CREATE CONSTRAINT TRIGGER dummy_ivm_trigger AFTER INSERT
+ON mv_base_a FROM mv_ivm_1 FOR EACH ROW
+EXECUTE PROCEDURE dummy_ivm_trigger_func();
+
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+
+REFRESH MATERIALIZED VIEW mv_ivm_1 WITH NO DATA;
+
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ROLLBACK;
+
+-- immediate maintenance
+BEGIN;
+INSERT INTO mv_base_b VALUES(5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+UPDATE mv_base_a SET j = 0 WHERE i = 1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+DELETE FROM mv_base_b WHERE (i,k) = (5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ROLLBACK;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+
+-- rename of IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS SELECT DISTINCT * FROM mv_base_a;
+ALTER MATERIALIZED VIEW mv_ivm_rename RENAME COLUMN __ivm_count__ TO xxx;
+DROP MATERIALIZED VIEW mv_ivm_rename;
+
+-- unique index on IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_unique AS SELECT DISTINCT * FROM mv_base_a;
+CREATE UNIQUE INDEX ON mv_ivm_unique(__ivm_count__);
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__));
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__ + 1));
+DROP MATERIALIZED VIEW mv_ivm_unique;
+
+-- TRUNCATE a base table in join views
+BEGIN;
+TRUNCATE mv_base_a;
+SELECT * FROM mv_ivm_1;
+ROLLBACK;
+
+BEGIN;
+TRUNCATE mv_base_b;
+SELECT * FROM mv_ivm_1;
+ROLLBACK;
+
+-- some query syntax
+BEGIN;
+CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql'
+ AS 'SELECT 1' IMMUTABLE;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_func AS SELECT * FROM ivm_func();
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_no_tbl AS SELECT 1;
+ROLLBACK;
+
+-- result of materialized view have DISTINCT clause or the duplicate result.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_duplicate AS SELECT j FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_distinct AS SELECT DISTINCT j FROM mv_base_a;
+INSERT INTO mv_base_a VALUES(6,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+DELETE FROM mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ROLLBACK;
+
+-- support SUM(), COUNT() and AVG() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+UPDATE mv_base_a SET j = 200 WHERE (i,j) = (2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+DELETE FROM mv_base_a WHERE (i,j) = (2,200);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ROLLBACK;
+
+-- support COUNT(*) aggregate function
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ROLLBACK;
+
+-- TRUNCATE a base table in aggregate views
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+TRUNCATE mv_base_a;
+SELECT sum, count FROM mv_ivm_agg;
+SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+ROLLBACK;
+
+-- support aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+INSERT INTO mv_base_a VALUES(6,60);
+SELECT * FROM mv_ivm_group ORDER BY 1;
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ROLLBACK;
+
+-- TRUNCATE a base table in aggregate views without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+TRUNCATE mv_base_a;
+SELECT sum, count, avg FROM mv_ivm_group;
+SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+ROLLBACK;
+
+-- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_avg_bug AS SELECT i, SUM(j), COUNT(j), AVG(j) FROM mv_base_A GROUP BY i;
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES
+ (1,0),
+ (1,0),
+ (2,30),
+ (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+DELETE FROM mv_base_a WHERE (i,j) = (1,0);
+DELETE FROM mv_base_a WHERE (i,j) = (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ROLLBACK;
+
+-- support MIN(), MAX() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES
+ (1,11), (1,12),
+ (2,21), (2,22),
+ (3,31), (3,32),
+ (4,41), (4,42),
+ (5,51), (5,52);
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+DELETE FROM mv_base_a WHERE (i,j) IN ((1,10), (2,21), (3,32));
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ROLLBACK;
+
+-- support MIN(), MAX() aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT MIN(j), MAX(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+INSERT INTO mv_base_a VALUES
+ (0,0), (6,60), (7,70);
+SELECT * FROM mv_ivm_min_max;
+DELETE FROM mv_base_a WHERE (i,j) IN ((0,0), (7,70));
+SELECT * FROM mv_ivm_min_max;
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+ROLLBACK;
+
+-- Test MIN/MAX after search_path change
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min AS SELECT MIN(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_min;
+
+CREATE SCHEMA myschema;
+GRANT ALL ON SCHEMA myschema TO public;
+CREATE TABLE myschema.mv_base_a (j int);
+INSERT INTO myschema.mv_base_a VALUES (1);
+
+DELETE FROM mv_base_a WHERE (i,j) = (1,10);
+SELECT * FROM mv_ivm_min;
+
+SET search_path TO myschema,public,pg_catalog;
+DELETE FROM public.mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_min;
+ROLLBACK;
+
+-- aggregate views with column names specified
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b,c) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+ROLLBACK;
+
+-- support self join view and multiple change on the same table
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_self(v1, v2) AS
+ SELECT t1.v, t2.v FROM base_t AS t1 JOIN base_t AS t2 ON t1.i = t2.i;
+SELECT * FROM mv_self ORDER BY v1;
+INSERT INTO base_t VALUES (4,40);
+DELETE FROM base_t WHERE i = 1;
+UPDATE base_t SET v = v*10 WHERE i=2;
+SELECT * FROM mv_self ORDER BY v1;
+WITH
+ ins_t1 AS (INSERT INTO base_t VALUES (5,50) RETURNING 1),
+ ins_t2 AS (INSERT INTO base_t VALUES (6,60) RETURNING 1),
+ upd_t AS (UPDATE base_t SET v = v + 100 RETURNING 1),
+ dlt_t AS (DELETE FROM base_t WHERE i IN (4,5) RETURNING 1)
+SELECT NULL;
+SELECT * FROM mv_self ORDER BY v1;
+
+--- with sub-transactions
+SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,70);
+RELEASE SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,77);
+SELECT * FROM mv_self ORDER BY v1, v2;
+
+ROLLBACK;
+
+-- support simultaneous table changes
+BEGIN;
+CREATE TABLE base_r (i int, v int);
+CREATE TABLE base_s (i int, v int);
+INSERT INTO base_r VALUES (1, 10), (2, 20), (3, 30);
+INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300);
+CREATE INCREMENTAL MATERIALIZED VIEW mv(v1, v2) AS
+ SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i);
+SELECT * FROM mv ORDER BY v1;
+WITH
+ ins_r AS (INSERT INTO base_r VALUES (1,11) RETURNING 1),
+ ins_r2 AS (INSERT INTO base_r VALUES (3,33) RETURNING 1),
+ ins_s AS (INSERT INTO base_s VALUES (2,222) RETURNING 1),
+ upd_r AS (UPDATE base_r SET v = v + 1000 WHERE i = 2 RETURNING 1),
+ dlt_s AS (DELETE FROM base_s WHERE i = 3 RETURNING 1)
+SELECT NULL;
+SELECT * FROM mv ORDER BY v1;
+ROLLBACK;
+
+-- support foreign reference constraints
+BEGIN;
+CREATE TABLE ri1 (i int PRIMARY KEY);
+CREATE TABLE ri2 (i int PRIMARY KEY REFERENCES ri1(i) ON UPDATE CASCADE ON DELETE CASCADE, v int);
+INSERT INTO ri1 VALUES (1),(2),(3);
+INSERT INTO ri2 VALUES (1),(2),(3);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ri(i1, i2) AS
+ SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i);
+SELECT * FROM mv_ri ORDER BY i1;
+UPDATE ri1 SET i=10 where i=1;
+DELETE FROM ri1 WHERE i=2;
+SELECT * FROM mv_ri ORDER BY i2;
+ROLLBACK;
+
+-- views including NULL
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1,10),(2, NULL);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+SELECT * FROM mv ORDER BY i;
+UPDATE base_t SET v = 20 WHERE i = 2;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+SELECT * FROM mv ORDER BY i;
+INSERT INTO base_t VALUES (1),(NULL);
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, sum(v) FROM base_t GROUP BY i;
+SELECT * FROM mv ORDER BY i;
+UPDATE base_t SET v = v * 10;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, min(v), max(v) FROM base_t GROUP BY i;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 1;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 3;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 5;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+-- IMMV containing user defined type
+BEGIN;
+
+CREATE TYPE mytype;
+CREATE FUNCTION mytype_in(cstring)
+ RETURNS mytype AS 'int4in'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_out(mytype)
+ RETURNS cstring AS 'int4out'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE TYPE mytype (
+ LIKE = int4,
+ INPUT = mytype_in,
+ OUTPUT = mytype_out
+);
+
+CREATE FUNCTION mytype_eq(mytype, mytype)
+ RETURNS bool AS 'int4eq'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_lt(mytype, mytype)
+ RETURNS bool AS 'int4lt'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_cmp(mytype, mytype)
+ RETURNS integer AS 'btint4cmp'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+
+CREATE OPERATOR = (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_eq);
+CREATE OPERATOR < (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_lt);
+
+CREATE OPERATOR CLASS mytype_ops
+ DEFAULT FOR TYPE mytype USING btree AS
+ OPERATOR 1 <,
+ OPERATOR 3 = ,
+ FUNCTION 1 mytype_cmp(mytype,mytype);
+
+CREATE TABLE t_mytype (x mytype);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_mytype AS
+ SELECT * FROM t_mytype;
+INSERT INTO t_mytype VALUES ('1'::mytype);
+SELECT * FROM mv_mytype;
+
+ROLLBACK;
+
+-- outer join is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv(a,b) AS SELECT a.i, b.i FROM mv_base_a a LEFT JOIN mv_base_b b ON a.i=b.i;
+-- CTE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS
+ WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i;
+-- contain system column
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm01 AS SELECT i,j,xmin FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT i,j,xmin::text AS x_min FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm06 AS SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a;
+-- contain subquery
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm03 AS SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 );
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT * FROM mv_base_b) b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm05 AS SELECT i,j, (SELECT k FROM mv_base_b b WHERE a.i = b.i) FROM mv_base_a a;
+-- contain ORDER BY
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) ORDER BY i,j,k;
+-- contain HAVING
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) GROUP BY i,j,k HAVING SUM(i) > 5;
+
+-- contain view or materialized view
+CREATE VIEW b_view AS SELECT i,k FROM mv_base_b;
+CREATE MATERIALIZED VIEW b_mview AS SELECT i,k FROM mv_base_b;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT a.i,a.j FROM mv_base_a a,b_view b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT a.i,a.j FROM mv_base_a a,b_mview b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm09 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm10 AS SELECT a.i,a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) OR a.i > 5;
+
+-- contain mutable functions
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+
+-- LIMIT/OFFSET is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm13 AS SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5;
+
+-- DISTINCT ON is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm14 AS SELECT DISTINCT ON(i) i, j FROM mv_base_a;
+
+-- TABLESAMPLE clause is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm15 AS SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50);
+
+-- window functions are not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm16 AS SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a;
+
+-- aggregate function with some options is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm17 AS SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm18 AS SELECT COUNT(DISTINCT i) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm19 AS SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm20 AS SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),());
+
+-- inheritance parent is not supported
+BEGIN;
+CREATE TABLE parent (i int, v int);
+CREATE TABLE child_a(options text) INHERITS(parent);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm21 AS SELECT * FROM parent;
+ROLLBACK;
+
+-- UNION statement is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm22 AS SELECT i,j FROM mv_base_a UNION ALL SELECT i,k FROM mv_base_b;;
+
+-- empty target list is not allowed with IVM
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm25 AS SELECT FROM mv_base_a;
+
+-- FOR UPDATE/SHARE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm26 AS SELECT i,j FROM mv_base_a FOR UPDATE;
+
+-- tartget list cannot contain ivm column that start with '__ivm'
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm28 AS SELECT i AS "__ivm_count__" FROM mv_base_a;
+
+-- expressions specified in GROUP BY must appear in the target list.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm29 AS SELECT COUNT(i) FROM mv_base_a GROUP BY i;
+
+-- experssions containing an aggregate is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm30 AS SELECT sum(i)*0.5 FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm31 AS SELECT sum(i)/sum(j) FROM mv_base_a;
+
+-- VALUES is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_only_values1 AS values(1);
+
+-- views containing base tables with Row Level Security
+DROP USER IF EXISTS regress_ivm_admin;
+DROP USER IF EXISTS regress_ivm_user;
+CREATE USER regress_ivm_admin;
+CREATE USER regress_ivm_user;
+
+--- create a table with RLS
+SET SESSION AUTHORIZATION regress_ivm_admin;
+CREATE TABLE rls_tbl(id int, data text, owner name);
+INSERT INTO rls_tbl VALUES
+ (1,'foo','regress_ivm_user'),
+ (2,'bar','postgres');
+CREATE TABLE num_tbl(id int, num text);
+INSERT INTO num_tbl VALUES
+ (1,'one'),
+ (2,'two'),
+ (3,'three'),
+ (4,'four'),
+ (5,'five'),
+ (6,'six');
+
+--- Users can access only their own rows
+CREATE POLICY rls_tbl_policy ON rls_tbl FOR SELECT TO PUBLIC USING(owner = current_user);
+ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
+GRANT ALL on rls_tbl TO PUBLIC;
+GRANT ALL on num_tbl TO PUBLIC;
+
+--- create a view owned by regress_ivm_user
+SET SESSION AUTHORIZATION regress_ivm_user;
+
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls AS SELECT * FROM rls_tbl;
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+RESET SESSION AUTHORIZATION;
+
+--- inserts rows owned by different users
+INSERT INTO rls_tbl VALUES
+ (3,'baz','regress_ivm_user'),
+ (4,'qux','postgres');
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+
+--- combination of diffent kinds of commands
+WITH
+ i AS (INSERT INTO rls_tbl VALUES(5,'quux','postgres'), (6,'corge','regress_ivm_user')),
+ u AS (UPDATE rls_tbl SET owner = 'postgres' WHERE id = 1),
+ u2 AS (UPDATE rls_tbl SET owner = 'regress_ivm_user' WHERE id = 2)
+SELECT;
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+
+---
+SET SESSION AUTHORIZATION regress_ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls2 AS SELECT * FROM rls_tbl JOIN num_tbl USING(id);
+RESET SESSION AUTHORIZATION;
+
+WITH
+ x AS (UPDATE rls_tbl SET data = data || '_2' where id in (3,4)),
+ y AS (UPDATE num_tbl SET num = num || '_2' where id in (3,4))
+SELECT;
+SELECT * FROM ivm_rls2 ORDER BY 1,2,3;
+
+-- automatic index creation
+CREATE TABLE base_a (i int primary key, j int);
+CREATE TABLE base_b (i int primary key, j int);
+
+--- group by: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx1 AS SELECT i, sum(j) FROM base_a GROUP BY i;
+
+--- distinct: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx2 AS SELECT DISTINCT j FROM base_a;
+
+--- with all pkey columns: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx3(i_a, i_b) AS SELECT a.i, b.i FROM base_a a, base_b b;
+
+--- missing some pkey columns: no index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx4 AS SELECT j FROM base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx5 AS SELECT a.i, b.j FROM base_a a, base_b b;
+
+-- cleanup
+
+DROP TABLE rls_tbl CASCADE;
+DROP TABLE num_tbl CASCADE;
+DROP USER regress_ivm_user;
+DROP USER regress_ivm_admin;
+
+DROP TABLE mv_base_b CASCADE;
+DROP TABLE mv_base_a CASCADE;
--
2.25.1
v32-0011-Add-documentations-about-Incremental-View-Mainte.patchtext/x-diff; name=v32-0011-Add-documentations-about-Incremental-View-Mainte.patchDownload
From a3e7f5ee46af55b2762904d8ce99adeed45b9ce6 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:25:34 +0900
Subject: [PATCH v32 11/11] Add documentations about Incremental View
Maintenance
---
doc/src/sgml/catalogs.sgml | 9 +
.../sgml/ref/create_materialized_view.sgml | 124 ++++-
.../sgml/ref/refresh_materialized_view.sgml | 8 +-
doc/src/sgml/rules.sgml | 437 ++++++++++++++++++
doc/src/sgml/system-views.sgml | 9 +
5 files changed, 583 insertions(+), 4 deletions(-)
diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index 096ddab481..d4255f1015 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -2231,6 +2231,15 @@ SCRAM-SHA-256$<replaceable><iteration count></replaceable>:<replaceable>&l
</para></entry>
</row>
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>relisivm</structfield> <type>bool</type>
+ </para>
+ <para>
+ True if relation is incrementally maintainable materialized view
+ </para></entry>
+ </row>
+
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>relrewrite</structfield> <type>oid</type>
diff --git a/doc/src/sgml/ref/create_materialized_view.sgml b/doc/src/sgml/ref/create_materialized_view.sgml
index 0d2fea2b97..8c574062db 100644
--- a/doc/src/sgml/ref/create_materialized_view.sgml
+++ b/doc/src/sgml/ref/create_materialized_view.sgml
@@ -21,7 +21,7 @@ PostgreSQL documentation
<refsynopsisdiv>
<synopsis>
-CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
+CREATE [ INCREMENTAL ] MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
[ (<replaceable>column_name</replaceable> [, ...] ) ]
[ USING <replaceable class="parameter">method</replaceable> ]
[ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
@@ -60,6 +60,125 @@ CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
<title>Parameters</title>
<variablelist>
+ <varlistentry>
+ <term><literal>INCREMENTAL</literal></term>
+ <listitem>
+ <para>
+ If specified, some triggers are automatically created so that the rows
+ of the materialized view are immediately updated when base tables of the
+ materialized view are updated. In general, this allows faster update of
+ the materialized view at a price of slower update of the base tables
+ because the triggers will be invoked. We call this form of materialized
+ view as "Incrementally Maintainable Materialized View" (IMMV).
+ </para>
+ <para>
+ When <acronym>IMMV</acronym> is defined without using <command>WITH NO DATA</command>,
+ a unique index is created on the view automatically if possible. If the view
+ definition query has a GROUP BY clause, a unique index is created on the columns
+ of GROUP BY expressions. Also, if the view has DISTINCT clause, a unique index
+ is created on all columns in the target list. Otherwise, if the view contains all
+ primary key attritubes of its base tables in the target list, a unique index is
+ created on these attritubes. In other cases, no index is created.
+ </para>
+ <para>
+ There are restrictions of query definitions allowed to use this
+ option. The following are supported in query definitions for IMMV:
+ <itemizedlist>
+
+ <listitem>
+ <para>
+ Inner joins (including self-joins).
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Some built-in aggregate functions (count, sum, avg, min, max) without a HAVING
+ clause.
+ </para>
+ </listitem>
+ </itemizedlist>
+
+ Unsupported queries with this option include the following:
+
+ <itemizedlist>
+ <listitem>
+ <para>
+ Outer joins.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Sub-queries.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Aggregate functions other than built-in count, sum, avg, min and max.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ Aggregate functions with a HAVING clause.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ DISTINCT ON, WINDOW, VALUES, LIMIT and OFFSET clause.
+ </para>
+ </listitem>
+ </itemizedlist>
+
+ Other restrictions include:
+ <itemizedlist>
+
+ <listitem>
+ <para>
+ IMMVs must be based on simple base tables. It's not supported to
+ create them on top of views or materialized views.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ It is not supported to include system columns in an IMMV.
+ <programlisting>
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+ERROR: system column is not supported with IVM
+ </programlisting>
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Non-immutable functions are not supported.
+ <programlisting>
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+ERROR: functions in IMMV must be marked IMMUTABLE
+ </programlisting>
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ IMMVs do not support expressions that contains aggregates
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Logical replication does not support IMMVs.
+ </para>
+ </listitem>
+
+ </itemizedlist>
+
+ </para>
+ </listitem>
+ </varlistentry>
+
<varlistentry>
<term><literal>IF NOT EXISTS</literal></term>
<listitem>
@@ -155,7 +274,8 @@ CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
This clause specifies whether or not the materialized view should be
populated at creation time. If not, the materialized view will be
flagged as unscannable and cannot be queried until <command>REFRESH
- MATERIALIZED VIEW</command> is used.
+ MATERIALIZED VIEW</command> is used. Also, if the view is IMMV,
+ triggers for maintaining the view are not created.
</para>
</listitem>
</varlistentry>
diff --git a/doc/src/sgml/ref/refresh_materialized_view.sgml b/doc/src/sgml/ref/refresh_materialized_view.sgml
index 8ed43ade80..a4d729bdf0 100644
--- a/doc/src/sgml/ref/refresh_materialized_view.sgml
+++ b/doc/src/sgml/ref/refresh_materialized_view.sgml
@@ -36,9 +36,13 @@ REFRESH MATERIALIZED VIEW [ CONCURRENTLY ] <replaceable class="parameter">name</
privilege on the materialized view. The old contents are discarded. If
<literal>WITH DATA</literal> is specified (or defaults) the backing query
is executed to provide the new data, and the materialized view is left in a
- scannable state. If <literal>WITH NO DATA</literal> is specified no new
+ scannable state. If the view is an incrementally maintainable materialized
+ view (IMMV) and was 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 <literal>WITH NO DATA</literal> is specified no new
data is generated and the materialized view is left in an unscannable
- state.
+ state. If the view is IMMV, the triggers are dropped.
</para>
<para>
<literal>CONCURRENTLY</literal> and <literal>WITH NO DATA</literal> may not
diff --git a/doc/src/sgml/rules.sgml b/doc/src/sgml/rules.sgml
index 7a928bd7b9..73597ea7a5 100644
--- a/doc/src/sgml/rules.sgml
+++ b/doc/src/sgml/rules.sgml
@@ -1100,6 +1100,443 @@ SELECT word FROM words ORDER BY word <-> 'caterpiler' LIMIT 10;
</sect1>
+<sect1 id="rules-ivm">
+<title>Incremental View Maintenance</title>
+
+<indexterm zone="rules-ivm">
+ <primary>incremental view maintenance</primary>
+</indexterm>
+
+<indexterm zone="rules-ivm">
+ <primary>materialized view</primary>
+ <secondary>incremental view maintenance</secondary>
+</indexterm>
+
+<indexterm zone="rules-ivm">
+ <primary>view</primary>
+ <secondary>incremental view maintenance</secondary>
+</indexterm>
+
+<sect2 id="rules-ivm-overview">
+<title>Overview</title>
+
+<para>
+ Incremental View Maintenance (<acronym>IVM</acronym>) is a way to make
+ materialized views up-to-date in which only incremental changes are computed
+ and applied on views rather than recomputing the contents from scratch as
+ <command>REFRESH MATERIALIZED VIEW</command> does. <acronym>IVM</acronym>
+ can update materialized views more efficiently than recomputation when only
+ small parts of the view are changed.
+</para>
+
+<para>
+ There are two approaches with regard to timing of view maintenance:
+ immediate and deferred. In immediate maintenance, views are updated in the
+ same transaction that its base table is modified. In deferred maintenance,
+ views are updated after the transaction is committed, for example, when the
+ view is accessed, as a response to user command like <command>REFRESH
+ MATERIALIZED VIEW</command>, or periodically in background, and so on.
+ <productname>PostgreSQL</productname> currently implements only a kind of
+ immediate maintenance, in which materialized views are updated immediately
+ in AFTER triggers when a base table is modified.
+</para>
+
+<para>
+ To create materialized views supporting <acronym>IVM</acronym>, use the
+ <command>CREATE INCREMENTAL MATERIALIZED VIEW</command>, for example:
+<programlisting>
+CREATE <emphasis>INCREMENTAL</emphasis> MATERIALIZED VIEW mymatview AS SELECT * FROM mytab;
+</programlisting>
+ When a materialized view is created with the <literal>INCREMENTAL</literal>
+ keyword, some triggers are automatically created so that the view's contents are
+ immediately updated when its base tables are modified. We call this form
+ of materialized view an Incrementally Maintainable Materialized View
+ (<acronym>IMMV</acronym>).
+<programlisting>
+postgres=# CREATE INCREMENTAL MATERIALIZED VIEW m AS SELECT * FROM t0;
+NOTICE: could not create an index on materialized view "m" automatically
+HINT: Create an index on the materialized view for effcient incremental maintenance.
+SELECT 3
+postgres=# SELECT * FROM m;
+ i
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+postgres=# INSERT INTO t0 VALUES (4);
+INSERT 0 1
+postgres=# SELECT * FROM m; -- automatically updated
+ i
+---
+ 1
+ 2
+ 3
+ 4
+(4 rows)
+</programlisting>
+</para>
+
+<para>
+ Some <acronym>IMMV</acronym>s have hidden columns which are added
+ automatically when a materialized view is created. Their name starts
+ with <literal>__ivm_</literal> and they contain information required
+ for maintaining the <acronym>IMMV</acronym>. Such columns are not visible
+ when the <acronym>IMMV</acronym> is accessed by <literal>SELECT *</literal>
+ but are visible if the column name is explicitly specified in the target
+ list. We can also see the hidden columns in <literal>\d</literal>
+ meta-commands of <command>psql</command> commands.
+</para>
+
+<para>
+ In general, <acronym>IMMV</acronym>s allow faster updates of materialized
+ views at the price of slower updates to their base tables. Updates of
+ <acronym>IMMV</acronym> is slower because triggers will be invoked and the
+ view is updated in triggers per modification statement.
+</para>
+
+<para>
+ For example, suppose a normal materialized view defined as below:
+
+<programlisting>
+test=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm AS
+ SELECT a.aid, b.bid, a.abalance, b.bbalance
+ FROM pgbench_accounts a JOIN pgbench_branches b USING(bid);
+SELECT 10000000
+
+</programlisting>
+
+ Updating a tuple in a base table of this materialized view is rapid but the
+ <command>REFRESH MATERIALIZED VIEW</command> command on this view takes a long time:
+
+<programlisting>
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 0.990 ms
+
+test=# REFRESH MATERIALIZED VIEW mv_normal ;
+REFRESH MATERIALIZED VIEW
+Time: 33533.952 ms (00:33.534)
+</programlisting>
+</para>
+
+<para>
+ On the other hand, after creating <acronym>IMMV</acronym> with the same view
+ definition as below:
+
+<programlisting>
+test=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm AS
+ SELECT a.aid, b.bid, a.abalance, b.bbalance
+ FROM pgbench_accounts a JOIN pgbench_branches b USING(bid);
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+NOTICE: created index "mv_ivm_index" on materialized view "mv_ivm"
+</programlisting>
+
+ updating a tuple in a base table takes more than the normal view,
+ but its content is updated automatically and this is faster than the
+ <command>REFRESH MATERIALIZED VIEW</command> command.
+
+<programlisting>
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 13.068 ms
+</programlisting>
+
+</para>
+
+<para>
+ Appropriate indexes on <acronym>IMMV</acronym>s are necessary for
+ efficient <acronym>IVM</acronym> because it looks for tuples to be
+ updated in <acronym>IMMV</acronym>. If there are no indexes, it
+ will take a long time.
+</para>
+
+<para>
+ Therefore, when <acronym>IMMV</acronym> is defined, a unique index is created on the view
+ automatically if possible. If the view definition query has a GROUP BY clause, a unique
+ index is created on the columns of GROUP BY expressions. Also, if the view has DISTINCT
+ clause, a unique index is created on all columns in the target list. Otherwise, if the
+ view contains all primary key attritubes of its base tables in the target list, a unique
+ index is created on these attritubes. In other cases, no index is created.
+</para>
+
+<para>
+ In the previous example, a unique index "mv_ivm_index" is created on aid and bid
+ columns of materialized view "mv_ivm", and this enables the rapid update of the view.
+ Dropping this index make updating the view take a loger time.
+<programlisting>
+test=# DROP INDEX mv_ivm_index;
+DROP INDEX
+Time: 67.081 ms
+
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 16386.245 ms (00:16.386)
+</programlisting>
+
+</para>
+
+<para>
+ <acronym>IVM</acronym> is effective when we want to keep a materialized
+ view up-to-date and small fraction of a base table is modified
+ infrequently. Due to the overhead of immediate maintenance, <acronym>IVM</acronym>
+ 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, <acronym>IVM</acronym> is not effective and the cost of
+ maintenance can be larger than the <command>REFRESH MATERIALIZED VIEW</command>
+ command. In such situation, we can use <command>REFRESH MATERIALIZED VIEW</command>
+ and specify <literal>WITH NO DATA</literal> to disable immediate
+ maintenance before modifying a base table. After a base table modification,
+ execute the <command>REFRESH MATERIALIZED VIEW</command> (with <literal>WITH DATA</literal>)
+ command to refresh the view data and enable immediate maintenance.
+</para>
+
+</sect2>
+
+<sect2 id="rules-ivm-support">
+<title>Supported View Definitions and Restrictions</title>
+
+<para>
+ Currently, we can create <acronym>IMMV</acronym>s using inner joins, and some
+ aggregates. However, several restrictions apply to the definition of IMMV.
+</para>
+
+<sect3 id="rules-ivm-support-joins">
+<title>Joins</title>
+<para>
+ Inner joins including self-join are supported. Outer joins are not supported.
+</para>
+</sect3>
+
+<sect3 id="rules-ivm-support-aggregates">
+<title>Aggregates</title>
+<para>
+ Supported aggregate functions are <function>count</function>, <function>sum</function>,
+ <function>avg</function>, <function>min</function>, and <function>max</function>.
+ Currently, only built-in aggregate functions are supported and user defined
+ aggregates cannot be used. When a base table is modified, the new aggregated
+ values are incrementally calculated using the old aggregated values and values
+ of related hidden columns stored in <acronym>IMMV</acronym>.
+</para>
+
+<para>
+ Note that for <function>min</function> or <function>max</function>, the new values
+ could be re-calculated from base tables with regard to the affected groups when a
+ tuple containing the current minimal or maximal values are deleted from a base table.
+ Therefore, it can takes a long time to update an <acronym>IMMV</acronym> containing
+ these functions.
+</para>
+
+<para>
+ Also note that using <function>sum</function> or <function>avg</function> on
+ <type>real</type> (<type>float4</type>) type or <type>double precision</type>
+ (<type>float8</type>) type in <acronym>IMMV</acronym> is unsafe. This is
+ because aggregated values in <acronym>IMMV</acronym> can become different from
+ results calculated from base tables due to the limited precision of these types.
+ To avoid this problem, use the <type>numeric</type> type instead.
+</para>
+
+ <sect4 id="rules-ivm-restrictions-aggregates">
+ <title>Restrictions on Aggregates</title>
+ <para>
+ There are the following restrictions:
+ <itemizedlist>
+ <listitem>
+ <para>
+ If we have a <literal>GROUP BY</literal> clause, expressions specified in
+ <literal>GROUP BY</literal> must appear in the target list. This is
+ how tuples to be updated in the <acronym>IMMV</acronym> are identified.
+ These attributes are used as scan keys for searching tuples in the
+ <acronym>IMMV</acronym>, so indexes on them are required for efficient
+ <acronym>IVM</acronym>.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <literal>HAVING</literal> clause cannot be used.
+ </para>
+ </listitem>
+ </itemizedlist>
+ </para>
+ </sect4>
+</sect3>
+
+<sect3 id="rules-ivm-general-restricitons">
+<title>Other General Restrictions</title>
+<para>
+ There are other restrictions which generally apply to <acronym>IMMV</acronym>:
+ <itemizedlist>
+ <listitem>
+ <para>
+ Sub-queries cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ CTEs cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Window functions cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s must be based on simple base tables. It's not
+ supported to create them on top of views, materialized views, foreign tables, inhe.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ LIMIT and OFFSET clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s cannot contain system columns.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s cannot contain non-immutable functions.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ UNION/INTERSECT/EXCEPT clauses cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ DISTINCT ON clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ TABLESAMPLE parameter cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ inheritance parent tables cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ VALUES clause cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <literal>GROUPING SETS</literal> and <literal>FILTER</literal> clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ FOR UPDATE/SHARE cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ targetlist cannot contain columns whose name start with <literal>__ivm_</literal>.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ targetlist cannot contain expressions which contain an aggregate in it.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Logical replication is not supported, that is, even when a base table
+ at a publisher node is modified, <acronym>IMMV</acronym>s at subscriber
+ nodes are not updated.
+ </para>
+ </listitem>
+
+ </itemizedlist>
+</para>
+</sect3>
+
+</sect2>
+
+<sect2 id="rules-ivm-distinct">
+<title><literal>DISTINCT</literal></title>
+
+<para>
+ <productname>PostgreSQL</productname> supports <acronym>IMMV</acronym> with
+ <literal>DISTINCT</literal>. For example, suppose a <acronym>IMMV</acronym>
+ defined with <literal>DISTINCT</literal> on a base table containing duplicate
+ tuples. When tuples are deleted from the base table, a tuple in the view is
+ deleted if and only if the multiplicity of the tuple becomes zero. Moreover,
+ when tuples are inserted into the base table, a tuple is inserted into the
+ view only if the same tuple doesn't already exist in it.
+</para>
+
+<para>
+ Physically, an <acronym>IMMV</acronym> defined with <literal>DISTINCT</literal>
+ contains tuples after eliminating duplicates, and the multiplicity of each tuple
+ is stored in a hidden column named <literal>__ivm_count__</literal>.
+</para>
+</sect2>
+
+<sect2 id="rules-ivm-concurrent-transactions">
+<title>Concurrent Transactions</title>
+<para>
+ Suppose an <acronym>IMMV</acronym> is defined on two base tables and each
+ table was modified in different a concurrent transaction simultaneously.
+ In the transaction which was committed first, <acronym>IMMV</acronym> can
+ be updated considering only the change which happened in this transaction.
+ On the other hand, in order to update the view correctly in the transaction
+ which was committed later, we need to know the changes occurred in
+ both transactions. For this reason, <literal>ExclusiveLock</literal>
+ is held on an <acronym>IMMV</acronym> immediately after a base table is
+ modified in <literal>READ COMMITTED</literal> mode to make sure that
+ the <acronym>IMMV</acronym> is updated in the latter transaction after
+ the former transaction is committed. In <literal>REPEATABLE READ</literal>
+ or <literal>SERIALIZABLE</literal> mode, an error is raised immediately
+ if lock acquisition fails because any changes which occurred in
+ other transactions are not be visible in these modes and
+ <acronym>IMMV</acronym> cannot be updated correctly in such situations.
+ However, as an exception if the view has only one base table and
+ <command>INSERT</command> is performed on the table,
+ the lock held on thew view is <literal>RowExclusiveLock</literal>.
+</para>
+</sect2>
+
+<sect2 id="rules-ivm-rls">
+<title>Row Level Security</title>
+<para>
+ If some base tables have row level security policy, rows that are not visible
+ to the materialized view's owner are excluded from the result. In addition, such
+ rows are excluded as well when views are incrementally maintained. However, if a
+ new policy is defined or policies are changed after the materialized view was created,
+ the new policy will not be applied to the view contents. To apply the new policy,
+ you need to refresh materialized views.
+</para>
+</sect2>
+
+</sect1>
+
<sect1 id="rules-update">
<title>Rules on <command>INSERT</command>, <command>UPDATE</command>, and <command>DELETE</command></title>
diff --git a/doc/src/sgml/system-views.sgml b/doc/src/sgml/system-views.sgml
index 3c8dca8ca3..da22606213 100644
--- a/doc/src/sgml/system-views.sgml
+++ b/doc/src/sgml/system-views.sgml
@@ -1787,6 +1787,15 @@ SELECT * FROM pg_locks pl LEFT JOIN pg_prepared_xacts ppx
</para></entry>
</row>
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>isimmv</structfield> <type>bool</type>
+ </para>
+ <para>
+ True if materialized view is incrementally maintainable
+ </para></entry>
+ </row>
+
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>definition</structfield> <type>text</type>
--
2.25.1
On Sun, 31 Mar 2024 22:59:31 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:
Also, I added a comment on RelationIsIVM() macro persuggestion from jian he.
In addition, I fixed a failure reported from cfbot on FreeBSD build caused by;WARNING: outfuncs/readfuncs failed to produce an equal rewritten parse tree
This warning was raised since I missed to modify outfuncs.c for a new field.
I found cfbot on FreeBSD still reported a failure due to
ENFORCE_REGRESSION_TEST_NAME_RESTRICTIONS because the regression test used
wrong role names. Attached is a fixed version, v32.
Attached is a rebased version, v33.
Regards,
Yugo Nagata
--
Yugo NAGATA <nagata@sraoss.co.jp>
Attachments:
v33-0001-Add-a-syntax-to-create-Incrementally-Maintainabl.patchtext/x-diff; name=v33-0001-Add-a-syntax-to-create-Incrementally-Maintainabl.patchDownload
From 2228e1a209e7fc5ac042870c64f7e1107ba728f6 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:05:02 +0900
Subject: [PATCH v33 01/11] Add a syntax to create Incrementally Maintainable
Materialized Views
Allow to create Incrementally Maintainable Materialized View (IMMV)
by using INCREMENTAL option in CREATE MATERIALIZED VIEW command
as follow:
CREATE [INCREMANTAL] MATERIALIZED VIEW xxxxx AS SELECT ....;
---
src/backend/parser/gram.y | 32 +++++++++++++++++++++-----------
src/include/nodes/primnodes.h | 1 +
src/include/parser/kwlist.h | 1 +
3 files changed, 23 insertions(+), 11 deletions(-)
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index a043fd4c66..943460fd2c 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -468,6 +468,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <range> OptTempTableName
%type <into> into_clause create_as_target create_mv_target
+%type <boolean> incremental
%type <defelt> createfunc_opt_item common_func_opt_item dostmt_opt_item
%type <fun_param> func_arg func_arg_with_default table_func_column aggr_arg
@@ -738,7 +739,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
HANDLER HAVING HEADER_P HOLD HOUR_P
IDENTITY_P IF_P ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IMPORT_P IN_P INCLUDE
- INCLUDING INCREMENT INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
+ INCLUDING INCREMENT INCREMENTAL INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
@@ -4803,32 +4804,34 @@ opt_with_data:
*****************************************************************************/
CreateMatViewStmt:
- CREATE OptNoLog MATERIALIZED VIEW create_mv_target AS SelectStmt opt_with_data
+ CREATE OptNoLog incremental MATERIALIZED VIEW create_mv_target AS SelectStmt opt_with_data
{
CreateTableAsStmt *ctas = makeNode(CreateTableAsStmt);
- ctas->query = $7;
- ctas->into = $5;
+ ctas->query = $8;
+ ctas->into = $6;
ctas->objtype = OBJECT_MATVIEW;
ctas->is_select_into = false;
ctas->if_not_exists = false;
/* cram additional flags into the IntoClause */
- $5->rel->relpersistence = $2;
- $5->skipData = !($8);
+ $6->rel->relpersistence = $2;
+ $6->skipData = !($9);
+ $6->ivm = $3;
$$ = (Node *) ctas;
}
- | CREATE OptNoLog MATERIALIZED VIEW IF_P NOT EXISTS create_mv_target AS SelectStmt opt_with_data
+ | CREATE OptNoLog incremental MATERIALIZED VIEW IF_P NOT EXISTS create_mv_target AS SelectStmt opt_with_data
{
CreateTableAsStmt *ctas = makeNode(CreateTableAsStmt);
- ctas->query = $10;
- ctas->into = $8;
+ ctas->query = $11;
+ ctas->into = $9;
ctas->objtype = OBJECT_MATVIEW;
ctas->is_select_into = false;
ctas->if_not_exists = true;
/* cram additional flags into the IntoClause */
- $8->rel->relpersistence = $2;
- $8->skipData = !($11);
+ $9->rel->relpersistence = $2;
+ $9->skipData = !($12);
+ $9->ivm = $3;
$$ = (Node *) ctas;
}
;
@@ -4845,9 +4848,14 @@ create_mv_target:
$$->tableSpaceName = $5;
$$->viewQuery = NULL; /* filled at analysis time */
$$->skipData = false; /* might get changed later */
+ $$->ivm = false;
}
;
+incremental: INCREMENTAL { $$ = true; }
+ | /*EMPTY*/ { $$ = false; }
+ ;
+
OptNoLog: UNLOGGED { $$ = RELPERSISTENCE_UNLOGGED; }
| /*EMPTY*/ { $$ = RELPERSISTENCE_PERMANENT; }
;
@@ -17686,6 +17694,7 @@ unreserved_keyword:
| INCLUDE
| INCLUDING
| INCREMENT
+ | INCREMENTAL
| INDENT
| INDEX
| INDEXES
@@ -18274,6 +18283,7 @@ bare_label_keyword:
| INCLUDE
| INCLUDING
| INCREMENT
+ | INCREMENTAL
| INDENT
| INDEX
| INDEXES
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index ea47652adb..6f01300a30 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 */
Node *viewQuery pg_node_attr(query_jumble_ignore);
bool skipData; /* true for WITH NO DATA */
+ bool ivm; /* true for WITH IVM */
} IntoClause;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index f7fe834cf4..1625fea602 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -210,6 +210,7 @@ PG_KEYWORD("in", IN_P, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("include", INCLUDE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("including", INCLUDING, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("increment", INCREMENT, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("incremental", INCREMENTAL, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("indent", INDENT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("index", INDEX, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("indexes", INDEXES, UNRESERVED_KEYWORD, BARE_LABEL)
--
2.25.1
v33-0002-Add-relisivm-column-to-pg_class-system-catalog.patchtext/x-diff; name=v33-0002-Add-relisivm-column-to-pg_class-system-catalog.patchDownload
From b141ff22adf75e657e04998a18411a735ce46fc8 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:07:23 +0900
Subject: [PATCH v33 02/11] Add relisivm column to pg_class system catalog
If this boolean column is true, a relations is Incrementally Maintainable
Materialized View (IMMV). This is set when IMMV is created.
Also, isimmv columns is added to pg_matviews system view.
isimmv
---
src/backend/catalog/heap.c | 1 +
src/backend/catalog/index.c | 1 +
src/backend/catalog/system_views.sql | 1 +
src/backend/utils/cache/lsyscache.c | 24 ++++++++++++++++++++++++
src/backend/utils/cache/relcache.c | 2 ++
src/include/catalog/pg_class.h | 3 +++
src/include/utils/lsyscache.h | 1 +
src/include/utils/rel.h | 6 ++++++
src/test/regress/expected/rules.out | 1 +
9 files changed, 40 insertions(+)
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index 00074c8a94..8d5470c8f7 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -938,6 +938,7 @@ InsertPgClassTuple(Relation pg_class_desc,
values[Anum_pg_class_relrewrite - 1] = ObjectIdGetDatum(rd_rel->relrewrite);
values[Anum_pg_class_relfrozenxid - 1] = TransactionIdGetDatum(rd_rel->relfrozenxid);
values[Anum_pg_class_relminmxid - 1] = MultiXactIdGetDatum(rd_rel->relminmxid);
+ values[Anum_pg_class_relisivm - 1] = BoolGetDatum(rd_rel->relisivm);
if (relacl != (Datum) 0)
values[Anum_pg_class_relacl - 1] = relacl;
else
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index a819b4197c..eb81685f6b 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -1007,6 +1007,7 @@ index_create(Relation heapRelation,
indexRelation->rd_rel->relowner = heapRelation->rd_rel->relowner;
indexRelation->rd_rel->relam = accessMethodId;
indexRelation->rd_rel->relispartition = OidIsValid(parentIndexRelid);
+ indexRelation->rd_rel->relisivm = false;
/*
* store index's pg_class entry
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index 19cabc9a47..c88c8af96b 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -146,6 +146,7 @@ CREATE VIEW pg_matviews AS
T.spcname AS tablespace,
C.relhasindex AS hasindexes,
C.relispopulated AS ispopulated,
+ C.relisivm AS isimmv,
pg_get_viewdef(C.oid) AS definition
FROM pg_class C LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
LEFT JOIN pg_tablespace T ON (T.oid = C.reltablespace)
diff --git a/src/backend/utils/cache/lsyscache.c b/src/backend/utils/cache/lsyscache.c
index 48a280d089..59c06b853c 100644
--- a/src/backend/utils/cache/lsyscache.c
+++ b/src/backend/utils/cache/lsyscache.c
@@ -2042,6 +2042,30 @@ get_rel_relispartition(Oid relid)
return false;
}
+/*
+ * get_rel_relisivm
+ *
+ * Returns the relisivm flag associated with a given relation.
+ */
+bool
+get_rel_relisivm(Oid relid)
+{
+ HeapTuple tp;
+
+ tp = SearchSysCache1(RELOID, ObjectIdGetDatum(relid));
+ if (HeapTupleIsValid(tp))
+ {
+ Form_pg_class reltup = (Form_pg_class) GETSTRUCT(tp);
+ bool result;
+
+ result = reltup->relisivm;
+ ReleaseSysCache(tp);
+ return result;
+ }
+ else
+ return false;
+}
+
/*
* get_rel_tablespace
*
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 66ed24e401..cba2eac1e8 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -1931,6 +1931,8 @@ formrdesc(const char *relationName, Oid relationReltype,
/* ... and they're always populated, too */
relation->rd_rel->relispopulated = true;
+ /* ... and they're always no ivm, too */
+ relation->rd_rel->relisivm = false;
relation->rd_rel->relreplident = REPLICA_IDENTITY_NOTHING;
relation->rd_rel->relpages = 0;
diff --git a/src/include/catalog/pg_class.h b/src/include/catalog/pg_class.h
index 0fc2c093b0..80cbee29ca 100644
--- a/src/include/catalog/pg_class.h
+++ b/src/include/catalog/pg_class.h
@@ -119,6 +119,9 @@ CATALOG(pg_class,1259,RelationRelationId) BKI_BOOTSTRAP BKI_ROWTYPE_OID(83,Relat
/* is relation a partition? */
bool relispartition BKI_DEFAULT(f);
+ /* is relation a matview with ivm? */
+ bool relisivm BKI_DEFAULT(f);
+
/* link to original rel during table rewrite; otherwise 0 */
Oid relrewrite BKI_DEFAULT(0) BKI_LOOKUP_OPT(pg_class);
diff --git a/src/include/utils/lsyscache.h b/src/include/utils/lsyscache.h
index 20446f6f83..6b17921d23 100644
--- a/src/include/utils/lsyscache.h
+++ b/src/include/utils/lsyscache.h
@@ -139,6 +139,7 @@ extern Oid get_rel_namespace(Oid relid);
extern Oid get_rel_type_id(Oid relid);
extern char get_rel_relkind(Oid relid);
extern bool get_rel_relispartition(Oid relid);
+extern bool get_rel_relisivm(Oid relid);
extern Oid get_rel_tablespace(Oid relid);
extern char get_rel_persistence(Oid relid);
extern Oid get_rel_relam(Oid relid);
diff --git a/src/include/utils/rel.h b/src/include/utils/rel.h
index 8700204953..7f36d6f5fa 100644
--- a/src/include/utils/rel.h
+++ b/src/include/utils/rel.h
@@ -676,6 +676,12 @@ RelationCloseSmgr(Relation relation)
*/
#define RelationIsPopulated(relation) ((relation)->rd_rel->relispopulated)
+/*
+ * RelationIsIVM
+ * True if relation is an incrementally maintainable materialized view.
+ */
+#define RelationIsIVM(relation) ((relation)->rd_rel->relisivm)
+
/*
* RelationIsAccessibleInLogicalDecoding
* True if we need to log enough information to have access via
diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out
index 4c789279e5..c7ba7be647 100644
--- a/src/test/regress/expected/rules.out
+++ b/src/test/regress/expected/rules.out
@@ -1393,6 +1393,7 @@ pg_matviews| SELECT n.nspname AS schemaname,
t.spcname AS tablespace,
c.relhasindex AS hasindexes,
c.relispopulated AS ispopulated,
+ c.relisivm AS isimmv,
pg_get_viewdef(c.oid) AS definition
FROM ((pg_class c
LEFT JOIN pg_namespace n ON ((n.oid = c.relnamespace)))
--
2.25.1
v33-0011-Add-documentations-about-Incremental-View-Mainte.patchtext/x-diff; name=v33-0011-Add-documentations-about-Incremental-View-Mainte.patchDownload
From b88ed4f72e93e0a57931e79644e79d64366ee28c Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:25:34 +0900
Subject: [PATCH v33 11/11] Add documentations about Incremental View
Maintenance
---
doc/src/sgml/catalogs.sgml | 9 +
.../sgml/ref/create_materialized_view.sgml | 124 ++++-
.../sgml/ref/refresh_materialized_view.sgml | 8 +-
doc/src/sgml/rules.sgml | 437 ++++++++++++++++++
doc/src/sgml/system-views.sgml | 9 +
5 files changed, 583 insertions(+), 4 deletions(-)
diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index b654fae1b2..8ef73edd12 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -2231,6 +2231,15 @@ SCRAM-SHA-256$<replaceable><iteration count></replaceable>:<replaceable>&l
</para></entry>
</row>
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>relisivm</structfield> <type>bool</type>
+ </para>
+ <para>
+ True if relation is incrementally maintainable materialized view
+ </para></entry>
+ </row>
+
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>relrewrite</structfield> <type>oid</type>
diff --git a/doc/src/sgml/ref/create_materialized_view.sgml b/doc/src/sgml/ref/create_materialized_view.sgml
index 0d2fea2b97..8c574062db 100644
--- a/doc/src/sgml/ref/create_materialized_view.sgml
+++ b/doc/src/sgml/ref/create_materialized_view.sgml
@@ -21,7 +21,7 @@ PostgreSQL documentation
<refsynopsisdiv>
<synopsis>
-CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
+CREATE [ INCREMENTAL ] MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
[ (<replaceable>column_name</replaceable> [, ...] ) ]
[ USING <replaceable class="parameter">method</replaceable> ]
[ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
@@ -60,6 +60,125 @@ CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
<title>Parameters</title>
<variablelist>
+ <varlistentry>
+ <term><literal>INCREMENTAL</literal></term>
+ <listitem>
+ <para>
+ If specified, some triggers are automatically created so that the rows
+ of the materialized view are immediately updated when base tables of the
+ materialized view are updated. In general, this allows faster update of
+ the materialized view at a price of slower update of the base tables
+ because the triggers will be invoked. We call this form of materialized
+ view as "Incrementally Maintainable Materialized View" (IMMV).
+ </para>
+ <para>
+ When <acronym>IMMV</acronym> is defined without using <command>WITH NO DATA</command>,
+ a unique index is created on the view automatically if possible. If the view
+ definition query has a GROUP BY clause, a unique index is created on the columns
+ of GROUP BY expressions. Also, if the view has DISTINCT clause, a unique index
+ is created on all columns in the target list. Otherwise, if the view contains all
+ primary key attritubes of its base tables in the target list, a unique index is
+ created on these attritubes. In other cases, no index is created.
+ </para>
+ <para>
+ There are restrictions of query definitions allowed to use this
+ option. The following are supported in query definitions for IMMV:
+ <itemizedlist>
+
+ <listitem>
+ <para>
+ Inner joins (including self-joins).
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Some built-in aggregate functions (count, sum, avg, min, max) without a HAVING
+ clause.
+ </para>
+ </listitem>
+ </itemizedlist>
+
+ Unsupported queries with this option include the following:
+
+ <itemizedlist>
+ <listitem>
+ <para>
+ Outer joins.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Sub-queries.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Aggregate functions other than built-in count, sum, avg, min and max.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ Aggregate functions with a HAVING clause.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ DISTINCT ON, WINDOW, VALUES, LIMIT and OFFSET clause.
+ </para>
+ </listitem>
+ </itemizedlist>
+
+ Other restrictions include:
+ <itemizedlist>
+
+ <listitem>
+ <para>
+ IMMVs must be based on simple base tables. It's not supported to
+ create them on top of views or materialized views.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ It is not supported to include system columns in an IMMV.
+ <programlisting>
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+ERROR: system column is not supported with IVM
+ </programlisting>
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Non-immutable functions are not supported.
+ <programlisting>
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+ERROR: functions in IMMV must be marked IMMUTABLE
+ </programlisting>
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ IMMVs do not support expressions that contains aggregates
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Logical replication does not support IMMVs.
+ </para>
+ </listitem>
+
+ </itemizedlist>
+
+ </para>
+ </listitem>
+ </varlistentry>
+
<varlistentry>
<term><literal>IF NOT EXISTS</literal></term>
<listitem>
@@ -155,7 +274,8 @@ CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
This clause specifies whether or not the materialized view should be
populated at creation time. If not, the materialized view will be
flagged as unscannable and cannot be queried until <command>REFRESH
- MATERIALIZED VIEW</command> is used.
+ MATERIALIZED VIEW</command> is used. Also, if the view is IMMV,
+ triggers for maintaining the view are not created.
</para>
</listitem>
</varlistentry>
diff --git a/doc/src/sgml/ref/refresh_materialized_view.sgml b/doc/src/sgml/ref/refresh_materialized_view.sgml
index 8ed43ade80..a4d729bdf0 100644
--- a/doc/src/sgml/ref/refresh_materialized_view.sgml
+++ b/doc/src/sgml/ref/refresh_materialized_view.sgml
@@ -36,9 +36,13 @@ REFRESH MATERIALIZED VIEW [ CONCURRENTLY ] <replaceable class="parameter">name</
privilege on the materialized view. The old contents are discarded. If
<literal>WITH DATA</literal> is specified (or defaults) the backing query
is executed to provide the new data, and the materialized view is left in a
- scannable state. If <literal>WITH NO DATA</literal> is specified no new
+ scannable state. If the view is an incrementally maintainable materialized
+ view (IMMV) and was 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 <literal>WITH NO DATA</literal> is specified no new
data is generated and the materialized view is left in an unscannable
- state.
+ state. If the view is IMMV, the triggers are dropped.
</para>
<para>
<literal>CONCURRENTLY</literal> and <literal>WITH NO DATA</literal> may not
diff --git a/doc/src/sgml/rules.sgml b/doc/src/sgml/rules.sgml
index 7a928bd7b9..73597ea7a5 100644
--- a/doc/src/sgml/rules.sgml
+++ b/doc/src/sgml/rules.sgml
@@ -1100,6 +1100,443 @@ SELECT word FROM words ORDER BY word <-> 'caterpiler' LIMIT 10;
</sect1>
+<sect1 id="rules-ivm">
+<title>Incremental View Maintenance</title>
+
+<indexterm zone="rules-ivm">
+ <primary>incremental view maintenance</primary>
+</indexterm>
+
+<indexterm zone="rules-ivm">
+ <primary>materialized view</primary>
+ <secondary>incremental view maintenance</secondary>
+</indexterm>
+
+<indexterm zone="rules-ivm">
+ <primary>view</primary>
+ <secondary>incremental view maintenance</secondary>
+</indexterm>
+
+<sect2 id="rules-ivm-overview">
+<title>Overview</title>
+
+<para>
+ Incremental View Maintenance (<acronym>IVM</acronym>) is a way to make
+ materialized views up-to-date in which only incremental changes are computed
+ and applied on views rather than recomputing the contents from scratch as
+ <command>REFRESH MATERIALIZED VIEW</command> does. <acronym>IVM</acronym>
+ can update materialized views more efficiently than recomputation when only
+ small parts of the view are changed.
+</para>
+
+<para>
+ There are two approaches with regard to timing of view maintenance:
+ immediate and deferred. In immediate maintenance, views are updated in the
+ same transaction that its base table is modified. In deferred maintenance,
+ views are updated after the transaction is committed, for example, when the
+ view is accessed, as a response to user command like <command>REFRESH
+ MATERIALIZED VIEW</command>, or periodically in background, and so on.
+ <productname>PostgreSQL</productname> currently implements only a kind of
+ immediate maintenance, in which materialized views are updated immediately
+ in AFTER triggers when a base table is modified.
+</para>
+
+<para>
+ To create materialized views supporting <acronym>IVM</acronym>, use the
+ <command>CREATE INCREMENTAL MATERIALIZED VIEW</command>, for example:
+<programlisting>
+CREATE <emphasis>INCREMENTAL</emphasis> MATERIALIZED VIEW mymatview AS SELECT * FROM mytab;
+</programlisting>
+ When a materialized view is created with the <literal>INCREMENTAL</literal>
+ keyword, some triggers are automatically created so that the view's contents are
+ immediately updated when its base tables are modified. We call this form
+ of materialized view an Incrementally Maintainable Materialized View
+ (<acronym>IMMV</acronym>).
+<programlisting>
+postgres=# CREATE INCREMENTAL MATERIALIZED VIEW m AS SELECT * FROM t0;
+NOTICE: could not create an index on materialized view "m" automatically
+HINT: Create an index on the materialized view for effcient incremental maintenance.
+SELECT 3
+postgres=# SELECT * FROM m;
+ i
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+postgres=# INSERT INTO t0 VALUES (4);
+INSERT 0 1
+postgres=# SELECT * FROM m; -- automatically updated
+ i
+---
+ 1
+ 2
+ 3
+ 4
+(4 rows)
+</programlisting>
+</para>
+
+<para>
+ Some <acronym>IMMV</acronym>s have hidden columns which are added
+ automatically when a materialized view is created. Their name starts
+ with <literal>__ivm_</literal> and they contain information required
+ for maintaining the <acronym>IMMV</acronym>. Such columns are not visible
+ when the <acronym>IMMV</acronym> is accessed by <literal>SELECT *</literal>
+ but are visible if the column name is explicitly specified in the target
+ list. We can also see the hidden columns in <literal>\d</literal>
+ meta-commands of <command>psql</command> commands.
+</para>
+
+<para>
+ In general, <acronym>IMMV</acronym>s allow faster updates of materialized
+ views at the price of slower updates to their base tables. Updates of
+ <acronym>IMMV</acronym> is slower because triggers will be invoked and the
+ view is updated in triggers per modification statement.
+</para>
+
+<para>
+ For example, suppose a normal materialized view defined as below:
+
+<programlisting>
+test=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm AS
+ SELECT a.aid, b.bid, a.abalance, b.bbalance
+ FROM pgbench_accounts a JOIN pgbench_branches b USING(bid);
+SELECT 10000000
+
+</programlisting>
+
+ Updating a tuple in a base table of this materialized view is rapid but the
+ <command>REFRESH MATERIALIZED VIEW</command> command on this view takes a long time:
+
+<programlisting>
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 0.990 ms
+
+test=# REFRESH MATERIALIZED VIEW mv_normal ;
+REFRESH MATERIALIZED VIEW
+Time: 33533.952 ms (00:33.534)
+</programlisting>
+</para>
+
+<para>
+ On the other hand, after creating <acronym>IMMV</acronym> with the same view
+ definition as below:
+
+<programlisting>
+test=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm AS
+ SELECT a.aid, b.bid, a.abalance, b.bbalance
+ FROM pgbench_accounts a JOIN pgbench_branches b USING(bid);
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+NOTICE: created index "mv_ivm_index" on materialized view "mv_ivm"
+</programlisting>
+
+ updating a tuple in a base table takes more than the normal view,
+ but its content is updated automatically and this is faster than the
+ <command>REFRESH MATERIALIZED VIEW</command> command.
+
+<programlisting>
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 13.068 ms
+</programlisting>
+
+</para>
+
+<para>
+ Appropriate indexes on <acronym>IMMV</acronym>s are necessary for
+ efficient <acronym>IVM</acronym> because it looks for tuples to be
+ updated in <acronym>IMMV</acronym>. If there are no indexes, it
+ will take a long time.
+</para>
+
+<para>
+ Therefore, when <acronym>IMMV</acronym> is defined, a unique index is created on the view
+ automatically if possible. If the view definition query has a GROUP BY clause, a unique
+ index is created on the columns of GROUP BY expressions. Also, if the view has DISTINCT
+ clause, a unique index is created on all columns in the target list. Otherwise, if the
+ view contains all primary key attritubes of its base tables in the target list, a unique
+ index is created on these attritubes. In other cases, no index is created.
+</para>
+
+<para>
+ In the previous example, a unique index "mv_ivm_index" is created on aid and bid
+ columns of materialized view "mv_ivm", and this enables the rapid update of the view.
+ Dropping this index make updating the view take a loger time.
+<programlisting>
+test=# DROP INDEX mv_ivm_index;
+DROP INDEX
+Time: 67.081 ms
+
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 16386.245 ms (00:16.386)
+</programlisting>
+
+</para>
+
+<para>
+ <acronym>IVM</acronym> is effective when we want to keep a materialized
+ view up-to-date and small fraction of a base table is modified
+ infrequently. Due to the overhead of immediate maintenance, <acronym>IVM</acronym>
+ 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, <acronym>IVM</acronym> is not effective and the cost of
+ maintenance can be larger than the <command>REFRESH MATERIALIZED VIEW</command>
+ command. In such situation, we can use <command>REFRESH MATERIALIZED VIEW</command>
+ and specify <literal>WITH NO DATA</literal> to disable immediate
+ maintenance before modifying a base table. After a base table modification,
+ execute the <command>REFRESH MATERIALIZED VIEW</command> (with <literal>WITH DATA</literal>)
+ command to refresh the view data and enable immediate maintenance.
+</para>
+
+</sect2>
+
+<sect2 id="rules-ivm-support">
+<title>Supported View Definitions and Restrictions</title>
+
+<para>
+ Currently, we can create <acronym>IMMV</acronym>s using inner joins, and some
+ aggregates. However, several restrictions apply to the definition of IMMV.
+</para>
+
+<sect3 id="rules-ivm-support-joins">
+<title>Joins</title>
+<para>
+ Inner joins including self-join are supported. Outer joins are not supported.
+</para>
+</sect3>
+
+<sect3 id="rules-ivm-support-aggregates">
+<title>Aggregates</title>
+<para>
+ Supported aggregate functions are <function>count</function>, <function>sum</function>,
+ <function>avg</function>, <function>min</function>, and <function>max</function>.
+ Currently, only built-in aggregate functions are supported and user defined
+ aggregates cannot be used. When a base table is modified, the new aggregated
+ values are incrementally calculated using the old aggregated values and values
+ of related hidden columns stored in <acronym>IMMV</acronym>.
+</para>
+
+<para>
+ Note that for <function>min</function> or <function>max</function>, the new values
+ could be re-calculated from base tables with regard to the affected groups when a
+ tuple containing the current minimal or maximal values are deleted from a base table.
+ Therefore, it can takes a long time to update an <acronym>IMMV</acronym> containing
+ these functions.
+</para>
+
+<para>
+ Also note that using <function>sum</function> or <function>avg</function> on
+ <type>real</type> (<type>float4</type>) type or <type>double precision</type>
+ (<type>float8</type>) type in <acronym>IMMV</acronym> is unsafe. This is
+ because aggregated values in <acronym>IMMV</acronym> can become different from
+ results calculated from base tables due to the limited precision of these types.
+ To avoid this problem, use the <type>numeric</type> type instead.
+</para>
+
+ <sect4 id="rules-ivm-restrictions-aggregates">
+ <title>Restrictions on Aggregates</title>
+ <para>
+ There are the following restrictions:
+ <itemizedlist>
+ <listitem>
+ <para>
+ If we have a <literal>GROUP BY</literal> clause, expressions specified in
+ <literal>GROUP BY</literal> must appear in the target list. This is
+ how tuples to be updated in the <acronym>IMMV</acronym> are identified.
+ These attributes are used as scan keys for searching tuples in the
+ <acronym>IMMV</acronym>, so indexes on them are required for efficient
+ <acronym>IVM</acronym>.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <literal>HAVING</literal> clause cannot be used.
+ </para>
+ </listitem>
+ </itemizedlist>
+ </para>
+ </sect4>
+</sect3>
+
+<sect3 id="rules-ivm-general-restricitons">
+<title>Other General Restrictions</title>
+<para>
+ There are other restrictions which generally apply to <acronym>IMMV</acronym>:
+ <itemizedlist>
+ <listitem>
+ <para>
+ Sub-queries cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ CTEs cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Window functions cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s must be based on simple base tables. It's not
+ supported to create them on top of views, materialized views, foreign tables, inhe.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ LIMIT and OFFSET clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s cannot contain system columns.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s cannot contain non-immutable functions.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ UNION/INTERSECT/EXCEPT clauses cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ DISTINCT ON clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ TABLESAMPLE parameter cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ inheritance parent tables cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ VALUES clause cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <literal>GROUPING SETS</literal> and <literal>FILTER</literal> clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ FOR UPDATE/SHARE cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ targetlist cannot contain columns whose name start with <literal>__ivm_</literal>.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ targetlist cannot contain expressions which contain an aggregate in it.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Logical replication is not supported, that is, even when a base table
+ at a publisher node is modified, <acronym>IMMV</acronym>s at subscriber
+ nodes are not updated.
+ </para>
+ </listitem>
+
+ </itemizedlist>
+</para>
+</sect3>
+
+</sect2>
+
+<sect2 id="rules-ivm-distinct">
+<title><literal>DISTINCT</literal></title>
+
+<para>
+ <productname>PostgreSQL</productname> supports <acronym>IMMV</acronym> with
+ <literal>DISTINCT</literal>. For example, suppose a <acronym>IMMV</acronym>
+ defined with <literal>DISTINCT</literal> on a base table containing duplicate
+ tuples. When tuples are deleted from the base table, a tuple in the view is
+ deleted if and only if the multiplicity of the tuple becomes zero. Moreover,
+ when tuples are inserted into the base table, a tuple is inserted into the
+ view only if the same tuple doesn't already exist in it.
+</para>
+
+<para>
+ Physically, an <acronym>IMMV</acronym> defined with <literal>DISTINCT</literal>
+ contains tuples after eliminating duplicates, and the multiplicity of each tuple
+ is stored in a hidden column named <literal>__ivm_count__</literal>.
+</para>
+</sect2>
+
+<sect2 id="rules-ivm-concurrent-transactions">
+<title>Concurrent Transactions</title>
+<para>
+ Suppose an <acronym>IMMV</acronym> is defined on two base tables and each
+ table was modified in different a concurrent transaction simultaneously.
+ In the transaction which was committed first, <acronym>IMMV</acronym> can
+ be updated considering only the change which happened in this transaction.
+ On the other hand, in order to update the view correctly in the transaction
+ which was committed later, we need to know the changes occurred in
+ both transactions. For this reason, <literal>ExclusiveLock</literal>
+ is held on an <acronym>IMMV</acronym> immediately after a base table is
+ modified in <literal>READ COMMITTED</literal> mode to make sure that
+ the <acronym>IMMV</acronym> is updated in the latter transaction after
+ the former transaction is committed. In <literal>REPEATABLE READ</literal>
+ or <literal>SERIALIZABLE</literal> mode, an error is raised immediately
+ if lock acquisition fails because any changes which occurred in
+ other transactions are not be visible in these modes and
+ <acronym>IMMV</acronym> cannot be updated correctly in such situations.
+ However, as an exception if the view has only one base table and
+ <command>INSERT</command> is performed on the table,
+ the lock held on thew view is <literal>RowExclusiveLock</literal>.
+</para>
+</sect2>
+
+<sect2 id="rules-ivm-rls">
+<title>Row Level Security</title>
+<para>
+ If some base tables have row level security policy, rows that are not visible
+ to the materialized view's owner are excluded from the result. In addition, such
+ rows are excluded as well when views are incrementally maintained. However, if a
+ new policy is defined or policies are changed after the materialized view was created,
+ the new policy will not be applied to the view contents. To apply the new policy,
+ you need to refresh materialized views.
+</para>
+</sect2>
+
+</sect1>
+
<sect1 id="rules-update">
<title>Rules on <command>INSERT</command>, <command>UPDATE</command>, and <command>DELETE</command></title>
diff --git a/doc/src/sgml/system-views.sgml b/doc/src/sgml/system-views.sgml
index bdc34cf94e..d4a1c99a91 100644
--- a/doc/src/sgml/system-views.sgml
+++ b/doc/src/sgml/system-views.sgml
@@ -1796,6 +1796,15 @@ SELECT * FROM pg_locks pl LEFT JOIN pg_prepared_xacts ppx
</para></entry>
</row>
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>isimmv</structfield> <type>bool</type>
+ </para>
+ <para>
+ True if materialized view is incrementally maintainable
+ </para></entry>
+ </row>
+
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>definition</structfield> <type>text</type>
--
2.25.1
v33-0010-Add-regression-tests-for-Incremental-View-Mainte.patchtext/x-diff; name=v33-0010-Add-regression-tests-for-Incremental-View-Mainte.patchDownload
From 7e14022df86f0e5315d2a6327ae4f30388a4ab5f Mon Sep 17 00:00:00 2001
From: Takuma Hoshiai <takuma.hoshiai@gmail.com>
Date: Wed, 10 Mar 2021 11:11:13 +0900
Subject: [PATCH v33 10/11] Add regression tests for Incremental View
Maintenance
---
.../regress/expected/incremental_matview.out | 1030 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/incremental_matview.sql | 533 +++++++++
3 files changed, 1564 insertions(+), 1 deletion(-)
create mode 100644 src/test/regress/expected/incremental_matview.out
create mode 100644 src/test/regress/sql/incremental_matview.sql
diff --git a/src/test/regress/expected/incremental_matview.out b/src/test/regress/expected/incremental_matview.out
new file mode 100644
index 0000000000..d65896425e
--- /dev/null
+++ b/src/test/regress/expected/incremental_matview.out
@@ -0,0 +1,1030 @@
+-- create a table to use as a basis for views and materialized views in various combinations
+CREATE TABLE mv_base_a (i int, j int);
+INSERT INTO mv_base_a VALUES
+ (1,10),
+ (2,20),
+ (3,30),
+ (4,40),
+ (5,50);
+CREATE TABLE mv_base_b (i int, k int);
+INSERT INTO mv_base_b VALUES
+ (1,101),
+ (2,102),
+ (3,103),
+ (4,104);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_1 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) WITH NO DATA;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ERROR: materialized view "mv_ivm_1" has not been populated
+HINT: Use the REFRESH MATERIALIZED VIEW command.
+REFRESH MATERIALIZED VIEW mv_ivm_1;
+NOTICE: could not create an index on materialized view "mv_ivm_1" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+-- REFRESH WITH NO DATA
+BEGIN;
+CREATE FUNCTION dummy_ivm_trigger_func() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+CREATE CONSTRAINT TRIGGER dummy_ivm_trigger AFTER INSERT
+ON mv_base_a FROM mv_ivm_1 FOR EACH ROW
+EXECUTE PROCEDURE dummy_ivm_trigger_func();
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ count
+-------
+ 17
+(1 row)
+
+REFRESH MATERIALIZED VIEW mv_ivm_1 WITH NO DATA;
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+-- immediate maintenance
+BEGIN;
+INSERT INTO mv_base_b VALUES(5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+ 5 | 50 | 105
+(5 rows)
+
+UPDATE mv_base_a SET j = 0 WHERE i = 1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 0 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+ 5 | 50 | 105
+(5 rows)
+
+DELETE FROM mv_base_b WHERE (i,k) = (5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 0 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+ROLLBACK;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+-- rename of IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS SELECT DISTINCT * FROM mv_base_a;
+NOTICE: created index "mv_ivm_rename_index" on materialized view "mv_ivm_rename"
+ALTER MATERIALIZED VIEW mv_ivm_rename RENAME COLUMN __ivm_count__ TO xxx;
+ERROR: IVM column can not be renamed
+DROP MATERIALIZED VIEW mv_ivm_rename;
+-- unique index on IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_unique AS SELECT DISTINCT * FROM mv_base_a;
+NOTICE: created index "mv_ivm_unique_index" on materialized view "mv_ivm_unique"
+CREATE UNIQUE INDEX ON mv_ivm_unique(__ivm_count__);
+ERROR: unique index creation on IVM columns is not supported
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__));
+ERROR: unique index creation on IVM columns is not supported
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__ + 1));
+ERROR: unique index creation on IVM columns is not supported
+DROP MATERIALIZED VIEW mv_ivm_unique;
+-- TRUNCATE a base table in join views
+BEGIN;
+TRUNCATE mv_base_a;
+SELECT * FROM mv_ivm_1;
+ i | j | k
+---+---+---
+(0 rows)
+
+ROLLBACK;
+BEGIN;
+TRUNCATE mv_base_b;
+SELECT * FROM mv_ivm_1;
+ i | j | k
+---+---+---
+(0 rows)
+
+ROLLBACK;
+-- some query syntax
+BEGIN;
+CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql'
+ AS 'SELECT 1' IMMUTABLE;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_func AS SELECT * FROM ivm_func();
+NOTICE: could not create an index on materialized view "mv_ivm_func" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_no_tbl AS SELECT 1;
+NOTICE: could not create an index on materialized view "mv_ivm_no_tbl" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+ROLLBACK;
+-- result of materialized view have DISTINCT clause or the duplicate result.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_duplicate AS SELECT j FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_duplicate" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_distinct AS SELECT DISTINCT j FROM mv_base_a;
+NOTICE: created index "mv_ivm_distinct_index" on materialized view "mv_ivm_distinct"
+INSERT INTO mv_base_a VALUES(6,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 20
+ 30
+ 40
+ 50
+(6 rows)
+
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+ROLLBACK;
+-- support SUM(), COUNT() and AVG() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 120 | 2 | 60.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+UPDATE mv_base_a SET j = 200 WHERE (i,j) = (2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+----------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 220 | 2 | 110.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (2,200);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+ROLLBACK;
+-- support COUNT(*) aggregate function
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ i | sum | count
+---+-----+-------
+ 1 | 10 | 1
+ 2 | 20 | 1
+ 3 | 30 | 1
+ 4 | 40 | 1
+ 5 | 50 | 1
+(5 rows)
+
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ i | sum | count
+---+-----+-------
+ 1 | 10 | 1
+ 2 | 120 | 2
+ 3 | 30 | 1
+ 4 | 40 | 1
+ 5 | 50 | 1
+(5 rows)
+
+ROLLBACK;
+-- TRUNCATE a base table in aggregate views
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+TRUNCATE mv_base_a;
+SELECT sum, count FROM mv_ivm_agg;
+ sum | count
+-----+-------
+(0 rows)
+
+SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+ i | sum | count
+---+-----+-------
+(0 rows)
+
+ROLLBACK;
+-- support aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_group" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+---------------------
+ 150 | 5 | 30.0000000000000000
+(1 row)
+
+INSERT INTO mv_base_a VALUES(6,60);
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+---------------------
+ 210 | 6 | 35.0000000000000000
+(1 row)
+
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+ROLLBACK;
+-- TRUNCATE a base table in aggregate views without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_group" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+TRUNCATE mv_base_a;
+SELECT sum, count, avg FROM mv_ivm_group;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+ROLLBACK;
+-- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_avg_bug AS SELECT i, SUM(j), COUNT(j), AVG(j) FROM mv_base_A GROUP BY i;
+NOTICE: created index "mv_ivm_avg_bug_index" on materialized view "mv_ivm_avg_bug"
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+INSERT INTO mv_base_a VALUES
+ (1,0),
+ (1,0),
+ (2,30),
+ (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 3 | 3.3333333333333333
+ 2 | 80 | 3 | 26.6666666666666667
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (1,0);
+DELETE FROM mv_base_a WHERE (i,j) = (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+ROLLBACK;
+-- support MIN(), MAX() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_min_max_index" on materialized view "mv_ivm_min_max"
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 10 | 10
+ 2 | 20 | 20
+ 3 | 30 | 30
+ 4 | 40 | 40
+ 5 | 50 | 50
+(5 rows)
+
+INSERT INTO mv_base_a VALUES
+ (1,11), (1,12),
+ (2,21), (2,22),
+ (3,31), (3,32),
+ (4,41), (4,42),
+ (5,51), (5,52);
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 10 | 12
+ 2 | 20 | 22
+ 3 | 30 | 32
+ 4 | 40 | 42
+ 5 | 50 | 52
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) IN ((1,10), (2,21), (3,32));
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 11 | 12
+ 2 | 20 | 22
+ 3 | 30 | 31
+ 4 | 40 | 42
+ 5 | 50 | 52
+(5 rows)
+
+ROLLBACK;
+-- support MIN(), MAX() aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT MIN(j), MAX(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_min_max" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 10 | 50
+(1 row)
+
+INSERT INTO mv_base_a VALUES
+ (0,0), (6,60), (7,70);
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 0 | 70
+(1 row)
+
+DELETE FROM mv_base_a WHERE (i,j) IN ((0,0), (7,70));
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 10 | 60
+(1 row)
+
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ |
+(1 row)
+
+ROLLBACK;
+-- Test MIN/MAX after search_path change
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min AS SELECT MIN(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_min" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 10
+(1 row)
+
+CREATE SCHEMA myschema;
+GRANT ALL ON SCHEMA myschema TO public;
+CREATE TABLE myschema.mv_base_a (j int);
+INSERT INTO myschema.mv_base_a VALUES (1);
+DELETE FROM mv_base_a WHERE (i,j) = (1,10);
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 20
+(1 row)
+
+SET search_path TO myschema,public,pg_catalog;
+DELETE FROM public.mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 30
+(1 row)
+
+ROLLBACK;
+-- aggregate views with column names specified
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ a | sum
+---+------
+ 1 | 110
+ 2 | 2200
+ 3 | 300
+ 4 | 40
+ 5 | 50
+(5 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ a | b
+---+------
+ 1 | 110
+ 2 | 2200
+ 3 | 300
+ 4 | 40
+ 5 | 50
+(5 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b,c) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+ERROR: too many column names were specified
+ROLLBACK;
+-- support self join view and multiple change on the same table
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_self(v1, v2) AS
+ SELECT t1.v, t2.v FROM base_t AS t1 JOIN base_t AS t2 ON t1.i = t2.i;
+NOTICE: could not create an index on materialized view "mv_self" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+----+----
+ 10 | 10
+ 20 | 20
+ 30 | 30
+(3 rows)
+
+INSERT INTO base_t VALUES (4,40);
+DELETE FROM base_t WHERE i = 1;
+UPDATE base_t SET v = v*10 WHERE i=2;
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+-----+-----
+ 30 | 30
+ 40 | 40
+ 200 | 200
+(3 rows)
+
+WITH
+ ins_t1 AS (INSERT INTO base_t VALUES (5,50) RETURNING 1),
+ ins_t2 AS (INSERT INTO base_t VALUES (6,60) RETURNING 1),
+ upd_t AS (UPDATE base_t SET v = v + 100 RETURNING 1),
+ dlt_t AS (DELETE FROM base_t WHERE i IN (4,5) RETURNING 1)
+SELECT NULL;
+ ?column?
+----------
+
+(1 row)
+
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+-----+-----
+ 50 | 50
+ 60 | 60
+ 130 | 130
+ 300 | 300
+(4 rows)
+
+--- with sub-transactions
+SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,70);
+RELEASE SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,77);
+SELECT * FROM mv_self ORDER BY v1, v2;
+ v1 | v2
+-----+-----
+ 50 | 50
+ 60 | 60
+ 70 | 70
+ 70 | 77
+ 77 | 70
+ 77 | 77
+ 130 | 130
+ 300 | 300
+(8 rows)
+
+ROLLBACK;
+-- support simultaneous table changes
+BEGIN;
+CREATE TABLE base_r (i int, v int);
+CREATE TABLE base_s (i int, v int);
+INSERT INTO base_r VALUES (1, 10), (2, 20), (3, 30);
+INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300);
+CREATE INCREMENTAL MATERIALIZED VIEW mv(v1, v2) AS
+ SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i);
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY v1;
+ v1 | v2
+----+-----
+ 10 | 100
+ 20 | 200
+ 30 | 300
+(3 rows)
+
+WITH
+ ins_r AS (INSERT INTO base_r VALUES (1,11) RETURNING 1),
+ ins_r2 AS (INSERT INTO base_r VALUES (3,33) RETURNING 1),
+ ins_s AS (INSERT INTO base_s VALUES (2,222) RETURNING 1),
+ upd_r AS (UPDATE base_r SET v = v + 1000 WHERE i = 2 RETURNING 1),
+ dlt_s AS (DELETE FROM base_s WHERE i = 3 RETURNING 1)
+SELECT NULL;
+ ?column?
+----------
+
+(1 row)
+
+SELECT * FROM mv ORDER BY v1;
+ v1 | v2
+------+-----
+ 10 | 100
+ 11 | 100
+ 1020 | 200
+ 1020 | 222
+(4 rows)
+
+ROLLBACK;
+-- support foreign reference constraints
+BEGIN;
+CREATE TABLE ri1 (i int PRIMARY KEY);
+CREATE TABLE ri2 (i int PRIMARY KEY REFERENCES ri1(i) ON UPDATE CASCADE ON DELETE CASCADE, v int);
+INSERT INTO ri1 VALUES (1),(2),(3);
+INSERT INTO ri2 VALUES (1),(2),(3);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ri(i1, i2) AS
+ SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i);
+NOTICE: created index "mv_ri_index" on materialized view "mv_ri"
+SELECT * FROM mv_ri ORDER BY i1;
+ i1 | i2
+----+----
+ 1 | 1
+ 2 | 2
+ 3 | 3
+(3 rows)
+
+UPDATE ri1 SET i=10 where i=1;
+DELETE FROM ri1 WHERE i=2;
+SELECT * FROM mv_ri ORDER BY i2;
+ i1 | i2
+----+----
+ 3 | 3
+ 10 | 10
+(2 rows)
+
+ROLLBACK;
+-- views including NULL
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1,10),(2, NULL);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY i;
+ i | v
+---+----
+ 1 | 10
+ 2 |
+(2 rows)
+
+UPDATE base_t SET v = 20 WHERE i = 2;
+SELECT * FROM mv ORDER BY i;
+ i | v
+---+----
+ 1 | 10
+ 2 | 20
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY i;
+ i
+---
+(0 rows)
+
+INSERT INTO base_t VALUES (1),(NULL);
+SELECT * FROM mv ORDER BY i;
+ i
+---
+ 1
+
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, sum(v) FROM base_t GROUP BY i;
+NOTICE: created index "mv_index" on materialized view "mv"
+SELECT * FROM mv ORDER BY i;
+ i | sum
+---+-----
+ 1 | 30
+ | 3
+(2 rows)
+
+UPDATE base_t SET v = v * 10;
+SELECT * FROM mv ORDER BY i;
+ i | sum
+---+-----
+ 1 | 300
+ | 30
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, min(v), max(v) FROM base_t GROUP BY i;
+NOTICE: created index "mv_index" on materialized view "mv"
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 1 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 1;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 3;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 5;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 4
+(1 row)
+
+ROLLBACK;
+-- IMMV containing user defined type
+BEGIN;
+CREATE TYPE mytype;
+CREATE FUNCTION mytype_in(cstring)
+ RETURNS mytype AS 'int4in'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+NOTICE: return type mytype is only a shell
+CREATE FUNCTION mytype_out(mytype)
+ RETURNS cstring AS 'int4out'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+NOTICE: argument type mytype is only a shell
+CREATE TYPE mytype (
+ LIKE = int4,
+ INPUT = mytype_in,
+ OUTPUT = mytype_out
+);
+CREATE FUNCTION mytype_eq(mytype, mytype)
+ RETURNS bool AS 'int4eq'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_lt(mytype, mytype)
+ RETURNS bool AS 'int4lt'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_cmp(mytype, mytype)
+ RETURNS integer AS 'btint4cmp'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE OPERATOR = (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_eq);
+CREATE OPERATOR < (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_lt);
+CREATE OPERATOR CLASS mytype_ops
+ DEFAULT FOR TYPE mytype USING btree AS
+ OPERATOR 1 <,
+ OPERATOR 3 = ,
+ FUNCTION 1 mytype_cmp(mytype,mytype);
+CREATE TABLE t_mytype (x mytype);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_mytype AS
+ SELECT * FROM t_mytype;
+NOTICE: could not create an index on materialized view "mv_mytype" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+INSERT INTO t_mytype VALUES ('1'::mytype);
+SELECT * FROM mv_mytype;
+ x
+---
+ 1
+(1 row)
+
+ROLLBACK;
+-- outer join is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv(a,b) AS SELECT a.i, b.i FROM mv_base_a a LEFT JOIN mv_base_b b ON a.i=b.i;
+ERROR: OUTER JOIN is not supported on incrementally maintainable materialized view
+-- CTE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS
+ WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i;
+ERROR: CTE is not supported on incrementally maintainable materialized view
+-- contain system column
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm01 AS SELECT i,j,xmin FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT i,j,xmin::text AS x_min FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm06 AS SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+-- contain subquery
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm03 AS SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 );
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT * FROM mv_base_b) b WHERE a.i = b.i;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm05 AS SELECT i,j, (SELECT k FROM mv_base_b b WHERE a.i = b.i) FROM mv_base_a a;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+-- contain ORDER BY
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) ORDER BY i,j,k;
+ERROR: ORDER BY clause is not supported on incrementally maintainable materialized view
+-- contain HAVING
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) GROUP BY i,j,k HAVING SUM(i) > 5;
+ERROR: HAVING clause is not supported on incrementally maintainable materialized view
+-- contain view or materialized view
+CREATE VIEW b_view AS SELECT i,k FROM mv_base_b;
+CREATE MATERIALIZED VIEW b_mview AS SELECT i,k FROM mv_base_b;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT a.i,a.j FROM mv_base_a a,b_view b WHERE a.i = b.i;
+ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT a.i,a.j FROM mv_base_a a,b_mview b WHERE a.i = b.i;
+ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm09 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) b WHERE a.i = b.i;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm10 AS SELECT a.i,a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) OR a.i > 5;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+-- contain mutable functions
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+ERROR: mutable function is not supported on incrementally maintainable materialized view
+HINT: functions must be marked IMMUTABLE
+-- LIMIT/OFFSET is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm13 AS SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5;
+ERROR: LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view
+-- DISTINCT ON is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm14 AS SELECT DISTINCT ON(i) i, j FROM mv_base_a;
+ERROR: DISTINCT ON is not supported on incrementally maintainable materialized view
+-- TABLESAMPLE clause is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm15 AS SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50);
+ERROR: TABLESAMPLE clause is not supported on incrementally maintainable materialized view
+-- window functions are not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm16 AS SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a;
+ERROR: window functions are not supported on incrementally maintainable materialized view
+-- aggregate function with some options is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm17 AS SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a;
+ERROR: aggregate function with FILTER clause is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm18 AS SELECT COUNT(DISTINCT i) FROM mv_base_a;
+ERROR: aggregate function with DISTINCT arguments is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm19 AS SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a;
+ERROR: aggregate function with ORDER clause is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm20 AS SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),());
+ERROR: GROUPING SETS, ROLLUP, or CUBE clauses is not supported on incrementally maintainable materialized view
+-- inheritance parent is not supported
+BEGIN;
+CREATE TABLE parent (i int, v int);
+CREATE TABLE child_a(options text) INHERITS(parent);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm21 AS SELECT * FROM parent;
+ERROR: inheritance parent is not supported on incrementally maintainable materialized view
+ROLLBACK;
+-- UNION statement is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm22 AS SELECT i,j FROM mv_base_a UNION ALL SELECT i,k FROM mv_base_b;;
+ERROR: UNION/INTERSECT/EXCEPT statements are not supported on incrementally maintainable materialized view
+-- empty target list is not allowed with IVM
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm25 AS SELECT FROM mv_base_a;
+ERROR: empty target list is not supported on incrementally maintainable materialized view
+-- FOR UPDATE/SHARE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm26 AS SELECT i,j FROM mv_base_a FOR UPDATE;
+ERROR: FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view
+-- tartget list cannot contain ivm column that start with '__ivm'
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm28 AS SELECT i AS "__ivm_count__" FROM mv_base_a;
+ERROR: column name __ivm_count__ is not supported on incrementally maintainable materialized view
+-- expressions specified in GROUP BY must appear in the target list.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm29 AS SELECT COUNT(i) FROM mv_base_a GROUP BY i;
+ERROR: GROUP BY expression not appearing in select list is not supported on incrementally maintainable materialized view
+-- experssions containing an aggregate is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm30 AS SELECT sum(i)*0.5 FROM mv_base_a;
+ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm31 AS SELECT sum(i)/sum(j) FROM mv_base_a;
+ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view
+-- VALUES is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_only_values1 AS values(1);
+ERROR: VALUES is not supported on incrementally maintainable materialized view
+-- views containing base tables with Row Level Security
+DROP USER IF EXISTS regress_ivm_admin;
+NOTICE: role "regress_ivm_admin" does not exist, skipping
+DROP USER IF EXISTS regress_ivm_user;
+NOTICE: role "regress_ivm_user" does not exist, skipping
+CREATE USER regress_ivm_admin;
+CREATE USER regress_ivm_user;
+--- create a table with RLS
+SET SESSION AUTHORIZATION regress_ivm_admin;
+CREATE TABLE rls_tbl(id int, data text, owner name);
+INSERT INTO rls_tbl VALUES
+ (1,'foo','regress_ivm_user'),
+ (2,'bar','postgres');
+CREATE TABLE num_tbl(id int, num text);
+INSERT INTO num_tbl VALUES
+ (1,'one'),
+ (2,'two'),
+ (3,'three'),
+ (4,'four'),
+ (5,'five'),
+ (6,'six');
+--- Users can access only their own rows
+CREATE POLICY rls_tbl_policy ON rls_tbl FOR SELECT TO PUBLIC USING(owner = current_user);
+ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
+GRANT ALL on rls_tbl TO PUBLIC;
+GRANT ALL on num_tbl TO PUBLIC;
+--- create a view owned by regress_ivm_user
+SET SESSION AUTHORIZATION regress_ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls AS SELECT * FROM rls_tbl;
+NOTICE: could not create an index on materialized view "ivm_rls" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+------+------------------
+ 1 | foo | regress_ivm_user
+(1 row)
+
+RESET SESSION AUTHORIZATION;
+--- inserts rows owned by different users
+INSERT INTO rls_tbl VALUES
+ (3,'baz','regress_ivm_user'),
+ (4,'qux','postgres');
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+------+------------------
+ 1 | foo | regress_ivm_user
+ 3 | baz | regress_ivm_user
+(2 rows)
+
+--- combination of diffent kinds of commands
+WITH
+ i AS (INSERT INTO rls_tbl VALUES(5,'quux','postgres'), (6,'corge','regress_ivm_user')),
+ u AS (UPDATE rls_tbl SET owner = 'postgres' WHERE id = 1),
+ u2 AS (UPDATE rls_tbl SET owner = 'regress_ivm_user' WHERE id = 2)
+SELECT;
+--
+(1 row)
+
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+-------+------------------
+ 2 | bar | regress_ivm_user
+ 3 | baz | regress_ivm_user
+ 6 | corge | regress_ivm_user
+(3 rows)
+
+---
+SET SESSION AUTHORIZATION regress_ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls2 AS SELECT * FROM rls_tbl JOIN num_tbl USING(id);
+NOTICE: could not create an index on materialized view "ivm_rls2" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+RESET SESSION AUTHORIZATION;
+WITH
+ x AS (UPDATE rls_tbl SET data = data || '_2' where id in (3,4)),
+ y AS (UPDATE num_tbl SET num = num || '_2' where id in (3,4))
+SELECT;
+--
+(1 row)
+
+SELECT * FROM ivm_rls2 ORDER BY 1,2,3;
+ id | data | owner | num
+----+-------+------------------+---------
+ 2 | bar | regress_ivm_user | two
+ 3 | baz_2 | regress_ivm_user | three_2
+ 6 | corge | regress_ivm_user | six
+(3 rows)
+
+-- automatic index creation
+CREATE TABLE base_a (i int primary key, j int);
+CREATE TABLE base_b (i int primary key, j int);
+--- group by: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx1 AS SELECT i, sum(j) FROM base_a GROUP BY i;
+NOTICE: created index "mv_idx1_index" on materialized view "mv_idx1"
+--- distinct: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx2 AS SELECT DISTINCT j FROM base_a;
+NOTICE: created index "mv_idx2_index" on materialized view "mv_idx2"
+--- with all pkey columns: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx3(i_a, i_b) AS SELECT a.i, b.i FROM base_a a, base_b b;
+NOTICE: created index "mv_idx3_index" on materialized view "mv_idx3"
+--- missing some pkey columns: no index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx4 AS SELECT j FROM base_a;
+NOTICE: could not create an index on materialized view "mv_idx4" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx5 AS SELECT a.i, b.j FROM base_a a, base_b b;
+NOTICE: could not create an index on materialized view "mv_idx5" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+-- cleanup
+DROP TABLE rls_tbl CASCADE;
+NOTICE: drop cascades to 2 other objects
+DETAIL: drop cascades to materialized view ivm_rls
+drop cascades to materialized view ivm_rls2
+DROP TABLE num_tbl CASCADE;
+DROP USER regress_ivm_user;
+DROP USER regress_ivm_admin;
+DROP TABLE mv_base_b CASCADE;
+NOTICE: drop cascades to 3 other objects
+DETAIL: drop cascades to materialized view mv_ivm_1
+drop cascades to view b_view
+drop cascades to materialized view b_mview
+DROP TABLE mv_base_a CASCADE;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 2429ec2bba..03814f34e9 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -78,7 +78,7 @@ test: brin_bloom brin_multi
# psql depends on create_am
# amutils depends on geometry, create_index_spgist, hash_index, brin
# ----------
-test: create_table_like alter_generic alter_operator misc async dbsize merge misc_functions sysviews tsrf tid tidscan tidrangescan collate.utf8 collate.icu.utf8 incremental_sort create_role
+test: create_table_like alter_generic alter_operator misc async dbsize merge misc_functions sysviews tsrf tid tidscan tidrangescan collate.utf8 collate.icu.utf8 incremental_sort create_role incremental_matview
# collate.linux.utf8 and collate.icu.utf8 tests cannot be run in parallel with each other
test: rules psql psql_crosstab amutils stats_ext collate.linux.utf8 collate.windows.win1252
diff --git a/src/test/regress/sql/incremental_matview.sql b/src/test/regress/sql/incremental_matview.sql
new file mode 100644
index 0000000000..90116edff8
--- /dev/null
+++ b/src/test/regress/sql/incremental_matview.sql
@@ -0,0 +1,533 @@
+-- create a table to use as a basis for views and materialized views in various combinations
+CREATE TABLE mv_base_a (i int, j int);
+INSERT INTO mv_base_a VALUES
+ (1,10),
+ (2,20),
+ (3,30),
+ (4,40),
+ (5,50);
+CREATE TABLE mv_base_b (i int, k int);
+INSERT INTO mv_base_b VALUES
+ (1,101),
+ (2,102),
+ (3,103),
+ (4,104);
+
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_1 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) WITH NO DATA;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+REFRESH MATERIALIZED VIEW mv_ivm_1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+
+-- REFRESH WITH NO DATA
+BEGIN;
+CREATE FUNCTION dummy_ivm_trigger_func() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+
+CREATE CONSTRAINT TRIGGER dummy_ivm_trigger AFTER INSERT
+ON mv_base_a FROM mv_ivm_1 FOR EACH ROW
+EXECUTE PROCEDURE dummy_ivm_trigger_func();
+
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+
+REFRESH MATERIALIZED VIEW mv_ivm_1 WITH NO DATA;
+
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ROLLBACK;
+
+-- immediate maintenance
+BEGIN;
+INSERT INTO mv_base_b VALUES(5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+UPDATE mv_base_a SET j = 0 WHERE i = 1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+DELETE FROM mv_base_b WHERE (i,k) = (5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ROLLBACK;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+
+-- rename of IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS SELECT DISTINCT * FROM mv_base_a;
+ALTER MATERIALIZED VIEW mv_ivm_rename RENAME COLUMN __ivm_count__ TO xxx;
+DROP MATERIALIZED VIEW mv_ivm_rename;
+
+-- unique index on IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_unique AS SELECT DISTINCT * FROM mv_base_a;
+CREATE UNIQUE INDEX ON mv_ivm_unique(__ivm_count__);
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__));
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__ + 1));
+DROP MATERIALIZED VIEW mv_ivm_unique;
+
+-- TRUNCATE a base table in join views
+BEGIN;
+TRUNCATE mv_base_a;
+SELECT * FROM mv_ivm_1;
+ROLLBACK;
+
+BEGIN;
+TRUNCATE mv_base_b;
+SELECT * FROM mv_ivm_1;
+ROLLBACK;
+
+-- some query syntax
+BEGIN;
+CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql'
+ AS 'SELECT 1' IMMUTABLE;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_func AS SELECT * FROM ivm_func();
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_no_tbl AS SELECT 1;
+ROLLBACK;
+
+-- result of materialized view have DISTINCT clause or the duplicate result.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_duplicate AS SELECT j FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_distinct AS SELECT DISTINCT j FROM mv_base_a;
+INSERT INTO mv_base_a VALUES(6,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+DELETE FROM mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ROLLBACK;
+
+-- support SUM(), COUNT() and AVG() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+UPDATE mv_base_a SET j = 200 WHERE (i,j) = (2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+DELETE FROM mv_base_a WHERE (i,j) = (2,200);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ROLLBACK;
+
+-- support COUNT(*) aggregate function
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ROLLBACK;
+
+-- TRUNCATE a base table in aggregate views
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+TRUNCATE mv_base_a;
+SELECT sum, count FROM mv_ivm_agg;
+SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+ROLLBACK;
+
+-- support aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+INSERT INTO mv_base_a VALUES(6,60);
+SELECT * FROM mv_ivm_group ORDER BY 1;
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ROLLBACK;
+
+-- TRUNCATE a base table in aggregate views without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+TRUNCATE mv_base_a;
+SELECT sum, count, avg FROM mv_ivm_group;
+SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+ROLLBACK;
+
+-- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_avg_bug AS SELECT i, SUM(j), COUNT(j), AVG(j) FROM mv_base_A GROUP BY i;
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES
+ (1,0),
+ (1,0),
+ (2,30),
+ (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+DELETE FROM mv_base_a WHERE (i,j) = (1,0);
+DELETE FROM mv_base_a WHERE (i,j) = (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ROLLBACK;
+
+-- support MIN(), MAX() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES
+ (1,11), (1,12),
+ (2,21), (2,22),
+ (3,31), (3,32),
+ (4,41), (4,42),
+ (5,51), (5,52);
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+DELETE FROM mv_base_a WHERE (i,j) IN ((1,10), (2,21), (3,32));
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ROLLBACK;
+
+-- support MIN(), MAX() aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT MIN(j), MAX(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+INSERT INTO mv_base_a VALUES
+ (0,0), (6,60), (7,70);
+SELECT * FROM mv_ivm_min_max;
+DELETE FROM mv_base_a WHERE (i,j) IN ((0,0), (7,70));
+SELECT * FROM mv_ivm_min_max;
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+ROLLBACK;
+
+-- Test MIN/MAX after search_path change
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min AS SELECT MIN(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_min;
+
+CREATE SCHEMA myschema;
+GRANT ALL ON SCHEMA myschema TO public;
+CREATE TABLE myschema.mv_base_a (j int);
+INSERT INTO myschema.mv_base_a VALUES (1);
+
+DELETE FROM mv_base_a WHERE (i,j) = (1,10);
+SELECT * FROM mv_ivm_min;
+
+SET search_path TO myschema,public,pg_catalog;
+DELETE FROM public.mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_min;
+ROLLBACK;
+
+-- aggregate views with column names specified
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b,c) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+ROLLBACK;
+
+-- support self join view and multiple change on the same table
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_self(v1, v2) AS
+ SELECT t1.v, t2.v FROM base_t AS t1 JOIN base_t AS t2 ON t1.i = t2.i;
+SELECT * FROM mv_self ORDER BY v1;
+INSERT INTO base_t VALUES (4,40);
+DELETE FROM base_t WHERE i = 1;
+UPDATE base_t SET v = v*10 WHERE i=2;
+SELECT * FROM mv_self ORDER BY v1;
+WITH
+ ins_t1 AS (INSERT INTO base_t VALUES (5,50) RETURNING 1),
+ ins_t2 AS (INSERT INTO base_t VALUES (6,60) RETURNING 1),
+ upd_t AS (UPDATE base_t SET v = v + 100 RETURNING 1),
+ dlt_t AS (DELETE FROM base_t WHERE i IN (4,5) RETURNING 1)
+SELECT NULL;
+SELECT * FROM mv_self ORDER BY v1;
+
+--- with sub-transactions
+SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,70);
+RELEASE SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,77);
+SELECT * FROM mv_self ORDER BY v1, v2;
+
+ROLLBACK;
+
+-- support simultaneous table changes
+BEGIN;
+CREATE TABLE base_r (i int, v int);
+CREATE TABLE base_s (i int, v int);
+INSERT INTO base_r VALUES (1, 10), (2, 20), (3, 30);
+INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300);
+CREATE INCREMENTAL MATERIALIZED VIEW mv(v1, v2) AS
+ SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i);
+SELECT * FROM mv ORDER BY v1;
+WITH
+ ins_r AS (INSERT INTO base_r VALUES (1,11) RETURNING 1),
+ ins_r2 AS (INSERT INTO base_r VALUES (3,33) RETURNING 1),
+ ins_s AS (INSERT INTO base_s VALUES (2,222) RETURNING 1),
+ upd_r AS (UPDATE base_r SET v = v + 1000 WHERE i = 2 RETURNING 1),
+ dlt_s AS (DELETE FROM base_s WHERE i = 3 RETURNING 1)
+SELECT NULL;
+SELECT * FROM mv ORDER BY v1;
+ROLLBACK;
+
+-- support foreign reference constraints
+BEGIN;
+CREATE TABLE ri1 (i int PRIMARY KEY);
+CREATE TABLE ri2 (i int PRIMARY KEY REFERENCES ri1(i) ON UPDATE CASCADE ON DELETE CASCADE, v int);
+INSERT INTO ri1 VALUES (1),(2),(3);
+INSERT INTO ri2 VALUES (1),(2),(3);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ri(i1, i2) AS
+ SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i);
+SELECT * FROM mv_ri ORDER BY i1;
+UPDATE ri1 SET i=10 where i=1;
+DELETE FROM ri1 WHERE i=2;
+SELECT * FROM mv_ri ORDER BY i2;
+ROLLBACK;
+
+-- views including NULL
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1,10),(2, NULL);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+SELECT * FROM mv ORDER BY i;
+UPDATE base_t SET v = 20 WHERE i = 2;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+SELECT * FROM mv ORDER BY i;
+INSERT INTO base_t VALUES (1),(NULL);
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, sum(v) FROM base_t GROUP BY i;
+SELECT * FROM mv ORDER BY i;
+UPDATE base_t SET v = v * 10;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, min(v), max(v) FROM base_t GROUP BY i;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 1;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 3;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 5;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+-- IMMV containing user defined type
+BEGIN;
+
+CREATE TYPE mytype;
+CREATE FUNCTION mytype_in(cstring)
+ RETURNS mytype AS 'int4in'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_out(mytype)
+ RETURNS cstring AS 'int4out'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE TYPE mytype (
+ LIKE = int4,
+ INPUT = mytype_in,
+ OUTPUT = mytype_out
+);
+
+CREATE FUNCTION mytype_eq(mytype, mytype)
+ RETURNS bool AS 'int4eq'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_lt(mytype, mytype)
+ RETURNS bool AS 'int4lt'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_cmp(mytype, mytype)
+ RETURNS integer AS 'btint4cmp'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+
+CREATE OPERATOR = (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_eq);
+CREATE OPERATOR < (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_lt);
+
+CREATE OPERATOR CLASS mytype_ops
+ DEFAULT FOR TYPE mytype USING btree AS
+ OPERATOR 1 <,
+ OPERATOR 3 = ,
+ FUNCTION 1 mytype_cmp(mytype,mytype);
+
+CREATE TABLE t_mytype (x mytype);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_mytype AS
+ SELECT * FROM t_mytype;
+INSERT INTO t_mytype VALUES ('1'::mytype);
+SELECT * FROM mv_mytype;
+
+ROLLBACK;
+
+-- outer join is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv(a,b) AS SELECT a.i, b.i FROM mv_base_a a LEFT JOIN mv_base_b b ON a.i=b.i;
+-- CTE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS
+ WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i;
+-- contain system column
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm01 AS SELECT i,j,xmin FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT i,j,xmin::text AS x_min FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm06 AS SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a;
+-- contain subquery
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm03 AS SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 );
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT * FROM mv_base_b) b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm05 AS SELECT i,j, (SELECT k FROM mv_base_b b WHERE a.i = b.i) FROM mv_base_a a;
+-- contain ORDER BY
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) ORDER BY i,j,k;
+-- contain HAVING
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) GROUP BY i,j,k HAVING SUM(i) > 5;
+
+-- contain view or materialized view
+CREATE VIEW b_view AS SELECT i,k FROM mv_base_b;
+CREATE MATERIALIZED VIEW b_mview AS SELECT i,k FROM mv_base_b;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT a.i,a.j FROM mv_base_a a,b_view b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT a.i,a.j FROM mv_base_a a,b_mview b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm09 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm10 AS SELECT a.i,a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) OR a.i > 5;
+
+-- contain mutable functions
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+
+-- LIMIT/OFFSET is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm13 AS SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5;
+
+-- DISTINCT ON is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm14 AS SELECT DISTINCT ON(i) i, j FROM mv_base_a;
+
+-- TABLESAMPLE clause is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm15 AS SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50);
+
+-- window functions are not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm16 AS SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a;
+
+-- aggregate function with some options is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm17 AS SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm18 AS SELECT COUNT(DISTINCT i) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm19 AS SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm20 AS SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),());
+
+-- inheritance parent is not supported
+BEGIN;
+CREATE TABLE parent (i int, v int);
+CREATE TABLE child_a(options text) INHERITS(parent);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm21 AS SELECT * FROM parent;
+ROLLBACK;
+
+-- UNION statement is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm22 AS SELECT i,j FROM mv_base_a UNION ALL SELECT i,k FROM mv_base_b;;
+
+-- empty target list is not allowed with IVM
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm25 AS SELECT FROM mv_base_a;
+
+-- FOR UPDATE/SHARE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm26 AS SELECT i,j FROM mv_base_a FOR UPDATE;
+
+-- tartget list cannot contain ivm column that start with '__ivm'
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm28 AS SELECT i AS "__ivm_count__" FROM mv_base_a;
+
+-- expressions specified in GROUP BY must appear in the target list.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm29 AS SELECT COUNT(i) FROM mv_base_a GROUP BY i;
+
+-- experssions containing an aggregate is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm30 AS SELECT sum(i)*0.5 FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm31 AS SELECT sum(i)/sum(j) FROM mv_base_a;
+
+-- VALUES is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_only_values1 AS values(1);
+
+-- views containing base tables with Row Level Security
+DROP USER IF EXISTS regress_ivm_admin;
+DROP USER IF EXISTS regress_ivm_user;
+CREATE USER regress_ivm_admin;
+CREATE USER regress_ivm_user;
+
+--- create a table with RLS
+SET SESSION AUTHORIZATION regress_ivm_admin;
+CREATE TABLE rls_tbl(id int, data text, owner name);
+INSERT INTO rls_tbl VALUES
+ (1,'foo','regress_ivm_user'),
+ (2,'bar','postgres');
+CREATE TABLE num_tbl(id int, num text);
+INSERT INTO num_tbl VALUES
+ (1,'one'),
+ (2,'two'),
+ (3,'three'),
+ (4,'four'),
+ (5,'five'),
+ (6,'six');
+
+--- Users can access only their own rows
+CREATE POLICY rls_tbl_policy ON rls_tbl FOR SELECT TO PUBLIC USING(owner = current_user);
+ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
+GRANT ALL on rls_tbl TO PUBLIC;
+GRANT ALL on num_tbl TO PUBLIC;
+
+--- create a view owned by regress_ivm_user
+SET SESSION AUTHORIZATION regress_ivm_user;
+
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls AS SELECT * FROM rls_tbl;
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+RESET SESSION AUTHORIZATION;
+
+--- inserts rows owned by different users
+INSERT INTO rls_tbl VALUES
+ (3,'baz','regress_ivm_user'),
+ (4,'qux','postgres');
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+
+--- combination of diffent kinds of commands
+WITH
+ i AS (INSERT INTO rls_tbl VALUES(5,'quux','postgres'), (6,'corge','regress_ivm_user')),
+ u AS (UPDATE rls_tbl SET owner = 'postgres' WHERE id = 1),
+ u2 AS (UPDATE rls_tbl SET owner = 'regress_ivm_user' WHERE id = 2)
+SELECT;
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+
+---
+SET SESSION AUTHORIZATION regress_ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls2 AS SELECT * FROM rls_tbl JOIN num_tbl USING(id);
+RESET SESSION AUTHORIZATION;
+
+WITH
+ x AS (UPDATE rls_tbl SET data = data || '_2' where id in (3,4)),
+ y AS (UPDATE num_tbl SET num = num || '_2' where id in (3,4))
+SELECT;
+SELECT * FROM ivm_rls2 ORDER BY 1,2,3;
+
+-- automatic index creation
+CREATE TABLE base_a (i int primary key, j int);
+CREATE TABLE base_b (i int primary key, j int);
+
+--- group by: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx1 AS SELECT i, sum(j) FROM base_a GROUP BY i;
+
+--- distinct: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx2 AS SELECT DISTINCT j FROM base_a;
+
+--- with all pkey columns: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx3(i_a, i_b) AS SELECT a.i, b.i FROM base_a a, base_b b;
+
+--- missing some pkey columns: no index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx4 AS SELECT j FROM base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx5 AS SELECT a.i, b.j FROM base_a a, base_b b;
+
+-- cleanup
+
+DROP TABLE rls_tbl CASCADE;
+DROP TABLE num_tbl CASCADE;
+DROP USER regress_ivm_user;
+DROP USER regress_ivm_admin;
+
+DROP TABLE mv_base_b CASCADE;
+DROP TABLE mv_base_a CASCADE;
--
2.25.1
v33-0009-Add-support-for-min-max-aggregates-for-IVM.patchtext/x-diff; name=v33-0009-Add-support-for-min-max-aggregates-for-IVM.patchDownload
From 1c9b9777b934e578d5a24e3083655f708ea6d64e Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 20:58:25 +0900
Subject: [PATCH v33 09/11] Add support for min/max aggregates for IVM
Supporting min and max is more complicated than count, sum, or avg.
For an example of min, when tuples are inserted, the current min value
in the view and the min value in the inseteted tuples are compared,
then the smaller one is used as the latest min value. On the other
hand, when tuples are deleted, if the current min value in the view
equals to the min in the deleted tuples, we need re-computation the
latest min value from base tables. Otherwise, the current value in
the view remains.
---
src/backend/commands/createas.c | 45 +++
src/backend/commands/matview.c | 644 +++++++++++++++++++++++++++++++-
2 files changed, 680 insertions(+), 9 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index d8767137d9..abce06d046 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -1309,6 +1309,51 @@ check_aggregate_supports_ivm(Oid aggfnoid)
case F_AVG_FLOAT8:
case F_AVG_INTERVAL:
+ /* min */
+ case F_MIN_ANYARRAY:
+ case F_MIN_INT8:
+ case F_MIN_INT4:
+ case F_MIN_INT2:
+ case F_MIN_OID:
+ case F_MIN_FLOAT4:
+ case F_MIN_FLOAT8:
+ case F_MIN_DATE:
+ case F_MIN_TIME:
+ case F_MIN_TIMETZ:
+ case F_MIN_MONEY:
+ case F_MIN_TIMESTAMP:
+ case F_MIN_TIMESTAMPTZ:
+ case F_MIN_INTERVAL:
+ case F_MIN_TEXT:
+ case F_MIN_NUMERIC:
+ case F_MIN_BPCHAR:
+ case F_MIN_TID:
+ case F_MIN_ANYENUM:
+ case F_MIN_INET:
+ case F_MIN_PG_LSN:
+
+ /* max */
+ case F_MAX_ANYARRAY:
+ case F_MAX_INT8:
+ case F_MAX_INT4:
+ case F_MAX_INT2:
+ case F_MAX_OID:
+ case F_MAX_FLOAT4:
+ case F_MAX_FLOAT8:
+ case F_MAX_DATE:
+ case F_MAX_TIME:
+ case F_MAX_TIMETZ:
+ case F_MAX_MONEY:
+ case F_MAX_TIMESTAMP:
+ case F_MAX_TIMESTAMPTZ:
+ case F_MAX_INTERVAL:
+ case F_MAX_TEXT:
+ case F_MAX_NUMERIC:
+ case F_MAX_BPCHAR:
+ case F_MAX_TID:
+ case F_MAX_ANYENUM:
+ case F_MAX_INET:
+ case F_MAX_PG_LSN:
return true;
default:
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index 97406b28c9..0ff5e3922b 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -69,6 +69,34 @@ typedef struct
#define MV_INIT_QUERYHASHSIZE 16
+/* MV query type codes */
+#define MV_PLAN_RECALC 1
+#define MV_PLAN_SET_VALUE 2
+
+/*
+ * MI_QueryKey
+ *
+ * The key identifying a prepared SPI plan in our query hashtable
+ */
+typedef struct MV_QueryKey
+{
+ Oid matview_id; /* OID of materialized view */
+ int32 query_type; /* query type ID, see MV_PLAN_XXX above */
+} MV_QueryKey;
+
+/*
+ * MV_QueryHashEntry
+ *
+ * Hash entry for cached plans used to maintain materialized views.
+ */
+typedef struct MV_QueryHashEntry
+{
+ MV_QueryKey key;
+ SPIPlanPtr plan;
+ SearchPathMatcher *search_path; /* search_path used for parsing
+ * and planning */
+} MV_QueryHashEntry;
+
/*
* MV_TriggerHashEntry
*
@@ -105,6 +133,7 @@ typedef struct MV_TriggerTable
TupleTableSlot *slot; /* for checking visibility in the pre-state table */
} MV_TriggerTable;
+static HTAB *mv_query_cache = NULL;
static HTAB *mv_trigger_info = NULL;
static bool in_delta_calculation = false;
@@ -165,6 +194,9 @@ static void append_set_clause_for_sum(const char *resname, StringInfo buf_old,
static void append_set_clause_for_avg(const char *resname, StringInfo buf_old,
StringInfo buf_new, StringInfo aggs_list,
const char *aggtype);
+static void append_set_clause_for_minmax(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ bool is_min);
static char *get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
const char* count_col, const char *castType);
static char *get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
@@ -173,17 +205,30 @@ static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
List *keys, StringInfo aggs_list, StringInfo aggs_set,
- const char *count_colname);
+ List *minmax_list, List *is_min_list,
+ const char *count_colname,
+ SPITupleTable **tuptable_recalc, uint64 *num_recalc);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
List *keys, StringInfo target_list, StringInfo aggs_set,
const char* count_colname);
static char *get_matching_condition_string(List *keys);
+static char *get_returning_string(List *minmax_list, List *is_min_list, List *keys);
+static char *get_minmax_recalc_condition_string(List *minmax_list, List *is_min_list);
+static char *get_select_for_recalc_string(List *keys);
+static void recalc_and_set_values(SPITupleTable *tuptable_recalc, int64 num_tuples,
+ List *namelist, List *keys, Relation matviewRel);
+static SPIPlanPtr get_plan_for_recalc(Oid matviewOid, List *namelist, List *keys, Oid *keyTypes);
+static SPIPlanPtr get_plan_for_set_values(Oid matviewOid, char *matviewname, List *namelist,
+ Oid *valTypes);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
static void mv_InitHashTables(void);
+static SPIPlanPtr mv_FetchPreparedPlan(MV_QueryKey *key);
+static void mv_HashPreparedPlan(MV_QueryKey *key, SPIPlanPtr plan);
+static void mv_BuildQueryKey(MV_QueryKey *key, Oid matview_id, int32 query_type);
static void clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort);
/*
@@ -2122,6 +2167,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
ListCell *lc;
int i;
List *keys = NIL;
+ List *minmax_list = NIL;
+ List *is_min_list = NIL;
/*
@@ -2203,6 +2250,17 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
append_set_clause_for_avg(resname, aggs_set_old, aggs_set_new, aggs_list_buf,
format_type_be(aggref->aggtype));
+ /* min/max */
+ else if (!strcmp(aggname, "min") || !strcmp(aggname, "max"))
+ {
+ bool is_min = (!strcmp(aggname, "min"));
+
+ append_set_clause_for_minmax(resname, aggs_set_old, aggs_set_new, aggs_list_buf, is_min);
+
+ /* make a resname list of min and max aggregates */
+ minmax_list = lappend(minmax_list, resname);
+ is_min_list = lappend_int(is_min_list, is_min);
+ }
else
elog(ERROR, "unsupported aggregate function: %s", aggname);
}
@@ -2232,6 +2290,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
{
EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ SPITupleTable *tuptable_recalc = NULL;
+ uint64 num_recalc;
int rc;
/* convert tuplestores to ENR, and register for SPI */
@@ -2250,10 +2310,18 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
/* apply old delta and get rows to be recalculated */
apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
keys, aggs_list_buf, aggs_set_old,
- count_colname);
+ minmax_list, is_min_list,
+ count_colname, &tuptable_recalc, &num_recalc);
else
apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+ /*
+ * If we have min or max, we might have to recalculate aggregate values from base tables
+ * on some tuples. TIDs and keys such tuples are returned as a result of the above query.
+ */
+ if (minmax_list && tuptable_recalc)
+ recalc_and_set_values(tuptable_recalc, num_recalc, minmax_list, keys, matviewRel);
+
}
/* For tuple insertion */
if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
@@ -2445,6 +2513,70 @@ append_set_clause_for_avg(const char *resname, StringInfo buf_old,
);
}
+/*
+ * append_set_clause_for_minmax
+ *
+ * Append SET clause string for min or max aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ * is_min is true if this is min, false if not.
+ */
+static void
+append_set_clause_for_minmax(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ bool is_min)
+{
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /*
+ * If the new value doesn't became NULL then use the value remaining
+ * in the view although this will be recomputated afterwords.
+ */
+ appendStringInfo(buf_old,
+ ", %s = CASE WHEN %s THEN NULL ELSE %s END",
+ quote_qualified_identifier(NULL, resname),
+ get_null_condition_string(IVM_SUB, "mv", "t", count_col),
+ quote_qualified_identifier("mv", resname)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /*
+ * min = LEAST(mv.min, diff.min)
+ * max = GREATEST(mv.max, diff.max)
+ */
+ appendStringInfo(buf_new,
+ ", %s = CASE WHEN %s THEN NULL ELSE %s(%s,%s) END",
+ quote_qualified_identifier(NULL, resname),
+ get_null_condition_string(IVM_ADD, "mv", "diff", count_col),
+
+ is_min ? "LEAST" : "GREATEST",
+ quote_qualified_identifier("mv", resname),
+ quote_qualified_identifier("diff", resname)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
/*
* get_operation_string
*
@@ -2547,19 +2679,44 @@ get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
* list to identify a tuple in the view. If the view has aggregates, this
* requires strings representing resnames of aggregates and SET clause for
* updating aggregate values.
+ *
+ * If the view has min or max aggregate, this requires a list of resnames of
+ * min/max aggregates and a list of boolean which represents which entries in
+ * minmax_list is min. These are necessary to check if we need to recalculate
+ * min or max aggregate values. In this case, this query returns TID and keys
+ * of tuples which need to be recalculated. This result and the number of rows
+ * are stored in tuptables and num_recalc repectedly.
+ *
*/
static void
apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
List *keys, StringInfo aggs_list, StringInfo aggs_set,
- const char *count_colname)
+ List *minmax_list, List *is_min_list,
+ const char *count_colname,
+ SPITupleTable **tuptable_recalc, uint64 *num_recalc)
{
StringInfoData querybuf;
char *match_cond;
+ char *updt_returning = "";
+ char *select_for_recalc = "SELECT";
bool agg_without_groupby = (list_length(keys) == 0);
+ Assert(tuptable_recalc != NULL);
+ Assert(num_recalc != NULL);
+
/* build WHERE condition for searching tuples to be deleted */
match_cond = get_matching_condition_string(keys);
+ /*
+ * We need a special RETURNING clause and SELECT statement for min/max to
+ * check which tuple needs re-calculation from base tables.
+ */
+ if (minmax_list)
+ {
+ updt_returning = get_returning_string(minmax_list, is_min_list, keys);
+ select_for_recalc = get_select_for_recalc_string(keys);
+ }
+
/* Search for matching tuples from the view and update or delete if found. */
initStringInfo(&querybuf);
appendStringInfo(&querybuf,
@@ -2574,10 +2731,11 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
"%s" /* SET clauses for aggregates */
"FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
- ")"
- /* delete a tuple if this is to be deleted */
- "DELETE FROM %s AS mv USING t "
- "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
+ "%s" /* RETURNING clause for recalc infomation */
+ "), dlt AS (" /* delete a tuple if this is to be deleted */
+ "DELETE FROM %s AS mv USING t "
+ "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt"
+ ") %s", /* SELECT returning which tuples need to be recalculated */
count_colname,
count_colname, count_colname, (agg_without_groupby ? "false" : "true"),
(aggs_list != NULL ? aggs_list->data : ""),
@@ -2585,10 +2743,25 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
match_cond,
matviewname, count_colname, count_colname, count_colname,
(aggs_set != NULL ? aggs_set->data : ""),
- matviewname);
+ updt_returning,
+ matviewname,
+ select_for_recalc);
- if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_SELECT)
elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+
+
+ /* Return tuples to be recalculated. */
+ if (minmax_list)
+ {
+ *tuptable_recalc = SPI_tuptable;
+ *num_recalc = SPI_processed;
+ }
+ else
+ {
+ *tuptable_recalc = NULL;
+ *num_recalc = 0;
+ }
}
/*
@@ -2771,6 +2944,349 @@ get_matching_condition_string(List *keys)
return match_cond.data;
}
+/*
+ * get_returning_string
+ *
+ * Build a string for RETURNING clause of UPDATE used in apply_old_delta_with_count.
+ * This clause returns ctid and a boolean value that indicates if we need to
+ * recalculate min or max value, for each updated row.
+ */
+static char *
+get_returning_string(List *minmax_list, List *is_min_list, List *keys)
+{
+ StringInfoData returning;
+ char *recalc_cond;
+ ListCell *lc;
+
+ Assert(minmax_list != NIL && is_min_list != NIL);
+ recalc_cond = get_minmax_recalc_condition_string(minmax_list, is_min_list);
+
+ initStringInfo(&returning);
+
+ appendStringInfo(&returning, "RETURNING mv.ctid AS tid, (%s) AS recalc", recalc_cond);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&returning, ", %s", quote_qualified_identifier("mv", resname));
+ }
+
+ return returning.data;
+}
+
+/*
+ * get_minmax_recalc_condition_string
+ *
+ * Build a predicate string for checking if any min/max aggregate
+ * value needs to be recalculated.
+ */
+static char *
+get_minmax_recalc_condition_string(List *minmax_list, List *is_min_list)
+{
+ StringInfoData recalc_cond;
+ ListCell *lc1, *lc2;
+
+ initStringInfo(&recalc_cond);
+
+ Assert (list_length(minmax_list) == list_length(is_min_list));
+
+ forboth (lc1, minmax_list, lc2, is_min_list)
+ {
+ char *resname = (char *) lfirst(lc1);
+ bool is_min = (bool) lfirst_int(lc2);
+ char *op_str = (is_min ? ">=" : "<=");
+
+ appendStringInfo(&recalc_cond, "%s OPERATOR(pg_catalog.%s) %s",
+ quote_qualified_identifier("mv", resname),
+ op_str,
+ quote_qualified_identifier("t", resname)
+ );
+
+ if (lnext(minmax_list, lc1))
+ appendStringInfo(&recalc_cond, " OR ");
+ }
+
+ return recalc_cond.data;
+}
+
+/*
+ * get_select_for_recalc_string
+ *
+ * Build a query to return tid and keys of tuples which need
+ * recalculation. This is used as the result of the query
+ * built by apply_old_delta.
+ */
+static char *
+get_select_for_recalc_string(List *keys)
+{
+ StringInfoData qry;
+ ListCell *lc;
+
+ initStringInfo(&qry);
+
+ appendStringInfo(&qry, "SELECT tid");
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ appendStringInfo(&qry, ", %s", NameStr(attr->attname));
+ }
+
+ appendStringInfo(&qry, " FROM updt WHERE recalc");
+
+ return qry.data;
+}
+
+/*
+ * recalc_and_set_values
+ *
+ * Recalculate tuples in a materialized from base tables and update these.
+ * The tuples which needs recalculation are specified by keys, and resnames
+ * of columns to be updated are specified by namelist. TIDs and key values
+ * are given by tuples in tuptable_recalc. Its first attribute must be TID
+ * and key values must be following this.
+ */
+static void
+recalc_and_set_values(SPITupleTable *tuptable_recalc, int64 num_tuples,
+ List *namelist, List *keys, Relation matviewRel)
+{
+ TupleDesc tupdesc_recalc = tuptable_recalc->tupdesc;
+ Oid *keyTypes = NULL, *types = NULL;
+ char *keyNulls = NULL, *nulls = NULL;
+ Datum *keyVals = NULL, *vals = NULL;
+ int num_vals = list_length(namelist);
+ int num_keys = list_length(keys);
+ uint64 i;
+ Oid matviewOid;
+ char *matviewname;
+
+ matviewOid = RelationGetRelid(matviewRel);
+ matviewname = quote_qualified_identifier(get_namespace_name(RelationGetNamespace(matviewRel)),
+ RelationGetRelationName(matviewRel));
+
+ /* If we have keys, initialize arrays for them. */
+ if (keys)
+ {
+ keyTypes = palloc(sizeof(Oid) * num_keys);
+ keyNulls = palloc(sizeof(char) * num_keys);
+ keyVals = palloc(sizeof(Datum) * num_keys);
+ /* a tuple contains keys to be recalculated and ctid to be updated*/
+ Assert(tupdesc_recalc->natts == num_keys + 1);
+
+ /* Types of key attributes */
+ for (i = 0; i < num_keys; i++)
+ keyTypes[i] = TupleDescAttr(tupdesc_recalc, i + 1)->atttypid;
+ }
+
+ /* allocate memory for all attribute names and tid */
+ types = palloc(sizeof(Oid) * (num_vals + 1));
+ nulls = palloc(sizeof(char) * (num_vals + 1));
+ vals = palloc(sizeof(Datum) * (num_vals + 1));
+
+ /* For each tuple which needs recalculation */
+ for (i = 0; i < num_tuples; i++)
+ {
+ int j;
+ bool isnull;
+ SPIPlanPtr plan;
+ SPITupleTable *tuptable_newvals;
+ TupleDesc tupdesc_newvals;
+
+ /* Set group key values as parameters if needed. */
+ if (keys)
+ {
+ for (j = 0; j < num_keys; j++)
+ {
+ keyVals[j] = SPI_getbinval(tuptable_recalc->vals[i], tupdesc_recalc, j + 2, &isnull);
+ if (isnull)
+ keyNulls[j] = 'n';
+ else
+ keyNulls[j] = ' ';
+ }
+ }
+
+ /*
+ * Get recalculated values from base tables. The result must be
+ * only one tuple thich contains the new values for specified keys.
+ */
+ plan = get_plan_for_recalc(matviewOid, namelist, keys, keyTypes);
+ if (SPI_execute_plan(plan, keyVals, keyNulls, false, 0) != SPI_OK_SELECT)
+ elog(ERROR, "SPI_execute_plan");
+ if (SPI_processed != 1)
+ elog(ERROR, "SPI_execute_plan returned zero or more than one rows");
+
+ tuptable_newvals = SPI_tuptable;
+ tupdesc_newvals = tuptable_newvals->tupdesc;
+
+ Assert(tupdesc_newvals->natts == num_vals);
+
+ /* Set the new values as parameters */
+ for (j = 0; j < tupdesc_newvals->natts; j++)
+ {
+ if (i == 0)
+ types[j] = TupleDescAttr(tupdesc_newvals, j)->atttypid;
+
+ vals[j] = SPI_getbinval(tuptable_newvals->vals[0], tupdesc_newvals, j + 1, &isnull);
+ if (isnull)
+ nulls[j] = 'n';
+ else
+ nulls[j] = ' ';
+ }
+ /* Set TID of the view tuple to be updated as a parameter */
+ types[j] = TIDOID;
+ vals[j] = SPI_getbinval(tuptable_recalc->vals[i], tupdesc_recalc, 1, &isnull);
+ nulls[j] = ' ';
+
+ /* Update the view tuple to the new values */
+ plan = get_plan_for_set_values(matviewOid, matviewname, namelist, types);
+ if (SPI_execute_plan(plan, vals, nulls, false, 0) != SPI_OK_UPDATE)
+ elog(ERROR, "SPI_execute_plan");
+ }
+}
+
+
+/*
+ * get_plan_for_recalc
+ *
+ * Create or fetch a plan for recalculating value in the view's target list
+ * from base tables using the definition query of materialized view specified
+ * by matviewOid. namelist is a list of resnames of values to be recalculated.
+ *
+ * keys is a list of keys to identify tuples to be recalculated if this is not
+ * empty. KeyTypes is an array of types of keys.
+ */
+static SPIPlanPtr
+get_plan_for_recalc(Oid matviewOid, List *namelist, List *keys, Oid *keyTypes)
+{
+ MV_QueryKey hash_key;
+ SPIPlanPtr plan;
+
+ /* Fetch or prepare a saved plan for the recalculation */
+ mv_BuildQueryKey(&hash_key, matviewOid, MV_PLAN_RECALC);
+ if ((plan = mv_FetchPreparedPlan(&hash_key)) == NULL)
+ {
+ ListCell *lc;
+ StringInfoData str;
+ char *viewdef;
+
+ /* get view definition of matview */
+ viewdef = text_to_cstring((text *) DatumGetPointer(
+ DirectFunctionCall1(pg_get_viewdef, ObjectIdGetDatum(matviewOid))));
+ /* get rid of trailing semi-colon */
+ viewdef[strlen(viewdef)-1] = '\0';
+
+ /*
+ * Build a query string for recalculating values. This is like
+ *
+ * SELECT x1, x2, x3, ... FROM ( ... view definition query ...) mv
+ * WHERE (key1, key2, ...) = ($1, $2, ...);
+ */
+
+ initStringInfo(&str);
+ appendStringInfo(&str, "SELECT ");
+ foreach (lc, namelist)
+ {
+ appendStringInfo(&str, "%s", (char *) lfirst(lc));
+ if (lnext(namelist, lc))
+ appendStringInfoString(&str, ", ");
+ }
+ appendStringInfo(&str, " FROM (%s) mv", viewdef);
+
+ if (keys)
+ {
+ int i = 1;
+ char paramname[16];
+
+ appendStringInfo(&str, " WHERE (");
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ Oid typid = attr->atttypid;
+
+ sprintf(paramname, "$%d", i);
+ appendStringInfo(&str, "(");
+ generate_equal(&str, typid, resname, paramname);
+ appendStringInfo(&str, " OR (%s IS NULL AND %s IS NULL))",
+ resname, paramname);
+
+ if (lnext(keys, lc))
+ appendStringInfoString(&str, " AND ");
+ i++;
+ }
+ appendStringInfo(&str, ")");
+ }
+ else
+ keyTypes = NULL;
+
+ plan = SPI_prepare(str.data, list_length(keys), keyTypes);
+ if (plan == NULL)
+ elog(ERROR, "SPI_prepare returned %s for %s", SPI_result_code_string(SPI_result), str.data);
+
+ SPI_keepplan(plan);
+ mv_HashPreparedPlan(&hash_key, plan);
+ }
+
+ return plan;
+}
+
+/*
+ * get_plan_for_set_values
+ *
+ * Create or fetch a plan for applying new values calculated by
+ * get_plan_for_recalc to a materialized view specified by matviewOid.
+ * matviewname is the name of the view. namelist is a list of resnames
+ * of attributes to be updated, and valTypes is an array of types of the
+ * values.
+ */
+static SPIPlanPtr
+get_plan_for_set_values(Oid matviewOid, char *matviewname, List *namelist,
+ Oid *valTypes)
+{
+ MV_QueryKey key;
+ SPIPlanPtr plan;
+
+ /* Fetch or prepare a saved plan for the real check */
+ mv_BuildQueryKey(&key, matviewOid, MV_PLAN_SET_VALUE);
+ if ((plan = mv_FetchPreparedPlan(&key)) == NULL)
+ {
+ ListCell *lc;
+ StringInfoData str;
+ int i;
+
+ /*
+ * Build a query string for applying min/max values. This is like
+ *
+ * UPDATE matviewname AS mv
+ * SET (x1, x2, x3, x4) = ($1, $2, $3, $4)
+ * WHERE ctid = $5;
+ */
+
+ initStringInfo(&str);
+ appendStringInfo(&str, "UPDATE %s AS mv SET (", matviewname);
+ foreach (lc, namelist)
+ {
+ appendStringInfo(&str, "%s", (char *) lfirst(lc));
+ if (lnext(namelist, lc))
+ appendStringInfoString(&str, ", ");
+ }
+ appendStringInfo(&str, ") = ROW(");
+
+ for (i = 1; i <= list_length(namelist); i++)
+ appendStringInfo(&str, "%s$%d", (i==1 ? "" : ", "), i);
+
+ appendStringInfo(&str, ") WHERE ctid OPERATOR(pg_catalog.=) $%d", i);
+
+ plan = SPI_prepare(str.data, list_length(namelist) + 1, valTypes);
+ if (plan == NULL)
+ elog(ERROR, "SPI_prepare returned %s for %s", SPI_result_code_string(SPI_result), str.data);
+
+ SPI_keepplan(plan);
+ mv_HashPreparedPlan(&key, plan);
+ }
+
+ return plan;
+}
+
/*
* generate_equals
*
@@ -2804,6 +3320,13 @@ mv_InitHashTables(void)
{
HASHCTL ctl;
+ memset(&ctl, 0, sizeof(ctl));
+ ctl.keysize = sizeof(MV_QueryKey);
+ ctl.entrysize = sizeof(MV_QueryHashEntry);
+ mv_query_cache = hash_create("MV query cache",
+ MV_INIT_QUERYHASHSIZE,
+ &ctl, HASH_ELEM | HASH_BLOBS);
+
memset(&ctl, 0, sizeof(ctl));
ctl.keysize = sizeof(Oid);
ctl.entrysize = sizeof(MV_TriggerHashEntry);
@@ -2812,6 +3335,109 @@ mv_InitHashTables(void)
&ctl, HASH_ELEM | HASH_BLOBS);
}
+/*
+ * mv_FetchPreparedPlan
+ */
+static SPIPlanPtr
+mv_FetchPreparedPlan(MV_QueryKey *key)
+{
+ MV_QueryHashEntry *entry;
+ SPIPlanPtr plan;
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_query_cache)
+ mv_InitHashTables();
+
+ /*
+ * Lookup for the key
+ */
+ entry = (MV_QueryHashEntry *) hash_search(mv_query_cache,
+ (void *) key,
+ HASH_FIND, NULL);
+ if (entry == NULL)
+ return NULL;
+
+ /*
+ * Check whether the plan is still valid. If it isn't, we don't want to
+ * simply rely on plancache.c to regenerate it; rather we should start
+ * from scratch and rebuild the query text too. This is to cover cases
+ * such as table/column renames. We depend on the plancache machinery to
+ * detect possible invalidations, though.
+ *
+ * CAUTION: this check is only trustworthy if the caller has already
+ * locked both materialized views and base tables.
+ *
+ * Also, check whether the search_path is still the same as when we made it.
+ * If it isn't, we need to rebuild the query text because the result of
+ * pg_ivm_get_viewdef() will change.
+ */
+ plan = entry->plan;
+ if (plan && SPI_plan_is_valid(plan) &&
+ SearchPathMatchesCurrentEnvironment(entry->search_path))
+ return plan;
+
+ /*
+ * Otherwise we might as well flush the cached plan now, to free a little
+ * memory space before we make a new one.
+ */
+ if (plan)
+ SPI_freeplan(plan);
+ if (entry->search_path)
+ pfree(entry->search_path);
+
+ entry->plan = NULL;
+ entry->search_path = NULL;
+
+ return NULL;
+}
+
+/*
+ * mv_HashPreparedPlan
+ *
+ * Add another plan to our private SPI query plan hashtable.
+ */
+static void
+mv_HashPreparedPlan(MV_QueryKey *key, SPIPlanPtr plan)
+{
+ MV_QueryHashEntry *entry;
+ bool found;
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_query_cache)
+ mv_InitHashTables();
+
+ /*
+ * Add the new plan. We might be overwriting an entry previously found
+ * invalid by mv_FetchPreparedPlan.
+ */
+ entry = (MV_QueryHashEntry *) hash_search(mv_query_cache,
+ (void *) key,
+ HASH_ENTER, &found);
+ Assert(!found || entry->plan == NULL);
+ entry->plan = plan;
+ entry->search_path = GetSearchPathMatcher(TopMemoryContext);
+}
+
+/*
+ * mv_BuildQueryKey
+ *
+ * Construct a hashtable key for a prepared SPI plan for IVM.
+ */
+static void
+mv_BuildQueryKey(MV_QueryKey *key, Oid matview_id, int32 query_type)
+{
+ /*
+ * We assume struct MV_QueryKey contains no padding bytes, else we'd need
+ * to use memset to clear them.
+ */
+ key->matview_id = matview_id;
+ key->query_type = query_type;
+}
+
/*
* AtAbort_IVM
*
--
2.25.1
v33-0008-Add-aggregates-support-in-IVM.patchtext/x-diff; name=v33-0008-Add-aggregates-support-in-IVM.patchDownload
From 46cb08f014cd88b0f132a308edfd717abf43419a Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 20:46:32 +0900
Subject: [PATCH v33 08/11] Add aggregates support in IVM
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit
count, sum, adn avg are supported.
As a restriction, expressions specified in GROUP BY must appear in
the target list because tuples to be updated in IMMV are identified
by using this group key. However, in the case of aggregates without
GROUP BY, there is only one tuple in the view, so keys are not uses
to identify tuples.
When creating a IMMV, in addition to __ivm_count column, some hidden
columns for each aggregate are added to the target list. For example,
names of these hidden columns are ivm_count_avg and ivm_sum_avg for
the average function, and so on.
When a base table is modified, the aggregated values and related
hidden columns are also updated as well as __ivm_count__. The
way of update depends the kind of aggregate function. Specifically,
sum and count are updated by simply adding or subtracting delta value
calculated from delta tables. avg is updated by using values of sum
and count stored in views as hidden columns and deltas calculated
from delta tables.
About aggregate functions except "count()" (sum and avg), NULLs in input
values are ignored, and the result of aggegate should be NULL when no
rows are selected. To support this specification, the numbers of non-NULL
input values are counted and stored in hidden columns. In the case of
count(), count(x) returns zero when no rows are selected, but count(*)
doesn't ignore NULL input.
---
src/backend/commands/createas.c | 265 +++++++++++++++++--
src/backend/commands/matview.c | 433 ++++++++++++++++++++++++++++++--
src/include/commands/createas.h | 1 +
3 files changed, 662 insertions(+), 37 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index 7138dd59ce..d8767137d9 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -51,13 +51,19 @@
#include "parser/parsetree.h"
#include "parser/parse_clause.h"
#include "parser/parse_func.h"
+#include "parser/parse_type.h"
#include "rewrite/rewriteHandler.h"
+#include "rewrite/rewriteManip.h"
+#include "storage/smgr.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
#include "utils/lsyscache.h"
+#include "utils/regproc.h"
+#include "utils/fmgroids.h"
#include "utils/rel.h"
#include "utils/rls.h"
#include "utils/snapmgr.h"
+#include "utils/syscache.h"
typedef struct
{
@@ -71,6 +77,11 @@ typedef struct
BulkInsertState bistate; /* bulk insert state */
} DR_intorel;
+typedef struct
+{
+ bool has_agg;
+} check_ivm_restriction_context;
+
/* utility functions for CTAS definition creation */
static ObjectAddress create_ctas_internal(List *attrList, IntoClause *into);
static ObjectAddress create_ctas_nodata(List *tlist, IntoClause *into);
@@ -85,8 +96,9 @@ static void CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid mat
Relids *relids, bool ex_lock);
static void CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock);
static void check_ivm_restriction(Node *node);
-static bool check_ivm_restriction_walker(Node *node, void *context);
+static bool check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context);
static Bitmapset *get_primary_key_attnos_from_query(Query *query, List **constraintList);
+static bool check_aggregate_supports_ivm(Oid aggfnoid);
/*
* create_ctas_internal
@@ -417,6 +429,7 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
* rewriteQueryForIMMV -- rewrite view definition query for IMMV
*
* count(*) is added for counting distinct tuples in views.
+ * Also, additional hidden columns are added for aggregate values.
*/
Query *
rewriteQueryForIMMV(Query *query, List *colNames)
@@ -430,16 +443,49 @@ rewriteQueryForIMMV(Query *query, List *colNames)
rewritten = copyObject(query);
pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
- /*
- * Convert DISTINCT to GROUP BY and add count(*) for counting distinct
- * tuples in views.
- */
- if (rewritten->distinctClause)
+ /* group keys must be in targetlist */
+ if (rewritten->groupClause)
{
- TargetEntry *tle;
+ ListCell *lc;
+ foreach(lc, rewritten->groupClause)
+ {
+ SortGroupClause *scl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(scl, rewritten->targetList);
+ if (tle->resjunk)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUP BY expression not appearing in select list is not supported on incrementally maintainable materialized view")));
+ }
+ }
+ /* Convert DISTINCT to GROUP BY. count(*) will be added afterward. */
+ else if (!rewritten->hasAggs && rewritten->distinctClause)
rewritten->groupClause = transformDistinctClause(NULL, &rewritten->targetList, rewritten->sortClause, false);
+ /* Add additional columns for aggregate values */
+ if (rewritten->hasAggs)
+ {
+ ListCell *lc;
+ List *aggs = NIL;
+ AttrNumber next_resno = list_length(rewritten->targetList) + 1;
+
+ foreach(lc, rewritten->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ char *resname = (colNames == NIL || foreach_current_index(lc) >= list_length(colNames) ?
+ tle->resname : strVal(list_nth(colNames, tle->resno - 1)));
+
+ if (IsA(tle->expr, Aggref))
+ makeIvmAggColumn(pstate, (Aggref *) tle->expr, resname, &next_resno, &aggs);
+ }
+ rewritten->targetList = list_concat(rewritten->targetList, aggs);
+ }
+
+ /* Add count(*) for counting distinct tuples in views */
+ if (rewritten->distinctClause || rewritten->hasAggs)
+ {
+ TargetEntry *tle;
+
fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
fn->agg_star = true;
@@ -456,6 +502,91 @@ rewriteQueryForIMMV(Query *query, List *colNames)
return rewritten;
}
+/*
+ * makeIvmAggColumn -- make additional aggregate columns for IVM
+ *
+ * For an aggregate column specified by aggref, additional aggregate columns
+ * are added, which are used to calculate the new aggregate value in IMMV.
+ * An additional aggregate columns has a name based on resname
+ * (ex. ivm_count_resname), and resno specified by next_resno. The created
+ * columns are returned to aggs, and the resno for the next column is also
+ * returned to next_resno.
+ *
+ * Currently, an additional count() is created for aggref other than count.
+ * In addition, sum() is created for avg aggregate column.
+ */
+void
+makeIvmAggColumn(ParseState *pstate, Aggref *aggref, char *resname, AttrNumber *next_resno, List **aggs)
+{
+ TargetEntry *tle_count;
+ Node *node;
+ FuncCall *fn;
+ Const *dmy_arg = makeConst(INT4OID,
+ -1,
+ InvalidOid,
+ sizeof(int32),
+ Int32GetDatum(1),
+ false,
+ true); /* pass by value */
+ const char *aggname = get_func_name(aggref->aggfnoid);
+
+ /*
+ * For aggregate functions except count, add count() func with the same arg parameters.
+ * This count result is used for determining if the aggregate value should be NULL or not.
+ * Also, add sum() func for avg because we need to calculate an average value as sum/count.
+ *
+ * XXX: If there are same expressions explicitly in the target list, we can use this instead
+ * of adding new duplicated one.
+ */
+ if (strcmp(aggname, "count") != 0)
+ {
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+
+ /* Make a Func with a dummy arg, and then override this by the original agg's args. */
+ node = ParseFuncOrColumn(pstate, fn->funcname, list_make1(dmy_arg), NULL, fn, false, -1);
+ ((Aggref *)node)->args = aggref->args;
+
+ tle_count = makeTargetEntry((Expr *) node,
+ *next_resno,
+ pstrdup(makeObjectName("__ivm_count",resname, "_")),
+ false);
+ *aggs = lappend(*aggs, tle_count);
+ (*next_resno)++;
+ }
+ if (strcmp(aggname, "avg") == 0)
+ {
+ List *dmy_args = NIL;
+ ListCell *lc;
+ foreach(lc, aggref->aggargtypes)
+ {
+ Oid typeid = lfirst_oid(lc);
+ Type type = typeidType(typeid);
+
+ Const *con = makeConst(typeid,
+ -1,
+ typeTypeCollation(type),
+ typeLen(type),
+ (Datum) 0,
+ true,
+ typeByVal(type));
+ dmy_args = lappend(dmy_args, con);
+ ReleaseSysCache(type);
+ }
+ fn = makeFuncCall(SystemFuncName("sum"), NIL, COERCE_EXPLICIT_CALL, -1);
+
+ /* Make a Func with dummy args, and then override this by the original agg's args. */
+ node = ParseFuncOrColumn(pstate, fn->funcname, dmy_args, NULL, fn, false, -1);
+ ((Aggref *)node)->args = aggref->args;
+
+ tle_count = makeTargetEntry((Expr *) node,
+ *next_resno,
+ pstrdup(makeObjectName("__ivm_sum",resname, "_")),
+ false);
+ *aggs = lappend(*aggs, tle_count);
+ (*next_resno)++;
+ }
+}
+
/*
* GetIntoRelEFlags --- compute executor flags needed for CREATE TABLE AS
*
@@ -939,11 +1070,13 @@ CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock
static void
check_ivm_restriction(Node *node)
{
- check_ivm_restriction_walker(node, NULL);
+ check_ivm_restriction_context context = {false};
+
+ check_ivm_restriction_walker(node, &context);
}
static bool
-check_ivm_restriction_walker(Node *node, void *context)
+check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context)
{
if (node == NULL)
return false;
@@ -972,6 +1105,10 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("CTE is not supported on incrementally maintainable materialized view")));
+ if (qry->groupClause != NIL && !qry->hasAggs)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUP BY clause without aggregate is not supported on incrementally maintainable materialized view")));
if (qry->havingQual != NULL)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
@@ -1024,6 +1161,8 @@ check_ivm_restriction_walker(Node *node, void *context)
}
}
+ context->has_agg |= qry->hasAggs;
+
/* restrictions for rtable */
foreach(lc, qry->rtable)
{
@@ -1072,7 +1211,7 @@ check_ivm_restriction_walker(Node *node, void *context)
}
- query_tree_walker(qry, check_ivm_restriction_walker, NULL, QTW_IGNORE_RANGE_TABLE);
+ query_tree_walker(qry, check_ivm_restriction_walker, (void *) context, QTW_IGNORE_RANGE_TABLE);
break;
}
@@ -1083,8 +1222,12 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("column name %s is not supported on incrementally maintainable materialized view", tle->resname)));
+ if (context->has_agg && !IsA(tle->expr, Aggref) && contain_aggs_of_level((Node *) tle->expr, 0))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("expression containing an aggregate in it is not supported on incrementally maintainable materialized view")));
- expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
break;
}
case T_JoinExpr:
@@ -1096,14 +1239,36 @@ check_ivm_restriction_walker(Node *node, void *context)
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("OUTER JOIN is not supported on incrementally maintainable materialized view")));
- expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
+ break;
}
- break;
case T_Aggref:
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("aggregate function is not supported on incrementally maintainable materialized view")));
- break;
+ {
+ /* Check if this supports IVM */
+ Aggref *aggref = (Aggref *) node;
+ const char *aggname = format_procedure(aggref->aggfnoid);
+
+ if (aggref->aggfilter != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with FILTER clause is not supported on incrementally maintainable materialized view")));
+
+ if (aggref->aggdistinct != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with DISTINCT arguments is not supported on incrementally maintainable materialized view")));
+
+ if (aggref->aggorder != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with ORDER clause is not supported on incrementally maintainable materialized view")));
+
+ if (!check_aggregate_supports_ivm(aggref->aggfnoid))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function %s is not supported on incrementally maintainable materialized view", aggname)));
+ break;
+ }
default:
expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
break;
@@ -1111,6 +1276,46 @@ check_ivm_restriction_walker(Node *node, void *context)
return false;
}
+/*
+ * check_aggregate_supports_ivm
+ *
+ * Check if the given aggregate function is supporting IVM
+ */
+static bool
+check_aggregate_supports_ivm(Oid aggfnoid)
+{
+ switch (aggfnoid)
+ {
+ /* count */
+ case F_COUNT_ANY:
+ case F_COUNT_:
+
+ /* sum */
+ case F_SUM_INT8:
+ case F_SUM_INT4:
+ case F_SUM_INT2:
+ case F_SUM_FLOAT4:
+ case F_SUM_FLOAT8:
+ case F_SUM_MONEY:
+ case F_SUM_INTERVAL:
+ case F_SUM_NUMERIC:
+
+ /* avg */
+ case F_AVG_INT8:
+ case F_AVG_INT4:
+ case F_AVG_INT2:
+ case F_AVG_NUMERIC:
+ case F_AVG_FLOAT4:
+ case F_AVG_FLOAT8:
+ case F_AVG_INTERVAL:
+
+ return true;
+
+ default:
+ return false;
+ }
+}
+
/*
* CreateIndexOnIMMV
*
@@ -1168,7 +1373,29 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
index->concurrent = false;
index->if_not_exists = false;
- if (query->distinctClause)
+ if (query->groupClause)
+ {
+ /* create unique constraint on GROUP BY expression columns */
+ foreach(lc, query->groupClause)
+ {
+ SortGroupClause *scl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(scl, query->targetList);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ else if (query->distinctClause)
{
/* create unique constraint on all columns */
foreach(lc, query->targetList)
@@ -1226,7 +1453,7 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
(errmsg("could not create an index on materialized view \"%s\" automatically",
RelationGetRelationName(matviewRel)),
errdetail("This target list does not have all the primary key columns, "
- "or this view does not contain DISTINCT clause."),
+ "or this view does not contain GROUP BY or DISTINCT clause."),
errhint("Create an index on the materialized view for efficient incremental maintenance.")));
return;
}
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index f2e8aa02a3..97406b28c9 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -27,6 +27,7 @@
#include "catalog/pg_trigger.h"
#include "catalog/pg_opclass.h"
#include "commands/cluster.h"
+#include "commands/defrem.h"
#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
@@ -36,6 +37,7 @@
#include "executor/tstoreReceiver.h"
#include "miscadmin.h"
#include "nodes/makefuncs.h"
+#include "optimizer/optimizer.h"
#include "parser/analyze.h"
#include "parser/parse_clause.h"
#include "parser/parse_func.h"
@@ -107,6 +109,13 @@ static HTAB *mv_trigger_info = NULL;
static bool in_delta_calculation = false;
+/* kind of IVM operation for the view */
+typedef enum
+{
+ IVM_ADD,
+ IVM_SUB
+} IvmOp;
+
/* ENR name for materialized view delta */
#define NEW_DELTA_ENRNAME "new_delta"
#define OLD_DELTA_ENRNAME "old_delta"
@@ -138,7 +147,7 @@ static RangeTblEntry *get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *tabl
QueryEnvironment *queryEnv, Oid matviewid);
static RangeTblEntry *replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
QueryEnvironment *queryEnv);
-static Query *rewrite_query_for_counting(Query *query, ParseState *pstate);
+static Query *rewrite_query_for_counting_and_aggregates(Query *query, ParseState *pstate);
static void calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
DestReceiver *dest_old, DestReceiver *dest_new,
@@ -149,14 +158,27 @@ static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *
static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
Query *query, bool use_count, char *count_colname);
+static void append_set_clause_for_count(const char *resname, StringInfo buf_old,
+ StringInfo buf_new,StringInfo aggs_list);
+static void append_set_clause_for_sum(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list);
+static void append_set_clause_for_avg(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ const char *aggtype);
+static char *get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
+ const char* count_col, const char *castType);
+static char *get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
+ const char* count_col);
static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
- List *keys, const char *count_colname);
+ List *keys, StringInfo aggs_list, StringInfo aggs_set,
+ const char *count_colname);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
- List *keys, StringInfo target_list, const char* count_colname);
+ List *keys, StringInfo target_list, StringInfo aggs_set,
+ const char* count_colname);
static char *get_matching_condition_string(List *keys);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
@@ -1452,11 +1474,44 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
* When a base table is truncated, the view content will be empty if the
* view definition query does not contain an aggregate without a GROUP clause.
* Therefore, such views can be truncated.
+ *
+ * Aggregate views without a GROUP clause always have one row. Therefore,
+ * if a base table is truncated, the view will not be empty and will contain
+ * a row with NULL value (or 0 for count()). So, in this case, we refresh the
+ * view instead of truncating it.
*/
if (TRIGGER_FIRED_BY_TRUNCATE(trigdata->tg_event))
{
- ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
- NIL, DROP_RESTRICT, false, false);
+ if (!(query->hasAggs && query->groupClause == NIL))
+ ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
+ NIL, DROP_RESTRICT, false, false);
+ else
+ {
+ Oid OIDNewHeap;
+ DestReceiver *dest;
+ uint64 processed = 0;
+ Query *dataQuery = rewriteQueryForIMMV(query, NIL);
+ char relpersistence = matviewRel->rd_rel->relpersistence;
+
+ /*
+ * Create the transient table that will receive the regenerated data. Lock
+ * it against access by any other process until commit (by which time it
+ * will be gone).
+ */
+ OIDNewHeap = make_new_heap(matviewOid, matviewRel->rd_rel->reltablespace,
+ matviewRel->rd_rel->relam,
+ relpersistence, ExclusiveLock);
+ LockRelationOid(OIDNewHeap, AccessExclusiveLock);
+ dest = CreateTransientRelDestReceiver(OIDNewHeap);
+
+ /* Generate the data */
+ processed = refresh_matview_datafill(dest, dataQuery, NULL, NULL, "");
+ refresh_by_heap_swap(matviewOid, OIDNewHeap, relpersistence);
+
+ /* Inform cumulative stats system about our activity */
+ pgstat_count_truncate(matviewRel);
+ pgstat_count_heap_insert(matviewRel, processed);
+ }
/* Clean up hash entry and delete tuplestores */
clean_up_IVM_hash_entry(entry, false);
@@ -1496,8 +1551,8 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
/* Set all tables in the query to pre-update state */
rewritten = rewrite_query_for_preupdate_state(rewritten, entry->tables,
pstate, matviewOid);
- /* Rewrite for counting duplicated tuples */
- rewritten = rewrite_query_for_counting(rewritten, pstate);
+ /* Rewrite for counting duplicated tuples and aggregates functions*/
+ rewritten = rewrite_query_for_counting_and_aggregates(rewritten, pstate);
/* Create tuplestores to store view deltas */
if (entry->has_old)
@@ -1548,7 +1603,7 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
count_colname = pstrdup("__ivm_count__");
- if (query->distinctClause)
+ if (query->hasAggs || query->distinctClause)
use_count = true;
/* calculate delta tables */
@@ -1944,17 +1999,34 @@ replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
}
/*
- * rewrite_query_for_counting
+ * rewrite_query_for_counting_and_aggregates
*
- * Rewrite query for counting duplicated tuples.
+ * Rewrite query for counting duplicated tuples and aggregate functions.
*/
static Query *
-rewrite_query_for_counting(Query *query, ParseState *pstate)
+rewrite_query_for_counting_and_aggregates(Query *query, ParseState *pstate)
{
TargetEntry *tle_count;
FuncCall *fn;
Node *node;
+ /* For aggregate views */
+ if (query->hasAggs)
+ {
+ ListCell *lc;
+ List *aggs = NIL;
+ AttrNumber next_resno = list_length(query->targetList) + 1;
+
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+
+ if (IsA(tle->expr, Aggref))
+ makeIvmAggColumn(pstate, (Aggref *)tle->expr, tle->resname, &next_resno, &aggs);
+ }
+ query->targetList = list_concat(query->targetList, aggs);
+ }
+
/* Add count(*) for counting distinct tuples in views */
fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
fn->agg_star = true;
@@ -2027,6 +2099,8 @@ rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte
return query;
}
+#define IVM_colname(type, col) makeObjectName("__ivm_" type, col, "_")
+
/*
* apply_delta
*
@@ -2040,6 +2114,9 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
{
StringInfoData querybuf;
StringInfoData target_list_buf;
+ StringInfo aggs_list_buf = NULL;
+ StringInfo aggs_set_old = NULL;
+ StringInfo aggs_set_new = NULL;
Relation matviewRel;
char *matviewname;
ListCell *lc;
@@ -2062,6 +2139,15 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
initStringInfo(&querybuf);
initStringInfo(&target_list_buf);
+ if (query->hasAggs)
+ {
+ if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
+ aggs_set_old = makeStringInfo();
+ if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
+ aggs_set_new = makeStringInfo();
+ aggs_list_buf = makeStringInfo();
+ }
+
/* build string of target list */
for (i = 0; i < matviewRel->rd_att->natts; i++)
{
@@ -2078,13 +2164,61 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
i++;
if (tle->resjunk)
continue;
- keys = lappend(keys, attr);
+ /*
+ * For views without aggregates, all attributes are used as keys to identify a
+ * tuple in a view.
+ */
+ if (!query->hasAggs)
+ keys = lappend(keys, attr);
+
+ /* For views with aggregates, we need to build SET clause for updating aggregate
+ * values. */
+ if (query->hasAggs && IsA(tle->expr, Aggref))
+ {
+ Aggref *aggref = (Aggref *) tle->expr;
+ const char *aggname = get_func_name(aggref->aggfnoid);
+
+ /*
+ * We can use function names here because it is already checked if these
+ * can be used in IMMV by its OID at the definition time.
+ */
+
+ /* count */
+ if (!strcmp(aggname, "count"))
+ append_set_clause_for_count(resname, aggs_set_old, aggs_set_new, aggs_list_buf);
+
+ /* sum */
+ else if (!strcmp(aggname, "sum"))
+ append_set_clause_for_sum(resname, aggs_set_old, aggs_set_new, aggs_list_buf);
+
+ /* avg */
+ else if (!strcmp(aggname, "avg"))
+ append_set_clause_for_avg(resname, aggs_set_old, aggs_set_new, aggs_list_buf,
+ format_type_be(aggref->aggtype));
+
+ else
+ elog(ERROR, "unsupported aggregate function: %s", aggname);
+ }
+ }
+
+ /* If we have GROUP BY clause, we use its entries as keys. */
+ if (query->hasAggs && query->groupClause)
+ {
+ foreach (lc, query->groupClause)
+ {
+ SortGroupClause *sgcl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(sgcl, query->targetList);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ keys = lappend(keys, attr);
+ }
}
/* Start maintaining the materialized view. */
@@ -2115,7 +2249,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (use_count)
/* apply old delta and get rows to be recalculated */
apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
- keys, count_colname);
+ keys, aggs_list_buf, aggs_set_old,
+ count_colname);
else
apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
@@ -2141,7 +2276,7 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
/* apply new delta */
if (use_count)
apply_new_delta_with_count(matviewname, NEW_DELTA_ENRNAME,
- keys, &target_list_buf, count_colname);
+ keys, aggs_set_new, &target_list_buf, count_colname);
else
apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
}
@@ -2156,6 +2291,250 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_finish failed");
}
+/*
+ * append_set_clause_for_count
+ *
+ * Append SET clause string for count aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_count(const char *resname, StringInfo buf_old,
+ StringInfo buf_new,StringInfo aggs_list)
+{
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* resname = mv.resname - t.resname */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, resname, "mv", "t", NULL, NULL));
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* resname = mv.resname + diff.resname */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, resname, "mv", "diff", NULL, NULL));
+ }
+
+ appendStringInfo(aggs_list, ", %s",
+ quote_qualified_identifier("diff", resname)
+ );
+}
+
+/*
+ * append_set_clause_for_sum
+ *
+ * Append SET clause string for sum aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_sum(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list)
+{
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* sum = mv.sum - t.sum */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, resname, "mv", "t", count_col, NULL)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* sum = mv.sum + diff.sum */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, resname, "mv", "diff", count_col, NULL)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
+/*
+ * append_set_clause_for_avg
+ *
+ * Append SET clause string for avg aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_avg(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ const char *aggtype)
+{
+ char *sum_col = IVM_colname("sum", resname);
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* avg = (mv.sum - t.sum)::aggtype / (mv.count - t.count) */
+ appendStringInfo(buf_old,
+ ", %s = %s OPERATOR(pg_catalog./) %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, sum_col, "mv", "t", count_col, aggtype),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ /* sum = mv.sum - t.sum */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, sum_col),
+ get_operation_string(IVM_SUB, sum_col, "mv", "t", count_col, NULL)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* avg = (mv.sum + diff.sum)::aggtype / (mv.count + diff.count) */
+ appendStringInfo(buf_new,
+ ", %s = %s OPERATOR(pg_catalog./) %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, sum_col, "mv", "diff", count_col, aggtype),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ /* sum = mv.sum + diff.sum */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, sum_col),
+ get_operation_string(IVM_ADD, sum_col, "mv", "diff", count_col, NULL)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("sum", resname)),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
+/*
+ * get_operation_string
+ *
+ * Build a string to calculate the new aggregate values.
+ */
+static char *
+get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
+ const char* count_col, const char *castType)
+{
+ StringInfoData buf;
+ StringInfoData castString;
+ char *col1 = quote_qualified_identifier(arg1, col);
+ char *col2 = quote_qualified_identifier(arg2, col);
+ char op_char = (op == IVM_SUB ? '-' : '+');
+
+ initStringInfo(&buf);
+ initStringInfo(&castString);
+
+ if (castType)
+ appendStringInfo(&castString, "::%s", castType);
+
+ if (!count_col)
+ {
+ /*
+ * If the attributes don't have count columns then calc the result
+ * by using the operator simply.
+ */
+ appendStringInfo(&buf, "(%s OPERATOR(pg_catalog.%c) %s)%s",
+ col1, op_char, col2, castString.data);
+ }
+ else
+ {
+ /*
+ * If the attributes have count columns then consider the condition
+ * where the result becomes NULL.
+ */
+ char *null_cond = get_null_condition_string(op, arg1, arg2, count_col);
+
+ appendStringInfo(&buf,
+ "(CASE WHEN %s THEN NULL "
+ "WHEN %s IS NULL THEN %s "
+ "WHEN %s IS NULL THEN %s "
+ "ELSE (%s OPERATOR(pg_catalog.%c) %s)%s END)",
+ null_cond,
+ col1, col2,
+ col2, col1,
+ col1, op_char, col2, castString.data
+ );
+ }
+
+ return buf.data;
+}
+
+/*
+ * get_null_condition_string
+ *
+ * Build a predicate string for CASE clause to check if an aggregate value
+ * will became NULL after the given operation is applied.
+ */
+static char *
+get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
+ const char* count_col)
+{
+ StringInfoData null_cond;
+ initStringInfo(&null_cond);
+
+ switch (op)
+ {
+ case IVM_ADD:
+ appendStringInfo(&null_cond,
+ "%s OPERATOR(pg_catalog.=) 0 AND %s OPERATOR(pg_catalog.=) 0",
+ quote_qualified_identifier(arg1, count_col),
+ quote_qualified_identifier(arg2, count_col)
+ );
+ break;
+ case IVM_SUB:
+ appendStringInfo(&null_cond,
+ "%s OPERATOR(pg_catalog.=) %s",
+ quote_qualified_identifier(arg1, count_col),
+ quote_qualified_identifier(arg2, count_col)
+ );
+ break;
+ default:
+ elog(ERROR,"unknown operation");
+ }
+
+ return null_cond.data;
+}
+
+
/*
* apply_old_delta_with_count
*
@@ -2163,13 +2542,20 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
* which contains tuples to be deleted from to a materialized view given by
* matviewname. This is used when counting is required, that is, the view
* has aggregate or distinct.
+ *
+ * If the view desn't have aggregates or has GROUP BY, this requires a keys
+ * list to identify a tuple in the view. If the view has aggregates, this
+ * requires strings representing resnames of aggregates and SET clause for
+ * updating aggregate values.
*/
static void
apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
- List *keys, const char *count_colname)
+ List *keys, StringInfo aggs_list, StringInfo aggs_set,
+ const char *count_colname)
{
StringInfoData querybuf;
char *match_cond;
+ bool agg_without_groupby = (list_length(keys) == 0);
/* build WHERE condition for searching tuples to be deleted */
match_cond = get_matching_condition_string(keys);
@@ -2179,22 +2565,26 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
appendStringInfo(&querybuf,
"WITH t AS (" /* collecting tid of target tuples in the view */
"SELECT diff.%s, " /* count column */
- "(diff.%s OPERATOR(pg_catalog.=) mv.%s) AS for_dlt, "
+ "(diff.%s OPERATOR(pg_catalog.=) mv.%s AND %s) AS for_dlt, "
"mv.ctid "
+ "%s " /* aggregate columns */
"FROM %s AS mv, %s AS diff "
"WHERE %s" /* tuple matching condition */
"), updt AS (" /* update a tuple if this is not to be deleted */
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
+ "%s" /* SET clauses for aggregates */
"FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
")"
/* delete a tuple if this is to be deleted */
"DELETE FROM %s AS mv USING t "
"WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
count_colname,
- count_colname, count_colname,
+ count_colname, count_colname, (agg_without_groupby ? "false" : "true"),
+ (aggs_list != NULL ? aggs_list->data : ""),
matviewname, deltaname_old,
match_cond,
matviewname, count_colname, count_colname, count_colname,
+ (aggs_set != NULL ? aggs_set->data : ""),
matviewname);
if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
@@ -2258,10 +2648,15 @@ apply_old_delta(const char *matviewname, const char *deltaname_old,
* matviewname. This is used when counting is required, that is, the view
* has aggregate or distinct. Also, when a table in EXISTS sub queries
* is modified.
+ *
+ * If the view desn't have aggregates or has GROUP BY, this requires a keys
+ * list to identify a tuple in the view. If the view has aggregates, this
+ * requires strings representing SET clause for updating aggregate values.
*/
static void
apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
- List *keys, StringInfo target_list, const char* count_colname)
+ List *keys, StringInfo aggs_set, StringInfo target_list,
+ const char* count_colname)
{
StringInfoData querybuf;
StringInfoData returning_keys;
@@ -2292,6 +2687,7 @@ apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
appendStringInfo(&querybuf,
"WITH updt AS (" /* update a tuple if this exists in the view */
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.+) diff.%s "
+ "%s " /* SET clauses for aggregates */
"FROM %s AS diff "
"WHERE %s " /* tuple matching condition */
"RETURNING %s" /* returning keys of updated tuples */
@@ -2299,6 +2695,7 @@ apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
"SELECT %s FROM %s AS diff "
"WHERE NOT EXISTS (SELECT 1 FROM updt AS mv WHERE %s);",
matviewname, count_colname, count_colname, count_colname,
+ (aggs_set != NULL ? aggs_set->data : ""),
deltaname_new,
match_cond,
returning_keys.data,
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 6b47e66bfd..af3a5b4b27 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -30,6 +30,7 @@ extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
extern Query *rewriteQueryForIMMV(Query *query, List *colNames);
+extern void makeIvmAggColumn(ParseState *pstate, Aggref *aggref, char *resname, AttrNumber *next_resno, List **aggs);
extern int GetIntoRelEFlags(IntoClause *intoClause);
--
2.25.1
v33-0007-Add-DISTINCT-support-for-IVM.patchtext/x-diff; name=v33-0007-Add-DISTINCT-support-for-IVM.patchDownload
From cf89f48f2f2cf5029f57a7b56cc0287b44aa4e39 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 19:08:51 +0900
Subject: [PATCH v33 07/11] Add DISTINCT support for IVM
When IMMV is created with DISTINCT, multiplicity of tuples is
counted and stored in "__ivm_count__" column, which is a hidden
column of IMMV. The value in __ivm_count__ is updated when IMMV
is maintained incrementally. A tuple in IMMV can be removed if
and only if the count becomes zero.
---
src/backend/commands/createas.c | 141 ++++++++++++++++++++------
src/backend/commands/indexcmds.c | 40 ++++++++
src/backend/commands/matview.c | 148 ++++++++++++++++++++++++++--
src/backend/commands/tablecmds.c | 9 ++
src/backend/nodes/outfuncs.c | 1 +
src/backend/nodes/readfuncs.c | 1 +
src/backend/parser/parse_relation.c | 18 +++-
src/backend/rewrite/rewriteDefine.c | 3 +-
src/include/commands/createas.h | 2 +
src/include/nodes/parsenodes.h | 2 +
10 files changed, 320 insertions(+), 45 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index a424abbd32..7138dd59ce 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -50,6 +50,7 @@
#include "parser/parser.h"
#include "parser/parsetree.h"
#include "parser/parse_clause.h"
+#include "parser/parse_func.h"
#include "rewrite/rewriteHandler.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
@@ -305,6 +306,9 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
errhint("functions must be marked IMMUTABLE")));
check_ivm_restriction((Node *) query);
+
+ /* For IMMV, we need to rewrite matview query */
+ query = rewriteQueryForIMMV(query, into->colNames);
}
if (into->skipData)
@@ -409,6 +413,49 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
return address;
}
+/*
+ * rewriteQueryForIMMV -- rewrite view definition query for IMMV
+ *
+ * count(*) is added for counting distinct tuples in views.
+ */
+Query *
+rewriteQueryForIMMV(Query *query, List *colNames)
+{
+ Query *rewritten;
+
+ Node *node;
+ ParseState *pstate = make_parsestate(NULL);
+ FuncCall *fn;
+
+ rewritten = copyObject(query);
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ /*
+ * Convert DISTINCT to GROUP BY and add count(*) for counting distinct
+ * tuples in views.
+ */
+ if (rewritten->distinctClause)
+ {
+ TargetEntry *tle;
+
+ rewritten->groupClause = transformDistinctClause(NULL, &rewritten->targetList, rewritten->sortClause, false);
+
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+ fn->agg_star = true;
+
+ node = ParseFuncOrColumn(pstate, fn->funcname, NIL, NULL, fn, false, -1);
+
+ tle = makeTargetEntry((Expr *) node,
+ list_length(rewritten->targetList) + 1,
+ pstrdup("__ivm_count__"),
+ false);
+ rewritten->targetList = lappend(rewritten->targetList, tle);
+ rewritten->hasAggs = true;
+ }
+
+ return rewritten;
+}
+
/*
* GetIntoRelEFlags --- compute executor flags needed for CREATE TABLE AS
*
@@ -532,7 +579,8 @@ intorel_startup(DestReceiver *self, int operation, TupleDesc typeinfo)
ColumnDef *col;
char *colname;
- if (lc)
+ /* Don't override hidden columns added for IVM */
+ if (lc && !isIvmName(NameStr(attribute->attname)))
{
colname = strVal(lfirst(lc));
lc = lnext(into->colNames, lc);
@@ -936,10 +984,6 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view")));
- if (qry->distinctClause)
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("DISTINCT is not supported on incrementally maintainable materialized view")));
if (qry->hasDistinctOn)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
@@ -1086,12 +1130,18 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
char idxname[NAMEDATALEN];
List *indexoidlist = RelationGetIndexList(matviewRel);
ListCell *indexoidscan;
- Bitmapset *key_attnos;
snprintf(idxname, sizeof(idxname), "%s_index", RelationGetRelationName(matviewRel));
index = makeNode(IndexStmt);
+ /*
+ * We consider null values not distinct to make sure that views with DISTINCT
+ * or GROUP BY don't contain multiple NULL rows when NULL is inserted to
+ * a base table concurrently.
+ */
+ index->nulls_not_distinct = true;
+
index->unique = true;
index->primary = false;
index->isconstraint = false;
@@ -1118,41 +1168,68 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
index->concurrent = false;
index->if_not_exists = false;
- /* create index on the base tables' primary key columns */
- key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
- if (key_attnos)
+ if (query->distinctClause)
{
+ /* create unique constraint on all columns */
foreach(lc, query->targetList)
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
-
- if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
- {
- IndexElem *iparam;
-
- iparam = makeNode(IndexElem);
- iparam->name = pstrdup(NameStr(attr->attname));
- iparam->expr = NULL;
- iparam->indexcolname = NULL;
- iparam->collation = NIL;
- iparam->opclass = NIL;
- iparam->opclassopts = NIL;
- iparam->ordering = SORTBY_DEFAULT;
- iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
- index->indexParams = lappend(index->indexParams, iparam);
- }
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
}
}
else
{
- /* create no index, just notice that an appropriate index is necessary for efficient IVM */
- ereport(NOTICE,
- (errmsg("could not create an index on materialized view \"%s\" automatically",
- RelationGetRelationName(matviewRel)),
- errdetail("This target list does not have all the primary key columns. "),
- errhint("Create an index on the materialized view for efficient incremental maintenance.")));
- return;
+ Bitmapset *key_attnos;
+
+ /* create index on the base tables' primary key columns */
+ key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
+ if (key_attnos)
+ {
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ }
+ else
+ {
+ /* create no index, just notice that an appropriate index is necessary for efficient IVM */
+ ereport(NOTICE,
+ (errmsg("could not create an index on materialized view \"%s\" automatically",
+ RelationGetRelationName(matviewRel)),
+ errdetail("This target list does not have all the primary key columns, "
+ "or this view does not contain DISTINCT clause."),
+ errhint("Create an index on the materialized view for efficient incremental maintenance.")));
+ return;
+ }
}
/* If we have a compatible index, we don't need to create another. */
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index 2caab88aa5..462c15f9c8 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -40,6 +40,7 @@
#include "commands/dbcommands.h"
#include "commands/defrem.h"
#include "commands/event_trigger.h"
+#include "commands/matview.h"
#include "commands/progress.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
@@ -1120,6 +1121,45 @@ DefineIndex(Oid tableId,
safe_index = indexInfo->ii_Expressions == NIL &&
indexInfo->ii_Predicate == NIL;
+ /*
+ * We disallow unique indexes on IVM columns of IMMVs.
+ */
+ if (RelationIsIVM(rel) && stmt->unique)
+ {
+ for (int i = 0; i < indexInfo->ii_NumIndexKeyAttrs; i++)
+ {
+ AttrNumber attno = indexInfo->ii_IndexAttrNumbers[i];
+ if (attno > 0)
+ {
+ char *name = NameStr(TupleDescAttr(rel->rd_att, attno - 1)->attname);
+ if (name && isIvmName(name))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("unique index creation on IVM columns is not supported")));
+ }
+ }
+
+ if (indexInfo->ii_Expressions)
+ {
+ Bitmapset *indexattrs = NULL;
+ int varno = -1;
+
+ pull_varattnos((Node *) indexInfo->ii_Expressions, 1, &indexattrs);
+
+ while ((varno = bms_next_member(indexattrs, varno)) >= 0)
+ {
+ int attno = varno + FirstLowInvalidHeapAttributeNumber;
+ char *name = NameStr(TupleDescAttr(rel->rd_att, attno - 1)->attname);
+ if (name && isIvmName(name))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("unique index creation on IVM columns is not supported")));
+ }
+
+ }
+ }
+
+
/*
* Report index creation if appropriate (delay this till after most of the
* error checks)
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index 1061c37b2c..f2e8aa02a3 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -148,11 +148,15 @@ static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *
static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
- Query *query);
+ Query *query, bool use_count, char *count_colname);
static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
+static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
+ List *keys, const char *count_colname);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
+static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
+ List *keys, StringInfo target_list, const char* count_colname);
static char *get_matching_condition_string(List *keys);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
@@ -267,6 +271,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
Oid matviewOid;
Relation matviewRel;
Query *dataQuery;
+ Query *viewQuery;
Oid tableSpace;
Oid relowner;
Oid OIDNewHeap;
@@ -329,8 +334,13 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
"CONCURRENTLY", "WITH NO DATA")));
- dataQuery = get_matview_query(matviewRel);
+ viewQuery = get_matview_query(matviewRel);
+ /* For IMMV, we need to rewrite matview query */
+ if (!stmt->skipData && RelationIsIVM(matviewRel))
+ dataQuery = rewriteQueryForIMMV(viewQuery,NIL);
+ else
+ dataQuery = viewQuery;
/*
* Check that there is a unique index with no WHERE clause on one or more
@@ -510,8 +520,8 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
if (!stmt->skipData && RelationIsIVM(matviewRel) && !oldPopulated)
{
- CreateIndexOnIMMV(dataQuery, matviewRel);
- CreateIvmTriggersOnBaseTables(dataQuery, matviewOid);
+ CreateIndexOnIMMV(viewQuery, matviewRel);
+ CreateIvmTriggersOnBaseTables(viewQuery, matviewOid);
}
table_close(matviewRel, NoLock);
@@ -1533,6 +1543,13 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
int rte_index = lfirst_int(lc2);
TupleDesc tupdesc_old;
TupleDesc tupdesc_new;
+ bool use_count = false;
+ char *count_colname = NULL;
+
+ count_colname = pstrdup("__ivm_count__");
+
+ if (query->distinctClause)
+ use_count = true;
/* calculate delta tables */
calc_delta(table, rte_index, rewritten, dest_old, dest_new,
@@ -1545,7 +1562,8 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
{
/* apply the delta tables to the materialized view */
apply_delta(matviewOid, old_tuplestore, new_tuplestore,
- tupdesc_old, tupdesc_new, query);
+ tupdesc_old, tupdesc_new, query, use_count,
+ count_colname);
}
PG_CATCH();
{
@@ -2018,7 +2036,7 @@ rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte
static void
apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
- Query *query)
+ Query *query, bool use_count, char *count_colname)
{
StringInfoData querybuf;
StringInfoData target_list_buf;
@@ -2094,7 +2112,12 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (rc != SPI_OK_REL_REGISTER)
elog(ERROR, "SPI_register failed");
- apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+ if (use_count)
+ /* apply old delta and get rows to be recalculated */
+ apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
+ keys, count_colname);
+ else
+ apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
}
/* For tuple insertion */
@@ -2116,7 +2139,11 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_register failed");
/* apply new delta */
- apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
+ if (use_count)
+ apply_new_delta_with_count(matviewname, NEW_DELTA_ENRNAME,
+ keys, &target_list_buf, count_colname);
+ else
+ apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
}
/* We're done maintaining the materialized view. */
@@ -2129,6 +2156,51 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_finish failed");
}
+/*
+ * apply_old_delta_with_count
+ *
+ * Execute a query for applying a delta table given by deltname_old
+ * which contains tuples to be deleted from to a materialized view given by
+ * matviewname. This is used when counting is required, that is, the view
+ * has aggregate or distinct.
+ */
+static void
+apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
+ List *keys, const char *count_colname)
+{
+ StringInfoData querybuf;
+ char *match_cond;
+
+ /* build WHERE condition for searching tuples to be deleted */
+ match_cond = get_matching_condition_string(keys);
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "WITH t AS (" /* collecting tid of target tuples in the view */
+ "SELECT diff.%s, " /* count column */
+ "(diff.%s OPERATOR(pg_catalog.=) mv.%s) AS for_dlt, "
+ "mv.ctid "
+ "FROM %s AS mv, %s AS diff "
+ "WHERE %s" /* tuple matching condition */
+ "), updt AS (" /* update a tuple if this is not to be deleted */
+ "UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
+ "FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
+ ")"
+ /* delete a tuple if this is to be deleted */
+ "DELETE FROM %s AS mv USING t "
+ "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
+ count_colname,
+ count_colname, count_colname,
+ matviewname, deltaname_old,
+ match_cond,
+ matviewname, count_colname, count_colname, count_colname,
+ matviewname);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
/*
* apply_old_delta
*
@@ -2178,6 +2250,66 @@ apply_old_delta(const char *matviewname, const char *deltaname_old,
elog(ERROR, "SPI_exec failed: %s", querybuf.data);
}
+/*
+ * apply_new_delta_with_count
+ *
+ * Execute a query for applying a delta table given by deltname_new
+ * which contains tuples to be inserted into a materialized view given by
+ * matviewname. This is used when counting is required, that is, the view
+ * has aggregate or distinct. Also, when a table in EXISTS sub queries
+ * is modified.
+ */
+static void
+apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
+ List *keys, StringInfo target_list, const char* count_colname)
+{
+ StringInfoData querybuf;
+ StringInfoData returning_keys;
+ ListCell *lc;
+ char *match_cond = "";
+
+ /* build WHERE condition for searching tuples to be updated */
+ match_cond = get_matching_condition_string(keys);
+
+ /* build string of keys list */
+ initStringInfo(&returning_keys);
+ if (keys)
+ {
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&returning_keys, "%s", quote_qualified_identifier("mv", resname));
+ if (lnext(keys, lc))
+ appendStringInfo(&returning_keys, ", ");
+ }
+ }
+ else
+ appendStringInfo(&returning_keys, "NULL");
+
+ /* Search for matching tuples from the view and update if found or insert if not. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "WITH updt AS (" /* update a tuple if this exists in the view */
+ "UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.+) diff.%s "
+ "FROM %s AS diff "
+ "WHERE %s " /* tuple matching condition */
+ "RETURNING %s" /* returning keys of updated tuples */
+ ") INSERT INTO %s (%s) " /* insert a new tuple if this doesn't exist */
+ "SELECT %s FROM %s AS diff "
+ "WHERE NOT EXISTS (SELECT 1 FROM updt AS mv WHERE %s);",
+ matviewname, count_colname, count_colname, count_colname,
+ deltaname_new,
+ match_cond,
+ returning_keys.data,
+ matviewname, target_list->data,
+ target_list->data, deltaname_new,
+ match_cond);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_INSERT)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
/*
* apply_new_delta
*
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index 9e9dc5c2c1..ddb0732542 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -57,6 +57,7 @@
#include "commands/cluster.h"
#include "commands/comment.h"
#include "commands/defrem.h"
+#include "commands/matview.h"
#include "commands/event_trigger.h"
#include "commands/sequence.h"
#include "commands/tablecmds.h"
@@ -3696,6 +3697,14 @@ renameatt_internal(Oid myrelid,
targetrelation = relation_open(myrelid, AccessExclusiveLock);
renameatt_check(myrelid, RelationGetForm(targetrelation), recursing);
+ /*
+ * Don't rename IVM columns.
+ */
+ if (RelationIsIVM(targetrelation) && isIvmName(oldattname))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("IVM column can not be renamed")));
+
/*
* if the 'recurse' flag is set then we are supposed to rename this
* attribute in all classes that inherit from 'relname' (as well as in
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 3337b77ae6..c191f70a6f 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -510,6 +510,7 @@ _outRangeTblEntry(StringInfo str, const RangeTblEntry *node)
WRITE_INT_FIELD(rellockmode);
WRITE_UINT_FIELD(perminfoindex);
WRITE_NODE_FIELD(tablesample);
+ WRITE_BOOL_FIELD(relisivm);
break;
case RTE_SUBQUERY:
WRITE_NODE_FIELD(subquery);
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index c4d01a441a..ffcab8cda2 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -361,6 +361,7 @@ _readRangeTblEntry(void)
READ_INT_FIELD(rellockmode);
READ_UINT_FIELD(perminfoindex);
READ_NODE_FIELD(tablesample);
+ READ_BOOL_FIELD(relisivm);
break;
case RTE_SUBQUERY:
READ_NODE_FIELD(subquery);
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index 2f64eaf0e3..a39358f125 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -36,6 +36,7 @@
#include "utils/rel.h"
#include "utils/syscache.h"
#include "utils/varlena.h"
+#include "commands/matview.h"
/*
@@ -97,7 +98,7 @@ static void expandTupleDesc(TupleDesc tupdesc, Alias *eref,
int count, int offset,
int rtindex, int sublevels_up,
int location, bool include_dropped,
- List **colnames, List **colvars);
+ List **colnames, List **colvars, bool is_ivm);
static int specialAttNum(const char *attname);
static bool rte_visible_if_lateral(ParseState *pstate, RangeTblEntry *rte);
static bool rte_visible_if_qualified(ParseState *pstate, RangeTblEntry *rte);
@@ -1503,6 +1504,7 @@ addRangeTableEntry(ParseState *pstate,
rte->inh = inh;
rte->relkind = rel->rd_rel->relkind;
rte->rellockmode = lockmode;
+ rte->relisivm = rel->rd_rel->relisivm;
/*
* Build the list of effective column names using user-supplied aliases
@@ -1588,6 +1590,7 @@ addRangeTableEntryForRelation(ParseState *pstate,
rte->inh = inh;
rte->relkind = rel->rd_rel->relkind;
rte->rellockmode = lockmode;
+ rte->relisivm = rel->rd_rel->relisivm;
/*
* Build the list of effective column names using user-supplied aliases
@@ -2757,7 +2760,7 @@ expandRTE(RangeTblEntry *rte, int rtindex, int sublevels_up,
expandTupleDesc(tupdesc, rte->eref,
rtfunc->funccolcount, atts_done,
rtindex, sublevels_up, location,
- include_dropped, colnames, colvars);
+ include_dropped, colnames, colvars, false);
}
else if (functypclass == TYPEFUNC_SCALAR)
{
@@ -3025,7 +3028,7 @@ expandRelation(Oid relid, Alias *eref, int rtindex, int sublevels_up,
expandTupleDesc(rel->rd_att, eref, rel->rd_att->natts, 0,
rtindex, sublevels_up,
location, include_dropped,
- colnames, colvars);
+ colnames, colvars, RelationIsIVM(rel));
relation_close(rel, AccessShareLock);
}
@@ -3042,7 +3045,7 @@ static void
expandTupleDesc(TupleDesc tupdesc, Alias *eref, int count, int offset,
int rtindex, int sublevels_up,
int location, bool include_dropped,
- List **colnames, List **colvars)
+ List **colnames, List **colvars, bool is_ivm)
{
ListCell *aliascell;
int varattno;
@@ -3055,6 +3058,9 @@ expandTupleDesc(TupleDesc tupdesc, Alias *eref, int count, int offset,
{
Form_pg_attribute attr = TupleDescAttr(tupdesc, varattno);
+ if (is_ivm && isIvmName(NameStr(attr->attname)) && !MatViewIncrementalMaintenanceIsEnabled())
+ continue;
+
if (attr->attisdropped)
{
if (include_dropped)
@@ -3217,6 +3223,10 @@ expandNSItemAttrs(ParseState *pstate, ParseNamespaceItem *nsitem,
Var *varnode = (Var *) lfirst(var);
TargetEntry *te;
+ /* if transform * into columnlist with IMMV, remove IVM columns */
+ if (rte->relisivm && isIvmName(label) && !MatViewIncrementalMaintenanceIsEnabled())
+ continue;
+
te = makeTargetEntry((Expr *) varnode,
(AttrNumber) pstate->p_next_resno++,
label,
diff --git a/src/backend/rewrite/rewriteDefine.c b/src/backend/rewrite/rewriteDefine.c
index 6cc9a8d8bf..5d22dbcfcf 100644
--- a/src/backend/rewrite/rewriteDefine.c
+++ b/src/backend/rewrite/rewriteDefine.c
@@ -614,7 +614,8 @@ checkRuleResultList(List *targetList, TupleDesc resultDesc, bool isSelect,
attr->atttypmod))));
}
- if (i != resultDesc->natts)
+ /* No check for materialized views since this could have special columns for IVM */
+ if ((!isSelect || requireColumnNameMatch) && i != resultDesc->natts)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
isSelect ?
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 396ad1bb4c..6b47e66bfd 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -29,6 +29,8 @@ extern ObjectAddress ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *st
extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
+extern Query *rewriteQueryForIMMV(Query *query, List *colNames);
+
extern int GetIntoRelEFlags(IntoClause *intoClause);
extern DestReceiver *CreateIntoRelDestReceiver(IntoClause *intoClause);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 85a62b538e..1366946bb4 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1106,6 +1106,8 @@ typedef struct RangeTblEntry
Index perminfoindex pg_node_attr(query_jumble_ignore);
/* sampling info, or NULL */
struct TableSampleClause *tablesample;
+ /* incrementally maintainable materialized view? */
+ bool relisivm;
/*
* Fields valid for a subquery RTE (else NULL):
--
2.25.1
v33-0006-Add-Incremental-View-Maintenance-support.patchtext/x-diff; name=v33-0006-Add-Incremental-View-Maintenance-support.patchDownload
From 23020a22722fc8f67f5aa1df76e36276731a9c94 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 18:59:50 +0900
Subject: [PATCH v33 06/11] Add Incremental View Maintenance support
In this implementation, AFTER triggers are used to collect
tuplestores containing transition table contents. When multiple tables
are changed, multiple AFTER triggers are invoked, then the final AFTER
trigger performs actual update of the matview. In addition, BEFORE
triggers are also used to handle global information for view
maintenance.
To calculate view deltas, we need both pre-state and post-state of base
tables. Post-update states are available in AFTER trigger, and pre-update
states can be calculated by removing inserted tuples and appending deleted
tuples. Insterted tuples are filtered using the snapshot taken before
table modiication, and deleted tuples are contained in the old transition
table.
Incrementally Maintainable Materialized Views (IMMV) can contain
duplicated tuples.
This patch also allows self-join, simultaneous updates of more than
one base table, and multiple updates of the same base table.
---
src/backend/access/transam/xact.c | 5 +
src/backend/commands/createas.c | 681 +++++++++++++
src/backend/commands/matview.c | 1468 ++++++++++++++++++++++++++++-
src/include/catalog/pg_proc.dat | 10 +
src/include/commands/createas.h | 4 +
src/include/commands/matview.h | 9 +
6 files changed, 2142 insertions(+), 35 deletions(-)
diff --git a/src/backend/access/transam/xact.c b/src/backend/access/transam/xact.c
index d119ab909d..5ea088f954 100644
--- a/src/backend/access/transam/xact.c
+++ b/src/backend/access/transam/xact.c
@@ -36,6 +36,7 @@
#include "catalog/pg_enum.h"
#include "catalog/storage.h"
#include "commands/async.h"
+#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/trigger.h"
#include "common/pg_prng.h"
@@ -2898,6 +2899,7 @@ AbortTransaction(void)
AtAbort_Notify();
AtEOXact_RelationMap(false, is_parallel_worker);
AtAbort_Twophase();
+ AtAbort_IVM();
/*
* Advertise the fact that we aborted in pg_xact (assuming that we got as
@@ -5228,6 +5230,9 @@ AbortSubTransaction(void)
pgstat_progress_end_command();
UnlockBuffers();
+ /* Clean up hash entries for incremental view maintenance */
+ AtAbort_IVM();
+
/* Reset WAL record construction state */
XLogResetInsertion();
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index 62050f4dc5..a424abbd32 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -29,15 +29,27 @@
#include "access/tableam.h"
#include "access/xact.h"
#include "catalog/namespace.h"
+#include "catalog/index.h"
+#include "catalog/pg_constraint.h"
+#include "catalog/pg_inherits.h"
+#include "catalog/pg_trigger.h"
#include "catalog/toasting.h"
#include "commands/createas.h"
+#include "commands/defrem.h"
#include "commands/matview.h"
#include "commands/prepare.h"
#include "commands/tablecmds.h"
+#include "commands/tablespace.h"
+#include "commands/trigger.h"
#include "commands/view.h"
#include "miscadmin.h"
+#include "optimizer/optimizer.h"
+#include "optimizer/prep.h"
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
+#include "parser/parser.h"
+#include "parser/parsetree.h"
+#include "parser/parse_clause.h"
#include "rewrite/rewriteHandler.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
@@ -68,6 +80,12 @@ static bool intorel_receive(TupleTableSlot *slot, DestReceiver *self);
static void intorel_shutdown(DestReceiver *self);
static void intorel_destroy(DestReceiver *self);
+static void CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid matviewOid,
+ Relids *relids, bool ex_lock);
+static void CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock);
+static void check_ivm_restriction(Node *node);
+static bool check_ivm_restriction_walker(Node *node, void *context);
+static Bitmapset *get_primary_key_attnos_from_query(Query *query, List **constraintList);
/*
* create_ctas_internal
@@ -277,6 +295,18 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
save_nestlevel = NewGUCNestLevel();
}
+ if (is_matview && into->ivm)
+ {
+ /* check if the query is supported in IMMV definition */
+ if (contain_mutable_functions((Node *) query))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("mutable function is not supported on incrementally maintainable materialized view"),
+ errhint("functions must be marked IMMUTABLE")));
+
+ check_ivm_restriction((Node *) query);
+ }
+
if (into->skipData)
{
/*
@@ -353,6 +383,27 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
/* Restore userid and security context */
SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ if (into->ivm)
+ {
+ Oid matviewOid = address.objectId;
+ Relation matviewRel = table_open(matviewOid, NoLock);
+
+ /*
+ * Mark relisivm field, if it's a matview and into->ivm is true.
+ */
+ SetMatViewIVMState(matviewRel, true);
+
+ if (!into->skipData)
+ {
+ /* Create an index on incremental maintainable materialized view, if possible */
+ CreateIndexOnIMMV((Query *) into->viewQuery, matviewRel);
+
+ /* Create triggers on incremental maintainable materialized view */
+ CreateIvmTriggersOnBaseTables((Query *) into->viewQuery, matviewOid);
+ }
+ table_close(matviewRel, NoLock);
+ }
}
return address;
@@ -630,3 +681,633 @@ intorel_destroy(DestReceiver *self)
{
pfree(self);
}
+
+/*
+ * CreateIvmTriggersOnBaseTables -- create IVM triggers on all base tables
+ */
+void
+CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid)
+{
+ Relids relids = NULL;
+ bool ex_lock = false;
+ RangeTblEntry *rte;
+
+ /* Immediately return if we don't have any base tables. */
+ if (list_length(qry->rtable) < 1)
+ return;
+
+ /*
+ * If the view has more than one base tables, we need an exclusive lock
+ * on the view so that the view would be maintained serially to avoid
+ * the inconsistency that occurs when two base tables are modified in
+ * concurrent transactions. However, if the view has only one table,
+ * we can use a weaker lock.
+ *
+ * The type of lock should be determined here, because if we check the
+ * view definition at maintenance time, we need to acquire a weaker lock,
+ * and upgrading the lock level after this increases probability of
+ * deadlock.
+ */
+
+ rte = list_nth(qry->rtable, 0);
+ if (list_length(qry->rtable) > 1 || rte->rtekind != RTE_RELATION)
+ ex_lock = true;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, (Node *)qry, matviewOid, &relids, ex_lock);
+
+ bms_free(relids);
+}
+
+static void
+CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid matviewOid,
+ Relids *relids, bool ex_lock)
+{
+ if (node == NULL)
+ return;
+
+ /* This can recurse, so check for excessive recursion */
+ check_stack_depth();
+
+ switch (nodeTag(node))
+ {
+ case T_Query:
+ {
+ Query *query = (Query *) node;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, (Node *)query->jointree, matviewOid, relids, ex_lock);
+ }
+ break;
+
+ case T_RangeTblRef:
+ {
+ int rti = ((RangeTblRef *) node)->rtindex;
+ RangeTblEntry *rte = rt_fetch(rti, qry->rtable);
+
+ if (rte->rtekind == RTE_RELATION && !bms_is_member(rte->relid, *relids))
+ {
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_INSERT, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_DELETE, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_UPDATE, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_TRUNCATE, TRIGGER_TYPE_BEFORE, true);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_INSERT, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_DELETE, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_UPDATE, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_TRUNCATE, TRIGGER_TYPE_AFTER, true);
+
+ *relids = bms_add_member(*relids, rte->relid);
+ }
+ }
+ break;
+
+ case T_FromExpr:
+ {
+ FromExpr *f = (FromExpr *) node;
+ ListCell *l;
+
+ foreach(l, f->fromlist)
+ CreateIvmTriggersOnBaseTablesRecurse(qry, lfirst(l), matviewOid, relids, ex_lock);
+ }
+ break;
+
+ case T_JoinExpr:
+ {
+ JoinExpr *j = (JoinExpr *) node;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, j->larg, matviewOid, relids, ex_lock);
+ CreateIvmTriggersOnBaseTablesRecurse(qry, j->rarg, matviewOid, relids, ex_lock);
+ }
+ break;
+
+ default:
+ elog(ERROR, "unrecognized node type: %d", (int) nodeTag(node));
+ }
+}
+
+/*
+ * CreateIvmTrigger -- create IVM trigger on a base table
+ */
+static void
+CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock)
+{
+ ObjectAddress refaddr;
+ ObjectAddress address;
+ CreateTrigStmt *ivm_trigger;
+ List *transitionRels = NIL;
+
+ Assert(timing == TRIGGER_TYPE_BEFORE || timing == TRIGGER_TYPE_AFTER);
+
+ refaddr.classId = RelationRelationId;
+ refaddr.objectId = viewOid;
+ refaddr.objectSubId = 0;
+
+ ivm_trigger = makeNode(CreateTrigStmt);
+ ivm_trigger->relation = NULL;
+ ivm_trigger->row = false;
+
+ ivm_trigger->timing = timing;
+ ivm_trigger->events = type;
+
+ switch (type)
+ {
+ case TRIGGER_TYPE_INSERT:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_ins_before" : "IVM_trigger_ins_after");
+ break;
+ case TRIGGER_TYPE_DELETE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_del_before" : "IVM_trigger_del_after");
+ break;
+ case TRIGGER_TYPE_UPDATE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_upd_before" : "IVM_trigger_upd_after");
+ break;
+ case TRIGGER_TYPE_TRUNCATE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_truncate_before" : "IVM_trigger_truncate_after");
+ break;
+ default:
+ elog(ERROR, "unsupported trigger type");
+ }
+
+ if (timing == TRIGGER_TYPE_AFTER)
+ {
+ if (type == TRIGGER_TYPE_INSERT || type == TRIGGER_TYPE_UPDATE)
+ {
+ TriggerTransition *n = makeNode(TriggerTransition);
+ n->name = "__ivm_newtable";
+ n->isNew = true;
+ n->isTable = true;
+
+ transitionRels = lappend(transitionRels, n);
+ }
+ if (type == TRIGGER_TYPE_DELETE || type == TRIGGER_TYPE_UPDATE)
+ {
+ TriggerTransition *n = makeNode(TriggerTransition);
+ n->name = "__ivm_oldtable";
+ n->isNew = false;
+ n->isTable = true;
+
+ transitionRels = lappend(transitionRels, n);
+ }
+ }
+
+ /*
+ * XXX: When using DELETE or UPDATE, we must use exclusive lock for now
+ * because apply_old_delta(_with_count) uses ctid to identify the tuple
+ * to be deleted/deleted, but doesn't work in concurrent situations.
+ *
+ * If the view doesn't have aggregate, distinct, or tuple duplicate,
+ * then it would work even in concurrent situations. However, we don't have
+ * any way to guarantee the view has a unique key before opening the IMMV
+ * at the maintenance time because users may drop the unique index.
+ */
+
+ if (type == TRIGGER_TYPE_DELETE || type == TRIGGER_TYPE_UPDATE)
+ ex_lock = true;
+
+ ivm_trigger->funcname =
+ (timing == TRIGGER_TYPE_BEFORE ? SystemFuncName("IVM_immediate_before") : SystemFuncName("IVM_immediate_maintenance"));
+
+ ivm_trigger->columns = NIL;
+ ivm_trigger->transitionRels = transitionRels;
+ ivm_trigger->whenClause = NULL;
+ ivm_trigger->isconstraint = false;
+ ivm_trigger->deferrable = false;
+ ivm_trigger->initdeferred = false;
+ ivm_trigger->constrrel = NULL;
+ ivm_trigger->args = list_make2(
+ makeString(DatumGetPointer(DirectFunctionCall1(oidout, ObjectIdGetDatum(viewOid)))),
+ makeString(DatumGetPointer(DirectFunctionCall1(boolout, BoolGetDatum(ex_lock))))
+ );
+
+ address = CreateTrigger(ivm_trigger, NULL, relOid, InvalidOid, InvalidOid,
+ InvalidOid, InvalidOid, InvalidOid, NULL, true, false);
+
+ recordDependencyOn(&address, &refaddr, DEPENDENCY_AUTO);
+
+ /* Make changes-so-far visible */
+ CommandCounterIncrement();
+}
+
+/*
+ * check_ivm_restriction --- look for specify nodes in the query tree
+ */
+static void
+check_ivm_restriction(Node *node)
+{
+ check_ivm_restriction_walker(node, NULL);
+}
+
+static bool
+check_ivm_restriction_walker(Node *node, void *context)
+{
+ if (node == NULL)
+ return false;
+
+ /*
+ * We currently don't support Sub-Query.
+ */
+ if (IsA(node, SubPlan) || IsA(node, SubLink))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("subquery is not supported on incrementally maintainable materialized view")));
+
+ /* This can recurse, so check for excessive recursion */
+ check_stack_depth();
+
+ switch (nodeTag(node))
+ {
+ case T_Query:
+ {
+ Query *qry = (Query *)node;
+ ListCell *lc;
+ List *vars;
+
+ /* if contained CTE, return error */
+ if (qry->cteList != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("CTE is not supported on incrementally maintainable materialized view")));
+ if (qry->havingQual != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg(" HAVING clause is not supported on incrementally maintainable materialized view")));
+ if (qry->sortClause != NIL) /* There is a possibility that we don't need to return an error */
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("ORDER BY clause is not supported on incrementally maintainable materialized view")));
+ if (qry->limitOffset != NULL || qry->limitCount != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view")));
+ if (qry->distinctClause)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("DISTINCT is not supported on incrementally maintainable materialized view")));
+ if (qry->hasDistinctOn)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("DISTINCT ON is not supported on incrementally maintainable materialized view")));
+ if (qry->hasWindowFuncs)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("window functions are not supported on incrementally maintainable materialized view")));
+ if (qry->groupingSets != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUPING SETS, ROLLUP, or CUBE clauses is not supported on incrementally maintainable materialized view")));
+ if (qry->setOperations != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("UNION/INTERSECT/EXCEPT statements are not supported on incrementally maintainable materialized view")));
+ if (list_length(qry->targetList) == 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("empty target list is not supported on incrementally maintainable materialized view")));
+ if (qry->rowMarks != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view")));
+
+ /* system column restrictions */
+ vars = pull_vars_of_level((Node *) qry, 0);
+ foreach(lc, vars)
+ {
+ if (IsA(lfirst(lc), Var))
+ {
+ Var *var = (Var *) lfirst(lc);
+ /* if system column, return error */
+ if (var->varattno < 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("system column is not supported on incrementally maintainable materialized view")));
+ }
+ }
+
+ /* restrictions for rtable */
+ foreach(lc, qry->rtable)
+ {
+ RangeTblEntry *rte = (RangeTblEntry *) lfirst(lc);
+
+ if (rte->subquery)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("subquery is not supported on incrementally maintainable materialized view")));
+
+ if (rte->tablesample != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("TABLESAMPLE clause is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitioned table is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_RELATION && has_superclass(rte->relid))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_RELATION && find_inheritance_children(rte->relid, NoLock) != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("inheritance parent is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_FOREIGN_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("foreign table is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_VIEW ||
+ rte->relkind == RELKIND_MATVIEW)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view")));
+
+ if (rte->rtekind == RTE_VALUES)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("VALUES is not supported on incrementally maintainable materialized view")));
+
+ }
+
+ query_tree_walker(qry, check_ivm_restriction_walker, NULL, QTW_IGNORE_RANGE_TABLE);
+
+ break;
+ }
+ case T_TargetEntry:
+ {
+ TargetEntry *tle = (TargetEntry *)node;
+ if (isIvmName(tle->resname))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("column name %s is not supported on incrementally maintainable materialized view", tle->resname)));
+
+ expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ break;
+ }
+ case T_JoinExpr:
+ {
+ JoinExpr *joinexpr = (JoinExpr *)node;
+
+ if (joinexpr->jointype > JOIN_INNER)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("OUTER JOIN is not supported on incrementally maintainable materialized view")));
+
+ expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ }
+ break;
+ case T_Aggref:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function is not supported on incrementally maintainable materialized view")));
+ break;
+ default:
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
+ break;
+ }
+ return false;
+}
+
+/*
+ * CreateIndexOnIMMV
+ *
+ * Create a unique index on incremental maintainable materialized view.
+ * If the view definition query has a GROUP BY clause, the index is created
+ * on the columns of GROUP BY expressions. Otherwise, if the view contains
+ * all primary key attritubes of its base tables in the target list, the index
+ * is created on these attritubes. In other cases, no index is created.
+ */
+void
+CreateIndexOnIMMV(Query *query, Relation matviewRel)
+{
+ ListCell *lc;
+ IndexStmt *index;
+ ObjectAddress address;
+ List *constraintList = NIL;
+ char idxname[NAMEDATALEN];
+ List *indexoidlist = RelationGetIndexList(matviewRel);
+ ListCell *indexoidscan;
+ Bitmapset *key_attnos;
+
+ snprintf(idxname, sizeof(idxname), "%s_index", RelationGetRelationName(matviewRel));
+
+ index = makeNode(IndexStmt);
+
+ index->unique = true;
+ index->primary = false;
+ index->isconstraint = false;
+ index->deferrable = false;
+ index->initdeferred = false;
+ index->idxname = idxname;
+ index->relation =
+ makeRangeVar(get_namespace_name(RelationGetNamespace(matviewRel)),
+ pstrdup(RelationGetRelationName(matviewRel)),
+ -1);
+ index->accessMethod = DEFAULT_INDEX_TYPE;
+ index->options = NIL;
+ index->tableSpace = get_tablespace_name(matviewRel->rd_rel->reltablespace);
+ index->whereClause = NULL;
+ index->indexParams = NIL;
+ index->indexIncludingParams = NIL;
+ index->excludeOpNames = NIL;
+ index->idxcomment = NULL;
+ index->indexOid = InvalidOid;
+ index->oldNumber = InvalidRelFileNumber;
+ index->oldCreateSubid = InvalidSubTransactionId;
+ index->oldFirstRelfilelocatorSubid = InvalidSubTransactionId;
+ index->transformed = true;
+ index->concurrent = false;
+ index->if_not_exists = false;
+
+ /* create index on the base tables' primary key columns */
+ key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
+ if (key_attnos)
+ {
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ }
+ else
+ {
+ /* create no index, just notice that an appropriate index is necessary for efficient IVM */
+ ereport(NOTICE,
+ (errmsg("could not create an index on materialized view \"%s\" automatically",
+ RelationGetRelationName(matviewRel)),
+ errdetail("This target list does not have all the primary key columns. "),
+ errhint("Create an index on the materialized view for efficient incremental maintenance.")));
+ return;
+ }
+
+ /* If we have a compatible index, we don't need to create another. */
+ foreach(indexoidscan, indexoidlist)
+ {
+ Oid indexoid = lfirst_oid(indexoidscan);
+ Relation indexRel;
+ bool hasCompatibleIndex = false;
+
+ indexRel = index_open(indexoid, AccessShareLock);
+
+ if (CheckIndexCompatible(indexRel->rd_id,
+ index->accessMethod,
+ index->indexParams,
+ index->excludeOpNames))
+ hasCompatibleIndex = true;
+
+ index_close(indexRel, AccessShareLock);
+
+ if (hasCompatibleIndex)
+ return;
+ }
+
+ address = DefineIndex(RelationGetRelid(matviewRel),
+ index,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ -1,
+ false, true, false, false, true);
+
+ ereport(NOTICE,
+ (errmsg("created index \"%s\" on materialized view \"%s\"",
+ idxname, RelationGetRelationName(matviewRel))));
+
+ /*
+ * Make dependencies so that the index is dropped if any base tables's
+ * primary key is dropped.
+ */
+ foreach(lc, constraintList)
+ {
+ Oid constraintOid = lfirst_oid(lc);
+ ObjectAddress refaddr;
+
+ refaddr.classId = ConstraintRelationId;
+ refaddr.objectId = constraintOid;
+ refaddr.objectSubId = 0;
+
+ recordDependencyOn(&address, &refaddr, DEPENDENCY_NORMAL);
+ }
+}
+
+
+/*
+ * get_primary_key_attnos_from_query
+ *
+ * Identify the columns in base tables' primary keys in the target list.
+ *
+ * Returns a Bitmapset of the column attnos of the primary key's columns of
+ * tables that used in the query. The attnos are offset by
+ * FirstLowInvalidHeapAttributeNumber as same as get_primary_key_attnos.
+ *
+ * If any table has no primary key or any primary key's columns is not in
+ * the target list, return NULL. We also return NULL if any pkey constraint
+ * is deferrable.
+ *
+ * constraintList is set to a list of the OIDs of the pkey constraints.
+ */
+static Bitmapset *
+get_primary_key_attnos_from_query(Query *query, List **constraintList)
+{
+ List *key_attnos_list = NIL;
+ ListCell *lc;
+ int i;
+ Bitmapset *keys = NULL;
+ Relids rels_in_from;
+
+ /*
+ * Collect primary key attributes from all tables used in query. The key attributes
+ * sets for each table are stored in key_attnos_list in order by RTE index.
+ */
+ foreach(lc, query->rtable)
+ {
+ RangeTblEntry *r = (RangeTblEntry*) lfirst(lc);
+ Bitmapset *key_attnos;
+ bool has_pkey = true;
+
+ /* for tables, call get_primary_key_attnos */
+ if (r->rtekind == RTE_RELATION)
+ {
+ Oid constraintOid;
+ key_attnos = get_primary_key_attnos(r->relid, false, &constraintOid);
+ *constraintList = lappend_oid(*constraintList, constraintOid);
+ has_pkey = (key_attnos != NULL);
+ }
+ /* for other RTEs, store NULL into key_attnos_list */
+ else
+ key_attnos = NULL;
+
+ /*
+ * If any table or subquery has no primary key or its pkey constraint is deferrable,
+ * we cannot get key attributes for this query, so return NULL.
+ */
+ if (!has_pkey)
+ return NULL;
+
+ key_attnos_list = lappend(key_attnos_list, key_attnos);
+ }
+
+ /* Collect key attributes appearing in the target list */
+ i = 1;
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) flatten_join_alias_vars(NULL, query, lfirst(lc));
+
+ if (IsA(tle->expr, Var))
+ {
+ Var *var = (Var*) tle->expr;
+ Bitmapset *key_attnos = list_nth(key_attnos_list, var->varno - 1);
+
+ /* check if this attribute is from a base table's primary key */
+ if (bms_is_member(var->varattno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ /*
+ * Remove found key attributes from key_attnos_list, and add this
+ * to the result list.
+ */
+ key_attnos = bms_del_member(key_attnos, var->varattno - FirstLowInvalidHeapAttributeNumber);
+ if (bms_is_empty(key_attnos))
+ {
+ key_attnos_list = list_delete_nth_cell(key_attnos_list, var->varno - 1);
+ key_attnos_list = list_insert_nth(key_attnos_list, var->varno - 1, NULL);
+ }
+ keys = bms_add_member(keys, i - FirstLowInvalidHeapAttributeNumber);
+ }
+ }
+ i++;
+ }
+
+ /* Collect RTE indexes of relations appearing in the FROM clause */
+ rels_in_from = get_relids_in_jointree((Node *) query->jointree, false, false);
+
+ /*
+ * Check if all key attributes of relations in FROM are appearing in the target
+ * list. If an attribute remains in key_attnos_list in spite of the table is used
+ * in FROM clause, the target is missing this key attribute, so we return NULL.
+ */
+ i = 1;
+ foreach(lc, key_attnos_list)
+ {
+ Bitmapset *bms = (Bitmapset *)lfirst(lc);
+ if (!bms_is_empty(bms) && bms_is_member(i, rels_in_from))
+ return NULL;
+ i++;
+ }
+
+ return keys;
+}
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index 6d09b75556..1061c37b2c 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -23,23 +23,35 @@
#include "catalog/indexing.h"
#include "catalog/namespace.h"
#include "catalog/pg_am.h"
+#include "catalog/pg_depend.h"
+#include "catalog/pg_trigger.h"
#include "catalog/pg_opclass.h"
#include "commands/cluster.h"
#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
+#include "commands/createas.h"
#include "executor/executor.h"
#include "executor/spi.h"
+#include "executor/tstoreReceiver.h"
#include "miscadmin.h"
+#include "nodes/makefuncs.h"
+#include "parser/analyze.h"
+#include "parser/parse_clause.h"
+#include "parser/parse_func.h"
+#include "parser/parse_relation.h"
#include "pgstat.h"
#include "rewrite/rewriteHandler.h"
+#include "rewrite/rowsecurity.h"
#include "storage/lmgr.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
+#include "utils/fmgroids.h"
#include "utils/lsyscache.h"
#include "utils/rel.h"
#include "utils/snapmgr.h"
#include "utils/syscache.h"
+#include "utils/typcache.h"
typedef struct
@@ -53,6 +65,52 @@ typedef struct
BulkInsertState bistate; /* bulk insert state */
} DR_transientrel;
+#define MV_INIT_QUERYHASHSIZE 16
+
+/*
+ * MV_TriggerHashEntry
+ *
+ * Hash entry for base tables on which IVM trigger is invoked
+ */
+typedef struct MV_TriggerHashEntry
+{
+ Oid matview_id; /* OID of the materialized view */
+ int before_trig_count; /* count of before triggers invoked */
+ int after_trig_count; /* count of after triggers invoked */
+
+ Snapshot snapshot; /* Snapshot just before table change */
+
+ List *tables; /* List of MV_TriggerTable */
+ bool has_old; /* tuples are deleted from any table? */
+ bool has_new; /* tuples are inserted into any table? */
+} MV_TriggerHashEntry;
+
+/*
+ * MV_TriggerTable
+ *
+ * IVM related data for tables on which the trigger is invoked.
+ */
+typedef struct MV_TriggerTable
+{
+ Oid table_id; /* OID of the modified table */
+ List *old_tuplestores; /* tuplestores for deleted tuples */
+ List *new_tuplestores; /* tuplestores for inserted tuples */
+
+ List *rte_indexes; /* List of RTE index of the modified table */
+ RangeTblEntry *original_rte; /* the original RTE saved before rewriting query */
+
+ Relation rel; /* relation of the modified table */
+ TupleTableSlot *slot; /* for checking visibility in the pre-state table */
+} MV_TriggerTable;
+
+static HTAB *mv_trigger_info = NULL;
+
+static bool in_delta_calculation = false;
+
+/* ENR name for materialized view delta */
+#define NEW_DELTA_ENRNAME "new_delta"
+#define OLD_DELTA_ENRNAME "old_delta"
+
static int matview_maintenance_depth = 0;
static void transientrel_startup(DestReceiver *self, int operation, TupleDesc typeinfo);
@@ -60,7 +118,9 @@ static bool transientrel_receive(TupleTableSlot *slot, DestReceiver *self);
static void transientrel_shutdown(DestReceiver *self);
static void transientrel_destroy(DestReceiver *self);
static uint64 refresh_matview_datafill(DestReceiver *dest, Query *query,
- const char *queryString);
+ QueryEnvironment *queryEnv,
+ TupleDesc *resultTupleDesc,
+ const char *queryString);
static char *make_temptable_name_n(char *tempname, int n);
static void refresh_by_match_merge(Oid matviewOid, Oid tempOid, Oid relowner,
int save_sec_context);
@@ -68,6 +128,37 @@ static void refresh_by_heap_swap(Oid matviewOid, Oid OIDNewHeap, char relpersist
static bool is_usable_unique_index(Relation indexRel);
static void OpenMatViewIncrementalMaintenance(void);
static void CloseMatViewIncrementalMaintenance(void);
+static Query *get_matview_query(Relation matviewRel);
+
+static Query *rewrite_query_for_preupdate_state(Query *query, List *tables,
+ ParseState *pstate, Oid matviewid);
+static void register_delta_ENRs(ParseState *pstate, Query *query, List *tables);
+static char *make_delta_enr_name(const char *prefix, Oid relid, int count);
+static RangeTblEntry *get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *table,
+ QueryEnvironment *queryEnv, Oid matviewid);
+static RangeTblEntry *replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
+ QueryEnvironment *queryEnv);
+static Query *rewrite_query_for_counting(Query *query, ParseState *pstate);
+
+static void calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
+ DestReceiver *dest_old, DestReceiver *dest_new,
+ TupleDesc *tupdesc_old, TupleDesc *tupdesc_new,
+ QueryEnvironment *queryEnv);
+static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte_index);
+
+static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
+ TupleDesc tupdesc_old, TupleDesc tupdesc_new,
+ Query *query);
+static void apply_old_delta(const char *matviewname, const char *deltaname_old,
+ List *keys);
+static void apply_new_delta(const char *matviewname, const char *deltaname_new,
+ StringInfo target_list);
+static char *get_matching_condition_string(List *keys);
+static void generate_equal(StringInfo querybuf, Oid opttype,
+ const char *leftop, const char *rightop);
+
+static void mv_InitHashTables(void);
+static void clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort);
/*
* SetMatViewPopulatedState
@@ -109,6 +200,46 @@ SetMatViewPopulatedState(Relation relation, bool newstate)
CommandCounterIncrement();
}
+/*
+ * SetMatViewIVMState
+ * Mark a materialized view as IVM, or not.
+ *
+ * NOTE: caller must be holding an appropriate lock on the relation.
+ */
+void
+SetMatViewIVMState(Relation relation, bool newstate)
+{
+ Relation pgrel;
+ HeapTuple tuple;
+
+ Assert(relation->rd_rel->relkind == RELKIND_MATVIEW);
+
+ /*
+ * Update relation's pg_class entry. Crucial side-effect: other backends
+ * (and this one too!) are sent SI message to make them rebuild relcache
+ * entries.
+ */
+ pgrel = table_open(RelationRelationId, RowExclusiveLock);
+ tuple = SearchSysCacheCopy1(RELOID,
+ ObjectIdGetDatum(RelationGetRelid(relation)));
+ if (!HeapTupleIsValid(tuple))
+ elog(ERROR, "cache lookup failed for relation %u",
+ RelationGetRelid(relation));
+
+ ((Form_pg_class) GETSTRUCT(tuple))->relisivm = newstate;
+
+ CatalogTupleUpdate(pgrel, &tuple->t_self, tuple);
+
+ heap_freetuple(tuple);
+ table_close(pgrel, RowExclusiveLock);
+
+ /*
+ * Advance command counter to make the updated pg_class row locally
+ * visible.
+ */
+ CommandCounterIncrement();
+}
+
/*
* ExecRefreshMatView -- execute a REFRESH MATERIALIZED VIEW command
*
@@ -135,8 +266,6 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
{
Oid matviewOid;
Relation matviewRel;
- RewriteRule *rule;
- List *actions;
Query *dataQuery;
Oid tableSpace;
Oid relowner;
@@ -150,6 +279,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
int save_sec_context;
int save_nestlevel;
ObjectAddress address;
+ bool oldPopulated;
/* Determine strength of lock needed. */
concurrent = stmt->concurrent;
@@ -176,6 +306,8 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
save_nestlevel = NewGUCNestLevel();
RestrictSearchPath();
+ oldPopulated = RelationIsPopulated(matviewRel);
+
/* Make sure it is a materialized view. */
if (matviewRel->rd_rel->relkind != RELKIND_MATVIEW)
ereport(ERROR,
@@ -196,32 +328,9 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
errmsg("%s and %s options cannot be used together",
"CONCURRENTLY", "WITH NO DATA")));
- /*
- * Check that everything is correct for a refresh. Problems at this point
- * are internal errors, so elog is sufficient.
- */
- if (matviewRel->rd_rel->relhasrules == false ||
- matviewRel->rd_rules->numLocks < 1)
- elog(ERROR,
- "materialized view \"%s\" is missing rewrite information",
- RelationGetRelationName(matviewRel));
-
- if (matviewRel->rd_rules->numLocks > 1)
- elog(ERROR,
- "materialized view \"%s\" has too many rules",
- RelationGetRelationName(matviewRel));
- rule = matviewRel->rd_rules->rules[0];
- if (rule->event != CMD_SELECT || !(rule->isInstead))
- elog(ERROR,
- "the rule for materialized view \"%s\" is not a SELECT INSTEAD OF rule",
- RelationGetRelationName(matviewRel));
+ dataQuery = get_matview_query(matviewRel);
- actions = rule->actions;
- if (list_length(actions) != 1)
- elog(ERROR,
- "the rule for materialized view \"%s\" is not a single action",
- RelationGetRelationName(matviewRel));
/*
* Check that there is a unique index with no WHERE clause on one or more
@@ -256,12 +365,6 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
errhint("Create a unique index with no WHERE clause on one or more columns of the materialized view.")));
}
- /*
- * The stored query was rewritten at the time of the MV definition, but
- * has not been scribbled on by the planner.
- */
- dataQuery = linitial_node(Query, actions);
-
/*
* Check for active uses of the relation in the current transaction, such
* as open scans.
@@ -289,6 +392,74 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
relpersistence = matviewRel->rd_rel->relpersistence;
}
+ /* delete IMMV triggers. */
+ if (RelationIsIVM(matviewRel) && stmt->skipData )
+ {
+ Relation tgRel;
+ Relation depRel;
+ ScanKeyData key;
+ SysScanDesc scan;
+ HeapTuple tup;
+ ObjectAddresses *immv_triggers;
+
+ immv_triggers = new_object_addresses();
+
+ tgRel = table_open(TriggerRelationId, RowExclusiveLock);
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ /* search triggers that depends on IMMV. */
+ ScanKeyInit(&key,
+ Anum_pg_depend_refobjid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(matviewOid));
+ scan = systable_beginscan(depRel, DependReferenceIndexId, true,
+ NULL, 1, &key);
+ while ((tup = systable_getnext(scan)) != NULL)
+ {
+ ObjectAddress obj;
+ Form_pg_depend foundDep = (Form_pg_depend) GETSTRUCT(tup);
+
+ if (foundDep->classid == TriggerRelationId)
+ {
+ HeapTuple tgtup;
+ ScanKeyData tgkey[1];
+ SysScanDesc tgscan;
+ Form_pg_trigger tgform;
+
+ /* Find the trigger name. */
+ ScanKeyInit(&tgkey[0],
+ Anum_pg_trigger_oid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(foundDep->objid));
+
+ tgscan = systable_beginscan(tgRel, TriggerOidIndexId, true,
+ NULL, 1, tgkey);
+ tgtup = systable_getnext(tgscan);
+ if (!HeapTupleIsValid(tgtup))
+ elog(ERROR, "could not find tuple for immv trigger %u", foundDep->objid);
+
+ tgform = (Form_pg_trigger) GETSTRUCT(tgtup);
+
+ /* If trigger is created by IMMV, delete it. */
+ if (strncmp(NameStr(tgform->tgname), "IVM_trigger_", 12) == 0)
+ {
+ obj.classId = foundDep->classid;
+ obj.objectId = foundDep->objid;
+ obj.objectSubId = foundDep->refobjsubid;
+ add_exact_object_address(&obj, immv_triggers);
+ }
+ systable_endscan(tgscan);
+ }
+ }
+ systable_endscan(scan);
+
+ performMultipleDeletions(immv_triggers, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ table_close(depRel, RowExclusiveLock);
+ table_close(tgRel, RowExclusiveLock);
+ free_object_addresses(immv_triggers);
+ }
+
/*
* Create the transient table that will receive the regenerated data. Lock
* it against access by any other process until commit (by which time it
@@ -302,7 +473,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
/* Generate the data, if wanted. */
if (!stmt->skipData)
- processed = refresh_matview_datafill(dest, dataQuery, queryString);
+ processed = refresh_matview_datafill(dest, dataQuery, NULL, NULL, queryString);
/* Make the matview match the newly generated data. */
if (concurrent)
@@ -337,6 +508,12 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
pgstat_count_heap_insert(matviewRel, processed);
}
+ if (!stmt->skipData && RelationIsIVM(matviewRel) && !oldPopulated)
+ {
+ CreateIndexOnIMMV(dataQuery, matviewRel);
+ CreateIvmTriggersOnBaseTables(dataQuery, matviewOid);
+ }
+
table_close(matviewRel, NoLock);
/* Roll back any GUC changes */
@@ -371,6 +548,8 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
*/
static uint64
refresh_matview_datafill(DestReceiver *dest, Query *query,
+ QueryEnvironment *queryEnv,
+ TupleDesc *resultTupleDesc,
const char *queryString)
{
List *rewritten;
@@ -407,7 +586,7 @@ refresh_matview_datafill(DestReceiver *dest, Query *query,
/* Create a QueryDesc, redirecting output to our tuple receiver */
queryDesc = CreateQueryDesc(plan, queryString,
GetActiveSnapshot(), InvalidSnapshot,
- dest, NULL, NULL, 0);
+ dest, NULL, queryEnv ? queryEnv: NULL, 0);
/* call ExecutorStart to prepare the plan for execution */
ExecutorStart(queryDesc, 0);
@@ -417,6 +596,9 @@ refresh_matview_datafill(DestReceiver *dest, Query *query,
processed = queryDesc->estate->es_processed;
+ if (resultTupleDesc)
+ *resultTupleDesc = CreateTupleDescCopy(queryDesc->tupDesc);
+
/* and clean up */
ExecutorFinish(queryDesc);
ExecutorEnd(queryDesc);
@@ -950,3 +1132,1219 @@ CloseMatViewIncrementalMaintenance(void)
matview_maintenance_depth--;
Assert(matview_maintenance_depth >= 0);
}
+
+/*
+ * get_matview_query - get the Query from a matview's _RETURN rule.
+ */
+static Query *
+get_matview_query(Relation matviewRel)
+{
+ RewriteRule *rule;
+ List * actions;
+
+ /*
+ * Check that everything is correct for a refresh. Problems at this point
+ * are internal errors, so elog is sufficient.
+ */
+ if (matviewRel->rd_rel->relhasrules == false ||
+ matviewRel->rd_rules->numLocks < 1)
+ elog(ERROR,
+ "materialized view \"%s\" is missing rewrite information",
+ RelationGetRelationName(matviewRel));
+
+ if (matviewRel->rd_rules->numLocks > 1)
+ elog(ERROR,
+ "materialized view \"%s\" has too many rules",
+ RelationGetRelationName(matviewRel));
+
+ rule = matviewRel->rd_rules->rules[0];
+ if (rule->event != CMD_SELECT || !(rule->isInstead))
+ elog(ERROR,
+ "the rule for materialized view \"%s\" is not a SELECT INSTEAD OF rule",
+ RelationGetRelationName(matviewRel));
+
+ actions = rule->actions;
+ if (list_length(actions) != 1)
+ elog(ERROR,
+ "the rule for materialized view \"%s\" is not a single action",
+ RelationGetRelationName(matviewRel));
+
+ /*
+ * The stored query was rewritten at the time of the MV definition, but
+ * has not been scribbled on by the planner.
+ */
+ return linitial_node(Query, actions);
+}
+
+
+/* ----------------------------------------------------
+ * Incremental View Maintenance routines
+ * ---------------------------------------------------
+ */
+
+/*
+ * IVM_immediate_before
+ *
+ * IVM trigger function invoked before base table is modified. If this is
+ * invoked firstly in the same statement, we save the transaction id and the
+ * command id at that time.
+ */
+Datum
+IVM_immediate_before(PG_FUNCTION_ARGS)
+{
+ TriggerData *trigdata = (TriggerData *) fcinfo->context;
+ char *matviewOid_text = trigdata->tg_trigger->tgargs[0];
+ char *ex_lock_text = trigdata->tg_trigger->tgargs[1];
+ Oid matviewOid;
+ MV_TriggerHashEntry *entry;
+ bool found;
+ bool ex_lock;
+
+ matviewOid = DatumGetObjectId(DirectFunctionCall1(oidin, CStringGetDatum(matviewOid_text)));
+ ex_lock = DatumGetBool(DirectFunctionCall1(boolin, CStringGetDatum(ex_lock_text)));
+
+ /* If the view has more than one tables, we have to use an exclusive lock. */
+ if (ex_lock)
+ {
+ /*
+ * Wait for concurrent transactions which update this materialized view at
+ * READ COMMITED. This is needed to see changes committed in other
+ * transactions. No wait and raise an error at REPEATABLE READ or
+ * SERIALIZABLE to prevent update anomalies of matviews.
+ * XXX: dead-lock is possible here.
+ */
+ if (!IsolationUsesXactSnapshot())
+ LockRelationOid(matviewOid, ExclusiveLock);
+ else if (!ConditionalLockRelationOid(matviewOid, ExclusiveLock))
+ {
+ /* try to throw error by name; relation could be deleted... */
+ char *relname = get_rel_name(matviewOid);
+
+ if (!relname)
+ ereport(ERROR,
+ (errcode(ERRCODE_LOCK_NOT_AVAILABLE),
+ errmsg("could not obtain lock on materialized view during incremental maintenance")));
+
+ ereport(ERROR,
+ (errcode(ERRCODE_LOCK_NOT_AVAILABLE),
+ errmsg("could not obtain lock on materialized view \"%s\" during incremental maintenance",
+ relname)));
+ }
+ }
+ else
+ LockRelationOid(matviewOid, RowExclusiveLock);
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_trigger_info)
+ mv_InitHashTables();
+
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_ENTER, &found);
+
+ /* On the first BEFORE to update the view, initialize trigger data */
+ if (!found)
+ {
+ /*
+ * Get a snapshot just before the table was modified for checking
+ * tuple visibility in the pre-update state of the table.
+ */
+ Snapshot snapshot = GetActiveSnapshot();
+
+ entry->matview_id = matviewOid;
+ entry->before_trig_count = 0;
+ entry->after_trig_count = 0;
+ entry->snapshot = RegisterSnapshot(snapshot);
+ entry->tables = NIL;
+ entry->has_old = false;
+ entry->has_new = false;
+ }
+
+ entry->before_trig_count++;
+
+ return PointerGetDatum(NULL);
+}
+
+/*
+ * IVM_immediate_maintenance
+ *
+ * IVM trigger function invoked after base table is modified.
+ * For each table, tuplestores of transition tables are collected.
+ * and after the last modification
+ */
+Datum
+IVM_immediate_maintenance(PG_FUNCTION_ARGS)
+{
+ TriggerData *trigdata = (TriggerData *) fcinfo->context;
+ Relation rel;
+ Oid relid;
+ Oid matviewOid;
+ Query *query;
+ Query *rewritten = NULL;
+ char *matviewOid_text = trigdata->tg_trigger->tgargs[0];
+ Relation matviewRel;
+ int old_depth = matview_maintenance_depth;
+
+ Oid relowner;
+ Tuplestorestate *old_tuplestore = NULL;
+ Tuplestorestate *new_tuplestore = NULL;
+ DestReceiver *dest_new = NULL, *dest_old = NULL;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ MV_TriggerHashEntry *entry;
+ MV_TriggerTable *table;
+ bool found;
+
+ ParseState *pstate;
+ QueryEnvironment *queryEnv = create_queryEnv();
+ MemoryContext oldcxt;
+ ListCell *lc;
+ int i;
+
+
+ /* Create a ParseState for rewriting the view definition query */
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ rel = trigdata->tg_relation;
+ relid = rel->rd_id;
+
+ matviewOid = DatumGetObjectId(DirectFunctionCall1(oidin, CStringGetDatum(matviewOid_text)));
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_trigger_info)
+ mv_InitHashTables();
+
+ /* get the entry for this materialized view */
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_FIND, &found);
+ Assert (found && entry != NULL);
+ entry->after_trig_count++;
+
+ /* search the entry for the modified table and create new entry if not found */
+ found = false;
+ foreach(lc, entry->tables)
+ {
+ table = (MV_TriggerTable *) lfirst(lc);
+ if (table->table_id == relid)
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ table = (MV_TriggerTable *) palloc0(sizeof(MV_TriggerTable));
+ table->table_id = relid;
+ table->old_tuplestores = NIL;
+ table->new_tuplestores = NIL;
+ table->rte_indexes = NIL;
+ table->slot = MakeSingleTupleTableSlot(RelationGetDescr(rel), table_slot_callbacks(rel));
+ table->rel = table_open(RelationGetRelid(rel), NoLock);
+ entry->tables = lappend(entry->tables, table);
+
+ MemoryContextSwitchTo(oldcxt);
+ }
+
+ /* Save the transition tables and make a request to not free immediately */
+ if (trigdata->tg_oldtable)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+ table->old_tuplestores = lappend(table->old_tuplestores, trigdata->tg_oldtable);
+ entry->has_old = true;
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (trigdata->tg_newtable)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+ table->new_tuplestores = lappend(table->new_tuplestores, trigdata->tg_newtable);
+ entry->has_new = true;
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (entry->has_new || entry->has_old)
+ {
+ CmdType cmd;
+
+ if (TRIGGER_FIRED_BY_INSERT(trigdata->tg_event))
+ cmd = CMD_INSERT;
+ else if (TRIGGER_FIRED_BY_DELETE(trigdata->tg_event))
+ cmd = CMD_DELETE;
+ else if (TRIGGER_FIRED_BY_UPDATE(trigdata->tg_event))
+ cmd = CMD_UPDATE;
+ else
+ elog(ERROR,"unsupported trigger type");
+
+ /* Prolong lifespan of transition tables to the end of the last AFTER trigger */
+ SetTransitionTablePreserved(relid, cmd);
+ }
+
+
+ /* If this is not the last AFTER trigger call, immediately exit. */
+ Assert (entry->before_trig_count >= entry->after_trig_count);
+ if (entry->before_trig_count != entry->after_trig_count)
+ return PointerGetDatum(NULL);
+
+ /*
+ * If this is the last AFTER trigger call, continue and update the view.
+ */
+
+ /*
+ * Advance command counter to make the updated base table row locally
+ * visible.
+ */
+ CommandCounterIncrement();
+
+ matviewRel = table_open(matviewOid, NoLock);
+
+ /* Make sure it is a materialized view. */
+ Assert(matviewRel->rd_rel->relkind == RELKIND_MATVIEW);
+
+ /*
+ * Get and push the latast snapshot to see any changes which is committed
+ * during waiting in other transactions at READ COMMITTED level.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /*
+ * Check for active uses of the relation in the current transaction, such
+ * as open scans.
+ *
+ * NB: We count on this to protect us against problems with refreshing the
+ * data using TABLE_INSERT_FROZEN.
+ */
+ CheckTableNotInUse(matviewRel, "refresh a materialized view incrementally");
+
+ /*
+ * Switch to the owner's userid, so that any functions are run as that
+ * user. Also arrange to make GUC variable changes local to this command.
+ * We will switch modes when we are about to execute user code.
+ */
+ relowner = matviewRel->rd_rel->relowner;
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+
+ /* get view query*/
+ query = get_matview_query(matviewRel);
+
+ /*
+ * When a base table is truncated, the view content will be empty if the
+ * view definition query does not contain an aggregate without a GROUP clause.
+ * Therefore, such views can be truncated.
+ */
+ if (TRIGGER_FIRED_BY_TRUNCATE(trigdata->tg_event))
+ {
+ ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
+ NIL, DROP_RESTRICT, false, false);
+
+ /* Clean up hash entry and delete tuplestores */
+ clean_up_IVM_hash_entry(entry, false);
+
+ /* Pop the original snapshot. */
+ PopActiveSnapshot();
+
+ table_close(matviewRel, NoLock);
+
+ /* Roll back any GUC changes */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ return PointerGetDatum(NULL);
+ }
+
+ /*
+ * rewrite query for calculating deltas
+ */
+
+ rewritten = copyObject(query);
+
+ /* Replace resnames in a target list with materialized view's attnames */
+ i = 0;
+ foreach (lc, rewritten->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
+
+ tle->resname = pstrdup(resname);
+ i++;
+ }
+
+ /* Set all tables in the query to pre-update state */
+ rewritten = rewrite_query_for_preupdate_state(rewritten, entry->tables,
+ pstate, matviewOid);
+ /* Rewrite for counting duplicated tuples */
+ rewritten = rewrite_query_for_counting(rewritten, pstate);
+
+ /* Create tuplestores to store view deltas */
+ if (entry->has_old)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ old_tuplestore = tuplestore_begin_heap(false, false, work_mem);
+ dest_old = CreateDestReceiver(DestTuplestore);
+ SetTuplestoreDestReceiverParams(dest_old,
+ old_tuplestore,
+ TopTransactionContext,
+ false,
+ NULL,
+ NULL);
+
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (entry->has_new)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ new_tuplestore = tuplestore_begin_heap(false, false, work_mem);
+ dest_new = CreateDestReceiver(DestTuplestore);
+ SetTuplestoreDestReceiverParams(dest_new,
+ new_tuplestore,
+ TopTransactionContext,
+ false,
+ NULL,
+ NULL);
+ MemoryContextSwitchTo(oldcxt);
+ }
+
+ /* for all modified tables */
+ foreach(lc, entry->tables)
+ {
+ ListCell *lc2;
+
+ table = (MV_TriggerTable *) lfirst(lc);
+
+ /* loop for self-join */
+ foreach(lc2, table->rte_indexes)
+ {
+ int rte_index = lfirst_int(lc2);
+ TupleDesc tupdesc_old;
+ TupleDesc tupdesc_new;
+
+ /* calculate delta tables */
+ calc_delta(table, rte_index, rewritten, dest_old, dest_new,
+ &tupdesc_old, &tupdesc_new, queryEnv);
+
+ /* Set the table in the query to post-update state */
+ rewritten = rewrite_query_for_postupdate_state(rewritten, table, rte_index);
+
+ PG_TRY();
+ {
+ /* apply the delta tables to the materialized view */
+ apply_delta(matviewOid, old_tuplestore, new_tuplestore,
+ tupdesc_old, tupdesc_new, query);
+ }
+ PG_CATCH();
+ {
+ matview_maintenance_depth = old_depth;
+ PG_RE_THROW();
+ }
+ PG_END_TRY();
+
+ /* clear view delta tuplestores */
+ if (old_tuplestore)
+ tuplestore_clear(old_tuplestore);
+ if (new_tuplestore)
+ tuplestore_clear(new_tuplestore);
+ }
+ }
+
+ /* Clean up hash entry and delete tuplestores */
+ clean_up_IVM_hash_entry(entry, false);
+ if (old_tuplestore)
+ {
+ dest_old->rDestroy(dest_old);
+ tuplestore_end(old_tuplestore);
+ }
+ if (new_tuplestore)
+ {
+ dest_new->rDestroy(dest_new);
+ tuplestore_end(new_tuplestore);
+ }
+
+ /* Pop the original snapshot. */
+ PopActiveSnapshot();
+
+ table_close(matviewRel, NoLock);
+
+ /* Roll back any GUC changes */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ return PointerGetDatum(NULL);
+}
+
+/*
+ * rewrite_query_for_preupdate_state
+ *
+ * Rewrite the query so that base tables' RTEs will represent "pre-update"
+ * state of tables. This is necessary to calculate view delta after multiple
+ * tables are modified.
+ */
+static Query*
+rewrite_query_for_preupdate_state(Query *query, List *tables,
+ ParseState *pstate, Oid matviewid)
+{
+ ListCell *lc;
+ int num_rte = list_length(query->rtable);
+ int i;
+
+
+ /* register delta ENRs */
+ register_delta_ENRs(pstate, query, tables);
+
+ /* XXX: Is necessary? Is this right timing? */
+ AcquireRewriteLocks(query, true, false);
+
+ i = 1;
+ foreach(lc, query->rtable)
+ {
+ RangeTblEntry *r = (RangeTblEntry*) lfirst(lc);
+
+ ListCell *lc2;
+ foreach(lc2, tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc2);
+ /*
+ * if the modified table is found then replace the original RTE with
+ * "pre-state" RTE and append its index to the list.
+ */
+ if (r->relid == table->table_id)
+ {
+ List *securityQuals;
+ List *withCheckOptions;
+ bool hasRowSecurity;
+ bool hasSubLinks;
+
+ RangeTblEntry *rte_pre = get_prestate_rte(r, table, pstate->p_queryEnv, matviewid);
+
+ /*
+ * Set a row security poslicies of the modified table to the subquery RTE which
+ * represents the pre-update state of the table.
+ */
+ get_row_security_policies(query, table->original_rte, i,
+ &securityQuals, &withCheckOptions,
+ &hasRowSecurity, &hasSubLinks);
+
+ if (hasRowSecurity)
+ {
+ query->hasRowSecurity = true;
+ rte_pre->security_barrier = true;
+ }
+ if (hasSubLinks)
+ query->hasSubLinks = true;
+
+ rte_pre->securityQuals = securityQuals;
+ lfirst(lc) = rte_pre;
+
+ table->rte_indexes = lappend_int(table->rte_indexes, i);
+ break;
+ }
+ }
+
+ /* finish the loop if we processed all RTE included in the original query */
+ if (i++ >= num_rte)
+ break;
+ }
+
+ return query;
+}
+
+/*
+ * register_delta_ENRs
+ *
+ * For all modified tables, make ENRs for their transition tables
+ * and register them to the queryEnv. ENR's RTEs are also appended
+ * into the list in query tree.
+ */
+static void
+register_delta_ENRs(ParseState *pstate, Query *query, List *tables)
+{
+ QueryEnvironment *queryEnv = pstate->p_queryEnv;
+ ListCell *lc;
+ RangeTblEntry *rte;
+
+ foreach(lc, tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc);
+ ListCell *lc2;
+ int count;
+
+ count = 0;
+ foreach(lc2, table->old_tuplestores)
+ {
+ Tuplestorestate *oldtable = (Tuplestorestate *) lfirst(lc2);
+ EphemeralNamedRelation enr =
+ palloc(sizeof(EphemeralNamedRelationData));
+ ParseNamespaceItem *nsitem;
+
+ enr->md.name = make_delta_enr_name("old", table->table_id, count);
+ enr->md.reliddesc = table->table_id;
+ enr->md.tupdesc = NULL;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(oldtable);
+ enr->reldata = oldtable;
+ register_ENR(queryEnv, enr);
+
+ nsitem = addRangeTableEntryForENR(pstate, makeRangeVar(NULL, enr->md.name, -1), true);
+ rte = nsitem->p_rte;
+
+ query->rtable = lappend(query->rtable, rte);
+
+ count++;
+ }
+
+ count = 0;
+ foreach(lc2, table->new_tuplestores)
+ {
+ Tuplestorestate *newtable = (Tuplestorestate *) lfirst(lc2);
+ EphemeralNamedRelation enr =
+ palloc(sizeof(EphemeralNamedRelationData));
+ ParseNamespaceItem *nsitem;
+
+ enr->md.name = make_delta_enr_name("new", table->table_id, count);
+ enr->md.reliddesc = table->table_id;
+ enr->md.tupdesc = NULL;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(newtable);
+ enr->reldata = newtable;
+ register_ENR(queryEnv, enr);
+
+ nsitem = addRangeTableEntryForENR(pstate, makeRangeVar(NULL, enr->md.name, -1), true);
+ rte = nsitem->p_rte;
+
+ query->rtable = lappend(query->rtable, rte);
+
+ count++;
+ }
+ }
+}
+
+#define DatumGetItemPointer(X) ((ItemPointer) DatumGetPointer(X))
+#define PG_GETARG_ITEMPOINTER(n) DatumGetItemPointer(PG_GETARG_DATUM(n))
+
+/*
+ * ivm_visible_in_prestate
+ *
+ * Check visibility of a tuple specified by the tableoid and item pointer
+ * using the snapshot taken just before the table was modified.
+ */
+Datum
+ivm_visible_in_prestate(PG_FUNCTION_ARGS)
+{
+ Oid tableoid = PG_GETARG_OID(0);
+ ItemPointer itemPtr = PG_GETARG_ITEMPOINTER(1);
+ Oid matviewOid = PG_GETARG_OID(2);
+ MV_TriggerHashEntry *entry;
+ MV_TriggerTable *table = NULL;
+ ListCell *lc;
+ bool found;
+ bool result;
+
+ if (!in_delta_calculation)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("ivm_visible_in_prestate can be called only in delta calculation")));
+
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_FIND, &found);
+ Assert (found && entry != NULL);
+
+ foreach(lc, entry->tables)
+ {
+ table = (MV_TriggerTable *) lfirst(lc);
+ if (table->table_id == tableoid)
+ break;
+ }
+
+ Assert (table != NULL);
+
+ result = table_tuple_fetch_row_version(table->rel, itemPtr, entry->snapshot, table->slot);
+
+ PG_RETURN_BOOL(result);
+}
+
+/*
+ * get_prestate_rte
+ *
+ * Rewrite RTE of the modified table to a subquery which represents
+ * "pre-state" table. The original RTE is saved in table->rte_original.
+ */
+static RangeTblEntry*
+get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *table,
+ QueryEnvironment *queryEnv, Oid matviewid)
+{
+ StringInfoData str;
+ RawStmt *raw;
+ Query *subquery;
+ Relation rel;
+ ParseState *pstate;
+ char *relname;
+ int i;
+
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ /*
+ * We can use NoLock here since AcquireRewriteLocks should
+ * have locked the relation already.
+ */
+ rel = table_open(table->table_id, NoLock);
+ relname = quote_qualified_identifier(
+ get_namespace_name(RelationGetNamespace(rel)),
+ RelationGetRelationName(rel));
+ table_close(rel, NoLock);
+
+ /*
+ * Filtering inserted row using the snapshot taken before the table
+ * is modified. ctid is required for maintaining outer join views.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str,
+ "SELECT t.* FROM %s t"
+ " WHERE pg_catalog.ivm_visible_in_prestate(t.tableoid, t.ctid ,%d::pg_catalog.oid)",
+ relname, matviewid);
+
+ /*
+ * Append deleted rows contained in old transition tables.
+ */
+ for (i = 0; i < list_length(table->old_tuplestores); i++)
+ {
+ appendStringInfo(&str, " UNION ALL ");
+ appendStringInfo(&str," SELECT * FROM %s",
+ make_delta_enr_name("old", table->table_id, i));
+ }
+
+ /* Get a subquery representing pre-state of the table */
+ raw = (RawStmt*)linitial(raw_parser(str.data, RAW_PARSE_DEFAULT));
+ subquery = transformStmt(pstate, raw->stmt);
+
+ /* save the original RTE */
+ table->original_rte = copyObject(rte);
+
+ rte->rtekind = RTE_SUBQUERY;
+ rte->subquery = subquery;
+ rte->security_barrier = false;
+
+ /* Clear fields that should not be set in a subquery RTE */
+ rte->relid = InvalidOid;
+ rte->relkind = 0;
+ rte->rellockmode = 0;
+ rte->tablesample = NULL;
+ rte->perminfoindex = 0; /* no permission checking for this RTE */
+ rte->inh = false; /* must not be set for a subquery */
+
+ return rte;
+}
+
+/*
+ * make_delta_enr_name
+ *
+ * Make a name for ENR of a transition table from the base table's oid.
+ * prefix will be "new" or "old" depending on its transition table kind..
+ */
+static char*
+make_delta_enr_name(const char *prefix, Oid relid, int count)
+{
+ char buf[NAMEDATALEN];
+ char *name;
+
+ snprintf(buf, NAMEDATALEN, "__ivm_%s_%u_%u", prefix, relid, count);
+ name = pstrdup(buf);
+
+ return name;
+}
+
+/*
+ * replace_rte_with_delta
+ *
+ * Replace RTE of the modified table with a single table delta that combine its
+ * all transition tables.
+ */
+static RangeTblEntry*
+replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
+ QueryEnvironment *queryEnv)
+{
+ Oid relid = table->table_id;
+ StringInfoData str;
+ ParseState *pstate;
+ RawStmt *raw;
+ Query *sub;
+ int num_tuplestores = list_length(is_new ? table->new_tuplestores : table->old_tuplestores);
+ int i;
+
+ /* the previous RTE must be a subquery which represents "pre-state" table */
+ Assert(rte->rtekind == RTE_SUBQUERY);
+
+ /* Create a ParseState for rewriting the view definition query */
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ initStringInfo(&str);
+
+ for (i = 0; i < num_tuplestores; i++)
+ {
+ if (i > 0)
+ appendStringInfo(&str, " UNION ALL ");
+
+ appendStringInfo(&str,
+ " SELECT * FROM %s",
+ make_delta_enr_name(is_new ? "new" : "old", relid, i));
+ }
+
+ raw = (RawStmt*)linitial(raw_parser(str.data, RAW_PARSE_DEFAULT));
+ sub = transformStmt(pstate, raw->stmt);
+
+ /*
+ * Update the subquery so that it represent the combined transition
+ * table. Note that we leave the security_barrier and securityQuals
+ * fields so that the subquery relation can be protected by the RLS
+ * policy as same as the modified table.
+ */
+ rte->rtekind = RTE_SUBQUERY;
+ rte->subquery = sub;
+
+ return rte;
+}
+
+/*
+ * rewrite_query_for_counting
+ *
+ * Rewrite query for counting duplicated tuples.
+ */
+static Query *
+rewrite_query_for_counting(Query *query, ParseState *pstate)
+{
+ TargetEntry *tle_count;
+ FuncCall *fn;
+ Node *node;
+
+ /* Add count(*) for counting distinct tuples in views */
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+ fn->agg_star = true;
+ if (!query->groupClause && !query->hasAggs)
+ query->groupClause = transformDistinctClause(NULL, &query->targetList, query->sortClause, false);
+
+ node = ParseFuncOrColumn(pstate, fn->funcname, NIL, NULL, fn, false, -1);
+
+ tle_count = makeTargetEntry((Expr *) node,
+ list_length(query->targetList) + 1,
+ pstrdup("__ivm_count__"),
+ false);
+ query->targetList = lappend(query->targetList, tle_count);
+ query->hasAggs = true;
+
+ return query;
+}
+
+/*
+ * calc_delta
+ *
+ * Calculate view deltas generated under the modification of a table specified
+ * by the RTE index.
+ */
+static void
+calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
+ DestReceiver *dest_old, DestReceiver *dest_new,
+ TupleDesc *tupdesc_old, TupleDesc *tupdesc_new,
+ QueryEnvironment *queryEnv)
+{
+ ListCell *lc = list_nth_cell(query->rtable, rte_index - 1);
+ RangeTblEntry *rte = (RangeTblEntry *) lfirst(lc);
+
+ in_delta_calculation = true;
+
+ /* Generate old delta */
+ if (list_length(table->old_tuplestores) > 0)
+ {
+ /* Replace the modified table with the old delta table and calculate the old view delta. */
+ replace_rte_with_delta(rte, table, false, queryEnv);
+ refresh_matview_datafill(dest_old, query, queryEnv, tupdesc_old, "");
+ }
+
+ /* Generate new delta */
+ if (list_length(table->new_tuplestores) > 0)
+ {
+ /* Replace the modified table with the new delta table and calculate the new view delta*/
+ replace_rte_with_delta(rte, table, true, queryEnv);
+ refresh_matview_datafill(dest_new, query, queryEnv, tupdesc_new, "");
+ }
+
+ in_delta_calculation = false;
+}
+
+/*
+ * rewrite_query_for_postupdate_state
+ *
+ * Rewrite the query so that the specified base table's RTEs will represent
+ * "post-update" state of tables. This is called after the view delta
+ * calculation due to changes on this table finishes.
+ */
+static Query*
+rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte_index)
+{
+ ListCell *lc = list_nth_cell(query->rtable, rte_index - 1);
+
+ /* Retore the original RTE */
+ lfirst(lc) = table->original_rte;
+
+ return query;
+}
+
+/*
+ * apply_delta
+ *
+ * Apply deltas to the materialized view. In outer join cases, this requires
+ * the view maintenance graph.
+ */
+static void
+apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
+ TupleDesc tupdesc_old, TupleDesc tupdesc_new,
+ Query *query)
+{
+ StringInfoData querybuf;
+ StringInfoData target_list_buf;
+ Relation matviewRel;
+ char *matviewname;
+ ListCell *lc;
+ int i;
+ List *keys = NIL;
+
+
+ /*
+ * get names of the materialized view and delta tables
+ */
+
+ matviewRel = table_open(matviewOid, NoLock);
+ matviewname = quote_qualified_identifier(get_namespace_name(RelationGetNamespace(matviewRel)),
+ RelationGetRelationName(matviewRel));
+
+ /*
+ * Build parts of the maintenance queries
+ */
+
+ initStringInfo(&querybuf);
+ initStringInfo(&target_list_buf);
+
+ /* build string of target list */
+ for (i = 0; i < matviewRel->rd_att->natts; i++)
+ {
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
+
+ if (i != 0)
+ appendStringInfo(&target_list_buf, ", ");
+ appendStringInfo(&target_list_buf, "%s", quote_qualified_identifier(NULL, resname));
+ }
+
+ i = 0;
+ foreach (lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+
+ i++;
+
+ if (tle->resjunk)
+ continue;
+
+ keys = lappend(keys, attr);
+ }
+
+ /* Start maintaining the materialized view. */
+ OpenMatViewIncrementalMaintenance();
+
+ /* Open SPI context. */
+ if (SPI_connect() != SPI_OK_CONNECT)
+ elog(ERROR, "SPI_connect failed");
+
+ /* For tuple deletion */
+ if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
+ {
+ EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ int rc;
+
+ /* convert tuplestores to ENR, and register for SPI */
+ enr->md.name = pstrdup(OLD_DELTA_ENRNAME);
+ enr->md.reliddesc = InvalidOid;
+ enr->md.tupdesc = tupdesc_old;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(old_tuplestores);
+ enr->reldata = old_tuplestores;
+
+ rc = SPI_register_relation(enr);
+ if (rc != SPI_OK_REL_REGISTER)
+ elog(ERROR, "SPI_register failed");
+
+ apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+
+ }
+ /* For tuple insertion */
+ if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
+ {
+ EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ int rc;
+
+ /* convert tuplestores to ENR, and register for SPI */
+ enr->md.name = pstrdup(NEW_DELTA_ENRNAME);
+ enr->md.reliddesc = InvalidOid;
+ enr->md.tupdesc = tupdesc_new;;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(new_tuplestores);
+ enr->reldata = new_tuplestores;
+
+ rc = SPI_register_relation(enr);
+ if (rc != SPI_OK_REL_REGISTER)
+ elog(ERROR, "SPI_register failed");
+
+ /* apply new delta */
+ apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
+ }
+
+ /* We're done maintaining the materialized view. */
+ CloseMatViewIncrementalMaintenance();
+
+ table_close(matviewRel, NoLock);
+
+ /* Close SPI context. */
+ if (SPI_finish() != SPI_OK_FINISH)
+ elog(ERROR, "SPI_finish failed");
+}
+
+/*
+ * apply_old_delta
+ *
+ * Execute a query for applying a delta table given by deltname_old
+ * which contains tuples to be deleted from to a materialized view given by
+ * matviewname. This is used when counting is not required.
+ */
+static void
+apply_old_delta(const char *matviewname, const char *deltaname_old,
+ List *keys)
+{
+ StringInfoData querybuf;
+ StringInfoData keysbuf;
+ char *match_cond;
+ ListCell *lc;
+
+ /* build WHERE condition for searching tuples to be deleted */
+ match_cond = get_matching_condition_string(keys);
+
+ /* build string of keys list */
+ initStringInfo(&keysbuf);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&keysbuf, "%s", quote_qualified_identifier("mv", resname));
+ if (lnext(keys, lc))
+ appendStringInfo(&keysbuf, ", ");
+ }
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "DELETE FROM %s WHERE ctid IN ("
+ "SELECT tid FROM (SELECT pg_catalog.row_number() over (partition by %s) AS \"__ivm_row_number__\","
+ "mv.ctid AS tid,"
+ "diff.\"__ivm_count__\""
+ "FROM %s AS mv, %s AS diff "
+ "WHERE %s) v "
+ "WHERE v.\"__ivm_row_number__\" OPERATOR(pg_catalog.<=) v.\"__ivm_count__\")",
+ matviewname,
+ keysbuf.data,
+ matviewname, deltaname_old,
+ match_cond);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
+/*
+ * apply_new_delta
+ *
+ * Execute a query for applying a delta table given by deltname_new
+ * which contains tuples to be inserted into a materialized view given by
+ * matviewname. This is used when counting is not required.
+ */
+static void
+apply_new_delta(const char *matviewname, const char *deltaname_new,
+ StringInfo target_list)
+{
+ StringInfoData querybuf;
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "INSERT INTO %s (%s) SELECT %s FROM ("
+ "SELECT diff.*, pg_catalog.generate_series(1, diff.\"__ivm_count__\")"
+ " AS __ivm_generate_series__ "
+ "FROM %s AS diff) AS v",
+ matviewname, target_list->data, target_list->data,
+ deltaname_new);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_INSERT)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
+/*
+ * get_matching_condition_string
+ *
+ * Build a predicate string for looking for a tuple with given keys.
+ */
+static char *
+get_matching_condition_string(List *keys)
+{
+ StringInfoData match_cond;
+ ListCell *lc;
+
+ /* If there is no key columns, the condition is always true. */
+ if (keys == NIL)
+ return "true";
+
+ initStringInfo(&match_cond);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ char *mv_resname = quote_qualified_identifier("mv", resname);
+ char *diff_resname = quote_qualified_identifier("diff", resname);
+ Oid typid = attr->atttypid;
+
+ /* Considering NULL values, we can not use simple = operator. */
+ appendStringInfo(&match_cond, "(");
+ generate_equal(&match_cond, typid, mv_resname, diff_resname);
+ appendStringInfo(&match_cond, " OR (%s IS NULL AND %s IS NULL))",
+ mv_resname, diff_resname);
+
+ if (lnext(keys, lc))
+ appendStringInfo(&match_cond, " AND ");
+ }
+
+ return match_cond.data;
+}
+
+/*
+ * generate_equals
+ *
+ * Generate an equality clause using given operands' default equality
+ * operator.
+ */
+static void
+generate_equal(StringInfo querybuf, Oid opttype,
+ const char *leftop, const char *rightop)
+{
+ TypeCacheEntry *typentry;
+
+ typentry = lookup_type_cache(opttype, TYPECACHE_EQ_OPR);
+ if (!OidIsValid(typentry->eq_opr))
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_FUNCTION),
+ errmsg("could not identify an equality operator for type %s",
+ format_type_be_qualified(opttype))));
+
+ generate_operator_clause(querybuf,
+ leftop, opttype,
+ typentry->eq_opr,
+ rightop, opttype);
+}
+
+/*
+ * mv_InitHashTables
+ */
+static void
+mv_InitHashTables(void)
+{
+ HASHCTL ctl;
+
+ memset(&ctl, 0, sizeof(ctl));
+ ctl.keysize = sizeof(Oid);
+ ctl.entrysize = sizeof(MV_TriggerHashEntry);
+ mv_trigger_info = hash_create("MV trigger info",
+ MV_INIT_QUERYHASHSIZE,
+ &ctl, HASH_ELEM | HASH_BLOBS);
+}
+
+/*
+ * AtAbort_IVM
+ *
+ * Clean up hash entries for all materialized views. This is called at
+ * transaction abort.
+ */
+void
+AtAbort_IVM()
+{
+ HASH_SEQ_STATUS seq;
+ MV_TriggerHashEntry *entry;
+
+ if (mv_trigger_info)
+ {
+ hash_seq_init(&seq, mv_trigger_info);
+ while ((entry = hash_seq_search(&seq)) != NULL)
+ clean_up_IVM_hash_entry(entry, true);
+ }
+ in_delta_calculation = false;
+}
+
+/*
+ * clean_up_IVM_hash_entry
+ *
+ * Clean up tuple stores and hash entries for a materialized view after its
+ * maintenance finished.
+ */
+static void
+clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort)
+{
+ bool found;
+ ListCell *lc;
+
+ foreach(lc, entry->tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc);
+
+ list_free(table->old_tuplestores);
+ list_free(table->new_tuplestores);
+ if (!is_abort)
+ {
+ ExecDropSingleTupleTableSlot(table->slot);
+ table_close(table->rel, NoLock);
+ }
+ }
+ list_free(entry->tables);
+
+ if (!is_abort)
+ UnregisterSnapshot(entry->snapshot);
+
+ hash_search(mv_trigger_info, (void *) &entry->matview_id, HASH_REMOVE, &found);
+}
+
+/*
+ * isIvmName
+ *
+ * Check if this is a IVM hidden column from the name.
+ */
+bool
+isIvmName(const char *s)
+{
+ if (s)
+ return (strncmp(s, "__ivm_", 6) == 0);
+ return false;
+}
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index d4ac578ae6..ff7862796d 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -12185,4 +12185,14 @@
proargnames => '{summarized_tli,summarized_lsn,pending_lsn,summarizer_pid}',
prosrc => 'pg_get_wal_summarizer_state' },
+# IVM
+{ oid => '786', descr => 'ivm trigger (before)',
+ proname => 'IVM_immediate_before', provolatile => 'v', prorettype => 'trigger',
+ proargtypes => '', prosrc => 'IVM_immediate_before' },
+{ oid => '787', descr => 'ivm trigger (after)',
+ proname => 'IVM_immediate_maintenance', provolatile => 'v', prorettype => 'trigger',
+ proargtypes => '', prosrc => 'IVM_immediate_maintenance' },
+{ oid => '788', descr => 'ivm filetring ',
+ proname => 'ivm_visible_in_prestate', provolatile => 's', prorettype => 'bool',
+ proargtypes => 'oid tid oid', prosrc => 'ivm_visible_in_prestate' },
]
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 94678e3834..396ad1bb4c 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -16,6 +16,7 @@
#include "catalog/objectaddress.h"
#include "nodes/params.h"
+#include "nodes/pathnodes.h"
#include "parser/parse_node.h"
#include "tcop/dest.h"
#include "utils/queryenvironment.h"
@@ -25,6 +26,9 @@ extern ObjectAddress ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *st
ParamListInfo params, QueryEnvironment *queryEnv,
QueryCompletion *qc);
+extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
+extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
+
extern int GetIntoRelEFlags(IntoClause *intoClause);
extern DestReceiver *CreateIntoRelDestReceiver(IntoClause *intoClause);
diff --git a/src/include/commands/matview.h b/src/include/commands/matview.h
index 817b2ba0b6..3257e1adff 100644
--- a/src/include/commands/matview.h
+++ b/src/include/commands/matview.h
@@ -15,6 +15,7 @@
#define MATVIEW_H
#include "catalog/objectaddress.h"
+#include "fmgr.h"
#include "nodes/params.h"
#include "nodes/parsenodes.h"
#include "tcop/dest.h"
@@ -23,6 +24,8 @@
extern void SetMatViewPopulatedState(Relation relation, bool newstate);
+extern void SetMatViewIVMState(Relation relation, bool newstate);
+
extern ObjectAddress ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
ParamListInfo params, QueryCompletion *qc);
@@ -30,4 +33,10 @@ extern DestReceiver *CreateTransientRelDestReceiver(Oid transientoid);
extern bool MatViewIncrementalMaintenanceIsEnabled(void);
+extern Datum IVM_immediate_before(PG_FUNCTION_ARGS);
+extern Datum IVM_immediate_maintenance(PG_FUNCTION_ARGS);
+extern Datum IVM_visible_in_prestate(PG_FUNCTION_ARGS);
+extern void AtAbort_IVM(void);
+extern bool isIvmName(const char *s);
+
#endif /* MATVIEW_H */
--
2.25.1
v33-0005-Add-Incremental-View-Maintenance-support-to-psql.patchtext/x-diff; name=v33-0005-Add-Incremental-View-Maintenance-support-to-psql.patchDownload
From a0bcb9537f75adf7af9754fb56e4ffb348b2dcfb Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:21:54 +0900
Subject: [PATCH v33 05/11] Add Incremental View Maintenance support to psql
Add tab completion and meta-command output for IVM.
---
src/bin/psql/describe.c | 32 +++++++++++++++++++++++++++++++-
src/bin/psql/tab-complete.c | 14 +++++++++-----
2 files changed, 40 insertions(+), 6 deletions(-)
diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c
index 7c9a1f234c..7aef397394 100644
--- a/src/bin/psql/describe.c
+++ b/src/bin/psql/describe.c
@@ -1574,6 +1574,7 @@ describeOneTableDetails(const char *schemaname,
char relpersistence;
char relreplident;
char *relam;
+ bool isivm;
} tableinfo;
bool show_column_details = false;
@@ -1586,7 +1587,26 @@ describeOneTableDetails(const char *schemaname,
initPQExpBuffer(&tmpbuf);
/* Get general table info */
- if (pset.sversion >= 120000)
+ if (pset.sversion >= 170000)
+ {
+ printfPQExpBuffer(&buf,
+ "SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
+ "c.relhastriggers, c.relrowsecurity, c.relforcerowsecurity, "
+ "false AS relhasoids, c.relispartition, %s, c.reltablespace, "
+ "CASE WHEN c.reloftype = 0 THEN '' ELSE c.reloftype::pg_catalog.regtype::pg_catalog.text END, "
+ "c.relpersistence, c.relreplident, am.amname, "
+ "c.relisivm\n"
+ "FROM pg_catalog.pg_class c\n "
+ "LEFT JOIN pg_catalog.pg_class tc ON (c.reltoastrelid = tc.oid)\n"
+ "LEFT JOIN pg_catalog.pg_am am ON (c.relam = am.oid)\n"
+ "WHERE c.oid = '%s';",
+ (verbose ?
+ "pg_catalog.array_to_string(c.reloptions || "
+ "array(select 'toast.' || x from pg_catalog.unnest(tc.reloptions) x), ', ')\n"
+ : "''"),
+ oid);
+ }
+ else if (pset.sversion >= 120000)
{
printfPQExpBuffer(&buf,
"SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
@@ -1706,6 +1726,10 @@ describeOneTableDetails(const char *schemaname,
(char *) NULL : pg_strdup(PQgetvalue(res, 0, 14));
else
tableinfo.relam = NULL;
+ if (pset.sversion >= 170000)
+ tableinfo.isivm = strcmp(PQgetvalue(res, 0, 15), "t") == 0;
+ else
+ tableinfo.isivm = false;
PQclear(res);
res = NULL;
@@ -3508,6 +3532,12 @@ describeOneTableDetails(const char *schemaname,
printfPQExpBuffer(&buf, _("Access method: %s"), tableinfo.relam);
printTableAddFooter(&cont, buf.data);
}
+
+ /* Incremental view maintance info */
+ if (verbose && tableinfo.relkind == RELKIND_MATVIEW && tableinfo.isivm)
+ {
+ printTableAddFooter(&cont, _("Incremental view maintenance: yes"));
+ }
}
/* reloptions, if verbose */
diff --git a/src/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c
index d453e224d9..5fc88b59a9 100644
--- a/src/bin/psql/tab-complete.c
+++ b/src/bin/psql/tab-complete.c
@@ -1245,6 +1245,7 @@ static const pgsql_thing_t words_after_create[] = {
{"FOREIGN TABLE", NULL, NULL, NULL},
{"FUNCTION", NULL, NULL, Query_for_list_of_functions},
{"GROUP", Query_for_list_of_roles},
+ {"INCREMENTAL MATERIALIZED VIEW", NULL, NULL, &Query_for_list_of_matviews, NULL, THING_NO_DROP | THING_NO_ALTER},
{"INDEX", NULL, NULL, &Query_for_list_of_indexes},
{"LANGUAGE", Query_for_list_of_languages},
{"LARGE OBJECT", NULL, NULL, NULL, NULL, THING_NO_CREATE | THING_NO_DROP},
@@ -3274,7 +3275,7 @@ psql_completion(const char *text, int start, int end)
if (HeadMatches("CREATE", "SCHEMA"))
COMPLETE_WITH("TABLE", "SEQUENCE");
else
- COMPLETE_WITH("TABLE", "SEQUENCE", "MATERIALIZED VIEW");
+ COMPLETE_WITH("TABLE", "SEQUENCE", "MATERIALIZED VIEW", "INCREMENTAL MATERIALIZED VIEW");
}
/* Complete PARTITION BY with RANGE ( or LIST ( or ... */
else if (TailMatches("PARTITION", "BY"))
@@ -3619,13 +3620,16 @@ psql_completion(const char *text, int start, int end)
COMPLETE_WITH("SELECT");
/* CREATE MATERIALIZED VIEW */
- else if (Matches("CREATE", "MATERIALIZED"))
+ else if (Matches("CREATE", "MATERIALIZED") ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED"))
COMPLETE_WITH("VIEW");
- /* Complete CREATE MATERIALIZED VIEW <name> with AS */
- else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny))
+ /* Complete CREATE MATERIALIZED VIEW <name> with AS */
+ else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny) ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED", "VIEW", MatchAny))
COMPLETE_WITH("AS");
/* Complete "CREATE MATERIALIZED VIEW <sth> AS with "SELECT" */
- else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny, "AS"))
+ else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny, "AS") ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED", "VIEW", MatchAny, "AS"))
COMPLETE_WITH("SELECT");
/* CREATE EVENT TRIGGER */
--
2.25.1
v33-0004-Add-Incremental-View-Maintenance-support-to-pg_d.patchtext/x-diff; name=v33-0004-Add-Incremental-View-Maintenance-support-to-pg_d.patchDownload
From 302b09c32f8132088c3abf3d60a735ab737616b2 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 11 Nov 2020 17:01:25 +0900
Subject: [PATCH v33 04/11] Add Incremental View Maintenance support to pg_dump
Support CREATE INCREMENTAL MATERIALIZED VIEW syntax.
---
src/bin/pg_dump/pg_dump.c | 18 +++++++++++++++---
src/bin/pg_dump/pg_dump.h | 2 ++
src/bin/pg_dump/t/002_pg_dump.pl | 18 ++++++++++++++++++
3 files changed, 35 insertions(+), 3 deletions(-)
diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c
index e324070828..c2e1f761dc 100644
--- a/src/bin/pg_dump/pg_dump.c
+++ b/src/bin/pg_dump/pg_dump.c
@@ -6740,6 +6740,7 @@ getTables(Archive *fout, int *numTables)
int i_relacl;
int i_acldefault;
int i_ispartition;
+ int i_isivm;
/*
* Find all the tables and table-like objects.
@@ -6842,10 +6843,17 @@ getTables(Archive *fout, int *numTables)
if (fout->remoteVersion >= 100000)
appendPQExpBufferStr(query,
- "c.relispartition AS ispartition ");
+ "c.relispartition AS ispartition, ");
else
appendPQExpBufferStr(query,
- "false AS ispartition ");
+ "false AS ispartition, ");
+
+ if (fout->remoteVersion >= 170000)
+ appendPQExpBufferStr(query,
+ "c.relisivm AS isivm ");
+ else
+ appendPQExpBufferStr(query,
+ "false AS isivm ");
/*
* Left join to pg_depend to pick up dependency info linking sequences to
@@ -6954,6 +6962,7 @@ getTables(Archive *fout, int *numTables)
i_relacl = PQfnumber(res, "relacl");
i_acldefault = PQfnumber(res, "acldefault");
i_ispartition = PQfnumber(res, "ispartition");
+ i_isivm = PQfnumber(res, "isivm");
if (dopt->lockWaitTimeout)
{
@@ -7033,6 +7042,7 @@ getTables(Archive *fout, int *numTables)
tblinfo[i].amname = pg_strdup(PQgetvalue(res, i, i_amname));
tblinfo[i].is_identity_sequence = (strcmp(PQgetvalue(res, i, i_is_identity_sequence), "t") == 0);
tblinfo[i].ispartition = (strcmp(PQgetvalue(res, i, i_ispartition), "t") == 0);
+ tblinfo[i].isivm = (strcmp(PQgetvalue(res, i, i_isivm), "t") == 0);
/* other fields were zeroed above */
@@ -15906,9 +15916,11 @@ dumpTableSchema(Archive *fout, const TableInfo *tbinfo)
binary_upgrade_set_pg_class_oids(fout, q,
tbinfo->dobj.catId.oid, false);
- appendPQExpBuffer(q, "CREATE %s%s %s",
+ appendPQExpBuffer(q, "CREATE %s%s%s %s",
tbinfo->relpersistence == RELPERSISTENCE_UNLOGGED ?
"UNLOGGED " : "",
+ tbinfo->relkind == RELKIND_MATVIEW && tbinfo->isivm ?
+ "INCREMENTAL " : "",
reltypename,
qualrelname);
diff --git a/src/bin/pg_dump/pg_dump.h b/src/bin/pg_dump/pg_dump.h
index 865823868f..7eac1e7c6f 100644
--- a/src/bin/pg_dump/pg_dump.h
+++ b/src/bin/pg_dump/pg_dump.h
@@ -325,6 +325,8 @@ typedef struct _tableInfo
int numParents; /* number of (immediate) parent tables */
struct _tableInfo **parents; /* TableInfos of immediate parents */
+ bool isivm; /* is incrementally maintainable materialized view? */
+
/*
* These fields are computed only if we decide the table is interesting
* (it's either a table to dump, or a direct parent of a dumpable table).
diff --git a/src/bin/pg_dump/t/002_pg_dump.pl b/src/bin/pg_dump/t/002_pg_dump.pl
index d3dd8784d6..62fc9b5bc4 100644
--- a/src/bin/pg_dump/t/002_pg_dump.pl
+++ b/src/bin/pg_dump/t/002_pg_dump.pl
@@ -2785,6 +2785,24 @@ my %tests = (
},
},
+ 'CREATE MATERIALIZED VIEW matview_ivm' => {
+ create_order => 21,
+ create_sql => 'CREATE INCREMENTAL MATERIALIZED VIEW dump_test.matview_ivm (col1) AS
+ SELECT col1 FROM dump_test.test_table;',
+ regexp => qr/^
+ \QCREATE INCREMENTAL MATERIALIZED VIEW dump_test.matview_ivm AS\E
+ \n\s+\QSELECT col1\E
+ \n\s+\QFROM dump_test.test_table\E
+ \n\s+\QWITH NO DATA;\E
+ /xm,
+ like =>
+ { %full_runs, %dump_test_schema_runs, section_pre_data => 1, },
+ unlike => {
+ exclude_dump_test_schema => 1,
+ only_dump_measurement => 1,
+ },
+ },
+
'CREATE POLICY p1 ON test_table' => {
create_order => 22,
create_sql => 'CREATE POLICY p1 ON dump_test.test_table
--
2.25.1
v33-0003-Allow-to-prolong-life-span-of-transition-tables-.patchtext/x-diff; name=v33-0003-Allow-to-prolong-life-span-of-transition-tables-.patchDownload
From 718f5877f55b9a042c163b84e042651bfc5c1b8e Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:09:45 +0900
Subject: [PATCH v33 03/11] Allow to prolong life span of transition tables
until transaction end
Originally, tuplestores of AFTER trigger's transition tables were
freed for each query depth. For our IVM implementation, we would like
to prolong life of the tuplestores because we have to preserve them
for a whole query assuming that some base tables might be changed
in some trigger functions.
---
src/backend/commands/trigger.c | 83 ++++++++++++++++++++++++++++++++--
src/include/commands/trigger.h | 2 +
2 files changed, 81 insertions(+), 4 deletions(-)
diff --git a/src/backend/commands/trigger.c b/src/backend/commands/trigger.c
index 58b7fc5bbd..bd4a2219a4 100644
--- a/src/backend/commands/trigger.c
+++ b/src/backend/commands/trigger.c
@@ -3753,6 +3753,10 @@ typedef struct AfterTriggerEventList
* end of the list, so it is relatively easy to discard them. The event
* list chunks themselves are stored in event_cxt.
*
+ * prolonged_tuplestored is a list of transition table tuplestores whose
+ * life are prolonged to the end of the outmost query instead of each nested
+ * query.
+ *
* query_depth is the current depth of nested AfterTriggerBeginQuery calls
* (-1 when the stack is empty).
*
@@ -3818,6 +3822,7 @@ typedef struct AfterTriggersData
SetConstraintState state; /* the active S C state */
AfterTriggerEventList events; /* deferred-event list */
MemoryContext event_cxt; /* memory context for events, if any */
+ List *prolonged_tuplestores; /* list of prolonged tuplestores */
/* per-query-level data: */
AfterTriggersQueryData *query_stack; /* array of structs shown below */
@@ -3853,6 +3858,7 @@ struct AfterTriggersTableData
bool closed; /* true when no longer OK to add tuples */
bool before_trig_done; /* did we already queue BS triggers? */
bool after_trig_done; /* did we already queue AS triggers? */
+ bool prolonged; /* are transition tables prolonged? */
AfterTriggerEventList after_trig_events; /* if so, saved list pointer */
/*
@@ -3902,6 +3908,7 @@ static void TransitionTableAddTuple(EState *estate,
TupleTableSlot *original_insert_tuple,
Tuplestorestate *tuplestore);
static void AfterTriggerFreeQuery(AfterTriggersQueryData *qs);
+static void release_or_prolong_tuplestore(Tuplestorestate *ts, bool prolonged);
static SetConstraintState SetConstraintStateCreate(int numalloc);
static SetConstraintState SetConstraintStateCopy(SetConstraintState origstate);
static SetConstraintState SetConstraintStateAddItem(SetConstraintState state,
@@ -4781,6 +4788,45 @@ afterTriggerInvokeEvents(AfterTriggerEventList *events,
}
+/*
+ * SetTransitionTablePreserved
+ *
+ * Prolong lifespan of transition tables corresponding specified relid and
+ * command type to the end of the outmost query instead of each nested query.
+ * This enables to use nested AFTER trigger's transition tables from outer
+ * query's triggers. Currently, only immediate incremental view maintenance
+ * uses this.
+ */
+void
+SetTransitionTablePreserved(Oid relid, CmdType cmdType)
+{
+ AfterTriggersTableData *table;
+ AfterTriggersQueryData *qs;
+ bool found = false;
+ ListCell *lc;
+
+ /* Check state, like AfterTriggerSaveEvent. */
+ if (afterTriggers.query_depth < 0)
+ elog(ERROR, "SetTransitionTablePreserved() called outside of query");
+
+ qs = &afterTriggers.query_stack[afterTriggers.query_depth];
+
+ foreach(lc, qs->tables)
+ {
+ table = (AfterTriggersTableData *) lfirst(lc);
+ if (table->relid == relid && table->cmdType == cmdType &&
+ table->closed)
+ {
+ table->prolonged = true;
+ found = true;
+ }
+ }
+
+ if (!found)
+ elog(ERROR,"could not find table with OID %d and command type %d", relid, cmdType);
+}
+
+
/*
* GetAfterTriggersTableData
*
@@ -4991,6 +5037,7 @@ AfterTriggerBeginXact(void)
*/
afterTriggers.firing_counter = (CommandId) 1; /* mustn't be 0 */
afterTriggers.query_depth = -1;
+ afterTriggers.prolonged_tuplestores = NIL;
/*
* Verify that there is no leftover state remaining. If these assertions
@@ -5151,19 +5198,19 @@ AfterTriggerFreeQuery(AfterTriggersQueryData *qs)
ts = table->old_upd_tuplestore;
table->old_upd_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->new_upd_tuplestore;
table->new_upd_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->old_del_tuplestore;
table->old_del_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->new_ins_tuplestore;
table->new_ins_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
if (table->storeslot)
{
TupleTableSlot *slot = table->storeslot;
@@ -5180,6 +5227,34 @@ AfterTriggerFreeQuery(AfterTriggersQueryData *qs)
*/
qs->tables = NIL;
list_free_deep(tables);
+
+ /* Release prolonged tuplestores at the end of the outmost query */
+ if (afterTriggers.query_depth == 0)
+ {
+ foreach(lc, afterTriggers.prolonged_tuplestores)
+ {
+ ts = (Tuplestorestate *) lfirst(lc);
+ if (ts)
+ tuplestore_end(ts);
+ }
+ afterTriggers.prolonged_tuplestores = NIL;
+ }
+}
+
+/*
+ * Release the tuplestore, or append it to the prolonged tuplestores list.
+ */
+static void
+release_or_prolong_tuplestore(Tuplestorestate *ts, bool prolonged)
+{
+ if (prolonged && afterTriggers.query_depth > 0)
+ {
+ MemoryContext oldcxt = MemoryContextSwitchTo(CurTransactionContext);
+ afterTriggers.prolonged_tuplestores = lappend(afterTriggers.prolonged_tuplestores, ts);
+ MemoryContextSwitchTo(oldcxt);
+ }
+ else
+ tuplestore_end(ts);
}
diff --git a/src/include/commands/trigger.h b/src/include/commands/trigger.h
index 8a5a9fe642..6718514d34 100644
--- a/src/include/commands/trigger.h
+++ b/src/include/commands/trigger.h
@@ -265,6 +265,8 @@ extern void AfterTriggerEndSubXact(bool isCommit);
extern void AfterTriggerSetState(ConstraintsSetStmt *stmt);
extern bool AfterTriggerPendingOnRel(Oid relid);
+extern void SetTransitionTablePreserved(Oid relid, CmdType cmdType);
+
/*
* in utils/adt/ri_triggers.c
--
2.25.1
On Tue, 2 Jul 2024 17:03:11 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:
On Sun, 31 Mar 2024 22:59:31 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:Also, I added a comment on RelationIsIVM() macro persuggestion from jian he.
In addition, I fixed a failure reported from cfbot on FreeBSD build caused by;WARNING: outfuncs/readfuncs failed to produce an equal rewritten parse tree
This warning was raised since I missed to modify outfuncs.c for a new field.
I found cfbot on FreeBSD still reported a failure due to
ENFORCE_REGRESSION_TEST_NAME_RESTRICTIONS because the regression test used
wrong role names. Attached is a fixed version, v32.Attached is a rebased version, v33.
I updated the patch to bump up the version numbers in psql and pg_dump codes
from 17 to 18.
Regards,
Yugo Nagata
Regards,
Yugo Nagata--
Yugo NAGATA <nagata@sraoss.co.jp>
--
Yugo NAGATA <nagata@sraoss.co.jp>
Attachments:
v34-0009-Add-support-for-min-max-aggregates-for-IVM.patchtext/x-diff; name=v34-0009-Add-support-for-min-max-aggregates-for-IVM.patchDownload
From dc01ff88ba309095bdff2c458beb2b26af36a2b6 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 20:58:25 +0900
Subject: [PATCH v34 09/11] Add support for min/max aggregates for IVM
Supporting min and max is more complicated than count, sum, or avg.
For an example of min, when tuples are inserted, the current min value
in the view and the min value in the inseteted tuples are compared,
then the smaller one is used as the latest min value. On the other
hand, when tuples are deleted, if the current min value in the view
equals to the min in the deleted tuples, we need re-computation the
latest min value from base tables. Otherwise, the current value in
the view remains.
---
src/backend/commands/createas.c | 45 +++
src/backend/commands/matview.c | 644 +++++++++++++++++++++++++++++++-
2 files changed, 680 insertions(+), 9 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index d8767137d9..abce06d046 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -1309,6 +1309,51 @@ check_aggregate_supports_ivm(Oid aggfnoid)
case F_AVG_FLOAT8:
case F_AVG_INTERVAL:
+ /* min */
+ case F_MIN_ANYARRAY:
+ case F_MIN_INT8:
+ case F_MIN_INT4:
+ case F_MIN_INT2:
+ case F_MIN_OID:
+ case F_MIN_FLOAT4:
+ case F_MIN_FLOAT8:
+ case F_MIN_DATE:
+ case F_MIN_TIME:
+ case F_MIN_TIMETZ:
+ case F_MIN_MONEY:
+ case F_MIN_TIMESTAMP:
+ case F_MIN_TIMESTAMPTZ:
+ case F_MIN_INTERVAL:
+ case F_MIN_TEXT:
+ case F_MIN_NUMERIC:
+ case F_MIN_BPCHAR:
+ case F_MIN_TID:
+ case F_MIN_ANYENUM:
+ case F_MIN_INET:
+ case F_MIN_PG_LSN:
+
+ /* max */
+ case F_MAX_ANYARRAY:
+ case F_MAX_INT8:
+ case F_MAX_INT4:
+ case F_MAX_INT2:
+ case F_MAX_OID:
+ case F_MAX_FLOAT4:
+ case F_MAX_FLOAT8:
+ case F_MAX_DATE:
+ case F_MAX_TIME:
+ case F_MAX_TIMETZ:
+ case F_MAX_MONEY:
+ case F_MAX_TIMESTAMP:
+ case F_MAX_TIMESTAMPTZ:
+ case F_MAX_INTERVAL:
+ case F_MAX_TEXT:
+ case F_MAX_NUMERIC:
+ case F_MAX_BPCHAR:
+ case F_MAX_TID:
+ case F_MAX_ANYENUM:
+ case F_MAX_INET:
+ case F_MAX_PG_LSN:
return true;
default:
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index ca6d236989..8cd7ed3b68 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -69,6 +69,34 @@ typedef struct
#define MV_INIT_QUERYHASHSIZE 16
+/* MV query type codes */
+#define MV_PLAN_RECALC 1
+#define MV_PLAN_SET_VALUE 2
+
+/*
+ * MI_QueryKey
+ *
+ * The key identifying a prepared SPI plan in our query hashtable
+ */
+typedef struct MV_QueryKey
+{
+ Oid matview_id; /* OID of materialized view */
+ int32 query_type; /* query type ID, see MV_PLAN_XXX above */
+} MV_QueryKey;
+
+/*
+ * MV_QueryHashEntry
+ *
+ * Hash entry for cached plans used to maintain materialized views.
+ */
+typedef struct MV_QueryHashEntry
+{
+ MV_QueryKey key;
+ SPIPlanPtr plan;
+ SearchPathMatcher *search_path; /* search_path used for parsing
+ * and planning */
+} MV_QueryHashEntry;
+
/*
* MV_TriggerHashEntry
*
@@ -105,6 +133,7 @@ typedef struct MV_TriggerTable
TupleTableSlot *slot; /* for checking visibility in the pre-state table */
} MV_TriggerTable;
+static HTAB *mv_query_cache = NULL;
static HTAB *mv_trigger_info = NULL;
static bool in_delta_calculation = false;
@@ -165,6 +194,9 @@ static void append_set_clause_for_sum(const char *resname, StringInfo buf_old,
static void append_set_clause_for_avg(const char *resname, StringInfo buf_old,
StringInfo buf_new, StringInfo aggs_list,
const char *aggtype);
+static void append_set_clause_for_minmax(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ bool is_min);
static char *get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
const char* count_col, const char *castType);
static char *get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
@@ -173,17 +205,30 @@ static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
List *keys, StringInfo aggs_list, StringInfo aggs_set,
- const char *count_colname);
+ List *minmax_list, List *is_min_list,
+ const char *count_colname,
+ SPITupleTable **tuptable_recalc, uint64 *num_recalc);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
List *keys, StringInfo target_list, StringInfo aggs_set,
const char* count_colname);
static char *get_matching_condition_string(List *keys);
+static char *get_returning_string(List *minmax_list, List *is_min_list, List *keys);
+static char *get_minmax_recalc_condition_string(List *minmax_list, List *is_min_list);
+static char *get_select_for_recalc_string(List *keys);
+static void recalc_and_set_values(SPITupleTable *tuptable_recalc, int64 num_tuples,
+ List *namelist, List *keys, Relation matviewRel);
+static SPIPlanPtr get_plan_for_recalc(Oid matviewOid, List *namelist, List *keys, Oid *keyTypes);
+static SPIPlanPtr get_plan_for_set_values(Oid matviewOid, char *matviewname, List *namelist,
+ Oid *valTypes);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
static void mv_InitHashTables(void);
+static SPIPlanPtr mv_FetchPreparedPlan(MV_QueryKey *key);
+static void mv_HashPreparedPlan(MV_QueryKey *key, SPIPlanPtr plan);
+static void mv_BuildQueryKey(MV_QueryKey *key, Oid matview_id, int32 query_type);
static void clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort);
/*
@@ -2124,6 +2169,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
ListCell *lc;
int i;
List *keys = NIL;
+ List *minmax_list = NIL;
+ List *is_min_list = NIL;
/*
@@ -2205,6 +2252,17 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
append_set_clause_for_avg(resname, aggs_set_old, aggs_set_new, aggs_list_buf,
format_type_be(aggref->aggtype));
+ /* min/max */
+ else if (!strcmp(aggname, "min") || !strcmp(aggname, "max"))
+ {
+ bool is_min = (!strcmp(aggname, "min"));
+
+ append_set_clause_for_minmax(resname, aggs_set_old, aggs_set_new, aggs_list_buf, is_min);
+
+ /* make a resname list of min and max aggregates */
+ minmax_list = lappend(minmax_list, resname);
+ is_min_list = lappend_int(is_min_list, is_min);
+ }
else
elog(ERROR, "unsupported aggregate function: %s", aggname);
}
@@ -2234,6 +2292,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
{
EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ SPITupleTable *tuptable_recalc = NULL;
+ uint64 num_recalc;
int rc;
/* convert tuplestores to ENR, and register for SPI */
@@ -2252,10 +2312,18 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
/* apply old delta and get rows to be recalculated */
apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
keys, aggs_list_buf, aggs_set_old,
- count_colname);
+ minmax_list, is_min_list,
+ count_colname, &tuptable_recalc, &num_recalc);
else
apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+ /*
+ * If we have min or max, we might have to recalculate aggregate values from base tables
+ * on some tuples. TIDs and keys such tuples are returned as a result of the above query.
+ */
+ if (minmax_list && tuptable_recalc)
+ recalc_and_set_values(tuptable_recalc, num_recalc, minmax_list, keys, matviewRel);
+
}
/* For tuple insertion */
if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
@@ -2447,6 +2515,70 @@ append_set_clause_for_avg(const char *resname, StringInfo buf_old,
);
}
+/*
+ * append_set_clause_for_minmax
+ *
+ * Append SET clause string for min or max aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ * is_min is true if this is min, false if not.
+ */
+static void
+append_set_clause_for_minmax(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ bool is_min)
+{
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /*
+ * If the new value doesn't became NULL then use the value remaining
+ * in the view although this will be recomputated afterwords.
+ */
+ appendStringInfo(buf_old,
+ ", %s = CASE WHEN %s THEN NULL ELSE %s END",
+ quote_qualified_identifier(NULL, resname),
+ get_null_condition_string(IVM_SUB, "mv", "t", count_col),
+ quote_qualified_identifier("mv", resname)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /*
+ * min = LEAST(mv.min, diff.min)
+ * max = GREATEST(mv.max, diff.max)
+ */
+ appendStringInfo(buf_new,
+ ", %s = CASE WHEN %s THEN NULL ELSE %s(%s,%s) END",
+ quote_qualified_identifier(NULL, resname),
+ get_null_condition_string(IVM_ADD, "mv", "diff", count_col),
+
+ is_min ? "LEAST" : "GREATEST",
+ quote_qualified_identifier("mv", resname),
+ quote_qualified_identifier("diff", resname)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
/*
* get_operation_string
*
@@ -2549,19 +2681,44 @@ get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
* list to identify a tuple in the view. If the view has aggregates, this
* requires strings representing resnames of aggregates and SET clause for
* updating aggregate values.
+ *
+ * If the view has min or max aggregate, this requires a list of resnames of
+ * min/max aggregates and a list of boolean which represents which entries in
+ * minmax_list is min. These are necessary to check if we need to recalculate
+ * min or max aggregate values. In this case, this query returns TID and keys
+ * of tuples which need to be recalculated. This result and the number of rows
+ * are stored in tuptables and num_recalc repectedly.
+ *
*/
static void
apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
List *keys, StringInfo aggs_list, StringInfo aggs_set,
- const char *count_colname)
+ List *minmax_list, List *is_min_list,
+ const char *count_colname,
+ SPITupleTable **tuptable_recalc, uint64 *num_recalc)
{
StringInfoData querybuf;
char *match_cond;
+ char *updt_returning = "";
+ char *select_for_recalc = "SELECT";
bool agg_without_groupby = (list_length(keys) == 0);
+ Assert(tuptable_recalc != NULL);
+ Assert(num_recalc != NULL);
+
/* build WHERE condition for searching tuples to be deleted */
match_cond = get_matching_condition_string(keys);
+ /*
+ * We need a special RETURNING clause and SELECT statement for min/max to
+ * check which tuple needs re-calculation from base tables.
+ */
+ if (minmax_list)
+ {
+ updt_returning = get_returning_string(minmax_list, is_min_list, keys);
+ select_for_recalc = get_select_for_recalc_string(keys);
+ }
+
/* Search for matching tuples from the view and update or delete if found. */
initStringInfo(&querybuf);
appendStringInfo(&querybuf,
@@ -2576,10 +2733,11 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
"%s" /* SET clauses for aggregates */
"FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
- ")"
- /* delete a tuple if this is to be deleted */
- "DELETE FROM %s AS mv USING t "
- "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
+ "%s" /* RETURNING clause for recalc infomation */
+ "), dlt AS (" /* delete a tuple if this is to be deleted */
+ "DELETE FROM %s AS mv USING t "
+ "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt"
+ ") %s", /* SELECT returning which tuples need to be recalculated */
count_colname,
count_colname, count_colname, (agg_without_groupby ? "false" : "true"),
(aggs_list != NULL ? aggs_list->data : ""),
@@ -2587,10 +2745,25 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
match_cond,
matviewname, count_colname, count_colname, count_colname,
(aggs_set != NULL ? aggs_set->data : ""),
- matviewname);
+ updt_returning,
+ matviewname,
+ select_for_recalc);
- if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_SELECT)
elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+
+
+ /* Return tuples to be recalculated. */
+ if (minmax_list)
+ {
+ *tuptable_recalc = SPI_tuptable;
+ *num_recalc = SPI_processed;
+ }
+ else
+ {
+ *tuptable_recalc = NULL;
+ *num_recalc = 0;
+ }
}
/*
@@ -2773,6 +2946,349 @@ get_matching_condition_string(List *keys)
return match_cond.data;
}
+/*
+ * get_returning_string
+ *
+ * Build a string for RETURNING clause of UPDATE used in apply_old_delta_with_count.
+ * This clause returns ctid and a boolean value that indicates if we need to
+ * recalculate min or max value, for each updated row.
+ */
+static char *
+get_returning_string(List *minmax_list, List *is_min_list, List *keys)
+{
+ StringInfoData returning;
+ char *recalc_cond;
+ ListCell *lc;
+
+ Assert(minmax_list != NIL && is_min_list != NIL);
+ recalc_cond = get_minmax_recalc_condition_string(minmax_list, is_min_list);
+
+ initStringInfo(&returning);
+
+ appendStringInfo(&returning, "RETURNING mv.ctid AS tid, (%s) AS recalc", recalc_cond);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&returning, ", %s", quote_qualified_identifier("mv", resname));
+ }
+
+ return returning.data;
+}
+
+/*
+ * get_minmax_recalc_condition_string
+ *
+ * Build a predicate string for checking if any min/max aggregate
+ * value needs to be recalculated.
+ */
+static char *
+get_minmax_recalc_condition_string(List *minmax_list, List *is_min_list)
+{
+ StringInfoData recalc_cond;
+ ListCell *lc1, *lc2;
+
+ initStringInfo(&recalc_cond);
+
+ Assert (list_length(minmax_list) == list_length(is_min_list));
+
+ forboth (lc1, minmax_list, lc2, is_min_list)
+ {
+ char *resname = (char *) lfirst(lc1);
+ bool is_min = (bool) lfirst_int(lc2);
+ char *op_str = (is_min ? ">=" : "<=");
+
+ appendStringInfo(&recalc_cond, "%s OPERATOR(pg_catalog.%s) %s",
+ quote_qualified_identifier("mv", resname),
+ op_str,
+ quote_qualified_identifier("t", resname)
+ );
+
+ if (lnext(minmax_list, lc1))
+ appendStringInfo(&recalc_cond, " OR ");
+ }
+
+ return recalc_cond.data;
+}
+
+/*
+ * get_select_for_recalc_string
+ *
+ * Build a query to return tid and keys of tuples which need
+ * recalculation. This is used as the result of the query
+ * built by apply_old_delta.
+ */
+static char *
+get_select_for_recalc_string(List *keys)
+{
+ StringInfoData qry;
+ ListCell *lc;
+
+ initStringInfo(&qry);
+
+ appendStringInfo(&qry, "SELECT tid");
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ appendStringInfo(&qry, ", %s", NameStr(attr->attname));
+ }
+
+ appendStringInfo(&qry, " FROM updt WHERE recalc");
+
+ return qry.data;
+}
+
+/*
+ * recalc_and_set_values
+ *
+ * Recalculate tuples in a materialized from base tables and update these.
+ * The tuples which needs recalculation are specified by keys, and resnames
+ * of columns to be updated are specified by namelist. TIDs and key values
+ * are given by tuples in tuptable_recalc. Its first attribute must be TID
+ * and key values must be following this.
+ */
+static void
+recalc_and_set_values(SPITupleTable *tuptable_recalc, int64 num_tuples,
+ List *namelist, List *keys, Relation matviewRel)
+{
+ TupleDesc tupdesc_recalc = tuptable_recalc->tupdesc;
+ Oid *keyTypes = NULL, *types = NULL;
+ char *keyNulls = NULL, *nulls = NULL;
+ Datum *keyVals = NULL, *vals = NULL;
+ int num_vals = list_length(namelist);
+ int num_keys = list_length(keys);
+ uint64 i;
+ Oid matviewOid;
+ char *matviewname;
+
+ matviewOid = RelationGetRelid(matviewRel);
+ matviewname = quote_qualified_identifier(get_namespace_name(RelationGetNamespace(matviewRel)),
+ RelationGetRelationName(matviewRel));
+
+ /* If we have keys, initialize arrays for them. */
+ if (keys)
+ {
+ keyTypes = palloc(sizeof(Oid) * num_keys);
+ keyNulls = palloc(sizeof(char) * num_keys);
+ keyVals = palloc(sizeof(Datum) * num_keys);
+ /* a tuple contains keys to be recalculated and ctid to be updated*/
+ Assert(tupdesc_recalc->natts == num_keys + 1);
+
+ /* Types of key attributes */
+ for (i = 0; i < num_keys; i++)
+ keyTypes[i] = TupleDescAttr(tupdesc_recalc, i + 1)->atttypid;
+ }
+
+ /* allocate memory for all attribute names and tid */
+ types = palloc(sizeof(Oid) * (num_vals + 1));
+ nulls = palloc(sizeof(char) * (num_vals + 1));
+ vals = palloc(sizeof(Datum) * (num_vals + 1));
+
+ /* For each tuple which needs recalculation */
+ for (i = 0; i < num_tuples; i++)
+ {
+ int j;
+ bool isnull;
+ SPIPlanPtr plan;
+ SPITupleTable *tuptable_newvals;
+ TupleDesc tupdesc_newvals;
+
+ /* Set group key values as parameters if needed. */
+ if (keys)
+ {
+ for (j = 0; j < num_keys; j++)
+ {
+ keyVals[j] = SPI_getbinval(tuptable_recalc->vals[i], tupdesc_recalc, j + 2, &isnull);
+ if (isnull)
+ keyNulls[j] = 'n';
+ else
+ keyNulls[j] = ' ';
+ }
+ }
+
+ /*
+ * Get recalculated values from base tables. The result must be
+ * only one tuple thich contains the new values for specified keys.
+ */
+ plan = get_plan_for_recalc(matviewOid, namelist, keys, keyTypes);
+ if (SPI_execute_plan(plan, keyVals, keyNulls, false, 0) != SPI_OK_SELECT)
+ elog(ERROR, "SPI_execute_plan");
+ if (SPI_processed != 1)
+ elog(ERROR, "SPI_execute_plan returned zero or more than one rows");
+
+ tuptable_newvals = SPI_tuptable;
+ tupdesc_newvals = tuptable_newvals->tupdesc;
+
+ Assert(tupdesc_newvals->natts == num_vals);
+
+ /* Set the new values as parameters */
+ for (j = 0; j < tupdesc_newvals->natts; j++)
+ {
+ if (i == 0)
+ types[j] = TupleDescAttr(tupdesc_newvals, j)->atttypid;
+
+ vals[j] = SPI_getbinval(tuptable_newvals->vals[0], tupdesc_newvals, j + 1, &isnull);
+ if (isnull)
+ nulls[j] = 'n';
+ else
+ nulls[j] = ' ';
+ }
+ /* Set TID of the view tuple to be updated as a parameter */
+ types[j] = TIDOID;
+ vals[j] = SPI_getbinval(tuptable_recalc->vals[i], tupdesc_recalc, 1, &isnull);
+ nulls[j] = ' ';
+
+ /* Update the view tuple to the new values */
+ plan = get_plan_for_set_values(matviewOid, matviewname, namelist, types);
+ if (SPI_execute_plan(plan, vals, nulls, false, 0) != SPI_OK_UPDATE)
+ elog(ERROR, "SPI_execute_plan");
+ }
+}
+
+
+/*
+ * get_plan_for_recalc
+ *
+ * Create or fetch a plan for recalculating value in the view's target list
+ * from base tables using the definition query of materialized view specified
+ * by matviewOid. namelist is a list of resnames of values to be recalculated.
+ *
+ * keys is a list of keys to identify tuples to be recalculated if this is not
+ * empty. KeyTypes is an array of types of keys.
+ */
+static SPIPlanPtr
+get_plan_for_recalc(Oid matviewOid, List *namelist, List *keys, Oid *keyTypes)
+{
+ MV_QueryKey hash_key;
+ SPIPlanPtr plan;
+
+ /* Fetch or prepare a saved plan for the recalculation */
+ mv_BuildQueryKey(&hash_key, matviewOid, MV_PLAN_RECALC);
+ if ((plan = mv_FetchPreparedPlan(&hash_key)) == NULL)
+ {
+ ListCell *lc;
+ StringInfoData str;
+ char *viewdef;
+
+ /* get view definition of matview */
+ viewdef = text_to_cstring((text *) DatumGetPointer(
+ DirectFunctionCall1(pg_get_viewdef, ObjectIdGetDatum(matviewOid))));
+ /* get rid of trailing semi-colon */
+ viewdef[strlen(viewdef)-1] = '\0';
+
+ /*
+ * Build a query string for recalculating values. This is like
+ *
+ * SELECT x1, x2, x3, ... FROM ( ... view definition query ...) mv
+ * WHERE (key1, key2, ...) = ($1, $2, ...);
+ */
+
+ initStringInfo(&str);
+ appendStringInfo(&str, "SELECT ");
+ foreach (lc, namelist)
+ {
+ appendStringInfo(&str, "%s", (char *) lfirst(lc));
+ if (lnext(namelist, lc))
+ appendStringInfoString(&str, ", ");
+ }
+ appendStringInfo(&str, " FROM (%s) mv", viewdef);
+
+ if (keys)
+ {
+ int i = 1;
+ char paramname[16];
+
+ appendStringInfo(&str, " WHERE (");
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ Oid typid = attr->atttypid;
+
+ sprintf(paramname, "$%d", i);
+ appendStringInfo(&str, "(");
+ generate_equal(&str, typid, resname, paramname);
+ appendStringInfo(&str, " OR (%s IS NULL AND %s IS NULL))",
+ resname, paramname);
+
+ if (lnext(keys, lc))
+ appendStringInfoString(&str, " AND ");
+ i++;
+ }
+ appendStringInfo(&str, ")");
+ }
+ else
+ keyTypes = NULL;
+
+ plan = SPI_prepare(str.data, list_length(keys), keyTypes);
+ if (plan == NULL)
+ elog(ERROR, "SPI_prepare returned %s for %s", SPI_result_code_string(SPI_result), str.data);
+
+ SPI_keepplan(plan);
+ mv_HashPreparedPlan(&hash_key, plan);
+ }
+
+ return plan;
+}
+
+/*
+ * get_plan_for_set_values
+ *
+ * Create or fetch a plan for applying new values calculated by
+ * get_plan_for_recalc to a materialized view specified by matviewOid.
+ * matviewname is the name of the view. namelist is a list of resnames
+ * of attributes to be updated, and valTypes is an array of types of the
+ * values.
+ */
+static SPIPlanPtr
+get_plan_for_set_values(Oid matviewOid, char *matviewname, List *namelist,
+ Oid *valTypes)
+{
+ MV_QueryKey key;
+ SPIPlanPtr plan;
+
+ /* Fetch or prepare a saved plan for the real check */
+ mv_BuildQueryKey(&key, matviewOid, MV_PLAN_SET_VALUE);
+ if ((plan = mv_FetchPreparedPlan(&key)) == NULL)
+ {
+ ListCell *lc;
+ StringInfoData str;
+ int i;
+
+ /*
+ * Build a query string for applying min/max values. This is like
+ *
+ * UPDATE matviewname AS mv
+ * SET (x1, x2, x3, x4) = ($1, $2, $3, $4)
+ * WHERE ctid = $5;
+ */
+
+ initStringInfo(&str);
+ appendStringInfo(&str, "UPDATE %s AS mv SET (", matviewname);
+ foreach (lc, namelist)
+ {
+ appendStringInfo(&str, "%s", (char *) lfirst(lc));
+ if (lnext(namelist, lc))
+ appendStringInfoString(&str, ", ");
+ }
+ appendStringInfo(&str, ") = ROW(");
+
+ for (i = 1; i <= list_length(namelist); i++)
+ appendStringInfo(&str, "%s$%d", (i==1 ? "" : ", "), i);
+
+ appendStringInfo(&str, ") WHERE ctid OPERATOR(pg_catalog.=) $%d", i);
+
+ plan = SPI_prepare(str.data, list_length(namelist) + 1, valTypes);
+ if (plan == NULL)
+ elog(ERROR, "SPI_prepare returned %s for %s", SPI_result_code_string(SPI_result), str.data);
+
+ SPI_keepplan(plan);
+ mv_HashPreparedPlan(&key, plan);
+ }
+
+ return plan;
+}
+
/*
* generate_equals
*
@@ -2806,6 +3322,13 @@ mv_InitHashTables(void)
{
HASHCTL ctl;
+ memset(&ctl, 0, sizeof(ctl));
+ ctl.keysize = sizeof(MV_QueryKey);
+ ctl.entrysize = sizeof(MV_QueryHashEntry);
+ mv_query_cache = hash_create("MV query cache",
+ MV_INIT_QUERYHASHSIZE,
+ &ctl, HASH_ELEM | HASH_BLOBS);
+
memset(&ctl, 0, sizeof(ctl));
ctl.keysize = sizeof(Oid);
ctl.entrysize = sizeof(MV_TriggerHashEntry);
@@ -2814,6 +3337,109 @@ mv_InitHashTables(void)
&ctl, HASH_ELEM | HASH_BLOBS);
}
+/*
+ * mv_FetchPreparedPlan
+ */
+static SPIPlanPtr
+mv_FetchPreparedPlan(MV_QueryKey *key)
+{
+ MV_QueryHashEntry *entry;
+ SPIPlanPtr plan;
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_query_cache)
+ mv_InitHashTables();
+
+ /*
+ * Lookup for the key
+ */
+ entry = (MV_QueryHashEntry *) hash_search(mv_query_cache,
+ (void *) key,
+ HASH_FIND, NULL);
+ if (entry == NULL)
+ return NULL;
+
+ /*
+ * Check whether the plan is still valid. If it isn't, we don't want to
+ * simply rely on plancache.c to regenerate it; rather we should start
+ * from scratch and rebuild the query text too. This is to cover cases
+ * such as table/column renames. We depend on the plancache machinery to
+ * detect possible invalidations, though.
+ *
+ * CAUTION: this check is only trustworthy if the caller has already
+ * locked both materialized views and base tables.
+ *
+ * Also, check whether the search_path is still the same as when we made it.
+ * If it isn't, we need to rebuild the query text because the result of
+ * pg_ivm_get_viewdef() will change.
+ */
+ plan = entry->plan;
+ if (plan && SPI_plan_is_valid(plan) &&
+ SearchPathMatchesCurrentEnvironment(entry->search_path))
+ return plan;
+
+ /*
+ * Otherwise we might as well flush the cached plan now, to free a little
+ * memory space before we make a new one.
+ */
+ if (plan)
+ SPI_freeplan(plan);
+ if (entry->search_path)
+ pfree(entry->search_path);
+
+ entry->plan = NULL;
+ entry->search_path = NULL;
+
+ return NULL;
+}
+
+/*
+ * mv_HashPreparedPlan
+ *
+ * Add another plan to our private SPI query plan hashtable.
+ */
+static void
+mv_HashPreparedPlan(MV_QueryKey *key, SPIPlanPtr plan)
+{
+ MV_QueryHashEntry *entry;
+ bool found;
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_query_cache)
+ mv_InitHashTables();
+
+ /*
+ * Add the new plan. We might be overwriting an entry previously found
+ * invalid by mv_FetchPreparedPlan.
+ */
+ entry = (MV_QueryHashEntry *) hash_search(mv_query_cache,
+ (void *) key,
+ HASH_ENTER, &found);
+ Assert(!found || entry->plan == NULL);
+ entry->plan = plan;
+ entry->search_path = GetSearchPathMatcher(TopMemoryContext);
+}
+
+/*
+ * mv_BuildQueryKey
+ *
+ * Construct a hashtable key for a prepared SPI plan for IVM.
+ */
+static void
+mv_BuildQueryKey(MV_QueryKey *key, Oid matview_id, int32 query_type)
+{
+ /*
+ * We assume struct MV_QueryKey contains no padding bytes, else we'd need
+ * to use memset to clear them.
+ */
+ key->matview_id = matview_id;
+ key->query_type = query_type;
+}
+
/*
* AtAbort_IVM
*
--
2.34.1
v34-0001-Add-a-syntax-to-create-Incrementally-Maintainabl.patchtext/x-diff; name=v34-0001-Add-a-syntax-to-create-Incrementally-Maintainabl.patchDownload
From 0db3e44ae5c47b91fe2cddf339a0c48aefdb3de9 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:05:02 +0900
Subject: [PATCH v34 01/11] Add a syntax to create Incrementally Maintainable
Materialized Views
Allow to create Incrementally Maintainable Materialized View (IMMV)
by using INCREMENTAL option in CREATE MATERIALIZED VIEW command
as follow:
CREATE [INCREMANTAL] MATERIALIZED VIEW xxxxx AS SELECT ....;
---
src/backend/parser/gram.y | 32 +++++++++++++++++++++-----------
src/include/nodes/primnodes.h | 1 +
src/include/parser/kwlist.h | 1 +
3 files changed, 23 insertions(+), 11 deletions(-)
diff --git a/src/backend/parser/gram.y b/src/backend/parser/gram.y
index a043fd4c66..943460fd2c 100644
--- a/src/backend/parser/gram.y
+++ b/src/backend/parser/gram.y
@@ -468,6 +468,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
%type <range> OptTempTableName
%type <into> into_clause create_as_target create_mv_target
+%type <boolean> incremental
%type <defelt> createfunc_opt_item common_func_opt_item dostmt_opt_item
%type <fun_param> func_arg func_arg_with_default table_func_column aggr_arg
@@ -738,7 +739,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
HANDLER HAVING HEADER_P HOLD HOUR_P
IDENTITY_P IF_P ILIKE IMMEDIATE IMMUTABLE IMPLICIT_P IMPORT_P IN_P INCLUDE
- INCLUDING INCREMENT INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
+ INCLUDING INCREMENT INCREMENTAL INDENT INDEX INDEXES INHERIT INHERITS INITIALLY INLINE_P
INNER_P INOUT INPUT_P INSENSITIVE INSERT INSTEAD INT_P INTEGER
INTERSECT INTERVAL INTO INVOKER IS ISNULL ISOLATION
@@ -4803,32 +4804,34 @@ opt_with_data:
*****************************************************************************/
CreateMatViewStmt:
- CREATE OptNoLog MATERIALIZED VIEW create_mv_target AS SelectStmt opt_with_data
+ CREATE OptNoLog incremental MATERIALIZED VIEW create_mv_target AS SelectStmt opt_with_data
{
CreateTableAsStmt *ctas = makeNode(CreateTableAsStmt);
- ctas->query = $7;
- ctas->into = $5;
+ ctas->query = $8;
+ ctas->into = $6;
ctas->objtype = OBJECT_MATVIEW;
ctas->is_select_into = false;
ctas->if_not_exists = false;
/* cram additional flags into the IntoClause */
- $5->rel->relpersistence = $2;
- $5->skipData = !($8);
+ $6->rel->relpersistence = $2;
+ $6->skipData = !($9);
+ $6->ivm = $3;
$$ = (Node *) ctas;
}
- | CREATE OptNoLog MATERIALIZED VIEW IF_P NOT EXISTS create_mv_target AS SelectStmt opt_with_data
+ | CREATE OptNoLog incremental MATERIALIZED VIEW IF_P NOT EXISTS create_mv_target AS SelectStmt opt_with_data
{
CreateTableAsStmt *ctas = makeNode(CreateTableAsStmt);
- ctas->query = $10;
- ctas->into = $8;
+ ctas->query = $11;
+ ctas->into = $9;
ctas->objtype = OBJECT_MATVIEW;
ctas->is_select_into = false;
ctas->if_not_exists = true;
/* cram additional flags into the IntoClause */
- $8->rel->relpersistence = $2;
- $8->skipData = !($11);
+ $9->rel->relpersistence = $2;
+ $9->skipData = !($12);
+ $9->ivm = $3;
$$ = (Node *) ctas;
}
;
@@ -4845,9 +4848,14 @@ create_mv_target:
$$->tableSpaceName = $5;
$$->viewQuery = NULL; /* filled at analysis time */
$$->skipData = false; /* might get changed later */
+ $$->ivm = false;
}
;
+incremental: INCREMENTAL { $$ = true; }
+ | /*EMPTY*/ { $$ = false; }
+ ;
+
OptNoLog: UNLOGGED { $$ = RELPERSISTENCE_UNLOGGED; }
| /*EMPTY*/ { $$ = RELPERSISTENCE_PERMANENT; }
;
@@ -17686,6 +17694,7 @@ unreserved_keyword:
| INCLUDE
| INCLUDING
| INCREMENT
+ | INCREMENTAL
| INDENT
| INDEX
| INDEXES
@@ -18274,6 +18283,7 @@ bare_label_keyword:
| INCLUDE
| INCLUDING
| INCREMENT
+ | INCREMENTAL
| INDENT
| INDEX
| INDEXES
diff --git a/src/include/nodes/primnodes.h b/src/include/nodes/primnodes.h
index ea47652adb..6f01300a30 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 */
Node *viewQuery pg_node_attr(query_jumble_ignore);
bool skipData; /* true for WITH NO DATA */
+ bool ivm; /* true for WITH IVM */
} IntoClause;
diff --git a/src/include/parser/kwlist.h b/src/include/parser/kwlist.h
index f7fe834cf4..1625fea602 100644
--- a/src/include/parser/kwlist.h
+++ b/src/include/parser/kwlist.h
@@ -210,6 +210,7 @@ PG_KEYWORD("in", IN_P, RESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("include", INCLUDE, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("including", INCLUDING, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("increment", INCREMENT, UNRESERVED_KEYWORD, BARE_LABEL)
+PG_KEYWORD("incremental", INCREMENTAL, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("indent", INDENT, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("index", INDEX, UNRESERVED_KEYWORD, BARE_LABEL)
PG_KEYWORD("indexes", INDEXES, UNRESERVED_KEYWORD, BARE_LABEL)
--
2.34.1
v34-0011-Add-documentations-about-Incremental-View-Mainte.patchtext/x-diff; name=v34-0011-Add-documentations-about-Incremental-View-Mainte.patchDownload
From 35e32bd599343f3ba0bdb70ceb11d65b73321805 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:25:34 +0900
Subject: [PATCH v34 11/11] Add documentations about Incremental View
Maintenance
---
doc/src/sgml/catalogs.sgml | 9 +
.../sgml/ref/create_materialized_view.sgml | 124 ++++-
.../sgml/ref/refresh_materialized_view.sgml | 8 +-
doc/src/sgml/rules.sgml | 437 ++++++++++++++++++
doc/src/sgml/system-views.sgml | 9 +
5 files changed, 583 insertions(+), 4 deletions(-)
diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml
index b654fae1b2..8ef73edd12 100644
--- a/doc/src/sgml/catalogs.sgml
+++ b/doc/src/sgml/catalogs.sgml
@@ -2231,6 +2231,15 @@ SCRAM-SHA-256$<replaceable><iteration count></replaceable>:<replaceable>&l
</para></entry>
</row>
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>relisivm</structfield> <type>bool</type>
+ </para>
+ <para>
+ True if relation is incrementally maintainable materialized view
+ </para></entry>
+ </row>
+
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>relrewrite</structfield> <type>oid</type>
diff --git a/doc/src/sgml/ref/create_materialized_view.sgml b/doc/src/sgml/ref/create_materialized_view.sgml
index 0d2fea2b97..8c574062db 100644
--- a/doc/src/sgml/ref/create_materialized_view.sgml
+++ b/doc/src/sgml/ref/create_materialized_view.sgml
@@ -21,7 +21,7 @@ PostgreSQL documentation
<refsynopsisdiv>
<synopsis>
-CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
+CREATE [ INCREMENTAL ] MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
[ (<replaceable>column_name</replaceable> [, ...] ) ]
[ USING <replaceable class="parameter">method</replaceable> ]
[ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
@@ -60,6 +60,125 @@ CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
<title>Parameters</title>
<variablelist>
+ <varlistentry>
+ <term><literal>INCREMENTAL</literal></term>
+ <listitem>
+ <para>
+ If specified, some triggers are automatically created so that the rows
+ of the materialized view are immediately updated when base tables of the
+ materialized view are updated. In general, this allows faster update of
+ the materialized view at a price of slower update of the base tables
+ because the triggers will be invoked. We call this form of materialized
+ view as "Incrementally Maintainable Materialized View" (IMMV).
+ </para>
+ <para>
+ When <acronym>IMMV</acronym> is defined without using <command>WITH NO DATA</command>,
+ a unique index is created on the view automatically if possible. If the view
+ definition query has a GROUP BY clause, a unique index is created on the columns
+ of GROUP BY expressions. Also, if the view has DISTINCT clause, a unique index
+ is created on all columns in the target list. Otherwise, if the view contains all
+ primary key attritubes of its base tables in the target list, a unique index is
+ created on these attritubes. In other cases, no index is created.
+ </para>
+ <para>
+ There are restrictions of query definitions allowed to use this
+ option. The following are supported in query definitions for IMMV:
+ <itemizedlist>
+
+ <listitem>
+ <para>
+ Inner joins (including self-joins).
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Some built-in aggregate functions (count, sum, avg, min, max) without a HAVING
+ clause.
+ </para>
+ </listitem>
+ </itemizedlist>
+
+ Unsupported queries with this option include the following:
+
+ <itemizedlist>
+ <listitem>
+ <para>
+ Outer joins.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Sub-queries.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Aggregate functions other than built-in count, sum, avg, min and max.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ Aggregate functions with a HAVING clause.
+ </para>
+ </listitem>
+ <listitem>
+ <para>
+ DISTINCT ON, WINDOW, VALUES, LIMIT and OFFSET clause.
+ </para>
+ </listitem>
+ </itemizedlist>
+
+ Other restrictions include:
+ <itemizedlist>
+
+ <listitem>
+ <para>
+ IMMVs must be based on simple base tables. It's not supported to
+ create them on top of views or materialized views.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ It is not supported to include system columns in an IMMV.
+ <programlisting>
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+ERROR: system column is not supported with IVM
+ </programlisting>
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Non-immutable functions are not supported.
+ <programlisting>
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+ERROR: functions in IMMV must be marked IMMUTABLE
+ </programlisting>
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ IMMVs do not support expressions that contains aggregates
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Logical replication does not support IMMVs.
+ </para>
+ </listitem>
+
+ </itemizedlist>
+
+ </para>
+ </listitem>
+ </varlistentry>
+
<varlistentry>
<term><literal>IF NOT EXISTS</literal></term>
<listitem>
@@ -155,7 +274,8 @@ CREATE MATERIALIZED VIEW [ IF NOT EXISTS ] <replaceable>table_name</replaceable>
This clause specifies whether or not the materialized view should be
populated at creation time. If not, the materialized view will be
flagged as unscannable and cannot be queried until <command>REFRESH
- MATERIALIZED VIEW</command> is used.
+ MATERIALIZED VIEW</command> is used. Also, if the view is IMMV,
+ triggers for maintaining the view are not created.
</para>
</listitem>
</varlistentry>
diff --git a/doc/src/sgml/ref/refresh_materialized_view.sgml b/doc/src/sgml/ref/refresh_materialized_view.sgml
index 8ed43ade80..a4d729bdf0 100644
--- a/doc/src/sgml/ref/refresh_materialized_view.sgml
+++ b/doc/src/sgml/ref/refresh_materialized_view.sgml
@@ -36,9 +36,13 @@ REFRESH MATERIALIZED VIEW [ CONCURRENTLY ] <replaceable class="parameter">name</
privilege on the materialized view. The old contents are discarded. If
<literal>WITH DATA</literal> is specified (or defaults) the backing query
is executed to provide the new data, and the materialized view is left in a
- scannable state. If <literal>WITH NO DATA</literal> is specified no new
+ scannable state. If the view is an incrementally maintainable materialized
+ view (IMMV) and was 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 <literal>WITH NO DATA</literal> is specified no new
data is generated and the materialized view is left in an unscannable
- state.
+ state. If the view is IMMV, the triggers are dropped.
</para>
<para>
<literal>CONCURRENTLY</literal> and <literal>WITH NO DATA</literal> may not
diff --git a/doc/src/sgml/rules.sgml b/doc/src/sgml/rules.sgml
index 7a928bd7b9..73597ea7a5 100644
--- a/doc/src/sgml/rules.sgml
+++ b/doc/src/sgml/rules.sgml
@@ -1100,6 +1100,443 @@ SELECT word FROM words ORDER BY word <-> 'caterpiler' LIMIT 10;
</sect1>
+<sect1 id="rules-ivm">
+<title>Incremental View Maintenance</title>
+
+<indexterm zone="rules-ivm">
+ <primary>incremental view maintenance</primary>
+</indexterm>
+
+<indexterm zone="rules-ivm">
+ <primary>materialized view</primary>
+ <secondary>incremental view maintenance</secondary>
+</indexterm>
+
+<indexterm zone="rules-ivm">
+ <primary>view</primary>
+ <secondary>incremental view maintenance</secondary>
+</indexterm>
+
+<sect2 id="rules-ivm-overview">
+<title>Overview</title>
+
+<para>
+ Incremental View Maintenance (<acronym>IVM</acronym>) is a way to make
+ materialized views up-to-date in which only incremental changes are computed
+ and applied on views rather than recomputing the contents from scratch as
+ <command>REFRESH MATERIALIZED VIEW</command> does. <acronym>IVM</acronym>
+ can update materialized views more efficiently than recomputation when only
+ small parts of the view are changed.
+</para>
+
+<para>
+ There are two approaches with regard to timing of view maintenance:
+ immediate and deferred. In immediate maintenance, views are updated in the
+ same transaction that its base table is modified. In deferred maintenance,
+ views are updated after the transaction is committed, for example, when the
+ view is accessed, as a response to user command like <command>REFRESH
+ MATERIALIZED VIEW</command>, or periodically in background, and so on.
+ <productname>PostgreSQL</productname> currently implements only a kind of
+ immediate maintenance, in which materialized views are updated immediately
+ in AFTER triggers when a base table is modified.
+</para>
+
+<para>
+ To create materialized views supporting <acronym>IVM</acronym>, use the
+ <command>CREATE INCREMENTAL MATERIALIZED VIEW</command>, for example:
+<programlisting>
+CREATE <emphasis>INCREMENTAL</emphasis> MATERIALIZED VIEW mymatview AS SELECT * FROM mytab;
+</programlisting>
+ When a materialized view is created with the <literal>INCREMENTAL</literal>
+ keyword, some triggers are automatically created so that the view's contents are
+ immediately updated when its base tables are modified. We call this form
+ of materialized view an Incrementally Maintainable Materialized View
+ (<acronym>IMMV</acronym>).
+<programlisting>
+postgres=# CREATE INCREMENTAL MATERIALIZED VIEW m AS SELECT * FROM t0;
+NOTICE: could not create an index on materialized view "m" automatically
+HINT: Create an index on the materialized view for effcient incremental maintenance.
+SELECT 3
+postgres=# SELECT * FROM m;
+ i
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+postgres=# INSERT INTO t0 VALUES (4);
+INSERT 0 1
+postgres=# SELECT * FROM m; -- automatically updated
+ i
+---
+ 1
+ 2
+ 3
+ 4
+(4 rows)
+</programlisting>
+</para>
+
+<para>
+ Some <acronym>IMMV</acronym>s have hidden columns which are added
+ automatically when a materialized view is created. Their name starts
+ with <literal>__ivm_</literal> and they contain information required
+ for maintaining the <acronym>IMMV</acronym>. Such columns are not visible
+ when the <acronym>IMMV</acronym> is accessed by <literal>SELECT *</literal>
+ but are visible if the column name is explicitly specified in the target
+ list. We can also see the hidden columns in <literal>\d</literal>
+ meta-commands of <command>psql</command> commands.
+</para>
+
+<para>
+ In general, <acronym>IMMV</acronym>s allow faster updates of materialized
+ views at the price of slower updates to their base tables. Updates of
+ <acronym>IMMV</acronym> is slower because triggers will be invoked and the
+ view is updated in triggers per modification statement.
+</para>
+
+<para>
+ For example, suppose a normal materialized view defined as below:
+
+<programlisting>
+test=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm AS
+ SELECT a.aid, b.bid, a.abalance, b.bbalance
+ FROM pgbench_accounts a JOIN pgbench_branches b USING(bid);
+SELECT 10000000
+
+</programlisting>
+
+ Updating a tuple in a base table of this materialized view is rapid but the
+ <command>REFRESH MATERIALIZED VIEW</command> command on this view takes a long time:
+
+<programlisting>
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 0.990 ms
+
+test=# REFRESH MATERIALIZED VIEW mv_normal ;
+REFRESH MATERIALIZED VIEW
+Time: 33533.952 ms (00:33.534)
+</programlisting>
+</para>
+
+<para>
+ On the other hand, after creating <acronym>IMMV</acronym> with the same view
+ definition as below:
+
+<programlisting>
+test=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm AS
+ SELECT a.aid, b.bid, a.abalance, b.bbalance
+ FROM pgbench_accounts a JOIN pgbench_branches b USING(bid);
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+NOTICE: created index "mv_ivm_index" on materialized view "mv_ivm"
+</programlisting>
+
+ updating a tuple in a base table takes more than the normal view,
+ but its content is updated automatically and this is faster than the
+ <command>REFRESH MATERIALIZED VIEW</command> command.
+
+<programlisting>
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 13.068 ms
+</programlisting>
+
+</para>
+
+<para>
+ Appropriate indexes on <acronym>IMMV</acronym>s are necessary for
+ efficient <acronym>IVM</acronym> because it looks for tuples to be
+ updated in <acronym>IMMV</acronym>. If there are no indexes, it
+ will take a long time.
+</para>
+
+<para>
+ Therefore, when <acronym>IMMV</acronym> is defined, a unique index is created on the view
+ automatically if possible. If the view definition query has a GROUP BY clause, a unique
+ index is created on the columns of GROUP BY expressions. Also, if the view has DISTINCT
+ clause, a unique index is created on all columns in the target list. Otherwise, if the
+ view contains all primary key attritubes of its base tables in the target list, a unique
+ index is created on these attritubes. In other cases, no index is created.
+</para>
+
+<para>
+ In the previous example, a unique index "mv_ivm_index" is created on aid and bid
+ columns of materialized view "mv_ivm", and this enables the rapid update of the view.
+ Dropping this index make updating the view take a loger time.
+<programlisting>
+test=# DROP INDEX mv_ivm_index;
+DROP INDEX
+Time: 67.081 ms
+
+test=# UPDATE pgbench_accounts SET abalance = 1000 WHERE aid = 1;
+UPDATE 1
+Time: 16386.245 ms (00:16.386)
+</programlisting>
+
+</para>
+
+<para>
+ <acronym>IVM</acronym> is effective when we want to keep a materialized
+ view up-to-date and small fraction of a base table is modified
+ infrequently. Due to the overhead of immediate maintenance, <acronym>IVM</acronym>
+ 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, <acronym>IVM</acronym> is not effective and the cost of
+ maintenance can be larger than the <command>REFRESH MATERIALIZED VIEW</command>
+ command. In such situation, we can use <command>REFRESH MATERIALIZED VIEW</command>
+ and specify <literal>WITH NO DATA</literal> to disable immediate
+ maintenance before modifying a base table. After a base table modification,
+ execute the <command>REFRESH MATERIALIZED VIEW</command> (with <literal>WITH DATA</literal>)
+ command to refresh the view data and enable immediate maintenance.
+</para>
+
+</sect2>
+
+<sect2 id="rules-ivm-support">
+<title>Supported View Definitions and Restrictions</title>
+
+<para>
+ Currently, we can create <acronym>IMMV</acronym>s using inner joins, and some
+ aggregates. However, several restrictions apply to the definition of IMMV.
+</para>
+
+<sect3 id="rules-ivm-support-joins">
+<title>Joins</title>
+<para>
+ Inner joins including self-join are supported. Outer joins are not supported.
+</para>
+</sect3>
+
+<sect3 id="rules-ivm-support-aggregates">
+<title>Aggregates</title>
+<para>
+ Supported aggregate functions are <function>count</function>, <function>sum</function>,
+ <function>avg</function>, <function>min</function>, and <function>max</function>.
+ Currently, only built-in aggregate functions are supported and user defined
+ aggregates cannot be used. When a base table is modified, the new aggregated
+ values are incrementally calculated using the old aggregated values and values
+ of related hidden columns stored in <acronym>IMMV</acronym>.
+</para>
+
+<para>
+ Note that for <function>min</function> or <function>max</function>, the new values
+ could be re-calculated from base tables with regard to the affected groups when a
+ tuple containing the current minimal or maximal values are deleted from a base table.
+ Therefore, it can takes a long time to update an <acronym>IMMV</acronym> containing
+ these functions.
+</para>
+
+<para>
+ Also note that using <function>sum</function> or <function>avg</function> on
+ <type>real</type> (<type>float4</type>) type or <type>double precision</type>
+ (<type>float8</type>) type in <acronym>IMMV</acronym> is unsafe. This is
+ because aggregated values in <acronym>IMMV</acronym> can become different from
+ results calculated from base tables due to the limited precision of these types.
+ To avoid this problem, use the <type>numeric</type> type instead.
+</para>
+
+ <sect4 id="rules-ivm-restrictions-aggregates">
+ <title>Restrictions on Aggregates</title>
+ <para>
+ There are the following restrictions:
+ <itemizedlist>
+ <listitem>
+ <para>
+ If we have a <literal>GROUP BY</literal> clause, expressions specified in
+ <literal>GROUP BY</literal> must appear in the target list. This is
+ how tuples to be updated in the <acronym>IMMV</acronym> are identified.
+ These attributes are used as scan keys for searching tuples in the
+ <acronym>IMMV</acronym>, so indexes on them are required for efficient
+ <acronym>IVM</acronym>.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <literal>HAVING</literal> clause cannot be used.
+ </para>
+ </listitem>
+ </itemizedlist>
+ </para>
+ </sect4>
+</sect3>
+
+<sect3 id="rules-ivm-general-restricitons">
+<title>Other General Restrictions</title>
+<para>
+ There are other restrictions which generally apply to <acronym>IMMV</acronym>:
+ <itemizedlist>
+ <listitem>
+ <para>
+ Sub-queries cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ CTEs cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Window functions cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s must be based on simple base tables. It's not
+ supported to create them on top of views, materialized views, foreign tables, inhe.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ LIMIT and OFFSET clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s cannot contain system columns.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <acronym>IMMV</acronym>s cannot contain non-immutable functions.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ UNION/INTERSECT/EXCEPT clauses cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ DISTINCT ON clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ TABLESAMPLE parameter cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ inheritance parent tables cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ VALUES clause cannnot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ <literal>GROUPING SETS</literal> and <literal>FILTER</literal> clauses cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ FOR UPDATE/SHARE cannot be used.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ targetlist cannot contain columns whose name start with <literal>__ivm_</literal>.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ targetlist cannot contain expressions which contain an aggregate in it.
+ </para>
+ </listitem>
+
+ <listitem>
+ <para>
+ Logical replication is not supported, that is, even when a base table
+ at a publisher node is modified, <acronym>IMMV</acronym>s at subscriber
+ nodes are not updated.
+ </para>
+ </listitem>
+
+ </itemizedlist>
+</para>
+</sect3>
+
+</sect2>
+
+<sect2 id="rules-ivm-distinct">
+<title><literal>DISTINCT</literal></title>
+
+<para>
+ <productname>PostgreSQL</productname> supports <acronym>IMMV</acronym> with
+ <literal>DISTINCT</literal>. For example, suppose a <acronym>IMMV</acronym>
+ defined with <literal>DISTINCT</literal> on a base table containing duplicate
+ tuples. When tuples are deleted from the base table, a tuple in the view is
+ deleted if and only if the multiplicity of the tuple becomes zero. Moreover,
+ when tuples are inserted into the base table, a tuple is inserted into the
+ view only if the same tuple doesn't already exist in it.
+</para>
+
+<para>
+ Physically, an <acronym>IMMV</acronym> defined with <literal>DISTINCT</literal>
+ contains tuples after eliminating duplicates, and the multiplicity of each tuple
+ is stored in a hidden column named <literal>__ivm_count__</literal>.
+</para>
+</sect2>
+
+<sect2 id="rules-ivm-concurrent-transactions">
+<title>Concurrent Transactions</title>
+<para>
+ Suppose an <acronym>IMMV</acronym> is defined on two base tables and each
+ table was modified in different a concurrent transaction simultaneously.
+ In the transaction which was committed first, <acronym>IMMV</acronym> can
+ be updated considering only the change which happened in this transaction.
+ On the other hand, in order to update the view correctly in the transaction
+ which was committed later, we need to know the changes occurred in
+ both transactions. For this reason, <literal>ExclusiveLock</literal>
+ is held on an <acronym>IMMV</acronym> immediately after a base table is
+ modified in <literal>READ COMMITTED</literal> mode to make sure that
+ the <acronym>IMMV</acronym> is updated in the latter transaction after
+ the former transaction is committed. In <literal>REPEATABLE READ</literal>
+ or <literal>SERIALIZABLE</literal> mode, an error is raised immediately
+ if lock acquisition fails because any changes which occurred in
+ other transactions are not be visible in these modes and
+ <acronym>IMMV</acronym> cannot be updated correctly in such situations.
+ However, as an exception if the view has only one base table and
+ <command>INSERT</command> is performed on the table,
+ the lock held on thew view is <literal>RowExclusiveLock</literal>.
+</para>
+</sect2>
+
+<sect2 id="rules-ivm-rls">
+<title>Row Level Security</title>
+<para>
+ If some base tables have row level security policy, rows that are not visible
+ to the materialized view's owner are excluded from the result. In addition, such
+ rows are excluded as well when views are incrementally maintained. However, if a
+ new policy is defined or policies are changed after the materialized view was created,
+ the new policy will not be applied to the view contents. To apply the new policy,
+ you need to refresh materialized views.
+</para>
+</sect2>
+
+</sect1>
+
<sect1 id="rules-update">
<title>Rules on <command>INSERT</command>, <command>UPDATE</command>, and <command>DELETE</command></title>
diff --git a/doc/src/sgml/system-views.sgml b/doc/src/sgml/system-views.sgml
index bdc34cf94e..d4a1c99a91 100644
--- a/doc/src/sgml/system-views.sgml
+++ b/doc/src/sgml/system-views.sgml
@@ -1796,6 +1796,15 @@ SELECT * FROM pg_locks pl LEFT JOIN pg_prepared_xacts ppx
</para></entry>
</row>
+ <row>
+ <entry role="catalog_table_entry"><para role="column_definition">
+ <structfield>isimmv</structfield> <type>bool</type>
+ </para>
+ <para>
+ True if materialized view is incrementally maintainable
+ </para></entry>
+ </row>
+
<row>
<entry role="catalog_table_entry"><para role="column_definition">
<structfield>definition</structfield> <type>text</type>
--
2.34.1
v34-0010-Add-regression-tests-for-Incremental-View-Mainte.patchtext/x-diff; name=v34-0010-Add-regression-tests-for-Incremental-View-Mainte.patchDownload
From e9f60b3796ec779cd33ac921129170f8e493cd9c Mon Sep 17 00:00:00 2001
From: Takuma Hoshiai <takuma.hoshiai@gmail.com>
Date: Wed, 10 Mar 2021 11:11:13 +0900
Subject: [PATCH v34 10/11] Add regression tests for Incremental View
Maintenance
---
.../regress/expected/incremental_matview.out | 1030 +++++++++++++++++
src/test/regress/parallel_schedule | 2 +-
src/test/regress/sql/incremental_matview.sql | 533 +++++++++
3 files changed, 1564 insertions(+), 1 deletion(-)
create mode 100644 src/test/regress/expected/incremental_matview.out
create mode 100644 src/test/regress/sql/incremental_matview.sql
diff --git a/src/test/regress/expected/incremental_matview.out b/src/test/regress/expected/incremental_matview.out
new file mode 100644
index 0000000000..d65896425e
--- /dev/null
+++ b/src/test/regress/expected/incremental_matview.out
@@ -0,0 +1,1030 @@
+-- create a table to use as a basis for views and materialized views in various combinations
+CREATE TABLE mv_base_a (i int, j int);
+INSERT INTO mv_base_a VALUES
+ (1,10),
+ (2,20),
+ (3,30),
+ (4,40),
+ (5,50);
+CREATE TABLE mv_base_b (i int, k int);
+INSERT INTO mv_base_b VALUES
+ (1,101),
+ (2,102),
+ (3,103),
+ (4,104);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_1 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) WITH NO DATA;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ERROR: materialized view "mv_ivm_1" has not been populated
+HINT: Use the REFRESH MATERIALIZED VIEW command.
+REFRESH MATERIALIZED VIEW mv_ivm_1;
+NOTICE: could not create an index on materialized view "mv_ivm_1" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+-- REFRESH WITH NO DATA
+BEGIN;
+CREATE FUNCTION dummy_ivm_trigger_func() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+CREATE CONSTRAINT TRIGGER dummy_ivm_trigger AFTER INSERT
+ON mv_base_a FROM mv_ivm_1 FOR EACH ROW
+EXECUTE PROCEDURE dummy_ivm_trigger_func();
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ count
+-------
+ 17
+(1 row)
+
+REFRESH MATERIALIZED VIEW mv_ivm_1 WITH NO DATA;
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+-- immediate maintenance
+BEGIN;
+INSERT INTO mv_base_b VALUES(5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+ 5 | 50 | 105
+(5 rows)
+
+UPDATE mv_base_a SET j = 0 WHERE i = 1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 0 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+ 5 | 50 | 105
+(5 rows)
+
+DELETE FROM mv_base_b WHERE (i,k) = (5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 0 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+ROLLBACK;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ i | j | k
+---+----+-----
+ 1 | 10 | 101
+ 2 | 20 | 102
+ 3 | 30 | 103
+ 4 | 40 | 104
+(4 rows)
+
+-- rename of IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS SELECT DISTINCT * FROM mv_base_a;
+NOTICE: created index "mv_ivm_rename_index" on materialized view "mv_ivm_rename"
+ALTER MATERIALIZED VIEW mv_ivm_rename RENAME COLUMN __ivm_count__ TO xxx;
+ERROR: IVM column can not be renamed
+DROP MATERIALIZED VIEW mv_ivm_rename;
+-- unique index on IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_unique AS SELECT DISTINCT * FROM mv_base_a;
+NOTICE: created index "mv_ivm_unique_index" on materialized view "mv_ivm_unique"
+CREATE UNIQUE INDEX ON mv_ivm_unique(__ivm_count__);
+ERROR: unique index creation on IVM columns is not supported
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__));
+ERROR: unique index creation on IVM columns is not supported
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__ + 1));
+ERROR: unique index creation on IVM columns is not supported
+DROP MATERIALIZED VIEW mv_ivm_unique;
+-- TRUNCATE a base table in join views
+BEGIN;
+TRUNCATE mv_base_a;
+SELECT * FROM mv_ivm_1;
+ i | j | k
+---+---+---
+(0 rows)
+
+ROLLBACK;
+BEGIN;
+TRUNCATE mv_base_b;
+SELECT * FROM mv_ivm_1;
+ i | j | k
+---+---+---
+(0 rows)
+
+ROLLBACK;
+-- some query syntax
+BEGIN;
+CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql'
+ AS 'SELECT 1' IMMUTABLE;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_func AS SELECT * FROM ivm_func();
+NOTICE: could not create an index on materialized view "mv_ivm_func" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_no_tbl AS SELECT 1;
+NOTICE: could not create an index on materialized view "mv_ivm_no_tbl" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+ROLLBACK;
+-- result of materialized view have DISTINCT clause or the duplicate result.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_duplicate AS SELECT j FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_duplicate" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_distinct AS SELECT DISTINCT j FROM mv_base_a;
+NOTICE: created index "mv_ivm_distinct_index" on materialized view "mv_ivm_distinct"
+INSERT INTO mv_base_a VALUES(6,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 20
+ 30
+ 40
+ 50
+(6 rows)
+
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ j
+----
+ 10
+ 20
+ 30
+ 40
+ 50
+(5 rows)
+
+ROLLBACK;
+-- support SUM(), COUNT() and AVG() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 120 | 2 | 60.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+UPDATE mv_base_a SET j = 200 WHERE (i,j) = (2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+----------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 220 | 2 | 110.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (2,200);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+ROLLBACK;
+-- support COUNT(*) aggregate function
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ i | sum | count
+---+-----+-------
+ 1 | 10 | 1
+ 2 | 20 | 1
+ 3 | 30 | 1
+ 4 | 40 | 1
+ 5 | 50 | 1
+(5 rows)
+
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ i | sum | count
+---+-----+-------
+ 1 | 10 | 1
+ 2 | 120 | 2
+ 3 | 30 | 1
+ 4 | 40 | 1
+ 5 | 50 | 1
+(5 rows)
+
+ROLLBACK;
+-- TRUNCATE a base table in aggregate views
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+TRUNCATE mv_base_a;
+SELECT sum, count FROM mv_ivm_agg;
+ sum | count
+-----+-------
+(0 rows)
+
+SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+ i | sum | count
+---+-----+-------
+(0 rows)
+
+ROLLBACK;
+-- support aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_group" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+---------------------
+ 150 | 5 | 30.0000000000000000
+(1 row)
+
+INSERT INTO mv_base_a VALUES(6,60);
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+---------------------
+ 210 | 6 | 35.0000000000000000
+(1 row)
+
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+ROLLBACK;
+-- TRUNCATE a base table in aggregate views without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_group" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+TRUNCATE mv_base_a;
+SELECT sum, count, avg FROM mv_ivm_group;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+ sum | count | avg
+-----+-------+-----
+ | 0 |
+(1 row)
+
+ROLLBACK;
+-- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_avg_bug AS SELECT i, SUM(j), COUNT(j), AVG(j) FROM mv_base_A GROUP BY i;
+NOTICE: created index "mv_ivm_avg_bug_index" on materialized view "mv_ivm_avg_bug"
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+INSERT INTO mv_base_a VALUES
+ (1,0),
+ (1,0),
+ (2,30),
+ (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 3 | 3.3333333333333333
+ 2 | 80 | 3 | 26.6666666666666667
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) = (1,0);
+DELETE FROM mv_base_a WHERE (i,j) = (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ i | sum | count | avg
+---+-----+-------+---------------------
+ 1 | 10 | 1 | 10.0000000000000000
+ 2 | 20 | 1 | 20.0000000000000000
+ 3 | 30 | 1 | 30.0000000000000000
+ 4 | 40 | 1 | 40.0000000000000000
+ 5 | 50 | 1 | 50.0000000000000000
+(5 rows)
+
+ROLLBACK;
+-- support MIN(), MAX() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_min_max_index" on materialized view "mv_ivm_min_max"
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 10 | 10
+ 2 | 20 | 20
+ 3 | 30 | 30
+ 4 | 40 | 40
+ 5 | 50 | 50
+(5 rows)
+
+INSERT INTO mv_base_a VALUES
+ (1,11), (1,12),
+ (2,21), (2,22),
+ (3,31), (3,32),
+ (4,41), (4,42),
+ (5,51), (5,52);
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 10 | 12
+ 2 | 20 | 22
+ 3 | 30 | 32
+ 4 | 40 | 42
+ 5 | 50 | 52
+(5 rows)
+
+DELETE FROM mv_base_a WHERE (i,j) IN ((1,10), (2,21), (3,32));
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ i | min | max
+---+-----+-----
+ 1 | 11 | 12
+ 2 | 20 | 22
+ 3 | 30 | 31
+ 4 | 40 | 42
+ 5 | 50 | 52
+(5 rows)
+
+ROLLBACK;
+-- support MIN(), MAX() aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT MIN(j), MAX(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_min_max" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 10 | 50
+(1 row)
+
+INSERT INTO mv_base_a VALUES
+ (0,0), (6,60), (7,70);
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 0 | 70
+(1 row)
+
+DELETE FROM mv_base_a WHERE (i,j) IN ((0,0), (7,70));
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ 10 | 60
+(1 row)
+
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+ min | max
+-----+-----
+ |
+(1 row)
+
+ROLLBACK;
+-- Test MIN/MAX after search_path change
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min AS SELECT MIN(j) FROM mv_base_a;
+NOTICE: could not create an index on materialized view "mv_ivm_min" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 10
+(1 row)
+
+CREATE SCHEMA myschema;
+GRANT ALL ON SCHEMA myschema TO public;
+CREATE TABLE myschema.mv_base_a (j int);
+INSERT INTO myschema.mv_base_a VALUES (1);
+DELETE FROM mv_base_a WHERE (i,j) = (1,10);
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 20
+(1 row)
+
+SET search_path TO myschema,public,pg_catalog;
+DELETE FROM public.mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_min;
+ min
+-----
+ 30
+(1 row)
+
+ROLLBACK;
+-- aggregate views with column names specified
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ a | sum
+---+------
+ 1 | 110
+ 2 | 2200
+ 3 | 300
+ 4 | 40
+ 5 | 50
+(5 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+NOTICE: created index "mv_ivm_agg_index" on materialized view "mv_ivm_agg"
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ a | b
+---+------
+ 1 | 110
+ 2 | 2200
+ 3 | 300
+ 4 | 40
+ 5 | 50
+(5 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b,c) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+ERROR: too many column names were specified
+ROLLBACK;
+-- support self join view and multiple change on the same table
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_self(v1, v2) AS
+ SELECT t1.v, t2.v FROM base_t AS t1 JOIN base_t AS t2 ON t1.i = t2.i;
+NOTICE: could not create an index on materialized view "mv_self" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+----+----
+ 10 | 10
+ 20 | 20
+ 30 | 30
+(3 rows)
+
+INSERT INTO base_t VALUES (4,40);
+DELETE FROM base_t WHERE i = 1;
+UPDATE base_t SET v = v*10 WHERE i=2;
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+-----+-----
+ 30 | 30
+ 40 | 40
+ 200 | 200
+(3 rows)
+
+WITH
+ ins_t1 AS (INSERT INTO base_t VALUES (5,50) RETURNING 1),
+ ins_t2 AS (INSERT INTO base_t VALUES (6,60) RETURNING 1),
+ upd_t AS (UPDATE base_t SET v = v + 100 RETURNING 1),
+ dlt_t AS (DELETE FROM base_t WHERE i IN (4,5) RETURNING 1)
+SELECT NULL;
+ ?column?
+----------
+
+(1 row)
+
+SELECT * FROM mv_self ORDER BY v1;
+ v1 | v2
+-----+-----
+ 50 | 50
+ 60 | 60
+ 130 | 130
+ 300 | 300
+(4 rows)
+
+--- with sub-transactions
+SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,70);
+RELEASE SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,77);
+SELECT * FROM mv_self ORDER BY v1, v2;
+ v1 | v2
+-----+-----
+ 50 | 50
+ 60 | 60
+ 70 | 70
+ 70 | 77
+ 77 | 70
+ 77 | 77
+ 130 | 130
+ 300 | 300
+(8 rows)
+
+ROLLBACK;
+-- support simultaneous table changes
+BEGIN;
+CREATE TABLE base_r (i int, v int);
+CREATE TABLE base_s (i int, v int);
+INSERT INTO base_r VALUES (1, 10), (2, 20), (3, 30);
+INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300);
+CREATE INCREMENTAL MATERIALIZED VIEW mv(v1, v2) AS
+ SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i);
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY v1;
+ v1 | v2
+----+-----
+ 10 | 100
+ 20 | 200
+ 30 | 300
+(3 rows)
+
+WITH
+ ins_r AS (INSERT INTO base_r VALUES (1,11) RETURNING 1),
+ ins_r2 AS (INSERT INTO base_r VALUES (3,33) RETURNING 1),
+ ins_s AS (INSERT INTO base_s VALUES (2,222) RETURNING 1),
+ upd_r AS (UPDATE base_r SET v = v + 1000 WHERE i = 2 RETURNING 1),
+ dlt_s AS (DELETE FROM base_s WHERE i = 3 RETURNING 1)
+SELECT NULL;
+ ?column?
+----------
+
+(1 row)
+
+SELECT * FROM mv ORDER BY v1;
+ v1 | v2
+------+-----
+ 10 | 100
+ 11 | 100
+ 1020 | 200
+ 1020 | 222
+(4 rows)
+
+ROLLBACK;
+-- support foreign reference constraints
+BEGIN;
+CREATE TABLE ri1 (i int PRIMARY KEY);
+CREATE TABLE ri2 (i int PRIMARY KEY REFERENCES ri1(i) ON UPDATE CASCADE ON DELETE CASCADE, v int);
+INSERT INTO ri1 VALUES (1),(2),(3);
+INSERT INTO ri2 VALUES (1),(2),(3);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ri(i1, i2) AS
+ SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i);
+NOTICE: created index "mv_ri_index" on materialized view "mv_ri"
+SELECT * FROM mv_ri ORDER BY i1;
+ i1 | i2
+----+----
+ 1 | 1
+ 2 | 2
+ 3 | 3
+(3 rows)
+
+UPDATE ri1 SET i=10 where i=1;
+DELETE FROM ri1 WHERE i=2;
+SELECT * FROM mv_ri ORDER BY i2;
+ i1 | i2
+----+----
+ 3 | 3
+ 10 | 10
+(2 rows)
+
+ROLLBACK;
+-- views including NULL
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1,10),(2, NULL);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY i;
+ i | v
+---+----
+ 1 | 10
+ 2 |
+(2 rows)
+
+UPDATE base_t SET v = 20 WHERE i = 2;
+SELECT * FROM mv ORDER BY i;
+ i | v
+---+----
+ 1 | 10
+ 2 | 20
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+NOTICE: could not create an index on materialized view "mv" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT * FROM mv ORDER BY i;
+ i
+---
+(0 rows)
+
+INSERT INTO base_t VALUES (1),(NULL);
+SELECT * FROM mv ORDER BY i;
+ i
+---
+ 1
+
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, sum(v) FROM base_t GROUP BY i;
+NOTICE: created index "mv_index" on materialized view "mv"
+SELECT * FROM mv ORDER BY i;
+ i | sum
+---+-----
+ 1 | 30
+ | 3
+(2 rows)
+
+UPDATE base_t SET v = v * 10;
+SELECT * FROM mv ORDER BY i;
+ i | sum
+---+-----
+ 1 | 300
+ | 30
+(2 rows)
+
+ROLLBACK;
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, min(v), max(v) FROM base_t GROUP BY i;
+NOTICE: created index "mv_index" on materialized view "mv"
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 1 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 1;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 3;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 5
+(1 row)
+
+DELETE FROM base_t WHERE v = 5;
+SELECT * FROM mv ORDER BY i;
+ i | min | max
+---+-----+-----
+ | 2 | 4
+(1 row)
+
+ROLLBACK;
+-- IMMV containing user defined type
+BEGIN;
+CREATE TYPE mytype;
+CREATE FUNCTION mytype_in(cstring)
+ RETURNS mytype AS 'int4in'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+NOTICE: return type mytype is only a shell
+CREATE FUNCTION mytype_out(mytype)
+ RETURNS cstring AS 'int4out'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+NOTICE: argument type mytype is only a shell
+CREATE TYPE mytype (
+ LIKE = int4,
+ INPUT = mytype_in,
+ OUTPUT = mytype_out
+);
+CREATE FUNCTION mytype_eq(mytype, mytype)
+ RETURNS bool AS 'int4eq'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_lt(mytype, mytype)
+ RETURNS bool AS 'int4lt'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_cmp(mytype, mytype)
+ RETURNS integer AS 'btint4cmp'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE OPERATOR = (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_eq);
+CREATE OPERATOR < (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_lt);
+CREATE OPERATOR CLASS mytype_ops
+ DEFAULT FOR TYPE mytype USING btree AS
+ OPERATOR 1 <,
+ OPERATOR 3 = ,
+ FUNCTION 1 mytype_cmp(mytype,mytype);
+CREATE TABLE t_mytype (x mytype);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_mytype AS
+ SELECT * FROM t_mytype;
+NOTICE: could not create an index on materialized view "mv_mytype" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+INSERT INTO t_mytype VALUES ('1'::mytype);
+SELECT * FROM mv_mytype;
+ x
+---
+ 1
+(1 row)
+
+ROLLBACK;
+-- outer join is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv(a,b) AS SELECT a.i, b.i FROM mv_base_a a LEFT JOIN mv_base_b b ON a.i=b.i;
+ERROR: OUTER JOIN is not supported on incrementally maintainable materialized view
+-- CTE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS
+ WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i;
+ERROR: CTE is not supported on incrementally maintainable materialized view
+-- contain system column
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm01 AS SELECT i,j,xmin FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT i,j,xmin::text AS x_min FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm06 AS SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a;
+ERROR: system column is not supported on incrementally maintainable materialized view
+-- contain subquery
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm03 AS SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 );
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT * FROM mv_base_b) b WHERE a.i = b.i;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm05 AS SELECT i,j, (SELECT k FROM mv_base_b b WHERE a.i = b.i) FROM mv_base_a a;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+-- contain ORDER BY
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) ORDER BY i,j,k;
+ERROR: ORDER BY clause is not supported on incrementally maintainable materialized view
+-- contain HAVING
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) GROUP BY i,j,k HAVING SUM(i) > 5;
+ERROR: HAVING clause is not supported on incrementally maintainable materialized view
+-- contain view or materialized view
+CREATE VIEW b_view AS SELECT i,k FROM mv_base_b;
+CREATE MATERIALIZED VIEW b_mview AS SELECT i,k FROM mv_base_b;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT a.i,a.j FROM mv_base_a a,b_view b WHERE a.i = b.i;
+ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT a.i,a.j FROM mv_base_a a,b_mview b WHERE a.i = b.i;
+ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm09 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) b WHERE a.i = b.i;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm10 AS SELECT a.i,a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) OR a.i > 5;
+ERROR: subquery is not supported on incrementally maintainable materialized view
+-- contain mutable functions
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+ERROR: mutable function is not supported on incrementally maintainable materialized view
+HINT: functions must be marked IMMUTABLE
+-- LIMIT/OFFSET is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm13 AS SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5;
+ERROR: LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view
+-- DISTINCT ON is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm14 AS SELECT DISTINCT ON(i) i, j FROM mv_base_a;
+ERROR: DISTINCT ON is not supported on incrementally maintainable materialized view
+-- TABLESAMPLE clause is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm15 AS SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50);
+ERROR: TABLESAMPLE clause is not supported on incrementally maintainable materialized view
+-- window functions are not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm16 AS SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a;
+ERROR: window functions are not supported on incrementally maintainable materialized view
+-- aggregate function with some options is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm17 AS SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a;
+ERROR: aggregate function with FILTER clause is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm18 AS SELECT COUNT(DISTINCT i) FROM mv_base_a;
+ERROR: aggregate function with DISTINCT arguments is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm19 AS SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a;
+ERROR: aggregate function with ORDER clause is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm20 AS SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),());
+ERROR: GROUPING SETS, ROLLUP, or CUBE clauses is not supported on incrementally maintainable materialized view
+-- inheritance parent is not supported
+BEGIN;
+CREATE TABLE parent (i int, v int);
+CREATE TABLE child_a(options text) INHERITS(parent);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm21 AS SELECT * FROM parent;
+ERROR: inheritance parent is not supported on incrementally maintainable materialized view
+ROLLBACK;
+-- UNION statement is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm22 AS SELECT i,j FROM mv_base_a UNION ALL SELECT i,k FROM mv_base_b;;
+ERROR: UNION/INTERSECT/EXCEPT statements are not supported on incrementally maintainable materialized view
+-- empty target list is not allowed with IVM
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm25 AS SELECT FROM mv_base_a;
+ERROR: empty target list is not supported on incrementally maintainable materialized view
+-- FOR UPDATE/SHARE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm26 AS SELECT i,j FROM mv_base_a FOR UPDATE;
+ERROR: FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view
+-- tartget list cannot contain ivm column that start with '__ivm'
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm28 AS SELECT i AS "__ivm_count__" FROM mv_base_a;
+ERROR: column name __ivm_count__ is not supported on incrementally maintainable materialized view
+-- expressions specified in GROUP BY must appear in the target list.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm29 AS SELECT COUNT(i) FROM mv_base_a GROUP BY i;
+ERROR: GROUP BY expression not appearing in select list is not supported on incrementally maintainable materialized view
+-- experssions containing an aggregate is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm30 AS SELECT sum(i)*0.5 FROM mv_base_a;
+ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm31 AS SELECT sum(i)/sum(j) FROM mv_base_a;
+ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view
+-- VALUES is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_only_values1 AS values(1);
+ERROR: VALUES is not supported on incrementally maintainable materialized view
+-- views containing base tables with Row Level Security
+DROP USER IF EXISTS regress_ivm_admin;
+NOTICE: role "regress_ivm_admin" does not exist, skipping
+DROP USER IF EXISTS regress_ivm_user;
+NOTICE: role "regress_ivm_user" does not exist, skipping
+CREATE USER regress_ivm_admin;
+CREATE USER regress_ivm_user;
+--- create a table with RLS
+SET SESSION AUTHORIZATION regress_ivm_admin;
+CREATE TABLE rls_tbl(id int, data text, owner name);
+INSERT INTO rls_tbl VALUES
+ (1,'foo','regress_ivm_user'),
+ (2,'bar','postgres');
+CREATE TABLE num_tbl(id int, num text);
+INSERT INTO num_tbl VALUES
+ (1,'one'),
+ (2,'two'),
+ (3,'three'),
+ (4,'four'),
+ (5,'five'),
+ (6,'six');
+--- Users can access only their own rows
+CREATE POLICY rls_tbl_policy ON rls_tbl FOR SELECT TO PUBLIC USING(owner = current_user);
+ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
+GRANT ALL on rls_tbl TO PUBLIC;
+GRANT ALL on num_tbl TO PUBLIC;
+--- create a view owned by regress_ivm_user
+SET SESSION AUTHORIZATION regress_ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls AS SELECT * FROM rls_tbl;
+NOTICE: could not create an index on materialized view "ivm_rls" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+------+------------------
+ 1 | foo | regress_ivm_user
+(1 row)
+
+RESET SESSION AUTHORIZATION;
+--- inserts rows owned by different users
+INSERT INTO rls_tbl VALUES
+ (3,'baz','regress_ivm_user'),
+ (4,'qux','postgres');
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+------+------------------
+ 1 | foo | regress_ivm_user
+ 3 | baz | regress_ivm_user
+(2 rows)
+
+--- combination of diffent kinds of commands
+WITH
+ i AS (INSERT INTO rls_tbl VALUES(5,'quux','postgres'), (6,'corge','regress_ivm_user')),
+ u AS (UPDATE rls_tbl SET owner = 'postgres' WHERE id = 1),
+ u2 AS (UPDATE rls_tbl SET owner = 'regress_ivm_user' WHERE id = 2)
+SELECT;
+--
+(1 row)
+
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+ id | data | owner
+----+-------+------------------
+ 2 | bar | regress_ivm_user
+ 3 | baz | regress_ivm_user
+ 6 | corge | regress_ivm_user
+(3 rows)
+
+---
+SET SESSION AUTHORIZATION regress_ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls2 AS SELECT * FROM rls_tbl JOIN num_tbl USING(id);
+NOTICE: could not create an index on materialized view "ivm_rls2" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+RESET SESSION AUTHORIZATION;
+WITH
+ x AS (UPDATE rls_tbl SET data = data || '_2' where id in (3,4)),
+ y AS (UPDATE num_tbl SET num = num || '_2' where id in (3,4))
+SELECT;
+--
+(1 row)
+
+SELECT * FROM ivm_rls2 ORDER BY 1,2,3;
+ id | data | owner | num
+----+-------+------------------+---------
+ 2 | bar | regress_ivm_user | two
+ 3 | baz_2 | regress_ivm_user | three_2
+ 6 | corge | regress_ivm_user | six
+(3 rows)
+
+-- automatic index creation
+CREATE TABLE base_a (i int primary key, j int);
+CREATE TABLE base_b (i int primary key, j int);
+--- group by: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx1 AS SELECT i, sum(j) FROM base_a GROUP BY i;
+NOTICE: created index "mv_idx1_index" on materialized view "mv_idx1"
+--- distinct: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx2 AS SELECT DISTINCT j FROM base_a;
+NOTICE: created index "mv_idx2_index" on materialized view "mv_idx2"
+--- with all pkey columns: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx3(i_a, i_b) AS SELECT a.i, b.i FROM base_a a, base_b b;
+NOTICE: created index "mv_idx3_index" on materialized view "mv_idx3"
+--- missing some pkey columns: no index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx4 AS SELECT j FROM base_a;
+NOTICE: could not create an index on materialized view "mv_idx4" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx5 AS SELECT a.i, b.j FROM base_a a, base_b b;
+NOTICE: could not create an index on materialized view "mv_idx5" automatically
+DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
+HINT: Create an index on the materialized view for efficient incremental maintenance.
+-- cleanup
+DROP TABLE rls_tbl CASCADE;
+NOTICE: drop cascades to 2 other objects
+DETAIL: drop cascades to materialized view ivm_rls
+drop cascades to materialized view ivm_rls2
+DROP TABLE num_tbl CASCADE;
+DROP USER regress_ivm_user;
+DROP USER regress_ivm_admin;
+DROP TABLE mv_base_b CASCADE;
+NOTICE: drop cascades to 3 other objects
+DETAIL: drop cascades to materialized view mv_ivm_1
+drop cascades to view b_view
+drop cascades to materialized view b_mview
+DROP TABLE mv_base_a CASCADE;
diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule
index 2429ec2bba..03814f34e9 100644
--- a/src/test/regress/parallel_schedule
+++ b/src/test/regress/parallel_schedule
@@ -78,7 +78,7 @@ test: brin_bloom brin_multi
# psql depends on create_am
# amutils depends on geometry, create_index_spgist, hash_index, brin
# ----------
-test: create_table_like alter_generic alter_operator misc async dbsize merge misc_functions sysviews tsrf tid tidscan tidrangescan collate.utf8 collate.icu.utf8 incremental_sort create_role
+test: create_table_like alter_generic alter_operator misc async dbsize merge misc_functions sysviews tsrf tid tidscan tidrangescan collate.utf8 collate.icu.utf8 incremental_sort create_role incremental_matview
# collate.linux.utf8 and collate.icu.utf8 tests cannot be run in parallel with each other
test: rules psql psql_crosstab amutils stats_ext collate.linux.utf8 collate.windows.win1252
diff --git a/src/test/regress/sql/incremental_matview.sql b/src/test/regress/sql/incremental_matview.sql
new file mode 100644
index 0000000000..90116edff8
--- /dev/null
+++ b/src/test/regress/sql/incremental_matview.sql
@@ -0,0 +1,533 @@
+-- create a table to use as a basis for views and materialized views in various combinations
+CREATE TABLE mv_base_a (i int, j int);
+INSERT INTO mv_base_a VALUES
+ (1,10),
+ (2,20),
+ (3,30),
+ (4,40),
+ (5,50);
+CREATE TABLE mv_base_b (i int, k int);
+INSERT INTO mv_base_b VALUES
+ (1,101),
+ (2,102),
+ (3,103),
+ (4,104);
+
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_1 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) WITH NO DATA;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+REFRESH MATERIALIZED VIEW mv_ivm_1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+
+-- REFRESH WITH NO DATA
+BEGIN;
+CREATE FUNCTION dummy_ivm_trigger_func() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+
+CREATE CONSTRAINT TRIGGER dummy_ivm_trigger AFTER INSERT
+ON mv_base_a FROM mv_ivm_1 FOR EACH ROW
+EXECUTE PROCEDURE dummy_ivm_trigger_func();
+
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+
+REFRESH MATERIALIZED VIEW mv_ivm_1 WITH NO DATA;
+
+SELECT COUNT(*)
+FROM pg_depend pd INNER JOIN pg_trigger pt ON pd.objid = pt.oid
+WHERE pd.classid = 'pg_trigger'::regclass AND pd.refobjid = 'mv_ivm_1'::regclass;
+ROLLBACK;
+
+-- immediate maintenance
+BEGIN;
+INSERT INTO mv_base_b VALUES(5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+UPDATE mv_base_a SET j = 0 WHERE i = 1;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+DELETE FROM mv_base_b WHERE (i,k) = (5,105);
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+ROLLBACK;
+SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
+
+-- rename of IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_rename AS SELECT DISTINCT * FROM mv_base_a;
+ALTER MATERIALIZED VIEW mv_ivm_rename RENAME COLUMN __ivm_count__ TO xxx;
+DROP MATERIALIZED VIEW mv_ivm_rename;
+
+-- unique index on IVM columns
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_unique AS SELECT DISTINCT * FROM mv_base_a;
+CREATE UNIQUE INDEX ON mv_ivm_unique(__ivm_count__);
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__));
+CREATE UNIQUE INDEX ON mv_ivm_unique((__ivm_count__ + 1));
+DROP MATERIALIZED VIEW mv_ivm_unique;
+
+-- TRUNCATE a base table in join views
+BEGIN;
+TRUNCATE mv_base_a;
+SELECT * FROM mv_ivm_1;
+ROLLBACK;
+
+BEGIN;
+TRUNCATE mv_base_b;
+SELECT * FROM mv_ivm_1;
+ROLLBACK;
+
+-- some query syntax
+BEGIN;
+CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql'
+ AS 'SELECT 1' IMMUTABLE;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_func AS SELECT * FROM ivm_func();
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_no_tbl AS SELECT 1;
+ROLLBACK;
+
+-- result of materialized view have DISTINCT clause or the duplicate result.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_duplicate AS SELECT j FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_distinct AS SELECT DISTINCT j FROM mv_base_a;
+INSERT INTO mv_base_a VALUES(6,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+DELETE FROM mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_duplicate ORDER BY 1;
+SELECT * FROM mv_ivm_distinct ORDER BY 1;
+ROLLBACK;
+
+-- support SUM(), COUNT() and AVG() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+UPDATE mv_base_a SET j = 200 WHERE (i,j) = (2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+DELETE FROM mv_base_a WHERE (i,j) = (2,200);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
+ROLLBACK;
+
+-- support COUNT(*) aggregate function
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES(2,100);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
+ROLLBACK;
+
+-- TRUNCATE a base table in aggregate views
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg AS SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+TRUNCATE mv_base_a;
+SELECT sum, count FROM mv_ivm_agg;
+SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
+ROLLBACK;
+
+-- support aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+INSERT INTO mv_base_a VALUES(6,60);
+SELECT * FROM mv_ivm_group ORDER BY 1;
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_group ORDER BY 1;
+ROLLBACK;
+
+-- TRUNCATE a base table in aggregate views without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_group AS SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+TRUNCATE mv_base_a;
+SELECT sum, count, avg FROM mv_ivm_group;
+SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
+ROLLBACK;
+
+-- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect.
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_avg_bug AS SELECT i, SUM(j), COUNT(j), AVG(j) FROM mv_base_A GROUP BY i;
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES
+ (1,0),
+ (1,0),
+ (2,30),
+ (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+DELETE FROM mv_base_a WHERE (i,j) = (1,0);
+DELETE FROM mv_base_a WHERE (i,j) = (2,30);
+SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
+ROLLBACK;
+
+-- support MIN(), MAX() aggregate functions
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i;
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+INSERT INTO mv_base_a VALUES
+ (1,11), (1,12),
+ (2,21), (2,22),
+ (3,31), (3,32),
+ (4,41), (4,42),
+ (5,51), (5,52);
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+DELETE FROM mv_base_a WHERE (i,j) IN ((1,10), (2,21), (3,32));
+SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
+ROLLBACK;
+
+-- support MIN(), MAX() aggregate functions without GROUP clause
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min_max AS SELECT MIN(j), MAX(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+INSERT INTO mv_base_a VALUES
+ (0,0), (6,60), (7,70);
+SELECT * FROM mv_ivm_min_max;
+DELETE FROM mv_base_a WHERE (i,j) IN ((0,0), (7,70));
+SELECT * FROM mv_ivm_min_max;
+DELETE FROM mv_base_a;
+SELECT * FROM mv_ivm_min_max;
+ROLLBACK;
+
+-- Test MIN/MAX after search_path change
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_min AS SELECT MIN(j) FROM mv_base_a;
+SELECT * FROM mv_ivm_min;
+
+CREATE SCHEMA myschema;
+GRANT ALL ON SCHEMA myschema TO public;
+CREATE TABLE myschema.mv_base_a (j int);
+INSERT INTO myschema.mv_base_a VALUES (1);
+
+DELETE FROM mv_base_a WHERE (i,j) = (1,10);
+SELECT * FROM mv_ivm_min;
+
+SET search_path TO myschema,public,pg_catalog;
+DELETE FROM public.mv_base_a WHERE (i,j) = (2,20);
+SELECT * FROM mv_ivm_min;
+ROLLBACK;
+
+-- aggregate views with column names specified
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
+UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
+DELETE FROM mv_base_a WHERE (i,j) = (3,30);
+SELECT * FROM mv_ivm_agg ORDER BY 1,2;
+ROLLBACK;
+BEGIN;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_agg(a,b,c) AS SELECT i, SUM(j) FROM mv_base_a GROUP BY i;
+ROLLBACK;
+
+-- support self join view and multiple change on the same table
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_self(v1, v2) AS
+ SELECT t1.v, t2.v FROM base_t AS t1 JOIN base_t AS t2 ON t1.i = t2.i;
+SELECT * FROM mv_self ORDER BY v1;
+INSERT INTO base_t VALUES (4,40);
+DELETE FROM base_t WHERE i = 1;
+UPDATE base_t SET v = v*10 WHERE i=2;
+SELECT * FROM mv_self ORDER BY v1;
+WITH
+ ins_t1 AS (INSERT INTO base_t VALUES (5,50) RETURNING 1),
+ ins_t2 AS (INSERT INTO base_t VALUES (6,60) RETURNING 1),
+ upd_t AS (UPDATE base_t SET v = v + 100 RETURNING 1),
+ dlt_t AS (DELETE FROM base_t WHERE i IN (4,5) RETURNING 1)
+SELECT NULL;
+SELECT * FROM mv_self ORDER BY v1;
+
+--- with sub-transactions
+SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,70);
+RELEASE SAVEPOINT p1;
+INSERT INTO base_t VALUES (7,77);
+SELECT * FROM mv_self ORDER BY v1, v2;
+
+ROLLBACK;
+
+-- support simultaneous table changes
+BEGIN;
+CREATE TABLE base_r (i int, v int);
+CREATE TABLE base_s (i int, v int);
+INSERT INTO base_r VALUES (1, 10), (2, 20), (3, 30);
+INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300);
+CREATE INCREMENTAL MATERIALIZED VIEW mv(v1, v2) AS
+ SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i);
+SELECT * FROM mv ORDER BY v1;
+WITH
+ ins_r AS (INSERT INTO base_r VALUES (1,11) RETURNING 1),
+ ins_r2 AS (INSERT INTO base_r VALUES (3,33) RETURNING 1),
+ ins_s AS (INSERT INTO base_s VALUES (2,222) RETURNING 1),
+ upd_r AS (UPDATE base_r SET v = v + 1000 WHERE i = 2 RETURNING 1),
+ dlt_s AS (DELETE FROM base_s WHERE i = 3 RETURNING 1)
+SELECT NULL;
+SELECT * FROM mv ORDER BY v1;
+ROLLBACK;
+
+-- support foreign reference constraints
+BEGIN;
+CREATE TABLE ri1 (i int PRIMARY KEY);
+CREATE TABLE ri2 (i int PRIMARY KEY REFERENCES ri1(i) ON UPDATE CASCADE ON DELETE CASCADE, v int);
+INSERT INTO ri1 VALUES (1),(2),(3);
+INSERT INTO ri2 VALUES (1),(2),(3);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ri(i1, i2) AS
+ SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i);
+SELECT * FROM mv_ri ORDER BY i1;
+UPDATE ri1 SET i=10 where i=1;
+DELETE FROM ri1 WHERE i=2;
+SELECT * FROM mv_ri ORDER BY i2;
+ROLLBACK;
+
+-- views including NULL
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (1,10),(2, NULL);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+SELECT * FROM mv ORDER BY i;
+UPDATE base_t SET v = 20 WHERE i = 2;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT * FROM base_t;
+SELECT * FROM mv ORDER BY i;
+INSERT INTO base_t VALUES (1),(NULL);
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, sum(v) FROM base_t GROUP BY i;
+SELECT * FROM mv ORDER BY i;
+UPDATE base_t SET v = v * 10;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+BEGIN;
+CREATE TABLE base_t (i int, v int);
+INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5);
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS SELECT i, min(v), max(v) FROM base_t GROUP BY i;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 1;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 3;
+SELECT * FROM mv ORDER BY i;
+DELETE FROM base_t WHERE v = 5;
+SELECT * FROM mv ORDER BY i;
+ROLLBACK;
+
+-- IMMV containing user defined type
+BEGIN;
+
+CREATE TYPE mytype;
+CREATE FUNCTION mytype_in(cstring)
+ RETURNS mytype AS 'int4in'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_out(mytype)
+ RETURNS cstring AS 'int4out'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE TYPE mytype (
+ LIKE = int4,
+ INPUT = mytype_in,
+ OUTPUT = mytype_out
+);
+
+CREATE FUNCTION mytype_eq(mytype, mytype)
+ RETURNS bool AS 'int4eq'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_lt(mytype, mytype)
+ RETURNS bool AS 'int4lt'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+CREATE FUNCTION mytype_cmp(mytype, mytype)
+ RETURNS integer AS 'btint4cmp'
+ LANGUAGE INTERNAL STRICT IMMUTABLE;
+
+CREATE OPERATOR = (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_eq);
+CREATE OPERATOR < (
+ leftarg = mytype, rightarg = mytype,
+ procedure = mytype_lt);
+
+CREATE OPERATOR CLASS mytype_ops
+ DEFAULT FOR TYPE mytype USING btree AS
+ OPERATOR 1 <,
+ OPERATOR 3 = ,
+ FUNCTION 1 mytype_cmp(mytype,mytype);
+
+CREATE TABLE t_mytype (x mytype);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_mytype AS
+ SELECT * FROM t_mytype;
+INSERT INTO t_mytype VALUES ('1'::mytype);
+SELECT * FROM mv_mytype;
+
+ROLLBACK;
+
+-- outer join is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv(a,b) AS SELECT a.i, b.i FROM mv_base_a a LEFT JOIN mv_base_b b ON a.i=b.i;
+-- CTE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv AS
+ WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i;
+-- contain system column
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm01 AS SELECT i,j,xmin FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm02 AS SELECT i,j FROM mv_base_a WHERE xmin = '610';
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT i,j,xmin::text AS x_min FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm06 AS SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a;
+-- contain subquery
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm03 AS SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 );
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm04 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT * FROM mv_base_b) b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm05 AS SELECT i,j, (SELECT k FROM mv_base_b b WHERE a.i = b.i) FROM mv_base_a a;
+-- contain ORDER BY
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) ORDER BY i,j,k;
+-- contain HAVING
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) GROUP BY i,j,k HAVING SUM(i) > 5;
+
+-- contain view or materialized view
+CREATE VIEW b_view AS SELECT i,k FROM mv_base_b;
+CREATE MATERIALIZED VIEW b_mview AS SELECT i,k FROM mv_base_b;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm07 AS SELECT a.i,a.j FROM mv_base_a a,b_view b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm08 AS SELECT a.i,a.j FROM mv_base_a a,b_mview b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm09 AS SELECT a.i,a.j FROM mv_base_a a, (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) b WHERE a.i = b.i;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm10 AS SELECT a.i,a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) OR a.i > 5;
+
+-- contain mutable functions
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm12 AS SELECT i,j FROM mv_base_a WHERE i = random()::int;
+
+-- LIMIT/OFFSET is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm13 AS SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5;
+
+-- DISTINCT ON is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm14 AS SELECT DISTINCT ON(i) i, j FROM mv_base_a;
+
+-- TABLESAMPLE clause is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm15 AS SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50);
+
+-- window functions are not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm16 AS SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a;
+
+-- aggregate function with some options is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm17 AS SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm18 AS SELECT COUNT(DISTINCT i) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm19 AS SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm20 AS SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),());
+
+-- inheritance parent is not supported
+BEGIN;
+CREATE TABLE parent (i int, v int);
+CREATE TABLE child_a(options text) INHERITS(parent);
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm21 AS SELECT * FROM parent;
+ROLLBACK;
+
+-- UNION statement is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm22 AS SELECT i,j FROM mv_base_a UNION ALL SELECT i,k FROM mv_base_b;;
+
+-- empty target list is not allowed with IVM
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm25 AS SELECT FROM mv_base_a;
+
+-- FOR UPDATE/SHARE is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm26 AS SELECT i,j FROM mv_base_a FOR UPDATE;
+
+-- tartget list cannot contain ivm column that start with '__ivm'
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm28 AS SELECT i AS "__ivm_count__" FROM mv_base_a;
+
+-- expressions specified in GROUP BY must appear in the target list.
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm29 AS SELECT COUNT(i) FROM mv_base_a GROUP BY i;
+
+-- experssions containing an aggregate is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm30 AS SELECT sum(i)*0.5 FROM mv_base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm31 AS SELECT sum(i)/sum(j) FROM mv_base_a;
+
+-- VALUES is not supported
+CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_only_values1 AS values(1);
+
+-- views containing base tables with Row Level Security
+DROP USER IF EXISTS regress_ivm_admin;
+DROP USER IF EXISTS regress_ivm_user;
+CREATE USER regress_ivm_admin;
+CREATE USER regress_ivm_user;
+
+--- create a table with RLS
+SET SESSION AUTHORIZATION regress_ivm_admin;
+CREATE TABLE rls_tbl(id int, data text, owner name);
+INSERT INTO rls_tbl VALUES
+ (1,'foo','regress_ivm_user'),
+ (2,'bar','postgres');
+CREATE TABLE num_tbl(id int, num text);
+INSERT INTO num_tbl VALUES
+ (1,'one'),
+ (2,'two'),
+ (3,'three'),
+ (4,'four'),
+ (5,'five'),
+ (6,'six');
+
+--- Users can access only their own rows
+CREATE POLICY rls_tbl_policy ON rls_tbl FOR SELECT TO PUBLIC USING(owner = current_user);
+ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
+GRANT ALL on rls_tbl TO PUBLIC;
+GRANT ALL on num_tbl TO PUBLIC;
+
+--- create a view owned by regress_ivm_user
+SET SESSION AUTHORIZATION regress_ivm_user;
+
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls AS SELECT * FROM rls_tbl;
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+RESET SESSION AUTHORIZATION;
+
+--- inserts rows owned by different users
+INSERT INTO rls_tbl VALUES
+ (3,'baz','regress_ivm_user'),
+ (4,'qux','postgres');
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+
+--- combination of diffent kinds of commands
+WITH
+ i AS (INSERT INTO rls_tbl VALUES(5,'quux','postgres'), (6,'corge','regress_ivm_user')),
+ u AS (UPDATE rls_tbl SET owner = 'postgres' WHERE id = 1),
+ u2 AS (UPDATE rls_tbl SET owner = 'regress_ivm_user' WHERE id = 2)
+SELECT;
+SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
+
+---
+SET SESSION AUTHORIZATION regress_ivm_user;
+CREATE INCREMENTAL MATERIALIZED VIEW ivm_rls2 AS SELECT * FROM rls_tbl JOIN num_tbl USING(id);
+RESET SESSION AUTHORIZATION;
+
+WITH
+ x AS (UPDATE rls_tbl SET data = data || '_2' where id in (3,4)),
+ y AS (UPDATE num_tbl SET num = num || '_2' where id in (3,4))
+SELECT;
+SELECT * FROM ivm_rls2 ORDER BY 1,2,3;
+
+-- automatic index creation
+CREATE TABLE base_a (i int primary key, j int);
+CREATE TABLE base_b (i int primary key, j int);
+
+--- group by: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx1 AS SELECT i, sum(j) FROM base_a GROUP BY i;
+
+--- distinct: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx2 AS SELECT DISTINCT j FROM base_a;
+
+--- with all pkey columns: create an index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx3(i_a, i_b) AS SELECT a.i, b.i FROM base_a a, base_b b;
+
+--- missing some pkey columns: no index
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx4 AS SELECT j FROM base_a;
+CREATE INCREMENTAL MATERIALIZED VIEW mv_idx5 AS SELECT a.i, b.j FROM base_a a, base_b b;
+
+-- cleanup
+
+DROP TABLE rls_tbl CASCADE;
+DROP TABLE num_tbl CASCADE;
+DROP USER regress_ivm_user;
+DROP USER regress_ivm_admin;
+
+DROP TABLE mv_base_b CASCADE;
+DROP TABLE mv_base_a CASCADE;
--
2.34.1
v34-0002-Add-relisivm-column-to-pg_class-system-catalog.patchtext/x-diff; name=v34-0002-Add-relisivm-column-to-pg_class-system-catalog.patchDownload
From 2060d442fb2bde33cbfc0dacaf0af9079c4f27b3 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:07:23 +0900
Subject: [PATCH v34 02/11] Add relisivm column to pg_class system catalog
If this boolean column is true, a relations is Incrementally Maintainable
Materialized View (IMMV). This is set when IMMV is created.
Also, isimmv columns is added to pg_matviews system view.
isimmv
---
src/backend/catalog/heap.c | 1 +
src/backend/catalog/index.c | 1 +
src/backend/catalog/system_views.sql | 1 +
src/backend/utils/cache/lsyscache.c | 24 ++++++++++++++++++++++++
src/backend/utils/cache/relcache.c | 2 ++
src/include/catalog/pg_class.h | 3 +++
src/include/utils/lsyscache.h | 1 +
src/include/utils/rel.h | 6 ++++++
src/test/regress/expected/rules.out | 1 +
9 files changed, 40 insertions(+)
diff --git a/src/backend/catalog/heap.c b/src/backend/catalog/heap.c
index 00074c8a94..8d5470c8f7 100644
--- a/src/backend/catalog/heap.c
+++ b/src/backend/catalog/heap.c
@@ -938,6 +938,7 @@ InsertPgClassTuple(Relation pg_class_desc,
values[Anum_pg_class_relrewrite - 1] = ObjectIdGetDatum(rd_rel->relrewrite);
values[Anum_pg_class_relfrozenxid - 1] = TransactionIdGetDatum(rd_rel->relfrozenxid);
values[Anum_pg_class_relminmxid - 1] = MultiXactIdGetDatum(rd_rel->relminmxid);
+ values[Anum_pg_class_relisivm - 1] = BoolGetDatum(rd_rel->relisivm);
if (relacl != (Datum) 0)
values[Anum_pg_class_relacl - 1] = relacl;
else
diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c
index a819b4197c..eb81685f6b 100644
--- a/src/backend/catalog/index.c
+++ b/src/backend/catalog/index.c
@@ -1007,6 +1007,7 @@ index_create(Relation heapRelation,
indexRelation->rd_rel->relowner = heapRelation->rd_rel->relowner;
indexRelation->rd_rel->relam = accessMethodId;
indexRelation->rd_rel->relispartition = OidIsValid(parentIndexRelid);
+ indexRelation->rd_rel->relisivm = false;
/*
* store index's pg_class entry
diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql
index 19cabc9a47..c88c8af96b 100644
--- a/src/backend/catalog/system_views.sql
+++ b/src/backend/catalog/system_views.sql
@@ -146,6 +146,7 @@ CREATE VIEW pg_matviews AS
T.spcname AS tablespace,
C.relhasindex AS hasindexes,
C.relispopulated AS ispopulated,
+ C.relisivm AS isimmv,
pg_get_viewdef(C.oid) AS definition
FROM pg_class C LEFT JOIN pg_namespace N ON (N.oid = C.relnamespace)
LEFT JOIN pg_tablespace T ON (T.oid = C.reltablespace)
diff --git a/src/backend/utils/cache/lsyscache.c b/src/backend/utils/cache/lsyscache.c
index 48a280d089..59c06b853c 100644
--- a/src/backend/utils/cache/lsyscache.c
+++ b/src/backend/utils/cache/lsyscache.c
@@ -2042,6 +2042,30 @@ get_rel_relispartition(Oid relid)
return false;
}
+/*
+ * get_rel_relisivm
+ *
+ * Returns the relisivm flag associated with a given relation.
+ */
+bool
+get_rel_relisivm(Oid relid)
+{
+ HeapTuple tp;
+
+ tp = SearchSysCache1(RELOID, ObjectIdGetDatum(relid));
+ if (HeapTupleIsValid(tp))
+ {
+ Form_pg_class reltup = (Form_pg_class) GETSTRUCT(tp);
+ bool result;
+
+ result = reltup->relisivm;
+ ReleaseSysCache(tp);
+ return result;
+ }
+ else
+ return false;
+}
+
/*
* get_rel_tablespace
*
diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c
index 66ed24e401..cba2eac1e8 100644
--- a/src/backend/utils/cache/relcache.c
+++ b/src/backend/utils/cache/relcache.c
@@ -1931,6 +1931,8 @@ formrdesc(const char *relationName, Oid relationReltype,
/* ... and they're always populated, too */
relation->rd_rel->relispopulated = true;
+ /* ... and they're always no ivm, too */
+ relation->rd_rel->relisivm = false;
relation->rd_rel->relreplident = REPLICA_IDENTITY_NOTHING;
relation->rd_rel->relpages = 0;
diff --git a/src/include/catalog/pg_class.h b/src/include/catalog/pg_class.h
index 0fc2c093b0..80cbee29ca 100644
--- a/src/include/catalog/pg_class.h
+++ b/src/include/catalog/pg_class.h
@@ -119,6 +119,9 @@ CATALOG(pg_class,1259,RelationRelationId) BKI_BOOTSTRAP BKI_ROWTYPE_OID(83,Relat
/* is relation a partition? */
bool relispartition BKI_DEFAULT(f);
+ /* is relation a matview with ivm? */
+ bool relisivm BKI_DEFAULT(f);
+
/* link to original rel during table rewrite; otherwise 0 */
Oid relrewrite BKI_DEFAULT(0) BKI_LOOKUP_OPT(pg_class);
diff --git a/src/include/utils/lsyscache.h b/src/include/utils/lsyscache.h
index 20446f6f83..6b17921d23 100644
--- a/src/include/utils/lsyscache.h
+++ b/src/include/utils/lsyscache.h
@@ -139,6 +139,7 @@ extern Oid get_rel_namespace(Oid relid);
extern Oid get_rel_type_id(Oid relid);
extern char get_rel_relkind(Oid relid);
extern bool get_rel_relispartition(Oid relid);
+extern bool get_rel_relisivm(Oid relid);
extern Oid get_rel_tablespace(Oid relid);
extern char get_rel_persistence(Oid relid);
extern Oid get_rel_relam(Oid relid);
diff --git a/src/include/utils/rel.h b/src/include/utils/rel.h
index 8700204953..7f36d6f5fa 100644
--- a/src/include/utils/rel.h
+++ b/src/include/utils/rel.h
@@ -676,6 +676,12 @@ RelationCloseSmgr(Relation relation)
*/
#define RelationIsPopulated(relation) ((relation)->rd_rel->relispopulated)
+/*
+ * RelationIsIVM
+ * True if relation is an incrementally maintainable materialized view.
+ */
+#define RelationIsIVM(relation) ((relation)->rd_rel->relisivm)
+
/*
* RelationIsAccessibleInLogicalDecoding
* True if we need to log enough information to have access via
diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out
index 4c789279e5..c7ba7be647 100644
--- a/src/test/regress/expected/rules.out
+++ b/src/test/regress/expected/rules.out
@@ -1393,6 +1393,7 @@ pg_matviews| SELECT n.nspname AS schemaname,
t.spcname AS tablespace,
c.relhasindex AS hasindexes,
c.relispopulated AS ispopulated,
+ c.relisivm AS isimmv,
pg_get_viewdef(c.oid) AS definition
FROM ((pg_class c
LEFT JOIN pg_namespace n ON ((n.oid = c.relnamespace)))
--
2.34.1
v34-0008-Add-aggregates-support-in-IVM.patchtext/x-diff; name=v34-0008-Add-aggregates-support-in-IVM.patchDownload
From 28f2b7e0cbd4e758a2b1fc0fe2fbcf64fa3a882d Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 20:46:32 +0900
Subject: [PATCH v34 08/11] Add aggregates support in IVM
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit
count, sum, adn avg are supported.
As a restriction, expressions specified in GROUP BY must appear in
the target list because tuples to be updated in IMMV are identified
by using this group key. However, in the case of aggregates without
GROUP BY, there is only one tuple in the view, so keys are not uses
to identify tuples.
When creating a IMMV, in addition to __ivm_count column, some hidden
columns for each aggregate are added to the target list. For example,
names of these hidden columns are ivm_count_avg and ivm_sum_avg for
the average function, and so on.
When a base table is modified, the aggregated values and related
hidden columns are also updated as well as __ivm_count__. The
way of update depends the kind of aggregate function. Specifically,
sum and count are updated by simply adding or subtracting delta value
calculated from delta tables. avg is updated by using values of sum
and count stored in views as hidden columns and deltas calculated
from delta tables.
About aggregate functions except "count()" (sum and avg), NULLs in input
values are ignored, and the result of aggegate should be NULL when no
rows are selected. To support this specification, the numbers of non-NULL
input values are counted and stored in hidden columns. In the case of
count(), count(x) returns zero when no rows are selected, but count(*)
doesn't ignore NULL input.
---
src/backend/commands/createas.c | 265 +++++++++++++++++--
src/backend/commands/matview.c | 433 ++++++++++++++++++++++++++++++--
src/include/commands/createas.h | 1 +
3 files changed, 662 insertions(+), 37 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index 7138dd59ce..d8767137d9 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -51,13 +51,19 @@
#include "parser/parsetree.h"
#include "parser/parse_clause.h"
#include "parser/parse_func.h"
+#include "parser/parse_type.h"
#include "rewrite/rewriteHandler.h"
+#include "rewrite/rewriteManip.h"
+#include "storage/smgr.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
#include "utils/lsyscache.h"
+#include "utils/regproc.h"
+#include "utils/fmgroids.h"
#include "utils/rel.h"
#include "utils/rls.h"
#include "utils/snapmgr.h"
+#include "utils/syscache.h"
typedef struct
{
@@ -71,6 +77,11 @@ typedef struct
BulkInsertState bistate; /* bulk insert state */
} DR_intorel;
+typedef struct
+{
+ bool has_agg;
+} check_ivm_restriction_context;
+
/* utility functions for CTAS definition creation */
static ObjectAddress create_ctas_internal(List *attrList, IntoClause *into);
static ObjectAddress create_ctas_nodata(List *tlist, IntoClause *into);
@@ -85,8 +96,9 @@ static void CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid mat
Relids *relids, bool ex_lock);
static void CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock);
static void check_ivm_restriction(Node *node);
-static bool check_ivm_restriction_walker(Node *node, void *context);
+static bool check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context);
static Bitmapset *get_primary_key_attnos_from_query(Query *query, List **constraintList);
+static bool check_aggregate_supports_ivm(Oid aggfnoid);
/*
* create_ctas_internal
@@ -417,6 +429,7 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
* rewriteQueryForIMMV -- rewrite view definition query for IMMV
*
* count(*) is added for counting distinct tuples in views.
+ * Also, additional hidden columns are added for aggregate values.
*/
Query *
rewriteQueryForIMMV(Query *query, List *colNames)
@@ -430,16 +443,49 @@ rewriteQueryForIMMV(Query *query, List *colNames)
rewritten = copyObject(query);
pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
- /*
- * Convert DISTINCT to GROUP BY and add count(*) for counting distinct
- * tuples in views.
- */
- if (rewritten->distinctClause)
+ /* group keys must be in targetlist */
+ if (rewritten->groupClause)
{
- TargetEntry *tle;
+ ListCell *lc;
+ foreach(lc, rewritten->groupClause)
+ {
+ SortGroupClause *scl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(scl, rewritten->targetList);
+ if (tle->resjunk)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUP BY expression not appearing in select list is not supported on incrementally maintainable materialized view")));
+ }
+ }
+ /* Convert DISTINCT to GROUP BY. count(*) will be added afterward. */
+ else if (!rewritten->hasAggs && rewritten->distinctClause)
rewritten->groupClause = transformDistinctClause(NULL, &rewritten->targetList, rewritten->sortClause, false);
+ /* Add additional columns for aggregate values */
+ if (rewritten->hasAggs)
+ {
+ ListCell *lc;
+ List *aggs = NIL;
+ AttrNumber next_resno = list_length(rewritten->targetList) + 1;
+
+ foreach(lc, rewritten->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ char *resname = (colNames == NIL || foreach_current_index(lc) >= list_length(colNames) ?
+ tle->resname : strVal(list_nth(colNames, tle->resno - 1)));
+
+ if (IsA(tle->expr, Aggref))
+ makeIvmAggColumn(pstate, (Aggref *) tle->expr, resname, &next_resno, &aggs);
+ }
+ rewritten->targetList = list_concat(rewritten->targetList, aggs);
+ }
+
+ /* Add count(*) for counting distinct tuples in views */
+ if (rewritten->distinctClause || rewritten->hasAggs)
+ {
+ TargetEntry *tle;
+
fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
fn->agg_star = true;
@@ -456,6 +502,91 @@ rewriteQueryForIMMV(Query *query, List *colNames)
return rewritten;
}
+/*
+ * makeIvmAggColumn -- make additional aggregate columns for IVM
+ *
+ * For an aggregate column specified by aggref, additional aggregate columns
+ * are added, which are used to calculate the new aggregate value in IMMV.
+ * An additional aggregate columns has a name based on resname
+ * (ex. ivm_count_resname), and resno specified by next_resno. The created
+ * columns are returned to aggs, and the resno for the next column is also
+ * returned to next_resno.
+ *
+ * Currently, an additional count() is created for aggref other than count.
+ * In addition, sum() is created for avg aggregate column.
+ */
+void
+makeIvmAggColumn(ParseState *pstate, Aggref *aggref, char *resname, AttrNumber *next_resno, List **aggs)
+{
+ TargetEntry *tle_count;
+ Node *node;
+ FuncCall *fn;
+ Const *dmy_arg = makeConst(INT4OID,
+ -1,
+ InvalidOid,
+ sizeof(int32),
+ Int32GetDatum(1),
+ false,
+ true); /* pass by value */
+ const char *aggname = get_func_name(aggref->aggfnoid);
+
+ /*
+ * For aggregate functions except count, add count() func with the same arg parameters.
+ * This count result is used for determining if the aggregate value should be NULL or not.
+ * Also, add sum() func for avg because we need to calculate an average value as sum/count.
+ *
+ * XXX: If there are same expressions explicitly in the target list, we can use this instead
+ * of adding new duplicated one.
+ */
+ if (strcmp(aggname, "count") != 0)
+ {
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+
+ /* Make a Func with a dummy arg, and then override this by the original agg's args. */
+ node = ParseFuncOrColumn(pstate, fn->funcname, list_make1(dmy_arg), NULL, fn, false, -1);
+ ((Aggref *)node)->args = aggref->args;
+
+ tle_count = makeTargetEntry((Expr *) node,
+ *next_resno,
+ pstrdup(makeObjectName("__ivm_count",resname, "_")),
+ false);
+ *aggs = lappend(*aggs, tle_count);
+ (*next_resno)++;
+ }
+ if (strcmp(aggname, "avg") == 0)
+ {
+ List *dmy_args = NIL;
+ ListCell *lc;
+ foreach(lc, aggref->aggargtypes)
+ {
+ Oid typeid = lfirst_oid(lc);
+ Type type = typeidType(typeid);
+
+ Const *con = makeConst(typeid,
+ -1,
+ typeTypeCollation(type),
+ typeLen(type),
+ (Datum) 0,
+ true,
+ typeByVal(type));
+ dmy_args = lappend(dmy_args, con);
+ ReleaseSysCache(type);
+ }
+ fn = makeFuncCall(SystemFuncName("sum"), NIL, COERCE_EXPLICIT_CALL, -1);
+
+ /* Make a Func with dummy args, and then override this by the original agg's args. */
+ node = ParseFuncOrColumn(pstate, fn->funcname, dmy_args, NULL, fn, false, -1);
+ ((Aggref *)node)->args = aggref->args;
+
+ tle_count = makeTargetEntry((Expr *) node,
+ *next_resno,
+ pstrdup(makeObjectName("__ivm_sum",resname, "_")),
+ false);
+ *aggs = lappend(*aggs, tle_count);
+ (*next_resno)++;
+ }
+}
+
/*
* GetIntoRelEFlags --- compute executor flags needed for CREATE TABLE AS
*
@@ -939,11 +1070,13 @@ CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock
static void
check_ivm_restriction(Node *node)
{
- check_ivm_restriction_walker(node, NULL);
+ check_ivm_restriction_context context = {false};
+
+ check_ivm_restriction_walker(node, &context);
}
static bool
-check_ivm_restriction_walker(Node *node, void *context)
+check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context)
{
if (node == NULL)
return false;
@@ -972,6 +1105,10 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("CTE is not supported on incrementally maintainable materialized view")));
+ if (qry->groupClause != NIL && !qry->hasAggs)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUP BY clause without aggregate is not supported on incrementally maintainable materialized view")));
if (qry->havingQual != NULL)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
@@ -1024,6 +1161,8 @@ check_ivm_restriction_walker(Node *node, void *context)
}
}
+ context->has_agg |= qry->hasAggs;
+
/* restrictions for rtable */
foreach(lc, qry->rtable)
{
@@ -1072,7 +1211,7 @@ check_ivm_restriction_walker(Node *node, void *context)
}
- query_tree_walker(qry, check_ivm_restriction_walker, NULL, QTW_IGNORE_RANGE_TABLE);
+ query_tree_walker(qry, check_ivm_restriction_walker, (void *) context, QTW_IGNORE_RANGE_TABLE);
break;
}
@@ -1083,8 +1222,12 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("column name %s is not supported on incrementally maintainable materialized view", tle->resname)));
+ if (context->has_agg && !IsA(tle->expr, Aggref) && contain_aggs_of_level((Node *) tle->expr, 0))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("expression containing an aggregate in it is not supported on incrementally maintainable materialized view")));
- expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
break;
}
case T_JoinExpr:
@@ -1096,14 +1239,36 @@ check_ivm_restriction_walker(Node *node, void *context)
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("OUTER JOIN is not supported on incrementally maintainable materialized view")));
- expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
+ break;
}
- break;
case T_Aggref:
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("aggregate function is not supported on incrementally maintainable materialized view")));
- break;
+ {
+ /* Check if this supports IVM */
+ Aggref *aggref = (Aggref *) node;
+ const char *aggname = format_procedure(aggref->aggfnoid);
+
+ if (aggref->aggfilter != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with FILTER clause is not supported on incrementally maintainable materialized view")));
+
+ if (aggref->aggdistinct != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with DISTINCT arguments is not supported on incrementally maintainable materialized view")));
+
+ if (aggref->aggorder != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function with ORDER clause is not supported on incrementally maintainable materialized view")));
+
+ if (!check_aggregate_supports_ivm(aggref->aggfnoid))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function %s is not supported on incrementally maintainable materialized view", aggname)));
+ break;
+ }
default:
expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
break;
@@ -1111,6 +1276,46 @@ check_ivm_restriction_walker(Node *node, void *context)
return false;
}
+/*
+ * check_aggregate_supports_ivm
+ *
+ * Check if the given aggregate function is supporting IVM
+ */
+static bool
+check_aggregate_supports_ivm(Oid aggfnoid)
+{
+ switch (aggfnoid)
+ {
+ /* count */
+ case F_COUNT_ANY:
+ case F_COUNT_:
+
+ /* sum */
+ case F_SUM_INT8:
+ case F_SUM_INT4:
+ case F_SUM_INT2:
+ case F_SUM_FLOAT4:
+ case F_SUM_FLOAT8:
+ case F_SUM_MONEY:
+ case F_SUM_INTERVAL:
+ case F_SUM_NUMERIC:
+
+ /* avg */
+ case F_AVG_INT8:
+ case F_AVG_INT4:
+ case F_AVG_INT2:
+ case F_AVG_NUMERIC:
+ case F_AVG_FLOAT4:
+ case F_AVG_FLOAT8:
+ case F_AVG_INTERVAL:
+
+ return true;
+
+ default:
+ return false;
+ }
+}
+
/*
* CreateIndexOnIMMV
*
@@ -1168,7 +1373,29 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
index->concurrent = false;
index->if_not_exists = false;
- if (query->distinctClause)
+ if (query->groupClause)
+ {
+ /* create unique constraint on GROUP BY expression columns */
+ foreach(lc, query->groupClause)
+ {
+ SortGroupClause *scl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(scl, query->targetList);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ else if (query->distinctClause)
{
/* create unique constraint on all columns */
foreach(lc, query->targetList)
@@ -1226,7 +1453,7 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
(errmsg("could not create an index on materialized view \"%s\" automatically",
RelationGetRelationName(matviewRel)),
errdetail("This target list does not have all the primary key columns, "
- "or this view does not contain DISTINCT clause."),
+ "or this view does not contain GROUP BY or DISTINCT clause."),
errhint("Create an index on the materialized view for efficient incremental maintenance.")));
return;
}
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index bd7d65888d..ca6d236989 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -27,6 +27,7 @@
#include "catalog/pg_trigger.h"
#include "catalog/pg_opclass.h"
#include "commands/cluster.h"
+#include "commands/defrem.h"
#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
@@ -36,6 +37,7 @@
#include "executor/tstoreReceiver.h"
#include "miscadmin.h"
#include "nodes/makefuncs.h"
+#include "optimizer/optimizer.h"
#include "parser/analyze.h"
#include "parser/parse_clause.h"
#include "parser/parse_func.h"
@@ -107,6 +109,13 @@ static HTAB *mv_trigger_info = NULL;
static bool in_delta_calculation = false;
+/* kind of IVM operation for the view */
+typedef enum
+{
+ IVM_ADD,
+ IVM_SUB
+} IvmOp;
+
/* ENR name for materialized view delta */
#define NEW_DELTA_ENRNAME "new_delta"
#define OLD_DELTA_ENRNAME "old_delta"
@@ -138,7 +147,7 @@ static RangeTblEntry *get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *tabl
QueryEnvironment *queryEnv, Oid matviewid);
static RangeTblEntry *replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
QueryEnvironment *queryEnv);
-static Query *rewrite_query_for_counting(Query *query, ParseState *pstate);
+static Query *rewrite_query_for_counting_and_aggregates(Query *query, ParseState *pstate);
static void calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
DestReceiver *dest_old, DestReceiver *dest_new,
@@ -149,14 +158,27 @@ static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *
static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
Query *query, bool use_count, char *count_colname);
+static void append_set_clause_for_count(const char *resname, StringInfo buf_old,
+ StringInfo buf_new,StringInfo aggs_list);
+static void append_set_clause_for_sum(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list);
+static void append_set_clause_for_avg(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ const char *aggtype);
+static char *get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
+ const char* count_col, const char *castType);
+static char *get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
+ const char* count_col);
static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
- List *keys, const char *count_colname);
+ List *keys, StringInfo aggs_list, StringInfo aggs_set,
+ const char *count_colname);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
- List *keys, StringInfo target_list, const char* count_colname);
+ List *keys, StringInfo target_list, StringInfo aggs_set,
+ const char* count_colname);
static char *get_matching_condition_string(List *keys);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
@@ -1454,11 +1476,44 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
* When a base table is truncated, the view content will be empty if the
* view definition query does not contain an aggregate without a GROUP clause.
* Therefore, such views can be truncated.
+ *
+ * Aggregate views without a GROUP clause always have one row. Therefore,
+ * if a base table is truncated, the view will not be empty and will contain
+ * a row with NULL value (or 0 for count()). So, in this case, we refresh the
+ * view instead of truncating it.
*/
if (TRIGGER_FIRED_BY_TRUNCATE(trigdata->tg_event))
{
- ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
- NIL, DROP_RESTRICT, false, false);
+ if (!(query->hasAggs && query->groupClause == NIL))
+ ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
+ NIL, DROP_RESTRICT, false, false);
+ else
+ {
+ Oid OIDNewHeap;
+ DestReceiver *dest;
+ uint64 processed = 0;
+ Query *dataQuery = rewriteQueryForIMMV(query, NIL);
+ char relpersistence = matviewRel->rd_rel->relpersistence;
+
+ /*
+ * Create the transient table that will receive the regenerated data. Lock
+ * it against access by any other process until commit (by which time it
+ * will be gone).
+ */
+ OIDNewHeap = make_new_heap(matviewOid, matviewRel->rd_rel->reltablespace,
+ matviewRel->rd_rel->relam,
+ relpersistence, ExclusiveLock);
+ LockRelationOid(OIDNewHeap, AccessExclusiveLock);
+ dest = CreateTransientRelDestReceiver(OIDNewHeap);
+
+ /* Generate the data */
+ processed = refresh_matview_datafill(dest, dataQuery, NULL, NULL, "");
+ refresh_by_heap_swap(matviewOid, OIDNewHeap, relpersistence);
+
+ /* Inform cumulative stats system about our activity */
+ pgstat_count_truncate(matviewRel);
+ pgstat_count_heap_insert(matviewRel, processed);
+ }
/* Clean up hash entry and delete tuplestores */
clean_up_IVM_hash_entry(entry, false);
@@ -1498,8 +1553,8 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
/* Set all tables in the query to pre-update state */
rewritten = rewrite_query_for_preupdate_state(rewritten, entry->tables,
pstate, matviewOid);
- /* Rewrite for counting duplicated tuples */
- rewritten = rewrite_query_for_counting(rewritten, pstate);
+ /* Rewrite for counting duplicated tuples and aggregates functions*/
+ rewritten = rewrite_query_for_counting_and_aggregates(rewritten, pstate);
/* Create tuplestores to store view deltas */
if (entry->has_old)
@@ -1550,7 +1605,7 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
count_colname = pstrdup("__ivm_count__");
- if (query->distinctClause)
+ if (query->hasAggs || query->distinctClause)
use_count = true;
/* calculate delta tables */
@@ -1946,17 +2001,34 @@ replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
}
/*
- * rewrite_query_for_counting
+ * rewrite_query_for_counting_and_aggregates
*
- * Rewrite query for counting duplicated tuples.
+ * Rewrite query for counting duplicated tuples and aggregate functions.
*/
static Query *
-rewrite_query_for_counting(Query *query, ParseState *pstate)
+rewrite_query_for_counting_and_aggregates(Query *query, ParseState *pstate)
{
TargetEntry *tle_count;
FuncCall *fn;
Node *node;
+ /* For aggregate views */
+ if (query->hasAggs)
+ {
+ ListCell *lc;
+ List *aggs = NIL;
+ AttrNumber next_resno = list_length(query->targetList) + 1;
+
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+
+ if (IsA(tle->expr, Aggref))
+ makeIvmAggColumn(pstate, (Aggref *)tle->expr, tle->resname, &next_resno, &aggs);
+ }
+ query->targetList = list_concat(query->targetList, aggs);
+ }
+
/* Add count(*) for counting distinct tuples in views */
fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
fn->agg_star = true;
@@ -2029,6 +2101,8 @@ rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte
return query;
}
+#define IVM_colname(type, col) makeObjectName("__ivm_" type, col, "_")
+
/*
* apply_delta
*
@@ -2042,6 +2116,9 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
{
StringInfoData querybuf;
StringInfoData target_list_buf;
+ StringInfo aggs_list_buf = NULL;
+ StringInfo aggs_set_old = NULL;
+ StringInfo aggs_set_new = NULL;
Relation matviewRel;
char *matviewname;
ListCell *lc;
@@ -2064,6 +2141,15 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
initStringInfo(&querybuf);
initStringInfo(&target_list_buf);
+ if (query->hasAggs)
+ {
+ if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
+ aggs_set_old = makeStringInfo();
+ if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
+ aggs_set_new = makeStringInfo();
+ aggs_list_buf = makeStringInfo();
+ }
+
/* build string of target list */
for (i = 0; i < matviewRel->rd_att->natts; i++)
{
@@ -2080,13 +2166,61 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
i++;
if (tle->resjunk)
continue;
- keys = lappend(keys, attr);
+ /*
+ * For views without aggregates, all attributes are used as keys to identify a
+ * tuple in a view.
+ */
+ if (!query->hasAggs)
+ keys = lappend(keys, attr);
+
+ /* For views with aggregates, we need to build SET clause for updating aggregate
+ * values. */
+ if (query->hasAggs && IsA(tle->expr, Aggref))
+ {
+ Aggref *aggref = (Aggref *) tle->expr;
+ const char *aggname = get_func_name(aggref->aggfnoid);
+
+ /*
+ * We can use function names here because it is already checked if these
+ * can be used in IMMV by its OID at the definition time.
+ */
+
+ /* count */
+ if (!strcmp(aggname, "count"))
+ append_set_clause_for_count(resname, aggs_set_old, aggs_set_new, aggs_list_buf);
+
+ /* sum */
+ else if (!strcmp(aggname, "sum"))
+ append_set_clause_for_sum(resname, aggs_set_old, aggs_set_new, aggs_list_buf);
+
+ /* avg */
+ else if (!strcmp(aggname, "avg"))
+ append_set_clause_for_avg(resname, aggs_set_old, aggs_set_new, aggs_list_buf,
+ format_type_be(aggref->aggtype));
+
+ else
+ elog(ERROR, "unsupported aggregate function: %s", aggname);
+ }
+ }
+
+ /* If we have GROUP BY clause, we use its entries as keys. */
+ if (query->hasAggs && query->groupClause)
+ {
+ foreach (lc, query->groupClause)
+ {
+ SortGroupClause *sgcl = (SortGroupClause *) lfirst(lc);
+ TargetEntry *tle = get_sortgroupclause_tle(sgcl, query->targetList);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ keys = lappend(keys, attr);
+ }
}
/* Start maintaining the materialized view. */
@@ -2117,7 +2251,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (use_count)
/* apply old delta and get rows to be recalculated */
apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
- keys, count_colname);
+ keys, aggs_list_buf, aggs_set_old,
+ count_colname);
else
apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
@@ -2143,7 +2278,7 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
/* apply new delta */
if (use_count)
apply_new_delta_with_count(matviewname, NEW_DELTA_ENRNAME,
- keys, &target_list_buf, count_colname);
+ keys, aggs_set_new, &target_list_buf, count_colname);
else
apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
}
@@ -2158,6 +2293,250 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_finish failed");
}
+/*
+ * append_set_clause_for_count
+ *
+ * Append SET clause string for count aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_count(const char *resname, StringInfo buf_old,
+ StringInfo buf_new,StringInfo aggs_list)
+{
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* resname = mv.resname - t.resname */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, resname, "mv", "t", NULL, NULL));
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* resname = mv.resname + diff.resname */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, resname, "mv", "diff", NULL, NULL));
+ }
+
+ appendStringInfo(aggs_list, ", %s",
+ quote_qualified_identifier("diff", resname)
+ );
+}
+
+/*
+ * append_set_clause_for_sum
+ *
+ * Append SET clause string for sum aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_sum(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list)
+{
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* sum = mv.sum - t.sum */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, resname, "mv", "t", count_col, NULL)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* sum = mv.sum + diff.sum */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, resname, "mv", "diff", count_col, NULL)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
+/*
+ * append_set_clause_for_avg
+ *
+ * Append SET clause string for avg aggregation to given buffers.
+ * Also, append resnames required for calculating the aggregate value.
+ */
+static void
+append_set_clause_for_avg(const char *resname, StringInfo buf_old,
+ StringInfo buf_new, StringInfo aggs_list,
+ const char *aggtype)
+{
+ char *sum_col = IVM_colname("sum", resname);
+ char *count_col = IVM_colname("count", resname);
+
+ /* For tuple deletion */
+ if (buf_old)
+ {
+ /* avg = (mv.sum - t.sum)::aggtype / (mv.count - t.count) */
+ appendStringInfo(buf_old,
+ ", %s = %s OPERATOR(pg_catalog./) %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_SUB, sum_col, "mv", "t", count_col, aggtype),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+ /* sum = mv.sum - t.sum */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, sum_col),
+ get_operation_string(IVM_SUB, sum_col, "mv", "t", count_col, NULL)
+ );
+ /* count = mv.count - t.count */
+ appendStringInfo(buf_old,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_SUB, count_col, "mv", "t", NULL, NULL)
+ );
+
+ }
+ /* For tuple insertion */
+ if (buf_new)
+ {
+ /* avg = (mv.sum + diff.sum)::aggtype / (mv.count + diff.count) */
+ appendStringInfo(buf_new,
+ ", %s = %s OPERATOR(pg_catalog./) %s",
+ quote_qualified_identifier(NULL, resname),
+ get_operation_string(IVM_ADD, sum_col, "mv", "diff", count_col, aggtype),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ /* sum = mv.sum + diff.sum */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, sum_col),
+ get_operation_string(IVM_ADD, sum_col, "mv", "diff", count_col, NULL)
+ );
+ /* count = mv.count + diff.count */
+ appendStringInfo(buf_new,
+ ", %s = %s",
+ quote_qualified_identifier(NULL, count_col),
+ get_operation_string(IVM_ADD, count_col, "mv", "diff", NULL, NULL)
+ );
+ }
+
+ appendStringInfo(aggs_list, ", %s, %s, %s",
+ quote_qualified_identifier("diff", resname),
+ quote_qualified_identifier("diff", IVM_colname("sum", resname)),
+ quote_qualified_identifier("diff", IVM_colname("count", resname))
+ );
+}
+
+/*
+ * get_operation_string
+ *
+ * Build a string to calculate the new aggregate values.
+ */
+static char *
+get_operation_string(IvmOp op, const char *col, const char *arg1, const char *arg2,
+ const char* count_col, const char *castType)
+{
+ StringInfoData buf;
+ StringInfoData castString;
+ char *col1 = quote_qualified_identifier(arg1, col);
+ char *col2 = quote_qualified_identifier(arg2, col);
+ char op_char = (op == IVM_SUB ? '-' : '+');
+
+ initStringInfo(&buf);
+ initStringInfo(&castString);
+
+ if (castType)
+ appendStringInfo(&castString, "::%s", castType);
+
+ if (!count_col)
+ {
+ /*
+ * If the attributes don't have count columns then calc the result
+ * by using the operator simply.
+ */
+ appendStringInfo(&buf, "(%s OPERATOR(pg_catalog.%c) %s)%s",
+ col1, op_char, col2, castString.data);
+ }
+ else
+ {
+ /*
+ * If the attributes have count columns then consider the condition
+ * where the result becomes NULL.
+ */
+ char *null_cond = get_null_condition_string(op, arg1, arg2, count_col);
+
+ appendStringInfo(&buf,
+ "(CASE WHEN %s THEN NULL "
+ "WHEN %s IS NULL THEN %s "
+ "WHEN %s IS NULL THEN %s "
+ "ELSE (%s OPERATOR(pg_catalog.%c) %s)%s END)",
+ null_cond,
+ col1, col2,
+ col2, col1,
+ col1, op_char, col2, castString.data
+ );
+ }
+
+ return buf.data;
+}
+
+/*
+ * get_null_condition_string
+ *
+ * Build a predicate string for CASE clause to check if an aggregate value
+ * will became NULL after the given operation is applied.
+ */
+static char *
+get_null_condition_string(IvmOp op, const char *arg1, const char *arg2,
+ const char* count_col)
+{
+ StringInfoData null_cond;
+ initStringInfo(&null_cond);
+
+ switch (op)
+ {
+ case IVM_ADD:
+ appendStringInfo(&null_cond,
+ "%s OPERATOR(pg_catalog.=) 0 AND %s OPERATOR(pg_catalog.=) 0",
+ quote_qualified_identifier(arg1, count_col),
+ quote_qualified_identifier(arg2, count_col)
+ );
+ break;
+ case IVM_SUB:
+ appendStringInfo(&null_cond,
+ "%s OPERATOR(pg_catalog.=) %s",
+ quote_qualified_identifier(arg1, count_col),
+ quote_qualified_identifier(arg2, count_col)
+ );
+ break;
+ default:
+ elog(ERROR,"unknown operation");
+ }
+
+ return null_cond.data;
+}
+
+
/*
* apply_old_delta_with_count
*
@@ -2165,13 +2544,20 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
* which contains tuples to be deleted from to a materialized view given by
* matviewname. This is used when counting is required, that is, the view
* has aggregate or distinct.
+ *
+ * If the view desn't have aggregates or has GROUP BY, this requires a keys
+ * list to identify a tuple in the view. If the view has aggregates, this
+ * requires strings representing resnames of aggregates and SET clause for
+ * updating aggregate values.
*/
static void
apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
- List *keys, const char *count_colname)
+ List *keys, StringInfo aggs_list, StringInfo aggs_set,
+ const char *count_colname)
{
StringInfoData querybuf;
char *match_cond;
+ bool agg_without_groupby = (list_length(keys) == 0);
/* build WHERE condition for searching tuples to be deleted */
match_cond = get_matching_condition_string(keys);
@@ -2181,22 +2567,26 @@ apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
appendStringInfo(&querybuf,
"WITH t AS (" /* collecting tid of target tuples in the view */
"SELECT diff.%s, " /* count column */
- "(diff.%s OPERATOR(pg_catalog.=) mv.%s) AS for_dlt, "
+ "(diff.%s OPERATOR(pg_catalog.=) mv.%s AND %s) AS for_dlt, "
"mv.ctid "
+ "%s " /* aggregate columns */
"FROM %s AS mv, %s AS diff "
"WHERE %s" /* tuple matching condition */
"), updt AS (" /* update a tuple if this is not to be deleted */
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
+ "%s" /* SET clauses for aggregates */
"FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
")"
/* delete a tuple if this is to be deleted */
"DELETE FROM %s AS mv USING t "
"WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
count_colname,
- count_colname, count_colname,
+ count_colname, count_colname, (agg_without_groupby ? "false" : "true"),
+ (aggs_list != NULL ? aggs_list->data : ""),
matviewname, deltaname_old,
match_cond,
matviewname, count_colname, count_colname, count_colname,
+ (aggs_set != NULL ? aggs_set->data : ""),
matviewname);
if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
@@ -2260,10 +2650,15 @@ apply_old_delta(const char *matviewname, const char *deltaname_old,
* matviewname. This is used when counting is required, that is, the view
* has aggregate or distinct. Also, when a table in EXISTS sub queries
* is modified.
+ *
+ * If the view desn't have aggregates or has GROUP BY, this requires a keys
+ * list to identify a tuple in the view. If the view has aggregates, this
+ * requires strings representing SET clause for updating aggregate values.
*/
static void
apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
- List *keys, StringInfo target_list, const char* count_colname)
+ List *keys, StringInfo aggs_set, StringInfo target_list,
+ const char* count_colname)
{
StringInfoData querybuf;
StringInfoData returning_keys;
@@ -2294,6 +2689,7 @@ apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
appendStringInfo(&querybuf,
"WITH updt AS (" /* update a tuple if this exists in the view */
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.+) diff.%s "
+ "%s " /* SET clauses for aggregates */
"FROM %s AS diff "
"WHERE %s " /* tuple matching condition */
"RETURNING %s" /* returning keys of updated tuples */
@@ -2301,6 +2697,7 @@ apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
"SELECT %s FROM %s AS diff "
"WHERE NOT EXISTS (SELECT 1 FROM updt AS mv WHERE %s);",
matviewname, count_colname, count_colname, count_colname,
+ (aggs_set != NULL ? aggs_set->data : ""),
deltaname_new,
match_cond,
returning_keys.data,
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 6b47e66bfd..af3a5b4b27 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -30,6 +30,7 @@ extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
extern Query *rewriteQueryForIMMV(Query *query, List *colNames);
+extern void makeIvmAggColumn(ParseState *pstate, Aggref *aggref, char *resname, AttrNumber *next_resno, List **aggs);
extern int GetIntoRelEFlags(IntoClause *intoClause);
--
2.34.1
v34-0007-Add-DISTINCT-support-for-IVM.patchtext/x-diff; name=v34-0007-Add-DISTINCT-support-for-IVM.patchDownload
From f154d7e665d5b180c9dc115f980ffda227d4cc55 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 19:08:51 +0900
Subject: [PATCH v34 07/11] Add DISTINCT support for IVM
When IMMV is created with DISTINCT, multiplicity of tuples is
counted and stored in "__ivm_count__" column, which is a hidden
column of IMMV. The value in __ivm_count__ is updated when IMMV
is maintained incrementally. A tuple in IMMV can be removed if
and only if the count becomes zero.
---
src/backend/commands/createas.c | 141 ++++++++++++++++++++------
src/backend/commands/indexcmds.c | 40 ++++++++
src/backend/commands/matview.c | 148 ++++++++++++++++++++++++++--
src/backend/commands/tablecmds.c | 9 ++
src/backend/nodes/outfuncs.c | 1 +
src/backend/nodes/readfuncs.c | 1 +
src/backend/parser/parse_relation.c | 18 +++-
src/backend/rewrite/rewriteDefine.c | 3 +-
src/include/commands/createas.h | 2 +
src/include/nodes/parsenodes.h | 2 +
10 files changed, 320 insertions(+), 45 deletions(-)
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index a424abbd32..7138dd59ce 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -50,6 +50,7 @@
#include "parser/parser.h"
#include "parser/parsetree.h"
#include "parser/parse_clause.h"
+#include "parser/parse_func.h"
#include "rewrite/rewriteHandler.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
@@ -305,6 +306,9 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
errhint("functions must be marked IMMUTABLE")));
check_ivm_restriction((Node *) query);
+
+ /* For IMMV, we need to rewrite matview query */
+ query = rewriteQueryForIMMV(query, into->colNames);
}
if (into->skipData)
@@ -409,6 +413,49 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
return address;
}
+/*
+ * rewriteQueryForIMMV -- rewrite view definition query for IMMV
+ *
+ * count(*) is added for counting distinct tuples in views.
+ */
+Query *
+rewriteQueryForIMMV(Query *query, List *colNames)
+{
+ Query *rewritten;
+
+ Node *node;
+ ParseState *pstate = make_parsestate(NULL);
+ FuncCall *fn;
+
+ rewritten = copyObject(query);
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ /*
+ * Convert DISTINCT to GROUP BY and add count(*) for counting distinct
+ * tuples in views.
+ */
+ if (rewritten->distinctClause)
+ {
+ TargetEntry *tle;
+
+ rewritten->groupClause = transformDistinctClause(NULL, &rewritten->targetList, rewritten->sortClause, false);
+
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+ fn->agg_star = true;
+
+ node = ParseFuncOrColumn(pstate, fn->funcname, NIL, NULL, fn, false, -1);
+
+ tle = makeTargetEntry((Expr *) node,
+ list_length(rewritten->targetList) + 1,
+ pstrdup("__ivm_count__"),
+ false);
+ rewritten->targetList = lappend(rewritten->targetList, tle);
+ rewritten->hasAggs = true;
+ }
+
+ return rewritten;
+}
+
/*
* GetIntoRelEFlags --- compute executor flags needed for CREATE TABLE AS
*
@@ -532,7 +579,8 @@ intorel_startup(DestReceiver *self, int operation, TupleDesc typeinfo)
ColumnDef *col;
char *colname;
- if (lc)
+ /* Don't override hidden columns added for IVM */
+ if (lc && !isIvmName(NameStr(attribute->attname)))
{
colname = strVal(lfirst(lc));
lc = lnext(into->colNames, lc);
@@ -936,10 +984,6 @@ check_ivm_restriction_walker(Node *node, void *context)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view")));
- if (qry->distinctClause)
- ereport(ERROR,
- (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
- errmsg("DISTINCT is not supported on incrementally maintainable materialized view")));
if (qry->hasDistinctOn)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
@@ -1086,12 +1130,18 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
char idxname[NAMEDATALEN];
List *indexoidlist = RelationGetIndexList(matviewRel);
ListCell *indexoidscan;
- Bitmapset *key_attnos;
snprintf(idxname, sizeof(idxname), "%s_index", RelationGetRelationName(matviewRel));
index = makeNode(IndexStmt);
+ /*
+ * We consider null values not distinct to make sure that views with DISTINCT
+ * or GROUP BY don't contain multiple NULL rows when NULL is inserted to
+ * a base table concurrently.
+ */
+ index->nulls_not_distinct = true;
+
index->unique = true;
index->primary = false;
index->isconstraint = false;
@@ -1118,41 +1168,68 @@ CreateIndexOnIMMV(Query *query, Relation matviewRel)
index->concurrent = false;
index->if_not_exists = false;
- /* create index on the base tables' primary key columns */
- key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
- if (key_attnos)
+ if (query->distinctClause)
{
+ /* create unique constraint on all columns */
foreach(lc, query->targetList)
{
TargetEntry *tle = (TargetEntry *) lfirst(lc);
Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
-
- if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
- {
- IndexElem *iparam;
-
- iparam = makeNode(IndexElem);
- iparam->name = pstrdup(NameStr(attr->attname));
- iparam->expr = NULL;
- iparam->indexcolname = NULL;
- iparam->collation = NIL;
- iparam->opclass = NIL;
- iparam->opclassopts = NIL;
- iparam->ordering = SORTBY_DEFAULT;
- iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
- index->indexParams = lappend(index->indexParams, iparam);
- }
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
}
}
else
{
- /* create no index, just notice that an appropriate index is necessary for efficient IVM */
- ereport(NOTICE,
- (errmsg("could not create an index on materialized view \"%s\" automatically",
- RelationGetRelationName(matviewRel)),
- errdetail("This target list does not have all the primary key columns. "),
- errhint("Create an index on the materialized view for efficient incremental maintenance.")));
- return;
+ Bitmapset *key_attnos;
+
+ /* create index on the base tables' primary key columns */
+ key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
+ if (key_attnos)
+ {
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ }
+ else
+ {
+ /* create no index, just notice that an appropriate index is necessary for efficient IVM */
+ ereport(NOTICE,
+ (errmsg("could not create an index on materialized view \"%s\" automatically",
+ RelationGetRelationName(matviewRel)),
+ errdetail("This target list does not have all the primary key columns, "
+ "or this view does not contain DISTINCT clause."),
+ errhint("Create an index on the materialized view for efficient incremental maintenance.")));
+ return;
+ }
}
/* If we have a compatible index, we don't need to create another. */
diff --git a/src/backend/commands/indexcmds.c b/src/backend/commands/indexcmds.c
index 2caab88aa5..462c15f9c8 100644
--- a/src/backend/commands/indexcmds.c
+++ b/src/backend/commands/indexcmds.c
@@ -40,6 +40,7 @@
#include "commands/dbcommands.h"
#include "commands/defrem.h"
#include "commands/event_trigger.h"
+#include "commands/matview.h"
#include "commands/progress.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
@@ -1120,6 +1121,45 @@ DefineIndex(Oid tableId,
safe_index = indexInfo->ii_Expressions == NIL &&
indexInfo->ii_Predicate == NIL;
+ /*
+ * We disallow unique indexes on IVM columns of IMMVs.
+ */
+ if (RelationIsIVM(rel) && stmt->unique)
+ {
+ for (int i = 0; i < indexInfo->ii_NumIndexKeyAttrs; i++)
+ {
+ AttrNumber attno = indexInfo->ii_IndexAttrNumbers[i];
+ if (attno > 0)
+ {
+ char *name = NameStr(TupleDescAttr(rel->rd_att, attno - 1)->attname);
+ if (name && isIvmName(name))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("unique index creation on IVM columns is not supported")));
+ }
+ }
+
+ if (indexInfo->ii_Expressions)
+ {
+ Bitmapset *indexattrs = NULL;
+ int varno = -1;
+
+ pull_varattnos((Node *) indexInfo->ii_Expressions, 1, &indexattrs);
+
+ while ((varno = bms_next_member(indexattrs, varno)) >= 0)
+ {
+ int attno = varno + FirstLowInvalidHeapAttributeNumber;
+ char *name = NameStr(TupleDescAttr(rel->rd_att, attno - 1)->attname);
+ if (name && isIvmName(name))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("unique index creation on IVM columns is not supported")));
+ }
+
+ }
+ }
+
+
/*
* Report index creation if appropriate (delay this till after most of the
* error checks)
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index 9629e0a47c..bd7d65888d 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -148,11 +148,15 @@ static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *
static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
- Query *query);
+ Query *query, bool use_count, char *count_colname);
static void apply_old_delta(const char *matviewname, const char *deltaname_old,
List *keys);
+static void apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
+ List *keys, const char *count_colname);
static void apply_new_delta(const char *matviewname, const char *deltaname_new,
StringInfo target_list);
+static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
+ List *keys, StringInfo target_list, const char* count_colname);
static char *get_matching_condition_string(List *keys);
static void generate_equal(StringInfo querybuf, Oid opttype,
const char *leftop, const char *rightop);
@@ -267,6 +271,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
Oid matviewOid;
Relation matviewRel;
Query *dataQuery;
+ Query *viewQuery;
Oid tableSpace;
Oid relowner;
Oid OIDNewHeap;
@@ -329,8 +334,13 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
"CONCURRENTLY", "WITH NO DATA")));
- dataQuery = get_matview_query(matviewRel);
+ viewQuery = get_matview_query(matviewRel);
+ /* For IMMV, we need to rewrite matview query */
+ if (!stmt->skipData && RelationIsIVM(matviewRel))
+ dataQuery = rewriteQueryForIMMV(viewQuery,NIL);
+ else
+ dataQuery = viewQuery;
/*
* Check that there is a unique index with no WHERE clause on one or more
@@ -510,8 +520,8 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
if (!stmt->skipData && RelationIsIVM(matviewRel) && !oldPopulated)
{
- CreateIndexOnIMMV(dataQuery, matviewRel);
- CreateIvmTriggersOnBaseTables(dataQuery, matviewOid);
+ CreateIndexOnIMMV(viewQuery, matviewRel);
+ CreateIvmTriggersOnBaseTables(viewQuery, matviewOid);
}
table_close(matviewRel, NoLock);
@@ -1535,6 +1545,13 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
int rte_index = lfirst_int(lc2);
TupleDesc tupdesc_old;
TupleDesc tupdesc_new;
+ bool use_count = false;
+ char *count_colname = NULL;
+
+ count_colname = pstrdup("__ivm_count__");
+
+ if (query->distinctClause)
+ use_count = true;
/* calculate delta tables */
calc_delta(table, rte_index, rewritten, dest_old, dest_new,
@@ -1547,7 +1564,8 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
{
/* apply the delta tables to the materialized view */
apply_delta(matviewOid, old_tuplestore, new_tuplestore,
- tupdesc_old, tupdesc_new, query);
+ tupdesc_old, tupdesc_new, query, use_count,
+ count_colname);
}
PG_CATCH();
{
@@ -2020,7 +2038,7 @@ rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte
static void
apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
TupleDesc tupdesc_old, TupleDesc tupdesc_new,
- Query *query)
+ Query *query, bool use_count, char *count_colname)
{
StringInfoData querybuf;
StringInfoData target_list_buf;
@@ -2096,7 +2114,12 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
if (rc != SPI_OK_REL_REGISTER)
elog(ERROR, "SPI_register failed");
- apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+ if (use_count)
+ /* apply old delta and get rows to be recalculated */
+ apply_old_delta_with_count(matviewname, OLD_DELTA_ENRNAME,
+ keys, count_colname);
+ else
+ apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
}
/* For tuple insertion */
@@ -2118,7 +2141,11 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_register failed");
/* apply new delta */
- apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
+ if (use_count)
+ apply_new_delta_with_count(matviewname, NEW_DELTA_ENRNAME,
+ keys, &target_list_buf, count_colname);
+ else
+ apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
}
/* We're done maintaining the materialized view. */
@@ -2131,6 +2158,51 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n
elog(ERROR, "SPI_finish failed");
}
+/*
+ * apply_old_delta_with_count
+ *
+ * Execute a query for applying a delta table given by deltname_old
+ * which contains tuples to be deleted from to a materialized view given by
+ * matviewname. This is used when counting is required, that is, the view
+ * has aggregate or distinct.
+ */
+static void
+apply_old_delta_with_count(const char *matviewname, const char *deltaname_old,
+ List *keys, const char *count_colname)
+{
+ StringInfoData querybuf;
+ char *match_cond;
+
+ /* build WHERE condition for searching tuples to be deleted */
+ match_cond = get_matching_condition_string(keys);
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "WITH t AS (" /* collecting tid of target tuples in the view */
+ "SELECT diff.%s, " /* count column */
+ "(diff.%s OPERATOR(pg_catalog.=) mv.%s) AS for_dlt, "
+ "mv.ctid "
+ "FROM %s AS mv, %s AS diff "
+ "WHERE %s" /* tuple matching condition */
+ "), updt AS (" /* update a tuple if this is not to be deleted */
+ "UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.-) t.%s "
+ "FROM t WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND NOT for_dlt "
+ ")"
+ /* delete a tuple if this is to be deleted */
+ "DELETE FROM %s AS mv USING t "
+ "WHERE mv.ctid OPERATOR(pg_catalog.=) t.ctid AND for_dlt",
+ count_colname,
+ count_colname, count_colname,
+ matviewname, deltaname_old,
+ match_cond,
+ matviewname, count_colname, count_colname, count_colname,
+ matviewname);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
/*
* apply_old_delta
*
@@ -2180,6 +2252,66 @@ apply_old_delta(const char *matviewname, const char *deltaname_old,
elog(ERROR, "SPI_exec failed: %s", querybuf.data);
}
+/*
+ * apply_new_delta_with_count
+ *
+ * Execute a query for applying a delta table given by deltname_new
+ * which contains tuples to be inserted into a materialized view given by
+ * matviewname. This is used when counting is required, that is, the view
+ * has aggregate or distinct. Also, when a table in EXISTS sub queries
+ * is modified.
+ */
+static void
+apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
+ List *keys, StringInfo target_list, const char* count_colname)
+{
+ StringInfoData querybuf;
+ StringInfoData returning_keys;
+ ListCell *lc;
+ char *match_cond = "";
+
+ /* build WHERE condition for searching tuples to be updated */
+ match_cond = get_matching_condition_string(keys);
+
+ /* build string of keys list */
+ initStringInfo(&returning_keys);
+ if (keys)
+ {
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&returning_keys, "%s", quote_qualified_identifier("mv", resname));
+ if (lnext(keys, lc))
+ appendStringInfo(&returning_keys, ", ");
+ }
+ }
+ else
+ appendStringInfo(&returning_keys, "NULL");
+
+ /* Search for matching tuples from the view and update if found or insert if not. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "WITH updt AS (" /* update a tuple if this exists in the view */
+ "UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.+) diff.%s "
+ "FROM %s AS diff "
+ "WHERE %s " /* tuple matching condition */
+ "RETURNING %s" /* returning keys of updated tuples */
+ ") INSERT INTO %s (%s) " /* insert a new tuple if this doesn't exist */
+ "SELECT %s FROM %s AS diff "
+ "WHERE NOT EXISTS (SELECT 1 FROM updt AS mv WHERE %s);",
+ matviewname, count_colname, count_colname, count_colname,
+ deltaname_new,
+ match_cond,
+ returning_keys.data,
+ matviewname, target_list->data,
+ target_list->data, deltaname_new,
+ match_cond);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_INSERT)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
/*
* apply_new_delta
*
diff --git a/src/backend/commands/tablecmds.c b/src/backend/commands/tablecmds.c
index dbfe0d6b1c..07382b9cc0 100644
--- a/src/backend/commands/tablecmds.c
+++ b/src/backend/commands/tablecmds.c
@@ -57,6 +57,7 @@
#include "commands/cluster.h"
#include "commands/comment.h"
#include "commands/defrem.h"
+#include "commands/matview.h"
#include "commands/event_trigger.h"
#include "commands/sequence.h"
#include "commands/tablecmds.h"
@@ -3696,6 +3697,14 @@ renameatt_internal(Oid myrelid,
targetrelation = relation_open(myrelid, AccessExclusiveLock);
renameatt_check(myrelid, RelationGetForm(targetrelation), recursing);
+ /*
+ * Don't rename IVM columns.
+ */
+ if (RelationIsIVM(targetrelation) && isIvmName(oldattname))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("IVM column can not be renamed")));
+
/*
* if the 'recurse' flag is set then we are supposed to rename this
* attribute in all classes that inherit from 'relname' (as well as in
diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c
index 3337b77ae6..c191f70a6f 100644
--- a/src/backend/nodes/outfuncs.c
+++ b/src/backend/nodes/outfuncs.c
@@ -510,6 +510,7 @@ _outRangeTblEntry(StringInfo str, const RangeTblEntry *node)
WRITE_INT_FIELD(rellockmode);
WRITE_UINT_FIELD(perminfoindex);
WRITE_NODE_FIELD(tablesample);
+ WRITE_BOOL_FIELD(relisivm);
break;
case RTE_SUBQUERY:
WRITE_NODE_FIELD(subquery);
diff --git a/src/backend/nodes/readfuncs.c b/src/backend/nodes/readfuncs.c
index c4d01a441a..ffcab8cda2 100644
--- a/src/backend/nodes/readfuncs.c
+++ b/src/backend/nodes/readfuncs.c
@@ -361,6 +361,7 @@ _readRangeTblEntry(void)
READ_INT_FIELD(rellockmode);
READ_UINT_FIELD(perminfoindex);
READ_NODE_FIELD(tablesample);
+ READ_BOOL_FIELD(relisivm);
break;
case RTE_SUBQUERY:
READ_NODE_FIELD(subquery);
diff --git a/src/backend/parser/parse_relation.c b/src/backend/parser/parse_relation.c
index 2f64eaf0e3..a39358f125 100644
--- a/src/backend/parser/parse_relation.c
+++ b/src/backend/parser/parse_relation.c
@@ -36,6 +36,7 @@
#include "utils/rel.h"
#include "utils/syscache.h"
#include "utils/varlena.h"
+#include "commands/matview.h"
/*
@@ -97,7 +98,7 @@ static void expandTupleDesc(TupleDesc tupdesc, Alias *eref,
int count, int offset,
int rtindex, int sublevels_up,
int location, bool include_dropped,
- List **colnames, List **colvars);
+ List **colnames, List **colvars, bool is_ivm);
static int specialAttNum(const char *attname);
static bool rte_visible_if_lateral(ParseState *pstate, RangeTblEntry *rte);
static bool rte_visible_if_qualified(ParseState *pstate, RangeTblEntry *rte);
@@ -1503,6 +1504,7 @@ addRangeTableEntry(ParseState *pstate,
rte->inh = inh;
rte->relkind = rel->rd_rel->relkind;
rte->rellockmode = lockmode;
+ rte->relisivm = rel->rd_rel->relisivm;
/*
* Build the list of effective column names using user-supplied aliases
@@ -1588,6 +1590,7 @@ addRangeTableEntryForRelation(ParseState *pstate,
rte->inh = inh;
rte->relkind = rel->rd_rel->relkind;
rte->rellockmode = lockmode;
+ rte->relisivm = rel->rd_rel->relisivm;
/*
* Build the list of effective column names using user-supplied aliases
@@ -2757,7 +2760,7 @@ expandRTE(RangeTblEntry *rte, int rtindex, int sublevels_up,
expandTupleDesc(tupdesc, rte->eref,
rtfunc->funccolcount, atts_done,
rtindex, sublevels_up, location,
- include_dropped, colnames, colvars);
+ include_dropped, colnames, colvars, false);
}
else if (functypclass == TYPEFUNC_SCALAR)
{
@@ -3025,7 +3028,7 @@ expandRelation(Oid relid, Alias *eref, int rtindex, int sublevels_up,
expandTupleDesc(rel->rd_att, eref, rel->rd_att->natts, 0,
rtindex, sublevels_up,
location, include_dropped,
- colnames, colvars);
+ colnames, colvars, RelationIsIVM(rel));
relation_close(rel, AccessShareLock);
}
@@ -3042,7 +3045,7 @@ static void
expandTupleDesc(TupleDesc tupdesc, Alias *eref, int count, int offset,
int rtindex, int sublevels_up,
int location, bool include_dropped,
- List **colnames, List **colvars)
+ List **colnames, List **colvars, bool is_ivm)
{
ListCell *aliascell;
int varattno;
@@ -3055,6 +3058,9 @@ expandTupleDesc(TupleDesc tupdesc, Alias *eref, int count, int offset,
{
Form_pg_attribute attr = TupleDescAttr(tupdesc, varattno);
+ if (is_ivm && isIvmName(NameStr(attr->attname)) && !MatViewIncrementalMaintenanceIsEnabled())
+ continue;
+
if (attr->attisdropped)
{
if (include_dropped)
@@ -3217,6 +3223,10 @@ expandNSItemAttrs(ParseState *pstate, ParseNamespaceItem *nsitem,
Var *varnode = (Var *) lfirst(var);
TargetEntry *te;
+ /* if transform * into columnlist with IMMV, remove IVM columns */
+ if (rte->relisivm && isIvmName(label) && !MatViewIncrementalMaintenanceIsEnabled())
+ continue;
+
te = makeTargetEntry((Expr *) varnode,
(AttrNumber) pstate->p_next_resno++,
label,
diff --git a/src/backend/rewrite/rewriteDefine.c b/src/backend/rewrite/rewriteDefine.c
index 6cc9a8d8bf..5d22dbcfcf 100644
--- a/src/backend/rewrite/rewriteDefine.c
+++ b/src/backend/rewrite/rewriteDefine.c
@@ -614,7 +614,8 @@ checkRuleResultList(List *targetList, TupleDesc resultDesc, bool isSelect,
attr->atttypmod))));
}
- if (i != resultDesc->natts)
+ /* No check for materialized views since this could have special columns for IVM */
+ if ((!isSelect || requireColumnNameMatch) && i != resultDesc->natts)
ereport(ERROR,
(errcode(ERRCODE_INVALID_OBJECT_DEFINITION),
isSelect ?
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 396ad1bb4c..6b47e66bfd 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -29,6 +29,8 @@ extern ObjectAddress ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *st
extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
+extern Query *rewriteQueryForIMMV(Query *query, List *colNames);
+
extern int GetIntoRelEFlags(IntoClause *intoClause);
extern DestReceiver *CreateIntoRelDestReceiver(IntoClause *intoClause);
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 85a62b538e..1366946bb4 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -1106,6 +1106,8 @@ typedef struct RangeTblEntry
Index perminfoindex pg_node_attr(query_jumble_ignore);
/* sampling info, or NULL */
struct TableSampleClause *tablesample;
+ /* incrementally maintainable materialized view? */
+ bool relisivm;
/*
* Fields valid for a subquery RTE (else NULL):
--
2.34.1
v34-0006-Add-Incremental-View-Maintenance-support.patchtext/x-diff; name=v34-0006-Add-Incremental-View-Maintenance-support.patchDownload
From 836779a106d51155ce597a1ac7ffb21162a1e5c7 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 31 May 2023 18:59:50 +0900
Subject: [PATCH v34 06/11] Add Incremental View Maintenance support
In this implementation, AFTER triggers are used to collect
tuplestores containing transition table contents. When multiple tables
are changed, multiple AFTER triggers are invoked, then the final AFTER
trigger performs actual update of the matview. In addition, BEFORE
triggers are also used to handle global information for view
maintenance.
To calculate view deltas, we need both pre-state and post-state of base
tables. Post-update states are available in AFTER trigger, and pre-update
states can be calculated by removing inserted tuples and appending deleted
tuples. Insterted tuples are filtered using the snapshot taken before
table modiication, and deleted tuples are contained in the old transition
table.
Incrementally Maintainable Materialized Views (IMMV) can contain
duplicated tuples.
This patch also allows self-join, simultaneous updates of more than
one base table, and multiple updates of the same base table.
---
src/backend/access/transam/xact.c | 5 +
src/backend/commands/createas.c | 681 +++++++++++++
src/backend/commands/matview.c | 1468 ++++++++++++++++++++++++++++-
src/include/catalog/pg_proc.dat | 10 +
src/include/commands/createas.h | 4 +
src/include/commands/matview.h | 9 +
6 files changed, 2142 insertions(+), 35 deletions(-)
diff --git a/src/backend/access/transam/xact.c b/src/backend/access/transam/xact.c
index d119ab909d..5ea088f954 100644
--- a/src/backend/access/transam/xact.c
+++ b/src/backend/access/transam/xact.c
@@ -36,6 +36,7 @@
#include "catalog/pg_enum.h"
#include "catalog/storage.h"
#include "commands/async.h"
+#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/trigger.h"
#include "common/pg_prng.h"
@@ -2898,6 +2899,7 @@ AbortTransaction(void)
AtAbort_Notify();
AtEOXact_RelationMap(false, is_parallel_worker);
AtAbort_Twophase();
+ AtAbort_IVM();
/*
* Advertise the fact that we aborted in pg_xact (assuming that we got as
@@ -5228,6 +5230,9 @@ AbortSubTransaction(void)
pgstat_progress_end_command();
UnlockBuffers();
+ /* Clean up hash entries for incremental view maintenance */
+ AtAbort_IVM();
+
/* Reset WAL record construction state */
XLogResetInsertion();
diff --git a/src/backend/commands/createas.c b/src/backend/commands/createas.c
index 62050f4dc5..a424abbd32 100644
--- a/src/backend/commands/createas.c
+++ b/src/backend/commands/createas.c
@@ -29,15 +29,27 @@
#include "access/tableam.h"
#include "access/xact.h"
#include "catalog/namespace.h"
+#include "catalog/index.h"
+#include "catalog/pg_constraint.h"
+#include "catalog/pg_inherits.h"
+#include "catalog/pg_trigger.h"
#include "catalog/toasting.h"
#include "commands/createas.h"
+#include "commands/defrem.h"
#include "commands/matview.h"
#include "commands/prepare.h"
#include "commands/tablecmds.h"
+#include "commands/tablespace.h"
+#include "commands/trigger.h"
#include "commands/view.h"
#include "miscadmin.h"
+#include "optimizer/optimizer.h"
+#include "optimizer/prep.h"
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
+#include "parser/parser.h"
+#include "parser/parsetree.h"
+#include "parser/parse_clause.h"
#include "rewrite/rewriteHandler.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
@@ -68,6 +80,12 @@ static bool intorel_receive(TupleTableSlot *slot, DestReceiver *self);
static void intorel_shutdown(DestReceiver *self);
static void intorel_destroy(DestReceiver *self);
+static void CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid matviewOid,
+ Relids *relids, bool ex_lock);
+static void CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock);
+static void check_ivm_restriction(Node *node);
+static bool check_ivm_restriction_walker(Node *node, void *context);
+static Bitmapset *get_primary_key_attnos_from_query(Query *query, List **constraintList);
/*
* create_ctas_internal
@@ -277,6 +295,18 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
save_nestlevel = NewGUCNestLevel();
}
+ if (is_matview && into->ivm)
+ {
+ /* check if the query is supported in IMMV definition */
+ if (contain_mutable_functions((Node *) query))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("mutable function is not supported on incrementally maintainable materialized view"),
+ errhint("functions must be marked IMMUTABLE")));
+
+ check_ivm_restriction((Node *) query);
+ }
+
if (into->skipData)
{
/*
@@ -353,6 +383,27 @@ ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *stmt,
/* Restore userid and security context */
SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ if (into->ivm)
+ {
+ Oid matviewOid = address.objectId;
+ Relation matviewRel = table_open(matviewOid, NoLock);
+
+ /*
+ * Mark relisivm field, if it's a matview and into->ivm is true.
+ */
+ SetMatViewIVMState(matviewRel, true);
+
+ if (!into->skipData)
+ {
+ /* Create an index on incremental maintainable materialized view, if possible */
+ CreateIndexOnIMMV((Query *) into->viewQuery, matviewRel);
+
+ /* Create triggers on incremental maintainable materialized view */
+ CreateIvmTriggersOnBaseTables((Query *) into->viewQuery, matviewOid);
+ }
+ table_close(matviewRel, NoLock);
+ }
}
return address;
@@ -630,3 +681,633 @@ intorel_destroy(DestReceiver *self)
{
pfree(self);
}
+
+/*
+ * CreateIvmTriggersOnBaseTables -- create IVM triggers on all base tables
+ */
+void
+CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid)
+{
+ Relids relids = NULL;
+ bool ex_lock = false;
+ RangeTblEntry *rte;
+
+ /* Immediately return if we don't have any base tables. */
+ if (list_length(qry->rtable) < 1)
+ return;
+
+ /*
+ * If the view has more than one base tables, we need an exclusive lock
+ * on the view so that the view would be maintained serially to avoid
+ * the inconsistency that occurs when two base tables are modified in
+ * concurrent transactions. However, if the view has only one table,
+ * we can use a weaker lock.
+ *
+ * The type of lock should be determined here, because if we check the
+ * view definition at maintenance time, we need to acquire a weaker lock,
+ * and upgrading the lock level after this increases probability of
+ * deadlock.
+ */
+
+ rte = list_nth(qry->rtable, 0);
+ if (list_length(qry->rtable) > 1 || rte->rtekind != RTE_RELATION)
+ ex_lock = true;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, (Node *)qry, matviewOid, &relids, ex_lock);
+
+ bms_free(relids);
+}
+
+static void
+CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid matviewOid,
+ Relids *relids, bool ex_lock)
+{
+ if (node == NULL)
+ return;
+
+ /* This can recurse, so check for excessive recursion */
+ check_stack_depth();
+
+ switch (nodeTag(node))
+ {
+ case T_Query:
+ {
+ Query *query = (Query *) node;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, (Node *)query->jointree, matviewOid, relids, ex_lock);
+ }
+ break;
+
+ case T_RangeTblRef:
+ {
+ int rti = ((RangeTblRef *) node)->rtindex;
+ RangeTblEntry *rte = rt_fetch(rti, qry->rtable);
+
+ if (rte->rtekind == RTE_RELATION && !bms_is_member(rte->relid, *relids))
+ {
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_INSERT, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_DELETE, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_UPDATE, TRIGGER_TYPE_BEFORE, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_TRUNCATE, TRIGGER_TYPE_BEFORE, true);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_INSERT, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_DELETE, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_UPDATE, TRIGGER_TYPE_AFTER, ex_lock);
+ CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_TRUNCATE, TRIGGER_TYPE_AFTER, true);
+
+ *relids = bms_add_member(*relids, rte->relid);
+ }
+ }
+ break;
+
+ case T_FromExpr:
+ {
+ FromExpr *f = (FromExpr *) node;
+ ListCell *l;
+
+ foreach(l, f->fromlist)
+ CreateIvmTriggersOnBaseTablesRecurse(qry, lfirst(l), matviewOid, relids, ex_lock);
+ }
+ break;
+
+ case T_JoinExpr:
+ {
+ JoinExpr *j = (JoinExpr *) node;
+
+ CreateIvmTriggersOnBaseTablesRecurse(qry, j->larg, matviewOid, relids, ex_lock);
+ CreateIvmTriggersOnBaseTablesRecurse(qry, j->rarg, matviewOid, relids, ex_lock);
+ }
+ break;
+
+ default:
+ elog(ERROR, "unrecognized node type: %d", (int) nodeTag(node));
+ }
+}
+
+/*
+ * CreateIvmTrigger -- create IVM trigger on a base table
+ */
+static void
+CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock)
+{
+ ObjectAddress refaddr;
+ ObjectAddress address;
+ CreateTrigStmt *ivm_trigger;
+ List *transitionRels = NIL;
+
+ Assert(timing == TRIGGER_TYPE_BEFORE || timing == TRIGGER_TYPE_AFTER);
+
+ refaddr.classId = RelationRelationId;
+ refaddr.objectId = viewOid;
+ refaddr.objectSubId = 0;
+
+ ivm_trigger = makeNode(CreateTrigStmt);
+ ivm_trigger->relation = NULL;
+ ivm_trigger->row = false;
+
+ ivm_trigger->timing = timing;
+ ivm_trigger->events = type;
+
+ switch (type)
+ {
+ case TRIGGER_TYPE_INSERT:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_ins_before" : "IVM_trigger_ins_after");
+ break;
+ case TRIGGER_TYPE_DELETE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_del_before" : "IVM_trigger_del_after");
+ break;
+ case TRIGGER_TYPE_UPDATE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_upd_before" : "IVM_trigger_upd_after");
+ break;
+ case TRIGGER_TYPE_TRUNCATE:
+ ivm_trigger->trigname = (timing == TRIGGER_TYPE_BEFORE ? "IVM_trigger_truncate_before" : "IVM_trigger_truncate_after");
+ break;
+ default:
+ elog(ERROR, "unsupported trigger type");
+ }
+
+ if (timing == TRIGGER_TYPE_AFTER)
+ {
+ if (type == TRIGGER_TYPE_INSERT || type == TRIGGER_TYPE_UPDATE)
+ {
+ TriggerTransition *n = makeNode(TriggerTransition);
+ n->name = "__ivm_newtable";
+ n->isNew = true;
+ n->isTable = true;
+
+ transitionRels = lappend(transitionRels, n);
+ }
+ if (type == TRIGGER_TYPE_DELETE || type == TRIGGER_TYPE_UPDATE)
+ {
+ TriggerTransition *n = makeNode(TriggerTransition);
+ n->name = "__ivm_oldtable";
+ n->isNew = false;
+ n->isTable = true;
+
+ transitionRels = lappend(transitionRels, n);
+ }
+ }
+
+ /*
+ * XXX: When using DELETE or UPDATE, we must use exclusive lock for now
+ * because apply_old_delta(_with_count) uses ctid to identify the tuple
+ * to be deleted/deleted, but doesn't work in concurrent situations.
+ *
+ * If the view doesn't have aggregate, distinct, or tuple duplicate,
+ * then it would work even in concurrent situations. However, we don't have
+ * any way to guarantee the view has a unique key before opening the IMMV
+ * at the maintenance time because users may drop the unique index.
+ */
+
+ if (type == TRIGGER_TYPE_DELETE || type == TRIGGER_TYPE_UPDATE)
+ ex_lock = true;
+
+ ivm_trigger->funcname =
+ (timing == TRIGGER_TYPE_BEFORE ? SystemFuncName("IVM_immediate_before") : SystemFuncName("IVM_immediate_maintenance"));
+
+ ivm_trigger->columns = NIL;
+ ivm_trigger->transitionRels = transitionRels;
+ ivm_trigger->whenClause = NULL;
+ ivm_trigger->isconstraint = false;
+ ivm_trigger->deferrable = false;
+ ivm_trigger->initdeferred = false;
+ ivm_trigger->constrrel = NULL;
+ ivm_trigger->args = list_make2(
+ makeString(DatumGetPointer(DirectFunctionCall1(oidout, ObjectIdGetDatum(viewOid)))),
+ makeString(DatumGetPointer(DirectFunctionCall1(boolout, BoolGetDatum(ex_lock))))
+ );
+
+ address = CreateTrigger(ivm_trigger, NULL, relOid, InvalidOid, InvalidOid,
+ InvalidOid, InvalidOid, InvalidOid, NULL, true, false);
+
+ recordDependencyOn(&address, &refaddr, DEPENDENCY_AUTO);
+
+ /* Make changes-so-far visible */
+ CommandCounterIncrement();
+}
+
+/*
+ * check_ivm_restriction --- look for specify nodes in the query tree
+ */
+static void
+check_ivm_restriction(Node *node)
+{
+ check_ivm_restriction_walker(node, NULL);
+}
+
+static bool
+check_ivm_restriction_walker(Node *node, void *context)
+{
+ if (node == NULL)
+ return false;
+
+ /*
+ * We currently don't support Sub-Query.
+ */
+ if (IsA(node, SubPlan) || IsA(node, SubLink))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("subquery is not supported on incrementally maintainable materialized view")));
+
+ /* This can recurse, so check for excessive recursion */
+ check_stack_depth();
+
+ switch (nodeTag(node))
+ {
+ case T_Query:
+ {
+ Query *qry = (Query *)node;
+ ListCell *lc;
+ List *vars;
+
+ /* if contained CTE, return error */
+ if (qry->cteList != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("CTE is not supported on incrementally maintainable materialized view")));
+ if (qry->havingQual != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg(" HAVING clause is not supported on incrementally maintainable materialized view")));
+ if (qry->sortClause != NIL) /* There is a possibility that we don't need to return an error */
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("ORDER BY clause is not supported on incrementally maintainable materialized view")));
+ if (qry->limitOffset != NULL || qry->limitCount != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view")));
+ if (qry->distinctClause)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("DISTINCT is not supported on incrementally maintainable materialized view")));
+ if (qry->hasDistinctOn)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("DISTINCT ON is not supported on incrementally maintainable materialized view")));
+ if (qry->hasWindowFuncs)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("window functions are not supported on incrementally maintainable materialized view")));
+ if (qry->groupingSets != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("GROUPING SETS, ROLLUP, or CUBE clauses is not supported on incrementally maintainable materialized view")));
+ if (qry->setOperations != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("UNION/INTERSECT/EXCEPT statements are not supported on incrementally maintainable materialized view")));
+ if (list_length(qry->targetList) == 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("empty target list is not supported on incrementally maintainable materialized view")));
+ if (qry->rowMarks != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view")));
+
+ /* system column restrictions */
+ vars = pull_vars_of_level((Node *) qry, 0);
+ foreach(lc, vars)
+ {
+ if (IsA(lfirst(lc), Var))
+ {
+ Var *var = (Var *) lfirst(lc);
+ /* if system column, return error */
+ if (var->varattno < 0)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("system column is not supported on incrementally maintainable materialized view")));
+ }
+ }
+
+ /* restrictions for rtable */
+ foreach(lc, qry->rtable)
+ {
+ RangeTblEntry *rte = (RangeTblEntry *) lfirst(lc);
+
+ if (rte->subquery)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("subquery is not supported on incrementally maintainable materialized view")));
+
+ if (rte->tablesample != NULL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("TABLESAMPLE clause is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_PARTITIONED_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitioned table is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_RELATION && has_superclass(rte->relid))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("partitions is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_RELATION && find_inheritance_children(rte->relid, NoLock) != NIL)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("inheritance parent is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_FOREIGN_TABLE)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("foreign table is not supported on incrementally maintainable materialized view")));
+
+ if (rte->relkind == RELKIND_VIEW ||
+ rte->relkind == RELKIND_MATVIEW)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view")));
+
+ if (rte->rtekind == RTE_VALUES)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("VALUES is not supported on incrementally maintainable materialized view")));
+
+ }
+
+ query_tree_walker(qry, check_ivm_restriction_walker, NULL, QTW_IGNORE_RANGE_TABLE);
+
+ break;
+ }
+ case T_TargetEntry:
+ {
+ TargetEntry *tle = (TargetEntry *)node;
+ if (isIvmName(tle->resname))
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("column name %s is not supported on incrementally maintainable materialized view", tle->resname)));
+
+ expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ break;
+ }
+ case T_JoinExpr:
+ {
+ JoinExpr *joinexpr = (JoinExpr *)node;
+
+ if (joinexpr->jointype > JOIN_INNER)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("OUTER JOIN is not supported on incrementally maintainable materialized view")));
+
+ expression_tree_walker(node, check_ivm_restriction_walker, NULL);
+ }
+ break;
+ case T_Aggref:
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("aggregate function is not supported on incrementally maintainable materialized view")));
+ break;
+ default:
+ expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
+ break;
+ }
+ return false;
+}
+
+/*
+ * CreateIndexOnIMMV
+ *
+ * Create a unique index on incremental maintainable materialized view.
+ * If the view definition query has a GROUP BY clause, the index is created
+ * on the columns of GROUP BY expressions. Otherwise, if the view contains
+ * all primary key attritubes of its base tables in the target list, the index
+ * is created on these attritubes. In other cases, no index is created.
+ */
+void
+CreateIndexOnIMMV(Query *query, Relation matviewRel)
+{
+ ListCell *lc;
+ IndexStmt *index;
+ ObjectAddress address;
+ List *constraintList = NIL;
+ char idxname[NAMEDATALEN];
+ List *indexoidlist = RelationGetIndexList(matviewRel);
+ ListCell *indexoidscan;
+ Bitmapset *key_attnos;
+
+ snprintf(idxname, sizeof(idxname), "%s_index", RelationGetRelationName(matviewRel));
+
+ index = makeNode(IndexStmt);
+
+ index->unique = true;
+ index->primary = false;
+ index->isconstraint = false;
+ index->deferrable = false;
+ index->initdeferred = false;
+ index->idxname = idxname;
+ index->relation =
+ makeRangeVar(get_namespace_name(RelationGetNamespace(matviewRel)),
+ pstrdup(RelationGetRelationName(matviewRel)),
+ -1);
+ index->accessMethod = DEFAULT_INDEX_TYPE;
+ index->options = NIL;
+ index->tableSpace = get_tablespace_name(matviewRel->rd_rel->reltablespace);
+ index->whereClause = NULL;
+ index->indexParams = NIL;
+ index->indexIncludingParams = NIL;
+ index->excludeOpNames = NIL;
+ index->idxcomment = NULL;
+ index->indexOid = InvalidOid;
+ index->oldNumber = InvalidRelFileNumber;
+ index->oldCreateSubid = InvalidSubTransactionId;
+ index->oldFirstRelfilelocatorSubid = InvalidSubTransactionId;
+ index->transformed = true;
+ index->concurrent = false;
+ index->if_not_exists = false;
+
+ /* create index on the base tables' primary key columns */
+ key_attnos = get_primary_key_attnos_from_query(query, &constraintList);
+ if (key_attnos)
+ {
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, tle->resno - 1);
+
+ if (bms_is_member(tle->resno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ IndexElem *iparam;
+
+ iparam = makeNode(IndexElem);
+ iparam->name = pstrdup(NameStr(attr->attname));
+ iparam->expr = NULL;
+ iparam->indexcolname = NULL;
+ iparam->collation = NIL;
+ iparam->opclass = NIL;
+ iparam->opclassopts = NIL;
+ iparam->ordering = SORTBY_DEFAULT;
+ iparam->nulls_ordering = SORTBY_NULLS_DEFAULT;
+ index->indexParams = lappend(index->indexParams, iparam);
+ }
+ }
+ }
+ else
+ {
+ /* create no index, just notice that an appropriate index is necessary for efficient IVM */
+ ereport(NOTICE,
+ (errmsg("could not create an index on materialized view \"%s\" automatically",
+ RelationGetRelationName(matviewRel)),
+ errdetail("This target list does not have all the primary key columns. "),
+ errhint("Create an index on the materialized view for efficient incremental maintenance.")));
+ return;
+ }
+
+ /* If we have a compatible index, we don't need to create another. */
+ foreach(indexoidscan, indexoidlist)
+ {
+ Oid indexoid = lfirst_oid(indexoidscan);
+ Relation indexRel;
+ bool hasCompatibleIndex = false;
+
+ indexRel = index_open(indexoid, AccessShareLock);
+
+ if (CheckIndexCompatible(indexRel->rd_id,
+ index->accessMethod,
+ index->indexParams,
+ index->excludeOpNames))
+ hasCompatibleIndex = true;
+
+ index_close(indexRel, AccessShareLock);
+
+ if (hasCompatibleIndex)
+ return;
+ }
+
+ address = DefineIndex(RelationGetRelid(matviewRel),
+ index,
+ InvalidOid,
+ InvalidOid,
+ InvalidOid,
+ -1,
+ false, true, false, false, true);
+
+ ereport(NOTICE,
+ (errmsg("created index \"%s\" on materialized view \"%s\"",
+ idxname, RelationGetRelationName(matviewRel))));
+
+ /*
+ * Make dependencies so that the index is dropped if any base tables's
+ * primary key is dropped.
+ */
+ foreach(lc, constraintList)
+ {
+ Oid constraintOid = lfirst_oid(lc);
+ ObjectAddress refaddr;
+
+ refaddr.classId = ConstraintRelationId;
+ refaddr.objectId = constraintOid;
+ refaddr.objectSubId = 0;
+
+ recordDependencyOn(&address, &refaddr, DEPENDENCY_NORMAL);
+ }
+}
+
+
+/*
+ * get_primary_key_attnos_from_query
+ *
+ * Identify the columns in base tables' primary keys in the target list.
+ *
+ * Returns a Bitmapset of the column attnos of the primary key's columns of
+ * tables that used in the query. The attnos are offset by
+ * FirstLowInvalidHeapAttributeNumber as same as get_primary_key_attnos.
+ *
+ * If any table has no primary key or any primary key's columns is not in
+ * the target list, return NULL. We also return NULL if any pkey constraint
+ * is deferrable.
+ *
+ * constraintList is set to a list of the OIDs of the pkey constraints.
+ */
+static Bitmapset *
+get_primary_key_attnos_from_query(Query *query, List **constraintList)
+{
+ List *key_attnos_list = NIL;
+ ListCell *lc;
+ int i;
+ Bitmapset *keys = NULL;
+ Relids rels_in_from;
+
+ /*
+ * Collect primary key attributes from all tables used in query. The key attributes
+ * sets for each table are stored in key_attnos_list in order by RTE index.
+ */
+ foreach(lc, query->rtable)
+ {
+ RangeTblEntry *r = (RangeTblEntry*) lfirst(lc);
+ Bitmapset *key_attnos;
+ bool has_pkey = true;
+
+ /* for tables, call get_primary_key_attnos */
+ if (r->rtekind == RTE_RELATION)
+ {
+ Oid constraintOid;
+ key_attnos = get_primary_key_attnos(r->relid, false, &constraintOid);
+ *constraintList = lappend_oid(*constraintList, constraintOid);
+ has_pkey = (key_attnos != NULL);
+ }
+ /* for other RTEs, store NULL into key_attnos_list */
+ else
+ key_attnos = NULL;
+
+ /*
+ * If any table or subquery has no primary key or its pkey constraint is deferrable,
+ * we cannot get key attributes for this query, so return NULL.
+ */
+ if (!has_pkey)
+ return NULL;
+
+ key_attnos_list = lappend(key_attnos_list, key_attnos);
+ }
+
+ /* Collect key attributes appearing in the target list */
+ i = 1;
+ foreach(lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) flatten_join_alias_vars(NULL, query, lfirst(lc));
+
+ if (IsA(tle->expr, Var))
+ {
+ Var *var = (Var*) tle->expr;
+ Bitmapset *key_attnos = list_nth(key_attnos_list, var->varno - 1);
+
+ /* check if this attribute is from a base table's primary key */
+ if (bms_is_member(var->varattno - FirstLowInvalidHeapAttributeNumber, key_attnos))
+ {
+ /*
+ * Remove found key attributes from key_attnos_list, and add this
+ * to the result list.
+ */
+ key_attnos = bms_del_member(key_attnos, var->varattno - FirstLowInvalidHeapAttributeNumber);
+ if (bms_is_empty(key_attnos))
+ {
+ key_attnos_list = list_delete_nth_cell(key_attnos_list, var->varno - 1);
+ key_attnos_list = list_insert_nth(key_attnos_list, var->varno - 1, NULL);
+ }
+ keys = bms_add_member(keys, i - FirstLowInvalidHeapAttributeNumber);
+ }
+ }
+ i++;
+ }
+
+ /* Collect RTE indexes of relations appearing in the FROM clause */
+ rels_in_from = get_relids_in_jointree((Node *) query->jointree, false, false);
+
+ /*
+ * Check if all key attributes of relations in FROM are appearing in the target
+ * list. If an attribute remains in key_attnos_list in spite of the table is used
+ * in FROM clause, the target is missing this key attribute, so we return NULL.
+ */
+ i = 1;
+ foreach(lc, key_attnos_list)
+ {
+ Bitmapset *bms = (Bitmapset *)lfirst(lc);
+ if (!bms_is_empty(bms) && bms_is_member(i, rels_in_from))
+ return NULL;
+ i++;
+ }
+
+ return keys;
+}
diff --git a/src/backend/commands/matview.c b/src/backend/commands/matview.c
index ea05d4b224..9629e0a47c 100644
--- a/src/backend/commands/matview.c
+++ b/src/backend/commands/matview.c
@@ -23,23 +23,35 @@
#include "catalog/indexing.h"
#include "catalog/namespace.h"
#include "catalog/pg_am.h"
+#include "catalog/pg_depend.h"
+#include "catalog/pg_trigger.h"
#include "catalog/pg_opclass.h"
#include "commands/cluster.h"
#include "commands/matview.h"
#include "commands/tablecmds.h"
#include "commands/tablespace.h"
+#include "commands/createas.h"
#include "executor/executor.h"
#include "executor/spi.h"
+#include "executor/tstoreReceiver.h"
#include "miscadmin.h"
+#include "nodes/makefuncs.h"
+#include "parser/analyze.h"
+#include "parser/parse_clause.h"
+#include "parser/parse_func.h"
+#include "parser/parse_relation.h"
#include "pgstat.h"
#include "rewrite/rewriteHandler.h"
+#include "rewrite/rowsecurity.h"
#include "storage/lmgr.h"
#include "tcop/tcopprot.h"
#include "utils/builtins.h"
+#include "utils/fmgroids.h"
#include "utils/lsyscache.h"
#include "utils/rel.h"
#include "utils/snapmgr.h"
#include "utils/syscache.h"
+#include "utils/typcache.h"
typedef struct
@@ -53,6 +65,52 @@ typedef struct
BulkInsertState bistate; /* bulk insert state */
} DR_transientrel;
+#define MV_INIT_QUERYHASHSIZE 16
+
+/*
+ * MV_TriggerHashEntry
+ *
+ * Hash entry for base tables on which IVM trigger is invoked
+ */
+typedef struct MV_TriggerHashEntry
+{
+ Oid matview_id; /* OID of the materialized view */
+ int before_trig_count; /* count of before triggers invoked */
+ int after_trig_count; /* count of after triggers invoked */
+
+ Snapshot snapshot; /* Snapshot just before table change */
+
+ List *tables; /* List of MV_TriggerTable */
+ bool has_old; /* tuples are deleted from any table? */
+ bool has_new; /* tuples are inserted into any table? */
+} MV_TriggerHashEntry;
+
+/*
+ * MV_TriggerTable
+ *
+ * IVM related data for tables on which the trigger is invoked.
+ */
+typedef struct MV_TriggerTable
+{
+ Oid table_id; /* OID of the modified table */
+ List *old_tuplestores; /* tuplestores for deleted tuples */
+ List *new_tuplestores; /* tuplestores for inserted tuples */
+
+ List *rte_indexes; /* List of RTE index of the modified table */
+ RangeTblEntry *original_rte; /* the original RTE saved before rewriting query */
+
+ Relation rel; /* relation of the modified table */
+ TupleTableSlot *slot; /* for checking visibility in the pre-state table */
+} MV_TriggerTable;
+
+static HTAB *mv_trigger_info = NULL;
+
+static bool in_delta_calculation = false;
+
+/* ENR name for materialized view delta */
+#define NEW_DELTA_ENRNAME "new_delta"
+#define OLD_DELTA_ENRNAME "old_delta"
+
static int matview_maintenance_depth = 0;
static void transientrel_startup(DestReceiver *self, int operation, TupleDesc typeinfo);
@@ -60,7 +118,9 @@ static bool transientrel_receive(TupleTableSlot *slot, DestReceiver *self);
static void transientrel_shutdown(DestReceiver *self);
static void transientrel_destroy(DestReceiver *self);
static uint64 refresh_matview_datafill(DestReceiver *dest, Query *query,
- const char *queryString);
+ QueryEnvironment *queryEnv,
+ TupleDesc *resultTupleDesc,
+ const char *queryString);
static char *make_temptable_name_n(char *tempname, int n);
static void refresh_by_match_merge(Oid matviewOid, Oid tempOid, Oid relowner,
int save_sec_context);
@@ -68,6 +128,37 @@ static void refresh_by_heap_swap(Oid matviewOid, Oid OIDNewHeap, char relpersist
static bool is_usable_unique_index(Relation indexRel);
static void OpenMatViewIncrementalMaintenance(void);
static void CloseMatViewIncrementalMaintenance(void);
+static Query *get_matview_query(Relation matviewRel);
+
+static Query *rewrite_query_for_preupdate_state(Query *query, List *tables,
+ ParseState *pstate, Oid matviewid);
+static void register_delta_ENRs(ParseState *pstate, Query *query, List *tables);
+static char *make_delta_enr_name(const char *prefix, Oid relid, int count);
+static RangeTblEntry *get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *table,
+ QueryEnvironment *queryEnv, Oid matviewid);
+static RangeTblEntry *replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
+ QueryEnvironment *queryEnv);
+static Query *rewrite_query_for_counting(Query *query, ParseState *pstate);
+
+static void calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
+ DestReceiver *dest_old, DestReceiver *dest_new,
+ TupleDesc *tupdesc_old, TupleDesc *tupdesc_new,
+ QueryEnvironment *queryEnv);
+static Query *rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte_index);
+
+static void apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
+ TupleDesc tupdesc_old, TupleDesc tupdesc_new,
+ Query *query);
+static void apply_old_delta(const char *matviewname, const char *deltaname_old,
+ List *keys);
+static void apply_new_delta(const char *matviewname, const char *deltaname_new,
+ StringInfo target_list);
+static char *get_matching_condition_string(List *keys);
+static void generate_equal(StringInfo querybuf, Oid opttype,
+ const char *leftop, const char *rightop);
+
+static void mv_InitHashTables(void);
+static void clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort);
/*
* SetMatViewPopulatedState
@@ -109,6 +200,46 @@ SetMatViewPopulatedState(Relation relation, bool newstate)
CommandCounterIncrement();
}
+/*
+ * SetMatViewIVMState
+ * Mark a materialized view as IVM, or not.
+ *
+ * NOTE: caller must be holding an appropriate lock on the relation.
+ */
+void
+SetMatViewIVMState(Relation relation, bool newstate)
+{
+ Relation pgrel;
+ HeapTuple tuple;
+
+ Assert(relation->rd_rel->relkind == RELKIND_MATVIEW);
+
+ /*
+ * Update relation's pg_class entry. Crucial side-effect: other backends
+ * (and this one too!) are sent SI message to make them rebuild relcache
+ * entries.
+ */
+ pgrel = table_open(RelationRelationId, RowExclusiveLock);
+ tuple = SearchSysCacheCopy1(RELOID,
+ ObjectIdGetDatum(RelationGetRelid(relation)));
+ if (!HeapTupleIsValid(tuple))
+ elog(ERROR, "cache lookup failed for relation %u",
+ RelationGetRelid(relation));
+
+ ((Form_pg_class) GETSTRUCT(tuple))->relisivm = newstate;
+
+ CatalogTupleUpdate(pgrel, &tuple->t_self, tuple);
+
+ heap_freetuple(tuple);
+ table_close(pgrel, RowExclusiveLock);
+
+ /*
+ * Advance command counter to make the updated pg_class row locally
+ * visible.
+ */
+ CommandCounterIncrement();
+}
+
/*
* ExecRefreshMatView -- execute a REFRESH MATERIALIZED VIEW command
*
@@ -135,8 +266,6 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
{
Oid matviewOid;
Relation matviewRel;
- RewriteRule *rule;
- List *actions;
Query *dataQuery;
Oid tableSpace;
Oid relowner;
@@ -150,6 +279,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
int save_sec_context;
int save_nestlevel;
ObjectAddress address;
+ bool oldPopulated;
/* Determine strength of lock needed. */
concurrent = stmt->concurrent;
@@ -176,6 +306,8 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
save_nestlevel = NewGUCNestLevel();
RestrictSearchPath();
+ oldPopulated = RelationIsPopulated(matviewRel);
+
/* Make sure it is a materialized view. */
if (matviewRel->rd_rel->relkind != RELKIND_MATVIEW)
ereport(ERROR,
@@ -196,32 +328,9 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
errmsg("%s and %s options cannot be used together",
"CONCURRENTLY", "WITH NO DATA")));
- /*
- * Check that everything is correct for a refresh. Problems at this point
- * are internal errors, so elog is sufficient.
- */
- if (matviewRel->rd_rel->relhasrules == false ||
- matviewRel->rd_rules->numLocks < 1)
- elog(ERROR,
- "materialized view \"%s\" is missing rewrite information",
- RelationGetRelationName(matviewRel));
-
- if (matviewRel->rd_rules->numLocks > 1)
- elog(ERROR,
- "materialized view \"%s\" has too many rules",
- RelationGetRelationName(matviewRel));
- rule = matviewRel->rd_rules->rules[0];
- if (rule->event != CMD_SELECT || !(rule->isInstead))
- elog(ERROR,
- "the rule for materialized view \"%s\" is not a SELECT INSTEAD OF rule",
- RelationGetRelationName(matviewRel));
+ dataQuery = get_matview_query(matviewRel);
- actions = rule->actions;
- if (list_length(actions) != 1)
- elog(ERROR,
- "the rule for materialized view \"%s\" is not a single action",
- RelationGetRelationName(matviewRel));
/*
* Check that there is a unique index with no WHERE clause on one or more
@@ -256,12 +365,6 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
errhint("Create a unique index with no WHERE clause on one or more columns of the materialized view.")));
}
- /*
- * The stored query was rewritten at the time of the MV definition, but
- * has not been scribbled on by the planner.
- */
- dataQuery = linitial_node(Query, actions);
-
/*
* Check for active uses of the relation in the current transaction, such
* as open scans.
@@ -289,6 +392,74 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
relpersistence = matviewRel->rd_rel->relpersistence;
}
+ /* delete IMMV triggers. */
+ if (RelationIsIVM(matviewRel) && stmt->skipData )
+ {
+ Relation tgRel;
+ Relation depRel;
+ ScanKeyData key;
+ SysScanDesc scan;
+ HeapTuple tup;
+ ObjectAddresses *immv_triggers;
+
+ immv_triggers = new_object_addresses();
+
+ tgRel = table_open(TriggerRelationId, RowExclusiveLock);
+ depRel = table_open(DependRelationId, RowExclusiveLock);
+
+ /* search triggers that depends on IMMV. */
+ ScanKeyInit(&key,
+ Anum_pg_depend_refobjid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(matviewOid));
+ scan = systable_beginscan(depRel, DependReferenceIndexId, true,
+ NULL, 1, &key);
+ while ((tup = systable_getnext(scan)) != NULL)
+ {
+ ObjectAddress obj;
+ Form_pg_depend foundDep = (Form_pg_depend) GETSTRUCT(tup);
+
+ if (foundDep->classid == TriggerRelationId)
+ {
+ HeapTuple tgtup;
+ ScanKeyData tgkey[1];
+ SysScanDesc tgscan;
+ Form_pg_trigger tgform;
+
+ /* Find the trigger name. */
+ ScanKeyInit(&tgkey[0],
+ Anum_pg_trigger_oid,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(foundDep->objid));
+
+ tgscan = systable_beginscan(tgRel, TriggerOidIndexId, true,
+ NULL, 1, tgkey);
+ tgtup = systable_getnext(tgscan);
+ if (!HeapTupleIsValid(tgtup))
+ elog(ERROR, "could not find tuple for immv trigger %u", foundDep->objid);
+
+ tgform = (Form_pg_trigger) GETSTRUCT(tgtup);
+
+ /* If trigger is created by IMMV, delete it. */
+ if (strncmp(NameStr(tgform->tgname), "IVM_trigger_", 12) == 0)
+ {
+ obj.classId = foundDep->classid;
+ obj.objectId = foundDep->objid;
+ obj.objectSubId = foundDep->refobjsubid;
+ add_exact_object_address(&obj, immv_triggers);
+ }
+ systable_endscan(tgscan);
+ }
+ }
+ systable_endscan(scan);
+
+ performMultipleDeletions(immv_triggers, DROP_RESTRICT, PERFORM_DELETION_INTERNAL);
+
+ table_close(depRel, RowExclusiveLock);
+ table_close(tgRel, RowExclusiveLock);
+ free_object_addresses(immv_triggers);
+ }
+
/*
* Create the transient table that will receive the regenerated data. Lock
* it against access by any other process until commit (by which time it
@@ -302,7 +473,7 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
/* Generate the data, if wanted. */
if (!stmt->skipData)
- processed = refresh_matview_datafill(dest, dataQuery, queryString);
+ processed = refresh_matview_datafill(dest, dataQuery, NULL, NULL, queryString);
/* Make the matview match the newly generated data. */
if (concurrent)
@@ -337,6 +508,12 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
pgstat_count_heap_insert(matviewRel, processed);
}
+ if (!stmt->skipData && RelationIsIVM(matviewRel) && !oldPopulated)
+ {
+ CreateIndexOnIMMV(dataQuery, matviewRel);
+ CreateIvmTriggersOnBaseTables(dataQuery, matviewOid);
+ }
+
table_close(matviewRel, NoLock);
/* Roll back any GUC changes */
@@ -371,6 +548,8 @@ ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
*/
static uint64
refresh_matview_datafill(DestReceiver *dest, Query *query,
+ QueryEnvironment *queryEnv,
+ TupleDesc *resultTupleDesc,
const char *queryString)
{
List *rewritten;
@@ -407,7 +586,7 @@ refresh_matview_datafill(DestReceiver *dest, Query *query,
/* Create a QueryDesc, redirecting output to our tuple receiver */
queryDesc = CreateQueryDesc(plan, queryString,
GetActiveSnapshot(), InvalidSnapshot,
- dest, NULL, NULL, 0);
+ dest, NULL, queryEnv ? queryEnv: NULL, 0);
/* call ExecutorStart to prepare the plan for execution */
ExecutorStart(queryDesc, 0);
@@ -417,6 +596,9 @@ refresh_matview_datafill(DestReceiver *dest, Query *query,
processed = queryDesc->estate->es_processed;
+ if (resultTupleDesc)
+ *resultTupleDesc = CreateTupleDescCopy(queryDesc->tupDesc);
+
/* and clean up */
ExecutorFinish(queryDesc);
ExecutorEnd(queryDesc);
@@ -952,3 +1134,1219 @@ CloseMatViewIncrementalMaintenance(void)
matview_maintenance_depth--;
Assert(matview_maintenance_depth >= 0);
}
+
+/*
+ * get_matview_query - get the Query from a matview's _RETURN rule.
+ */
+static Query *
+get_matview_query(Relation matviewRel)
+{
+ RewriteRule *rule;
+ List * actions;
+
+ /*
+ * Check that everything is correct for a refresh. Problems at this point
+ * are internal errors, so elog is sufficient.
+ */
+ if (matviewRel->rd_rel->relhasrules == false ||
+ matviewRel->rd_rules->numLocks < 1)
+ elog(ERROR,
+ "materialized view \"%s\" is missing rewrite information",
+ RelationGetRelationName(matviewRel));
+
+ if (matviewRel->rd_rules->numLocks > 1)
+ elog(ERROR,
+ "materialized view \"%s\" has too many rules",
+ RelationGetRelationName(matviewRel));
+
+ rule = matviewRel->rd_rules->rules[0];
+ if (rule->event != CMD_SELECT || !(rule->isInstead))
+ elog(ERROR,
+ "the rule for materialized view \"%s\" is not a SELECT INSTEAD OF rule",
+ RelationGetRelationName(matviewRel));
+
+ actions = rule->actions;
+ if (list_length(actions) != 1)
+ elog(ERROR,
+ "the rule for materialized view \"%s\" is not a single action",
+ RelationGetRelationName(matviewRel));
+
+ /*
+ * The stored query was rewritten at the time of the MV definition, but
+ * has not been scribbled on by the planner.
+ */
+ return linitial_node(Query, actions);
+}
+
+
+/* ----------------------------------------------------
+ * Incremental View Maintenance routines
+ * ---------------------------------------------------
+ */
+
+/*
+ * IVM_immediate_before
+ *
+ * IVM trigger function invoked before base table is modified. If this is
+ * invoked firstly in the same statement, we save the transaction id and the
+ * command id at that time.
+ */
+Datum
+IVM_immediate_before(PG_FUNCTION_ARGS)
+{
+ TriggerData *trigdata = (TriggerData *) fcinfo->context;
+ char *matviewOid_text = trigdata->tg_trigger->tgargs[0];
+ char *ex_lock_text = trigdata->tg_trigger->tgargs[1];
+ Oid matviewOid;
+ MV_TriggerHashEntry *entry;
+ bool found;
+ bool ex_lock;
+
+ matviewOid = DatumGetObjectId(DirectFunctionCall1(oidin, CStringGetDatum(matviewOid_text)));
+ ex_lock = DatumGetBool(DirectFunctionCall1(boolin, CStringGetDatum(ex_lock_text)));
+
+ /* If the view has more than one tables, we have to use an exclusive lock. */
+ if (ex_lock)
+ {
+ /*
+ * Wait for concurrent transactions which update this materialized view at
+ * READ COMMITED. This is needed to see changes committed in other
+ * transactions. No wait and raise an error at REPEATABLE READ or
+ * SERIALIZABLE to prevent update anomalies of matviews.
+ * XXX: dead-lock is possible here.
+ */
+ if (!IsolationUsesXactSnapshot())
+ LockRelationOid(matviewOid, ExclusiveLock);
+ else if (!ConditionalLockRelationOid(matviewOid, ExclusiveLock))
+ {
+ /* try to throw error by name; relation could be deleted... */
+ char *relname = get_rel_name(matviewOid);
+
+ if (!relname)
+ ereport(ERROR,
+ (errcode(ERRCODE_LOCK_NOT_AVAILABLE),
+ errmsg("could not obtain lock on materialized view during incremental maintenance")));
+
+ ereport(ERROR,
+ (errcode(ERRCODE_LOCK_NOT_AVAILABLE),
+ errmsg("could not obtain lock on materialized view \"%s\" during incremental maintenance",
+ relname)));
+ }
+ }
+ else
+ LockRelationOid(matviewOid, RowExclusiveLock);
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_trigger_info)
+ mv_InitHashTables();
+
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_ENTER, &found);
+
+ /* On the first BEFORE to update the view, initialize trigger data */
+ if (!found)
+ {
+ /*
+ * Get a snapshot just before the table was modified for checking
+ * tuple visibility in the pre-update state of the table.
+ */
+ Snapshot snapshot = GetActiveSnapshot();
+
+ entry->matview_id = matviewOid;
+ entry->before_trig_count = 0;
+ entry->after_trig_count = 0;
+ entry->snapshot = RegisterSnapshot(snapshot);
+ entry->tables = NIL;
+ entry->has_old = false;
+ entry->has_new = false;
+ }
+
+ entry->before_trig_count++;
+
+ return PointerGetDatum(NULL);
+}
+
+/*
+ * IVM_immediate_maintenance
+ *
+ * IVM trigger function invoked after base table is modified.
+ * For each table, tuplestores of transition tables are collected.
+ * and after the last modification
+ */
+Datum
+IVM_immediate_maintenance(PG_FUNCTION_ARGS)
+{
+ TriggerData *trigdata = (TriggerData *) fcinfo->context;
+ Relation rel;
+ Oid relid;
+ Oid matviewOid;
+ Query *query;
+ Query *rewritten = NULL;
+ char *matviewOid_text = trigdata->tg_trigger->tgargs[0];
+ Relation matviewRel;
+ int old_depth = matview_maintenance_depth;
+
+ Oid relowner;
+ Tuplestorestate *old_tuplestore = NULL;
+ Tuplestorestate *new_tuplestore = NULL;
+ DestReceiver *dest_new = NULL, *dest_old = NULL;
+ Oid save_userid;
+ int save_sec_context;
+ int save_nestlevel;
+
+ MV_TriggerHashEntry *entry;
+ MV_TriggerTable *table;
+ bool found;
+
+ ParseState *pstate;
+ QueryEnvironment *queryEnv = create_queryEnv();
+ MemoryContext oldcxt;
+ ListCell *lc;
+ int i;
+
+
+ /* Create a ParseState for rewriting the view definition query */
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ rel = trigdata->tg_relation;
+ relid = rel->rd_id;
+
+ matviewOid = DatumGetObjectId(DirectFunctionCall1(oidin, CStringGetDatum(matviewOid_text)));
+
+ /*
+ * On the first call initialize the hashtable
+ */
+ if (!mv_trigger_info)
+ mv_InitHashTables();
+
+ /* get the entry for this materialized view */
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_FIND, &found);
+ Assert (found && entry != NULL);
+ entry->after_trig_count++;
+
+ /* search the entry for the modified table and create new entry if not found */
+ found = false;
+ foreach(lc, entry->tables)
+ {
+ table = (MV_TriggerTable *) lfirst(lc);
+ if (table->table_id == relid)
+ {
+ found = true;
+ break;
+ }
+ }
+ if (!found)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ table = (MV_TriggerTable *) palloc0(sizeof(MV_TriggerTable));
+ table->table_id = relid;
+ table->old_tuplestores = NIL;
+ table->new_tuplestores = NIL;
+ table->rte_indexes = NIL;
+ table->slot = MakeSingleTupleTableSlot(RelationGetDescr(rel), table_slot_callbacks(rel));
+ table->rel = table_open(RelationGetRelid(rel), NoLock);
+ entry->tables = lappend(entry->tables, table);
+
+ MemoryContextSwitchTo(oldcxt);
+ }
+
+ /* Save the transition tables and make a request to not free immediately */
+ if (trigdata->tg_oldtable)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+ table->old_tuplestores = lappend(table->old_tuplestores, trigdata->tg_oldtable);
+ entry->has_old = true;
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (trigdata->tg_newtable)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+ table->new_tuplestores = lappend(table->new_tuplestores, trigdata->tg_newtable);
+ entry->has_new = true;
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (entry->has_new || entry->has_old)
+ {
+ CmdType cmd;
+
+ if (TRIGGER_FIRED_BY_INSERT(trigdata->tg_event))
+ cmd = CMD_INSERT;
+ else if (TRIGGER_FIRED_BY_DELETE(trigdata->tg_event))
+ cmd = CMD_DELETE;
+ else if (TRIGGER_FIRED_BY_UPDATE(trigdata->tg_event))
+ cmd = CMD_UPDATE;
+ else
+ elog(ERROR,"unsupported trigger type");
+
+ /* Prolong lifespan of transition tables to the end of the last AFTER trigger */
+ SetTransitionTablePreserved(relid, cmd);
+ }
+
+
+ /* If this is not the last AFTER trigger call, immediately exit. */
+ Assert (entry->before_trig_count >= entry->after_trig_count);
+ if (entry->before_trig_count != entry->after_trig_count)
+ return PointerGetDatum(NULL);
+
+ /*
+ * If this is the last AFTER trigger call, continue and update the view.
+ */
+
+ /*
+ * Advance command counter to make the updated base table row locally
+ * visible.
+ */
+ CommandCounterIncrement();
+
+ matviewRel = table_open(matviewOid, NoLock);
+
+ /* Make sure it is a materialized view. */
+ Assert(matviewRel->rd_rel->relkind == RELKIND_MATVIEW);
+
+ /*
+ * Get and push the latast snapshot to see any changes which is committed
+ * during waiting in other transactions at READ COMMITTED level.
+ */
+ PushActiveSnapshot(GetTransactionSnapshot());
+
+ /*
+ * Check for active uses of the relation in the current transaction, such
+ * as open scans.
+ *
+ * NB: We count on this to protect us against problems with refreshing the
+ * data using TABLE_INSERT_FROZEN.
+ */
+ CheckTableNotInUse(matviewRel, "refresh a materialized view incrementally");
+
+ /*
+ * Switch to the owner's userid, so that any functions are run as that
+ * user. Also arrange to make GUC variable changes local to this command.
+ * We will switch modes when we are about to execute user code.
+ */
+ relowner = matviewRel->rd_rel->relowner;
+ GetUserIdAndSecContext(&save_userid, &save_sec_context);
+ SetUserIdAndSecContext(relowner,
+ save_sec_context | SECURITY_RESTRICTED_OPERATION);
+ save_nestlevel = NewGUCNestLevel();
+
+ /* get view query*/
+ query = get_matview_query(matviewRel);
+
+ /*
+ * When a base table is truncated, the view content will be empty if the
+ * view definition query does not contain an aggregate without a GROUP clause.
+ * Therefore, such views can be truncated.
+ */
+ if (TRIGGER_FIRED_BY_TRUNCATE(trigdata->tg_event))
+ {
+ ExecuteTruncateGuts(list_make1(matviewRel), list_make1_oid(matviewOid),
+ NIL, DROP_RESTRICT, false, false);
+
+ /* Clean up hash entry and delete tuplestores */
+ clean_up_IVM_hash_entry(entry, false);
+
+ /* Pop the original snapshot. */
+ PopActiveSnapshot();
+
+ table_close(matviewRel, NoLock);
+
+ /* Roll back any GUC changes */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ return PointerGetDatum(NULL);
+ }
+
+ /*
+ * rewrite query for calculating deltas
+ */
+
+ rewritten = copyObject(query);
+
+ /* Replace resnames in a target list with materialized view's attnames */
+ i = 0;
+ foreach (lc, rewritten->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
+
+ tle->resname = pstrdup(resname);
+ i++;
+ }
+
+ /* Set all tables in the query to pre-update state */
+ rewritten = rewrite_query_for_preupdate_state(rewritten, entry->tables,
+ pstate, matviewOid);
+ /* Rewrite for counting duplicated tuples */
+ rewritten = rewrite_query_for_counting(rewritten, pstate);
+
+ /* Create tuplestores to store view deltas */
+ if (entry->has_old)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ old_tuplestore = tuplestore_begin_heap(false, false, work_mem);
+ dest_old = CreateDestReceiver(DestTuplestore);
+ SetTuplestoreDestReceiverParams(dest_old,
+ old_tuplestore,
+ TopTransactionContext,
+ false,
+ NULL,
+ NULL);
+
+ MemoryContextSwitchTo(oldcxt);
+ }
+ if (entry->has_new)
+ {
+ oldcxt = MemoryContextSwitchTo(TopTransactionContext);
+
+ new_tuplestore = tuplestore_begin_heap(false, false, work_mem);
+ dest_new = CreateDestReceiver(DestTuplestore);
+ SetTuplestoreDestReceiverParams(dest_new,
+ new_tuplestore,
+ TopTransactionContext,
+ false,
+ NULL,
+ NULL);
+ MemoryContextSwitchTo(oldcxt);
+ }
+
+ /* for all modified tables */
+ foreach(lc, entry->tables)
+ {
+ ListCell *lc2;
+
+ table = (MV_TriggerTable *) lfirst(lc);
+
+ /* loop for self-join */
+ foreach(lc2, table->rte_indexes)
+ {
+ int rte_index = lfirst_int(lc2);
+ TupleDesc tupdesc_old;
+ TupleDesc tupdesc_new;
+
+ /* calculate delta tables */
+ calc_delta(table, rte_index, rewritten, dest_old, dest_new,
+ &tupdesc_old, &tupdesc_new, queryEnv);
+
+ /* Set the table in the query to post-update state */
+ rewritten = rewrite_query_for_postupdate_state(rewritten, table, rte_index);
+
+ PG_TRY();
+ {
+ /* apply the delta tables to the materialized view */
+ apply_delta(matviewOid, old_tuplestore, new_tuplestore,
+ tupdesc_old, tupdesc_new, query);
+ }
+ PG_CATCH();
+ {
+ matview_maintenance_depth = old_depth;
+ PG_RE_THROW();
+ }
+ PG_END_TRY();
+
+ /* clear view delta tuplestores */
+ if (old_tuplestore)
+ tuplestore_clear(old_tuplestore);
+ if (new_tuplestore)
+ tuplestore_clear(new_tuplestore);
+ }
+ }
+
+ /* Clean up hash entry and delete tuplestores */
+ clean_up_IVM_hash_entry(entry, false);
+ if (old_tuplestore)
+ {
+ dest_old->rDestroy(dest_old);
+ tuplestore_end(old_tuplestore);
+ }
+ if (new_tuplestore)
+ {
+ dest_new->rDestroy(dest_new);
+ tuplestore_end(new_tuplestore);
+ }
+
+ /* Pop the original snapshot. */
+ PopActiveSnapshot();
+
+ table_close(matviewRel, NoLock);
+
+ /* Roll back any GUC changes */
+ AtEOXact_GUC(false, save_nestlevel);
+
+ /* Restore userid and security context */
+ SetUserIdAndSecContext(save_userid, save_sec_context);
+
+ return PointerGetDatum(NULL);
+}
+
+/*
+ * rewrite_query_for_preupdate_state
+ *
+ * Rewrite the query so that base tables' RTEs will represent "pre-update"
+ * state of tables. This is necessary to calculate view delta after multiple
+ * tables are modified.
+ */
+static Query*
+rewrite_query_for_preupdate_state(Query *query, List *tables,
+ ParseState *pstate, Oid matviewid)
+{
+ ListCell *lc;
+ int num_rte = list_length(query->rtable);
+ int i;
+
+
+ /* register delta ENRs */
+ register_delta_ENRs(pstate, query, tables);
+
+ /* XXX: Is necessary? Is this right timing? */
+ AcquireRewriteLocks(query, true, false);
+
+ i = 1;
+ foreach(lc, query->rtable)
+ {
+ RangeTblEntry *r = (RangeTblEntry*) lfirst(lc);
+
+ ListCell *lc2;
+ foreach(lc2, tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc2);
+ /*
+ * if the modified table is found then replace the original RTE with
+ * "pre-state" RTE and append its index to the list.
+ */
+ if (r->relid == table->table_id)
+ {
+ List *securityQuals;
+ List *withCheckOptions;
+ bool hasRowSecurity;
+ bool hasSubLinks;
+
+ RangeTblEntry *rte_pre = get_prestate_rte(r, table, pstate->p_queryEnv, matviewid);
+
+ /*
+ * Set a row security poslicies of the modified table to the subquery RTE which
+ * represents the pre-update state of the table.
+ */
+ get_row_security_policies(query, table->original_rte, i,
+ &securityQuals, &withCheckOptions,
+ &hasRowSecurity, &hasSubLinks);
+
+ if (hasRowSecurity)
+ {
+ query->hasRowSecurity = true;
+ rte_pre->security_barrier = true;
+ }
+ if (hasSubLinks)
+ query->hasSubLinks = true;
+
+ rte_pre->securityQuals = securityQuals;
+ lfirst(lc) = rte_pre;
+
+ table->rte_indexes = lappend_int(table->rte_indexes, i);
+ break;
+ }
+ }
+
+ /* finish the loop if we processed all RTE included in the original query */
+ if (i++ >= num_rte)
+ break;
+ }
+
+ return query;
+}
+
+/*
+ * register_delta_ENRs
+ *
+ * For all modified tables, make ENRs for their transition tables
+ * and register them to the queryEnv. ENR's RTEs are also appended
+ * into the list in query tree.
+ */
+static void
+register_delta_ENRs(ParseState *pstate, Query *query, List *tables)
+{
+ QueryEnvironment *queryEnv = pstate->p_queryEnv;
+ ListCell *lc;
+ RangeTblEntry *rte;
+
+ foreach(lc, tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc);
+ ListCell *lc2;
+ int count;
+
+ count = 0;
+ foreach(lc2, table->old_tuplestores)
+ {
+ Tuplestorestate *oldtable = (Tuplestorestate *) lfirst(lc2);
+ EphemeralNamedRelation enr =
+ palloc(sizeof(EphemeralNamedRelationData));
+ ParseNamespaceItem *nsitem;
+
+ enr->md.name = make_delta_enr_name("old", table->table_id, count);
+ enr->md.reliddesc = table->table_id;
+ enr->md.tupdesc = NULL;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(oldtable);
+ enr->reldata = oldtable;
+ register_ENR(queryEnv, enr);
+
+ nsitem = addRangeTableEntryForENR(pstate, makeRangeVar(NULL, enr->md.name, -1), true);
+ rte = nsitem->p_rte;
+
+ query->rtable = lappend(query->rtable, rte);
+
+ count++;
+ }
+
+ count = 0;
+ foreach(lc2, table->new_tuplestores)
+ {
+ Tuplestorestate *newtable = (Tuplestorestate *) lfirst(lc2);
+ EphemeralNamedRelation enr =
+ palloc(sizeof(EphemeralNamedRelationData));
+ ParseNamespaceItem *nsitem;
+
+ enr->md.name = make_delta_enr_name("new", table->table_id, count);
+ enr->md.reliddesc = table->table_id;
+ enr->md.tupdesc = NULL;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(newtable);
+ enr->reldata = newtable;
+ register_ENR(queryEnv, enr);
+
+ nsitem = addRangeTableEntryForENR(pstate, makeRangeVar(NULL, enr->md.name, -1), true);
+ rte = nsitem->p_rte;
+
+ query->rtable = lappend(query->rtable, rte);
+
+ count++;
+ }
+ }
+}
+
+#define DatumGetItemPointer(X) ((ItemPointer) DatumGetPointer(X))
+#define PG_GETARG_ITEMPOINTER(n) DatumGetItemPointer(PG_GETARG_DATUM(n))
+
+/*
+ * ivm_visible_in_prestate
+ *
+ * Check visibility of a tuple specified by the tableoid and item pointer
+ * using the snapshot taken just before the table was modified.
+ */
+Datum
+ivm_visible_in_prestate(PG_FUNCTION_ARGS)
+{
+ Oid tableoid = PG_GETARG_OID(0);
+ ItemPointer itemPtr = PG_GETARG_ITEMPOINTER(1);
+ Oid matviewOid = PG_GETARG_OID(2);
+ MV_TriggerHashEntry *entry;
+ MV_TriggerTable *table = NULL;
+ ListCell *lc;
+ bool found;
+ bool result;
+
+ if (!in_delta_calculation)
+ ereport(ERROR,
+ (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+ errmsg("ivm_visible_in_prestate can be called only in delta calculation")));
+
+ entry = (MV_TriggerHashEntry *) hash_search(mv_trigger_info,
+ (void *) &matviewOid,
+ HASH_FIND, &found);
+ Assert (found && entry != NULL);
+
+ foreach(lc, entry->tables)
+ {
+ table = (MV_TriggerTable *) lfirst(lc);
+ if (table->table_id == tableoid)
+ break;
+ }
+
+ Assert (table != NULL);
+
+ result = table_tuple_fetch_row_version(table->rel, itemPtr, entry->snapshot, table->slot);
+
+ PG_RETURN_BOOL(result);
+}
+
+/*
+ * get_prestate_rte
+ *
+ * Rewrite RTE of the modified table to a subquery which represents
+ * "pre-state" table. The original RTE is saved in table->rte_original.
+ */
+static RangeTblEntry*
+get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *table,
+ QueryEnvironment *queryEnv, Oid matviewid)
+{
+ StringInfoData str;
+ RawStmt *raw;
+ Query *subquery;
+ Relation rel;
+ ParseState *pstate;
+ char *relname;
+ int i;
+
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ /*
+ * We can use NoLock here since AcquireRewriteLocks should
+ * have locked the relation already.
+ */
+ rel = table_open(table->table_id, NoLock);
+ relname = quote_qualified_identifier(
+ get_namespace_name(RelationGetNamespace(rel)),
+ RelationGetRelationName(rel));
+ table_close(rel, NoLock);
+
+ /*
+ * Filtering inserted row using the snapshot taken before the table
+ * is modified. ctid is required for maintaining outer join views.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str,
+ "SELECT t.* FROM %s t"
+ " WHERE pg_catalog.ivm_visible_in_prestate(t.tableoid, t.ctid ,%d::pg_catalog.oid)",
+ relname, matviewid);
+
+ /*
+ * Append deleted rows contained in old transition tables.
+ */
+ for (i = 0; i < list_length(table->old_tuplestores); i++)
+ {
+ appendStringInfo(&str, " UNION ALL ");
+ appendStringInfo(&str," SELECT * FROM %s",
+ make_delta_enr_name("old", table->table_id, i));
+ }
+
+ /* Get a subquery representing pre-state of the table */
+ raw = (RawStmt*)linitial(raw_parser(str.data, RAW_PARSE_DEFAULT));
+ subquery = transformStmt(pstate, raw->stmt);
+
+ /* save the original RTE */
+ table->original_rte = copyObject(rte);
+
+ rte->rtekind = RTE_SUBQUERY;
+ rte->subquery = subquery;
+ rte->security_barrier = false;
+
+ /* Clear fields that should not be set in a subquery RTE */
+ rte->relid = InvalidOid;
+ rte->relkind = 0;
+ rte->rellockmode = 0;
+ rte->tablesample = NULL;
+ rte->perminfoindex = 0; /* no permission checking for this RTE */
+ rte->inh = false; /* must not be set for a subquery */
+
+ return rte;
+}
+
+/*
+ * make_delta_enr_name
+ *
+ * Make a name for ENR of a transition table from the base table's oid.
+ * prefix will be "new" or "old" depending on its transition table kind..
+ */
+static char*
+make_delta_enr_name(const char *prefix, Oid relid, int count)
+{
+ char buf[NAMEDATALEN];
+ char *name;
+
+ snprintf(buf, NAMEDATALEN, "__ivm_%s_%u_%u", prefix, relid, count);
+ name = pstrdup(buf);
+
+ return name;
+}
+
+/*
+ * replace_rte_with_delta
+ *
+ * Replace RTE of the modified table with a single table delta that combine its
+ * all transition tables.
+ */
+static RangeTblEntry*
+replace_rte_with_delta(RangeTblEntry *rte, MV_TriggerTable *table, bool is_new,
+ QueryEnvironment *queryEnv)
+{
+ Oid relid = table->table_id;
+ StringInfoData str;
+ ParseState *pstate;
+ RawStmt *raw;
+ Query *sub;
+ int num_tuplestores = list_length(is_new ? table->new_tuplestores : table->old_tuplestores);
+ int i;
+
+ /* the previous RTE must be a subquery which represents "pre-state" table */
+ Assert(rte->rtekind == RTE_SUBQUERY);
+
+ /* Create a ParseState for rewriting the view definition query */
+ pstate = make_parsestate(NULL);
+ pstate->p_queryEnv = queryEnv;
+ pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
+
+ initStringInfo(&str);
+
+ for (i = 0; i < num_tuplestores; i++)
+ {
+ if (i > 0)
+ appendStringInfo(&str, " UNION ALL ");
+
+ appendStringInfo(&str,
+ " SELECT * FROM %s",
+ make_delta_enr_name(is_new ? "new" : "old", relid, i));
+ }
+
+ raw = (RawStmt*)linitial(raw_parser(str.data, RAW_PARSE_DEFAULT));
+ sub = transformStmt(pstate, raw->stmt);
+
+ /*
+ * Update the subquery so that it represent the combined transition
+ * table. Note that we leave the security_barrier and securityQuals
+ * fields so that the subquery relation can be protected by the RLS
+ * policy as same as the modified table.
+ */
+ rte->rtekind = RTE_SUBQUERY;
+ rte->subquery = sub;
+
+ return rte;
+}
+
+/*
+ * rewrite_query_for_counting
+ *
+ * Rewrite query for counting duplicated tuples.
+ */
+static Query *
+rewrite_query_for_counting(Query *query, ParseState *pstate)
+{
+ TargetEntry *tle_count;
+ FuncCall *fn;
+ Node *node;
+
+ /* Add count(*) for counting distinct tuples in views */
+ fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
+ fn->agg_star = true;
+ if (!query->groupClause && !query->hasAggs)
+ query->groupClause = transformDistinctClause(NULL, &query->targetList, query->sortClause, false);
+
+ node = ParseFuncOrColumn(pstate, fn->funcname, NIL, NULL, fn, false, -1);
+
+ tle_count = makeTargetEntry((Expr *) node,
+ list_length(query->targetList) + 1,
+ pstrdup("__ivm_count__"),
+ false);
+ query->targetList = lappend(query->targetList, tle_count);
+ query->hasAggs = true;
+
+ return query;
+}
+
+/*
+ * calc_delta
+ *
+ * Calculate view deltas generated under the modification of a table specified
+ * by the RTE index.
+ */
+static void
+calc_delta(MV_TriggerTable *table, int rte_index, Query *query,
+ DestReceiver *dest_old, DestReceiver *dest_new,
+ TupleDesc *tupdesc_old, TupleDesc *tupdesc_new,
+ QueryEnvironment *queryEnv)
+{
+ ListCell *lc = list_nth_cell(query->rtable, rte_index - 1);
+ RangeTblEntry *rte = (RangeTblEntry *) lfirst(lc);
+
+ in_delta_calculation = true;
+
+ /* Generate old delta */
+ if (list_length(table->old_tuplestores) > 0)
+ {
+ /* Replace the modified table with the old delta table and calculate the old view delta. */
+ replace_rte_with_delta(rte, table, false, queryEnv);
+ refresh_matview_datafill(dest_old, query, queryEnv, tupdesc_old, "");
+ }
+
+ /* Generate new delta */
+ if (list_length(table->new_tuplestores) > 0)
+ {
+ /* Replace the modified table with the new delta table and calculate the new view delta*/
+ replace_rte_with_delta(rte, table, true, queryEnv);
+ refresh_matview_datafill(dest_new, query, queryEnv, tupdesc_new, "");
+ }
+
+ in_delta_calculation = false;
+}
+
+/*
+ * rewrite_query_for_postupdate_state
+ *
+ * Rewrite the query so that the specified base table's RTEs will represent
+ * "post-update" state of tables. This is called after the view delta
+ * calculation due to changes on this table finishes.
+ */
+static Query*
+rewrite_query_for_postupdate_state(Query *query, MV_TriggerTable *table, int rte_index)
+{
+ ListCell *lc = list_nth_cell(query->rtable, rte_index - 1);
+
+ /* Retore the original RTE */
+ lfirst(lc) = table->original_rte;
+
+ return query;
+}
+
+/*
+ * apply_delta
+ *
+ * Apply deltas to the materialized view. In outer join cases, this requires
+ * the view maintenance graph.
+ */
+static void
+apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *new_tuplestores,
+ TupleDesc tupdesc_old, TupleDesc tupdesc_new,
+ Query *query)
+{
+ StringInfoData querybuf;
+ StringInfoData target_list_buf;
+ Relation matviewRel;
+ char *matviewname;
+ ListCell *lc;
+ int i;
+ List *keys = NIL;
+
+
+ /*
+ * get names of the materialized view and delta tables
+ */
+
+ matviewRel = table_open(matviewOid, NoLock);
+ matviewname = quote_qualified_identifier(get_namespace_name(RelationGetNamespace(matviewRel)),
+ RelationGetRelationName(matviewRel));
+
+ /*
+ * Build parts of the maintenance queries
+ */
+
+ initStringInfo(&querybuf);
+ initStringInfo(&target_list_buf);
+
+ /* build string of target list */
+ for (i = 0; i < matviewRel->rd_att->natts; i++)
+ {
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+ char *resname = NameStr(attr->attname);
+
+ if (i != 0)
+ appendStringInfo(&target_list_buf, ", ");
+ appendStringInfo(&target_list_buf, "%s", quote_qualified_identifier(NULL, resname));
+ }
+
+ i = 0;
+ foreach (lc, query->targetList)
+ {
+ TargetEntry *tle = (TargetEntry *) lfirst(lc);
+ Form_pg_attribute attr = TupleDescAttr(matviewRel->rd_att, i);
+
+ i++;
+
+ if (tle->resjunk)
+ continue;
+
+ keys = lappend(keys, attr);
+ }
+
+ /* Start maintaining the materialized view. */
+ OpenMatViewIncrementalMaintenance();
+
+ /* Open SPI context. */
+ if (SPI_connect() != SPI_OK_CONNECT)
+ elog(ERROR, "SPI_connect failed");
+
+ /* For tuple deletion */
+ if (old_tuplestores && tuplestore_tuple_count(old_tuplestores) > 0)
+ {
+ EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ int rc;
+
+ /* convert tuplestores to ENR, and register for SPI */
+ enr->md.name = pstrdup(OLD_DELTA_ENRNAME);
+ enr->md.reliddesc = InvalidOid;
+ enr->md.tupdesc = tupdesc_old;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(old_tuplestores);
+ enr->reldata = old_tuplestores;
+
+ rc = SPI_register_relation(enr);
+ if (rc != SPI_OK_REL_REGISTER)
+ elog(ERROR, "SPI_register failed");
+
+ apply_old_delta(matviewname, OLD_DELTA_ENRNAME, keys);
+
+ }
+ /* For tuple insertion */
+ if (new_tuplestores && tuplestore_tuple_count(new_tuplestores) > 0)
+ {
+ EphemeralNamedRelation enr = palloc(sizeof(EphemeralNamedRelationData));
+ int rc;
+
+ /* convert tuplestores to ENR, and register for SPI */
+ enr->md.name = pstrdup(NEW_DELTA_ENRNAME);
+ enr->md.reliddesc = InvalidOid;
+ enr->md.tupdesc = tupdesc_new;;
+ enr->md.enrtype = ENR_NAMED_TUPLESTORE;
+ enr->md.enrtuples = tuplestore_tuple_count(new_tuplestores);
+ enr->reldata = new_tuplestores;
+
+ rc = SPI_register_relation(enr);
+ if (rc != SPI_OK_REL_REGISTER)
+ elog(ERROR, "SPI_register failed");
+
+ /* apply new delta */
+ apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf);
+ }
+
+ /* We're done maintaining the materialized view. */
+ CloseMatViewIncrementalMaintenance();
+
+ table_close(matviewRel, NoLock);
+
+ /* Close SPI context. */
+ if (SPI_finish() != SPI_OK_FINISH)
+ elog(ERROR, "SPI_finish failed");
+}
+
+/*
+ * apply_old_delta
+ *
+ * Execute a query for applying a delta table given by deltname_old
+ * which contains tuples to be deleted from to a materialized view given by
+ * matviewname. This is used when counting is not required.
+ */
+static void
+apply_old_delta(const char *matviewname, const char *deltaname_old,
+ List *keys)
+{
+ StringInfoData querybuf;
+ StringInfoData keysbuf;
+ char *match_cond;
+ ListCell *lc;
+
+ /* build WHERE condition for searching tuples to be deleted */
+ match_cond = get_matching_condition_string(keys);
+
+ /* build string of keys list */
+ initStringInfo(&keysbuf);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ appendStringInfo(&keysbuf, "%s", quote_qualified_identifier("mv", resname));
+ if (lnext(keys, lc))
+ appendStringInfo(&keysbuf, ", ");
+ }
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "DELETE FROM %s WHERE ctid IN ("
+ "SELECT tid FROM (SELECT pg_catalog.row_number() over (partition by %s) AS \"__ivm_row_number__\","
+ "mv.ctid AS tid,"
+ "diff.\"__ivm_count__\""
+ "FROM %s AS mv, %s AS diff "
+ "WHERE %s) v "
+ "WHERE v.\"__ivm_row_number__\" OPERATOR(pg_catalog.<=) v.\"__ivm_count__\")",
+ matviewname,
+ keysbuf.data,
+ matviewname, deltaname_old,
+ match_cond);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_DELETE)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
+/*
+ * apply_new_delta
+ *
+ * Execute a query for applying a delta table given by deltname_new
+ * which contains tuples to be inserted into a materialized view given by
+ * matviewname. This is used when counting is not required.
+ */
+static void
+apply_new_delta(const char *matviewname, const char *deltaname_new,
+ StringInfo target_list)
+{
+ StringInfoData querybuf;
+
+ /* Search for matching tuples from the view and update or delete if found. */
+ initStringInfo(&querybuf);
+ appendStringInfo(&querybuf,
+ "INSERT INTO %s (%s) SELECT %s FROM ("
+ "SELECT diff.*, pg_catalog.generate_series(1, diff.\"__ivm_count__\")"
+ " AS __ivm_generate_series__ "
+ "FROM %s AS diff) AS v",
+ matviewname, target_list->data, target_list->data,
+ deltaname_new);
+
+ if (SPI_exec(querybuf.data, 0) != SPI_OK_INSERT)
+ elog(ERROR, "SPI_exec failed: %s", querybuf.data);
+}
+
+/*
+ * get_matching_condition_string
+ *
+ * Build a predicate string for looking for a tuple with given keys.
+ */
+static char *
+get_matching_condition_string(List *keys)
+{
+ StringInfoData match_cond;
+ ListCell *lc;
+
+ /* If there is no key columns, the condition is always true. */
+ if (keys == NIL)
+ return "true";
+
+ initStringInfo(&match_cond);
+ foreach (lc, keys)
+ {
+ Form_pg_attribute attr = (Form_pg_attribute) lfirst(lc);
+ char *resname = NameStr(attr->attname);
+ char *mv_resname = quote_qualified_identifier("mv", resname);
+ char *diff_resname = quote_qualified_identifier("diff", resname);
+ Oid typid = attr->atttypid;
+
+ /* Considering NULL values, we can not use simple = operator. */
+ appendStringInfo(&match_cond, "(");
+ generate_equal(&match_cond, typid, mv_resname, diff_resname);
+ appendStringInfo(&match_cond, " OR (%s IS NULL AND %s IS NULL))",
+ mv_resname, diff_resname);
+
+ if (lnext(keys, lc))
+ appendStringInfo(&match_cond, " AND ");
+ }
+
+ return match_cond.data;
+}
+
+/*
+ * generate_equals
+ *
+ * Generate an equality clause using given operands' default equality
+ * operator.
+ */
+static void
+generate_equal(StringInfo querybuf, Oid opttype,
+ const char *leftop, const char *rightop)
+{
+ TypeCacheEntry *typentry;
+
+ typentry = lookup_type_cache(opttype, TYPECACHE_EQ_OPR);
+ if (!OidIsValid(typentry->eq_opr))
+ ereport(ERROR,
+ (errcode(ERRCODE_UNDEFINED_FUNCTION),
+ errmsg("could not identify an equality operator for type %s",
+ format_type_be_qualified(opttype))));
+
+ generate_operator_clause(querybuf,
+ leftop, opttype,
+ typentry->eq_opr,
+ rightop, opttype);
+}
+
+/*
+ * mv_InitHashTables
+ */
+static void
+mv_InitHashTables(void)
+{
+ HASHCTL ctl;
+
+ memset(&ctl, 0, sizeof(ctl));
+ ctl.keysize = sizeof(Oid);
+ ctl.entrysize = sizeof(MV_TriggerHashEntry);
+ mv_trigger_info = hash_create("MV trigger info",
+ MV_INIT_QUERYHASHSIZE,
+ &ctl, HASH_ELEM | HASH_BLOBS);
+}
+
+/*
+ * AtAbort_IVM
+ *
+ * Clean up hash entries for all materialized views. This is called at
+ * transaction abort.
+ */
+void
+AtAbort_IVM()
+{
+ HASH_SEQ_STATUS seq;
+ MV_TriggerHashEntry *entry;
+
+ if (mv_trigger_info)
+ {
+ hash_seq_init(&seq, mv_trigger_info);
+ while ((entry = hash_seq_search(&seq)) != NULL)
+ clean_up_IVM_hash_entry(entry, true);
+ }
+ in_delta_calculation = false;
+}
+
+/*
+ * clean_up_IVM_hash_entry
+ *
+ * Clean up tuple stores and hash entries for a materialized view after its
+ * maintenance finished.
+ */
+static void
+clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort)
+{
+ bool found;
+ ListCell *lc;
+
+ foreach(lc, entry->tables)
+ {
+ MV_TriggerTable *table = (MV_TriggerTable *) lfirst(lc);
+
+ list_free(table->old_tuplestores);
+ list_free(table->new_tuplestores);
+ if (!is_abort)
+ {
+ ExecDropSingleTupleTableSlot(table->slot);
+ table_close(table->rel, NoLock);
+ }
+ }
+ list_free(entry->tables);
+
+ if (!is_abort)
+ UnregisterSnapshot(entry->snapshot);
+
+ hash_search(mv_trigger_info, (void *) &entry->matview_id, HASH_REMOVE, &found);
+}
+
+/*
+ * isIvmName
+ *
+ * Check if this is a IVM hidden column from the name.
+ */
+bool
+isIvmName(const char *s)
+{
+ if (s)
+ return (strncmp(s, "__ivm_", 6) == 0);
+ return false;
+}
diff --git a/src/include/catalog/pg_proc.dat b/src/include/catalog/pg_proc.dat
index 0d140003e7..2bb99dc29a 100644
--- a/src/include/catalog/pg_proc.dat
+++ b/src/include/catalog/pg_proc.dat
@@ -12196,4 +12196,14 @@
proargnames => '{summarized_tli,summarized_lsn,pending_lsn,summarizer_pid}',
prosrc => 'pg_get_wal_summarizer_state' },
+# IVM
+{ oid => '786', descr => 'ivm trigger (before)',
+ proname => 'IVM_immediate_before', provolatile => 'v', prorettype => 'trigger',
+ proargtypes => '', prosrc => 'IVM_immediate_before' },
+{ oid => '787', descr => 'ivm trigger (after)',
+ proname => 'IVM_immediate_maintenance', provolatile => 'v', prorettype => 'trigger',
+ proargtypes => '', prosrc => 'IVM_immediate_maintenance' },
+{ oid => '788', descr => 'ivm filetring ',
+ proname => 'ivm_visible_in_prestate', provolatile => 's', prorettype => 'bool',
+ proargtypes => 'oid tid oid', prosrc => 'ivm_visible_in_prestate' },
]
diff --git a/src/include/commands/createas.h b/src/include/commands/createas.h
index 94678e3834..396ad1bb4c 100644
--- a/src/include/commands/createas.h
+++ b/src/include/commands/createas.h
@@ -16,6 +16,7 @@
#include "catalog/objectaddress.h"
#include "nodes/params.h"
+#include "nodes/pathnodes.h"
#include "parser/parse_node.h"
#include "tcop/dest.h"
#include "utils/queryenvironment.h"
@@ -25,6 +26,9 @@ extern ObjectAddress ExecCreateTableAs(ParseState *pstate, CreateTableAsStmt *st
ParamListInfo params, QueryEnvironment *queryEnv,
QueryCompletion *qc);
+extern void CreateIvmTriggersOnBaseTables(Query *qry, Oid matviewOid);
+extern void CreateIndexOnIMMV(Query *query, Relation matviewRel);
+
extern int GetIntoRelEFlags(IntoClause *intoClause);
extern DestReceiver *CreateIntoRelDestReceiver(IntoClause *intoClause);
diff --git a/src/include/commands/matview.h b/src/include/commands/matview.h
index 817b2ba0b6..3257e1adff 100644
--- a/src/include/commands/matview.h
+++ b/src/include/commands/matview.h
@@ -15,6 +15,7 @@
#define MATVIEW_H
#include "catalog/objectaddress.h"
+#include "fmgr.h"
#include "nodes/params.h"
#include "nodes/parsenodes.h"
#include "tcop/dest.h"
@@ -23,6 +24,8 @@
extern void SetMatViewPopulatedState(Relation relation, bool newstate);
+extern void SetMatViewIVMState(Relation relation, bool newstate);
+
extern ObjectAddress ExecRefreshMatView(RefreshMatViewStmt *stmt, const char *queryString,
ParamListInfo params, QueryCompletion *qc);
@@ -30,4 +33,10 @@ extern DestReceiver *CreateTransientRelDestReceiver(Oid transientoid);
extern bool MatViewIncrementalMaintenanceIsEnabled(void);
+extern Datum IVM_immediate_before(PG_FUNCTION_ARGS);
+extern Datum IVM_immediate_maintenance(PG_FUNCTION_ARGS);
+extern Datum IVM_visible_in_prestate(PG_FUNCTION_ARGS);
+extern void AtAbort_IVM(void);
+extern bool isIvmName(const char *s);
+
#endif /* MATVIEW_H */
--
2.34.1
v34-0005-Add-Incremental-View-Maintenance-support-to-psql.patchtext/x-diff; name=v34-0005-Add-Incremental-View-Maintenance-support-to-psql.patchDownload
From 45a748b4f7ae5db9b92262121097ab9f5bfd5045 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:21:54 +0900
Subject: [PATCH v34 05/11] Add Incremental View Maintenance support to psql
Add tab completion and meta-command output for IVM.
---
src/bin/psql/describe.c | 32 +++++++++++++++++++++++++++++++-
src/bin/psql/tab-complete.c | 14 +++++++++-----
2 files changed, 40 insertions(+), 6 deletions(-)
diff --git a/src/bin/psql/describe.c b/src/bin/psql/describe.c
index 7c9a1f234c..10e6e0ab9b 100644
--- a/src/bin/psql/describe.c
+++ b/src/bin/psql/describe.c
@@ -1574,6 +1574,7 @@ describeOneTableDetails(const char *schemaname,
char relpersistence;
char relreplident;
char *relam;
+ bool isivm;
} tableinfo;
bool show_column_details = false;
@@ -1586,7 +1587,26 @@ describeOneTableDetails(const char *schemaname,
initPQExpBuffer(&tmpbuf);
/* Get general table info */
- if (pset.sversion >= 120000)
+ if (pset.sversion >= 180000)
+ {
+ printfPQExpBuffer(&buf,
+ "SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
+ "c.relhastriggers, c.relrowsecurity, c.relforcerowsecurity, "
+ "false AS relhasoids, c.relispartition, %s, c.reltablespace, "
+ "CASE WHEN c.reloftype = 0 THEN '' ELSE c.reloftype::pg_catalog.regtype::pg_catalog.text END, "
+ "c.relpersistence, c.relreplident, am.amname, "
+ "c.relisivm\n"
+ "FROM pg_catalog.pg_class c\n "
+ "LEFT JOIN pg_catalog.pg_class tc ON (c.reltoastrelid = tc.oid)\n"
+ "LEFT JOIN pg_catalog.pg_am am ON (c.relam = am.oid)\n"
+ "WHERE c.oid = '%s';",
+ (verbose ?
+ "pg_catalog.array_to_string(c.reloptions || "
+ "array(select 'toast.' || x from pg_catalog.unnest(tc.reloptions) x), ', ')\n"
+ : "''"),
+ oid);
+ }
+ else if (pset.sversion >= 120000)
{
printfPQExpBuffer(&buf,
"SELECT c.relchecks, c.relkind, c.relhasindex, c.relhasrules, "
@@ -1706,6 +1726,10 @@ describeOneTableDetails(const char *schemaname,
(char *) NULL : pg_strdup(PQgetvalue(res, 0, 14));
else
tableinfo.relam = NULL;
+ if (pset.sversion >= 180000)
+ tableinfo.isivm = strcmp(PQgetvalue(res, 0, 15), "t") == 0;
+ else
+ tableinfo.isivm = false;
PQclear(res);
res = NULL;
@@ -3508,6 +3532,12 @@ describeOneTableDetails(const char *schemaname,
printfPQExpBuffer(&buf, _("Access method: %s"), tableinfo.relam);
printTableAddFooter(&cont, buf.data);
}
+
+ /* Incremental view maintance info */
+ if (verbose && tableinfo.relkind == RELKIND_MATVIEW && tableinfo.isivm)
+ {
+ printTableAddFooter(&cont, _("Incremental view maintenance: yes"));
+ }
}
/* reloptions, if verbose */
diff --git a/src/bin/psql/tab-complete.c b/src/bin/psql/tab-complete.c
index d453e224d9..5fc88b59a9 100644
--- a/src/bin/psql/tab-complete.c
+++ b/src/bin/psql/tab-complete.c
@@ -1245,6 +1245,7 @@ static const pgsql_thing_t words_after_create[] = {
{"FOREIGN TABLE", NULL, NULL, NULL},
{"FUNCTION", NULL, NULL, Query_for_list_of_functions},
{"GROUP", Query_for_list_of_roles},
+ {"INCREMENTAL MATERIALIZED VIEW", NULL, NULL, &Query_for_list_of_matviews, NULL, THING_NO_DROP | THING_NO_ALTER},
{"INDEX", NULL, NULL, &Query_for_list_of_indexes},
{"LANGUAGE", Query_for_list_of_languages},
{"LARGE OBJECT", NULL, NULL, NULL, NULL, THING_NO_CREATE | THING_NO_DROP},
@@ -3274,7 +3275,7 @@ psql_completion(const char *text, int start, int end)
if (HeadMatches("CREATE", "SCHEMA"))
COMPLETE_WITH("TABLE", "SEQUENCE");
else
- COMPLETE_WITH("TABLE", "SEQUENCE", "MATERIALIZED VIEW");
+ COMPLETE_WITH("TABLE", "SEQUENCE", "MATERIALIZED VIEW", "INCREMENTAL MATERIALIZED VIEW");
}
/* Complete PARTITION BY with RANGE ( or LIST ( or ... */
else if (TailMatches("PARTITION", "BY"))
@@ -3619,13 +3620,16 @@ psql_completion(const char *text, int start, int end)
COMPLETE_WITH("SELECT");
/* CREATE MATERIALIZED VIEW */
- else if (Matches("CREATE", "MATERIALIZED"))
+ else if (Matches("CREATE", "MATERIALIZED") ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED"))
COMPLETE_WITH("VIEW");
- /* Complete CREATE MATERIALIZED VIEW <name> with AS */
- else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny))
+ /* Complete CREATE MATERIALIZED VIEW <name> with AS */
+ else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny) ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED", "VIEW", MatchAny))
COMPLETE_WITH("AS");
/* Complete "CREATE MATERIALIZED VIEW <sth> AS with "SELECT" */
- else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny, "AS"))
+ else if (Matches("CREATE", "MATERIALIZED", "VIEW", MatchAny, "AS") ||
+ Matches("CREATE", "INCREMENTAL", "MATERIALIZED", "VIEW", MatchAny, "AS"))
COMPLETE_WITH("SELECT");
/* CREATE EVENT TRIGGER */
--
2.34.1
v34-0004-Add-Incremental-View-Maintenance-support-to-pg_d.patchtext/x-diff; name=v34-0004-Add-Incremental-View-Maintenance-support-to-pg_d.patchDownload
From 347149a6f3abe85bba0d80c55e8f8eaa8994c017 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Wed, 11 Nov 2020 17:01:25 +0900
Subject: [PATCH v34 04/11] Add Incremental View Maintenance support to pg_dump
Support CREATE INCREMENTAL MATERIALIZED VIEW syntax.
---
src/bin/pg_dump/pg_dump.c | 18 +++++++++++++++---
src/bin/pg_dump/pg_dump.h | 2 ++
src/bin/pg_dump/t/002_pg_dump.pl | 18 ++++++++++++++++++
3 files changed, 35 insertions(+), 3 deletions(-)
diff --git a/src/bin/pg_dump/pg_dump.c b/src/bin/pg_dump/pg_dump.c
index b8b1888bd3..dedb91c5f0 100644
--- a/src/bin/pg_dump/pg_dump.c
+++ b/src/bin/pg_dump/pg_dump.c
@@ -6722,6 +6722,7 @@ getTables(Archive *fout, int *numTables)
int i_relacl;
int i_acldefault;
int i_ispartition;
+ int i_isivm;
/*
* Find all the tables and table-like objects.
@@ -6824,10 +6825,17 @@ getTables(Archive *fout, int *numTables)
if (fout->remoteVersion >= 100000)
appendPQExpBufferStr(query,
- "c.relispartition AS ispartition ");
+ "c.relispartition AS ispartition, ");
else
appendPQExpBufferStr(query,
- "false AS ispartition ");
+ "false AS ispartition, ");
+
+ if (fout->remoteVersion >= 180000)
+ appendPQExpBufferStr(query,
+ "c.relisivm AS isivm ");
+ else
+ appendPQExpBufferStr(query,
+ "false AS isivm ");
/*
* Left join to pg_depend to pick up dependency info linking sequences to
@@ -6936,6 +6944,7 @@ getTables(Archive *fout, int *numTables)
i_relacl = PQfnumber(res, "relacl");
i_acldefault = PQfnumber(res, "acldefault");
i_ispartition = PQfnumber(res, "ispartition");
+ i_isivm = PQfnumber(res, "isivm");
if (dopt->lockWaitTimeout)
{
@@ -7015,6 +7024,7 @@ getTables(Archive *fout, int *numTables)
tblinfo[i].amname = pg_strdup(PQgetvalue(res, i, i_amname));
tblinfo[i].is_identity_sequence = (strcmp(PQgetvalue(res, i, i_is_identity_sequence), "t") == 0);
tblinfo[i].ispartition = (strcmp(PQgetvalue(res, i, i_ispartition), "t") == 0);
+ tblinfo[i].isivm = (strcmp(PQgetvalue(res, i, i_isivm), "t") == 0);
/* other fields were zeroed above */
@@ -15812,9 +15822,11 @@ dumpTableSchema(Archive *fout, const TableInfo *tbinfo)
binary_upgrade_set_pg_class_oids(fout, q,
tbinfo->dobj.catId.oid);
- appendPQExpBuffer(q, "CREATE %s%s %s",
+ appendPQExpBuffer(q, "CREATE %s%s%s %s",
tbinfo->relpersistence == RELPERSISTENCE_UNLOGGED ?
"UNLOGGED " : "",
+ tbinfo->relkind == RELKIND_MATVIEW && tbinfo->isivm ?
+ "INCREMENTAL " : "",
reltypename,
qualrelname);
diff --git a/src/bin/pg_dump/pg_dump.h b/src/bin/pg_dump/pg_dump.h
index 4b2e5870a9..87df430a71 100644
--- a/src/bin/pg_dump/pg_dump.h
+++ b/src/bin/pg_dump/pg_dump.h
@@ -325,6 +325,8 @@ typedef struct _tableInfo
int numParents; /* number of (immediate) parent tables */
struct _tableInfo **parents; /* TableInfos of immediate parents */
+ bool isivm; /* is incrementally maintainable materialized view? */
+
/*
* These fields are computed only if we decide the table is interesting
* (it's either a table to dump, or a direct parent of a dumpable table).
diff --git a/src/bin/pg_dump/t/002_pg_dump.pl b/src/bin/pg_dump/t/002_pg_dump.pl
index d3dd8784d6..62fc9b5bc4 100644
--- a/src/bin/pg_dump/t/002_pg_dump.pl
+++ b/src/bin/pg_dump/t/002_pg_dump.pl
@@ -2785,6 +2785,24 @@ my %tests = (
},
},
+ 'CREATE MATERIALIZED VIEW matview_ivm' => {
+ create_order => 21,
+ create_sql => 'CREATE INCREMENTAL MATERIALIZED VIEW dump_test.matview_ivm (col1) AS
+ SELECT col1 FROM dump_test.test_table;',
+ regexp => qr/^
+ \QCREATE INCREMENTAL MATERIALIZED VIEW dump_test.matview_ivm AS\E
+ \n\s+\QSELECT col1\E
+ \n\s+\QFROM dump_test.test_table\E
+ \n\s+\QWITH NO DATA;\E
+ /xm,
+ like =>
+ { %full_runs, %dump_test_schema_runs, section_pre_data => 1, },
+ unlike => {
+ exclude_dump_test_schema => 1,
+ only_dump_measurement => 1,
+ },
+ },
+
'CREATE POLICY p1 ON test_table' => {
create_order => 22,
create_sql => 'CREATE POLICY p1 ON dump_test.test_table
--
2.34.1
v34-0003-Allow-to-prolong-life-span-of-transition-tables-.patchtext/x-diff; name=v34-0003-Allow-to-prolong-life-span-of-transition-tables-.patchDownload
From 8bade602c25f8e9bb6ba210ca23c1872b3a45b59 Mon Sep 17 00:00:00 2001
From: Yugo Nagata <nagata@sraoss.co.jp>
Date: Fri, 20 Dec 2019 10:09:45 +0900
Subject: [PATCH v34 03/11] Allow to prolong life span of transition tables
until transaction end
Originally, tuplestores of AFTER trigger's transition tables were
freed for each query depth. For our IVM implementation, we would like
to prolong life of the tuplestores because we have to preserve them
for a whole query assuming that some base tables might be changed
in some trigger functions.
---
src/backend/commands/trigger.c | 83 ++++++++++++++++++++++++++++++++--
src/include/commands/trigger.h | 2 +
2 files changed, 81 insertions(+), 4 deletions(-)
diff --git a/src/backend/commands/trigger.c b/src/backend/commands/trigger.c
index 170360edda..0e1b3faed7 100644
--- a/src/backend/commands/trigger.c
+++ b/src/backend/commands/trigger.c
@@ -3754,6 +3754,10 @@ typedef struct AfterTriggerEventList
* end of the list, so it is relatively easy to discard them. The event
* list chunks themselves are stored in event_cxt.
*
+ * prolonged_tuplestored is a list of transition table tuplestores whose
+ * life are prolonged to the end of the outmost query instead of each nested
+ * query.
+ *
* query_depth is the current depth of nested AfterTriggerBeginQuery calls
* (-1 when the stack is empty).
*
@@ -3819,6 +3823,7 @@ typedef struct AfterTriggersData
SetConstraintState state; /* the active S C state */
AfterTriggerEventList events; /* deferred-event list */
MemoryContext event_cxt; /* memory context for events, if any */
+ List *prolonged_tuplestores; /* list of prolonged tuplestores */
/* per-query-level data: */
AfterTriggersQueryData *query_stack; /* array of structs shown below */
@@ -3854,6 +3859,7 @@ struct AfterTriggersTableData
bool closed; /* true when no longer OK to add tuples */
bool before_trig_done; /* did we already queue BS triggers? */
bool after_trig_done; /* did we already queue AS triggers? */
+ bool prolonged; /* are transition tables prolonged? */
AfterTriggerEventList after_trig_events; /* if so, saved list pointer */
/*
@@ -3903,6 +3909,7 @@ static void TransitionTableAddTuple(EState *estate,
TupleTableSlot *original_insert_tuple,
Tuplestorestate *tuplestore);
static void AfterTriggerFreeQuery(AfterTriggersQueryData *qs);
+static void release_or_prolong_tuplestore(Tuplestorestate *ts, bool prolonged);
static SetConstraintState SetConstraintStateCreate(int numalloc);
static SetConstraintState SetConstraintStateCopy(SetConstraintState origstate);
static SetConstraintState SetConstraintStateAddItem(SetConstraintState state,
@@ -4782,6 +4789,45 @@ afterTriggerInvokeEvents(AfterTriggerEventList *events,
}
+/*
+ * SetTransitionTablePreserved
+ *
+ * Prolong lifespan of transition tables corresponding specified relid and
+ * command type to the end of the outmost query instead of each nested query.
+ * This enables to use nested AFTER trigger's transition tables from outer
+ * query's triggers. Currently, only immediate incremental view maintenance
+ * uses this.
+ */
+void
+SetTransitionTablePreserved(Oid relid, CmdType cmdType)
+{
+ AfterTriggersTableData *table;
+ AfterTriggersQueryData *qs;
+ bool found = false;
+ ListCell *lc;
+
+ /* Check state, like AfterTriggerSaveEvent. */
+ if (afterTriggers.query_depth < 0)
+ elog(ERROR, "SetTransitionTablePreserved() called outside of query");
+
+ qs = &afterTriggers.query_stack[afterTriggers.query_depth];
+
+ foreach(lc, qs->tables)
+ {
+ table = (AfterTriggersTableData *) lfirst(lc);
+ if (table->relid == relid && table->cmdType == cmdType &&
+ table->closed)
+ {
+ table->prolonged = true;
+ found = true;
+ }
+ }
+
+ if (!found)
+ elog(ERROR,"could not find table with OID %d and command type %d", relid, cmdType);
+}
+
+
/*
* GetAfterTriggersTableData
*
@@ -4992,6 +5038,7 @@ AfterTriggerBeginXact(void)
*/
afterTriggers.firing_counter = (CommandId) 1; /* mustn't be 0 */
afterTriggers.query_depth = -1;
+ afterTriggers.prolonged_tuplestores = NIL;
/*
* Verify that there is no leftover state remaining. If these assertions
@@ -5152,19 +5199,19 @@ AfterTriggerFreeQuery(AfterTriggersQueryData *qs)
ts = table->old_upd_tuplestore;
table->old_upd_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->new_upd_tuplestore;
table->new_upd_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->old_del_tuplestore;
table->old_del_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
ts = table->new_ins_tuplestore;
table->new_ins_tuplestore = NULL;
if (ts)
- tuplestore_end(ts);
+ release_or_prolong_tuplestore(ts, table->prolonged);
if (table->storeslot)
{
TupleTableSlot *slot = table->storeslot;
@@ -5181,6 +5228,34 @@ AfterTriggerFreeQuery(AfterTriggersQueryData *qs)
*/
qs->tables = NIL;
list_free_deep(tables);
+
+ /* Release prolonged tuplestores at the end of the outmost query */
+ if (afterTriggers.query_depth == 0)
+ {
+ foreach(lc, afterTriggers.prolonged_tuplestores)
+ {
+ ts = (Tuplestorestate *) lfirst(lc);
+ if (ts)
+ tuplestore_end(ts);
+ }
+ afterTriggers.prolonged_tuplestores = NIL;
+ }
+}
+
+/*
+ * Release the tuplestore, or append it to the prolonged tuplestores list.
+ */
+static void
+release_or_prolong_tuplestore(Tuplestorestate *ts, bool prolonged)
+{
+ if (prolonged && afterTriggers.query_depth > 0)
+ {
+ MemoryContext oldcxt = MemoryContextSwitchTo(CurTransactionContext);
+ afterTriggers.prolonged_tuplestores = lappend(afterTriggers.prolonged_tuplestores, ts);
+ MemoryContextSwitchTo(oldcxt);
+ }
+ else
+ tuplestore_end(ts);
}
diff --git a/src/include/commands/trigger.h b/src/include/commands/trigger.h
index 8a5a9fe642..6718514d34 100644
--- a/src/include/commands/trigger.h
+++ b/src/include/commands/trigger.h
@@ -265,6 +265,8 @@ extern void AfterTriggerEndSubXact(bool isCommit);
extern void AfterTriggerSetState(ConstraintsSetStmt *stmt);
extern bool AfterTriggerPendingOnRel(Oid relid);
+extern void SetTransitionTablePreserved(Oid relid, CmdType cmdType);
+
/*
* in utils/adt/ri_triggers.c
--
2.34.1
Import Notes
Reply to msg id not found: 20240702170311.1ddb417759a48ff12c555b92@sranhm.sraoss.co.jp.sranhm
Hi!
Cloudberry DB (Greenplum fork) uses IMMV feature for AQUMV (auto query
use matview) feature, so i got interested in how it is implemented.
On Thu, 11 Jul 2024 at 09:24, Yugo NAGATA <nagata@sraoss.co.jp> wrote:
I updated the patch to bump up the version numbers in psql and pg_dump codes
from 17 to 18.
Few suggestions:
1) `Add-relisivm-column-to-pg_class-system-catalog` commit message
should be fixed, there is "isimmv" in the last line.
2) I dont get why `Add-Incremental-View-Maintenance-support.patch`
goes after 0005 & 0004. Shoulndt we first implement feature server
side, only when client (psql & pg_dump) side?
3) Can we provide regression tests for each function separately? Test
for main feature in main patch, test for DISTINCT support in
v34-0007-Add-DISTINCT-support-for-IVM.patch etc? This way the patchset
will be easier to review, and can be committed separelety.
4) v34-0006-Add-Incremental-View-Maintenance-support.patch no longer
applies due to 4b74ebf726d444ba820830cad986a1f92f724649. After
resolving issues manually, it does not compile, because
4b74ebf726d444ba820830cad986a1f92f724649 also removes
save_userid/save_sec_context fields from ExecCreateTableAs.
if (RelationIsIVM(matviewRel) && stmt->skipData)
Now this function accepts skipData param.
5) For DISTINCT support patch uses hidden __ivm* columns. Is this
design discussed anywhere? I wonder if this is a necessity (only
solution) or if there are alternatives.
6)
What are the caveats of supporting some simple cases for aggregation
funcs like in example?
```
regress=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_2 AS SELECT
sum(j) + sum(i) from mv_base_a;
ERROR: expression containing an aggregate in it is not supported on
incrementally maintainable materialized view
```
I can see some difficulties with division CREATE IMMV .... AS SELECT
1/sum(i) from mv_base_a; (sum(i) == 0 case), but adding &
multiplication should be ok, aren't they?
Overall, patchset looks mature, however it is far from being
committable due to lack of testing/feedback/discussion. There is only
one way to fix this... Test and discuss it!
On Sat, 27 Jul 2024 at 13:26, Kirill Reshke <reshkekirill@gmail.com> wrote:
Hi!
Cloudberry DB (Greenplum fork) uses IMMV feature for AQUMV (auto query
use matview) feature, so i got interested in how it is implemented.On Thu, 11 Jul 2024 at 09:24, Yugo NAGATA <nagata@sraoss.co.jp> wrote:
I updated the patch to bump up the version numbers in psql and pg_dump codes
from 17 to 18.Few suggestions:
1) `Add-relisivm-column-to-pg_class-system-catalog` commit message
should be fixed, there is "isimmv" in the last line.
2) I dont get why `Add-Incremental-View-Maintenance-support.patch`
goes after 0005 & 0004. Shoulndt we first implement feature server
side, only when client (psql & pg_dump) side?
3) Can we provide regression tests for each function separately? Test
for main feature in main patch, test for DISTINCT support in
v34-0007-Add-DISTINCT-support-for-IVM.patch etc? This way the patchset
will be easier to review, and can be committed separelety.
4) v34-0006-Add-Incremental-View-Maintenance-support.patch no longer
applies due to 4b74ebf726d444ba820830cad986a1f92f724649. After
resolving issues manually, it does not compile, because
4b74ebf726d444ba820830cad986a1f92f724649 also removes
save_userid/save_sec_context fields from ExecCreateTableAs.if (RelationIsIVM(matviewRel) && stmt->skipData)
Now this function accepts skipData param.
5) For DISTINCT support patch uses hidden __ivm* columns. Is this
design discussed anywhere? I wonder if this is a necessity (only
solution) or if there are alternatives.
6)
What are the caveats of supporting some simple cases for aggregation
funcs like in example?
```
regress=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_2 AS SELECT
sum(j) + sum(i) from mv_base_a;
ERROR: expression containing an aggregate in it is not supported on
incrementally maintainable materialized view
```
I can see some difficulties with division CREATE IMMV .... AS SELECT
1/sum(i) from mv_base_a; (sum(i) == 0 case), but adding &
multiplication should be ok, aren't they?Overall, patchset looks mature, however it is far from being
committable due to lack of testing/feedback/discussion. There is only
one way to fix this... Test and discuss it!
Hi! Small update: I tried to run a regression test and all
IMMV-related tests failed on my vm. Maybe I'm doing something wrong, I
will try to investigate.
Another suggestion: support for \d and \d+ commands in psql. With v34
patchset applied, psql does not show anything IMMV-related in \d mode.
```
reshke=# \d m1
Materialized view "public.m1"
Column | Type | Collation | Nullable | Default
--------+---------+-----------+----------+---------
i | integer | | |
Distributed by: (i)
reshke=# \d+ m1
Materialized view "public.m1"
Column | Type | Collation | Nullable | Default | Storage |
Compression | Stats target | Description
--------+---------+-----------+----------+---------+---------+-------------+--------------+-------------
i | integer | | | | plain |
| |
View definition:
SELECT t1.i
FROM t1;
Distributed by: (i)
Access method: heap
```
Output should be 'Incrementally materialized view "public.m1"' IMO.
Hi,
On Tue, 30 Jul 2024 03:32:19 +0500
Kirill Reshke <reshkekirill@gmail.com> wrote:
On Sat, 27 Jul 2024 at 13:26, Kirill Reshke <reshkekirill@gmail.com> wrote:
Hi!
Cloudberry DB (Greenplum fork) uses IMMV feature for AQUMV (auto query
use matview) feature, so i got interested in how it is implemented.
Thank you so much for a lot of comments!
I will respond to the comments soon.
On Thu, 11 Jul 2024 at 09:24, Yugo NAGATA <nagata@sraoss.co.jp> wrote:
I updated the patch to bump up the version numbers in psql and pg_dump codes
from 17 to 18.Few suggestions:
1) `Add-relisivm-column-to-pg_class-system-catalog` commit message
should be fixed, there is "isimmv" in the last line.
2) I dont get why `Add-Incremental-View-Maintenance-support.patch`
goes after 0005 & 0004. Shoulndt we first implement feature server
side, only when client (psql & pg_dump) side?
3) Can we provide regression tests for each function separately? Test
for main feature in main patch, test for DISTINCT support in
v34-0007-Add-DISTINCT-support-for-IVM.patch etc? This way the patchset
will be easier to review, and can be committed separelety.
4) v34-0006-Add-Incremental-View-Maintenance-support.patch no longer
applies due to 4b74ebf726d444ba820830cad986a1f92f724649. After
resolving issues manually, it does not compile, because
4b74ebf726d444ba820830cad986a1f92f724649 also removes
save_userid/save_sec_context fields from ExecCreateTableAs.if (RelationIsIVM(matviewRel) && stmt->skipData)
Now this function accepts skipData param.
5) For DISTINCT support patch uses hidden __ivm* columns. Is this
design discussed anywhere? I wonder if this is a necessity (only
solution) or if there are alternatives.
6)
What are the caveats of supporting some simple cases for aggregation
funcs like in example?
```
regress=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_2 AS SELECT
sum(j) + sum(i) from mv_base_a;
ERROR: expression containing an aggregate in it is not supported on
incrementally maintainable materialized view
```
I can see some difficulties with division CREATE IMMV .... AS SELECT
1/sum(i) from mv_base_a; (sum(i) == 0 case), but adding &
multiplication should be ok, aren't they?Overall, patchset looks mature, however it is far from being
committable due to lack of testing/feedback/discussion. There is only
one way to fix this... Test and discuss it!Hi! Small update: I tried to run a regression test and all
IMMV-related tests failed on my vm. Maybe I'm doing something wrong, I
will try to investigate.Another suggestion: support for \d and \d+ commands in psql. With v34
patchset applied, psql does not show anything IMMV-related in \d mode.```
reshke=# \d m1
Materialized view "public.m1"
Column | Type | Collation | Nullable | Default
--------+---------+-----------+----------+---------
i | integer | | |
Distributed by: (i)reshke=# \d+ m1
Materialized view "public.m1"
Column | Type | Collation | Nullable | Default | Storage |
Compression | Stats target | Description
--------+---------+-----------+----------+---------+---------+-------------+--------------+-------------
i | integer | | | | plain |
| |
View definition:
SELECT t1.i
FROM t1;
Distributed by: (i)
Access method: heap```
Output should be 'Incrementally materialized view "public.m1"' IMO.
--
Yugo NAGATA <nagata@sraoss.co.jp>
On Tue, 30 Jul 2024 at 03:32, Kirill Reshke <reshkekirill@gmail.com> wrote:
On Sat, 27 Jul 2024 at 13:26, Kirill Reshke <reshkekirill@gmail.com> wrote:
Hi!
Cloudberry DB (Greenplum fork) uses IMMV feature for AQUMV (auto query
use matview) feature, so i got interested in how it is implemented.On Thu, 11 Jul 2024 at 09:24, Yugo NAGATA <nagata@sraoss.co.jp> wrote:
I updated the patch to bump up the version numbers in psql and pg_dump codes
from 17 to 18.Few suggestions:
1) `Add-relisivm-column-to-pg_class-system-catalog` commit message
should be fixed, there is "isimmv" in the last line.
2) I dont get why `Add-Incremental-View-Maintenance-support.patch`
goes after 0005 & 0004. Shoulndt we first implement feature server
side, only when client (psql & pg_dump) side?
3) Can we provide regression tests for each function separately? Test
for main feature in main patch, test for DISTINCT support in
v34-0007-Add-DISTINCT-support-for-IVM.patch etc? This way the patchset
will be easier to review, and can be committed separelety.
4) v34-0006-Add-Incremental-View-Maintenance-support.patch no longer
applies due to 4b74ebf726d444ba820830cad986a1f92f724649. After
resolving issues manually, it does not compile, because
4b74ebf726d444ba820830cad986a1f92f724649 also removes
save_userid/save_sec_context fields from ExecCreateTableAs.if (RelationIsIVM(matviewRel) && stmt->skipData)
Now this function accepts skipData param.
5) For DISTINCT support patch uses hidden __ivm* columns. Is this
design discussed anywhere? I wonder if this is a necessity (only
solution) or if there are alternatives.
6)
What are the caveats of supporting some simple cases for aggregation
funcs like in example?
```
regress=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_2 AS SELECT
sum(j) + sum(i) from mv_base_a;
ERROR: expression containing an aggregate in it is not supported on
incrementally maintainable materialized view
```
I can see some difficulties with division CREATE IMMV .... AS SELECT
1/sum(i) from mv_base_a; (sum(i) == 0 case), but adding &
multiplication should be ok, aren't they?Overall, patchset looks mature, however it is far from being
committable due to lack of testing/feedback/discussion. There is only
one way to fix this... Test and discuss it!Hi! Small update: I tried to run a regression test and all
IMMV-related tests failed on my vm. Maybe I'm doing something wrong, I
will try to investigate.Another suggestion: support for \d and \d+ commands in psql. With v34
patchset applied, psql does not show anything IMMV-related in \d mode.```
reshke=# \d m1
Materialized view "public.m1"
Column | Type | Collation | Nullable | Default
--------+---------+-----------+----------+---------
i | integer | | |
Distributed by: (i)reshke=# \d+ m1
Materialized view "public.m1"
Column | Type | Collation | Nullable | Default | Storage |
Compression | Stats target | Description
--------+---------+-----------+----------+---------+---------+-------------+--------------+-------------
i | integer | | | | plain |
| |
View definition:
SELECT t1.i
FROM t1;
Distributed by: (i)
Access method: heap```
Output should be 'Incrementally materialized view "public.m1"' IMO.
And one more thing, noticed today while playing with patchset:
I believe non-terminal incremental should be OptIncremental
Im talking about this:
```
incremental: INCREMENTAL { $$ = true; }
| /*EMPTY*/ { $$ = false; }
;
```
On Thu, 11 Jul 2024 at 09:24, Yugo NAGATA <nagata@sraoss.co.jp> wrote:
On Tue, 2 Jul 2024 17:03:11 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:On Sun, 31 Mar 2024 22:59:31 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:Also, I added a comment on RelationIsIVM() macro persuggestion from jian he.
In addition, I fixed a failure reported from cfbot on FreeBSD build caused by;WARNING: outfuncs/readfuncs failed to produce an equal rewritten parse tree
This warning was raised since I missed to modify outfuncs.c for a new field.
I found cfbot on FreeBSD still reported a failure due to
ENFORCE_REGRESSION_TEST_NAME_RESTRICTIONS because the regression test used
wrong role names. Attached is a fixed version, v32.Attached is a rebased version, v33.
I updated the patch to bump up the version numbers in psql and pg_dump codes
from 17 to 18.Regards,
Yugo NagataRegards,
Yugo Nagata--
Yugo NAGATA <nagata@sraoss.co.jp>--
Yugo NAGATA <nagata@sraoss.co.jp>
Small updates with something o found recent days:
```
db2=# create incremental materialized view v2 as select * from v1;
ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally
maintainable materialized view
```
Error messaging is not true, create view v2 as select * from v1; works fine.
```
db2=# create incremental materialized view vv2 as select i,j2, i / j2
from t1 join t2 on true;
db2=# insert into t2 values(1,0);
ERROR: division by zero
```
It is very strange to receive `division by zero` while inserting into
relation, isn't it? Can we add some hints/CONTEXT here?
Regular triggers do it:
```
db2=# insert into ttt values(100000,0);
ERROR: division by zero
CONTEXT: PL/pgSQL function f1() line 3 at IF
```
--
Best regards,
Kirill Reshke
I am really sorry for splitting my review comments into multiple
emails. I'll try to do a better review in a future, all-in-one.
On Thu, 11 Jul 2024 at 09:24, Yugo NAGATA <nagata@sraoss.co.jp> wrote:
On Tue, 2 Jul 2024 17:03:11 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:On Sun, 31 Mar 2024 22:59:31 +0900
Yugo NAGATA <nagata@sraoss.co.jp> wrote:Also, I added a comment on RelationIsIVM() macro persuggestion from jian he.
In addition, I fixed a failure reported from cfbot on FreeBSD build caused by;WARNING: outfuncs/readfuncs failed to produce an equal rewritten parse tree
This warning was raised since I missed to modify outfuncs.c for a new field.
I found cfbot on FreeBSD still reported a failure due to
ENFORCE_REGRESSION_TEST_NAME_RESTRICTIONS because the regression test used
wrong role names. Attached is a fixed version, v32.Attached is a rebased version, v33.
I updated the patch to bump up the version numbers in psql and pg_dump codes
from 17 to 18.Regards,
Yugo NagataRegards,
Yugo Nagata--
Yugo NAGATA <nagata@sraoss.co.jp>--
Yugo NAGATA <nagata@sraoss.co.jp>
1) Provided patches do not set process title correctly:
```
reshke 2602433 18.7 0.1 203012 39760 ? Rs 20:41 1:58
postgres: reshke ivm [local] CREATE MATERIALIZED VIEW
```
2) We allow to REFRESH IMMV. Why? IMMV should be always up to date.
Well, I can see that this utility command may be useful in case of
corruption of some base relation/view itself, so there will be a need
to rebuild the whole from scratch.
But we already have VACUUM FULL for this, aren't we?
3) Triggers created for IMMV are not listed via \dS [tablename]
4) apply_old_delta_with_count executes non-trivial SQL statements for
IMMV. It would be really helpful to see this in EXPLAIN ANALYZE.
5)
+ "DELETE FROM %s WHERE ctid IN (" + "SELECT tid FROM (SELECT pg_catalog.row_number() over (partition by %s) AS \"__ivm_row_number__\"," + "mv.ctid AS tid," + "diff.\"__ivm_count__\"" + "FROM %s AS mv, %s AS diff " + "WHERE %s) v " + "WHERE v.\"__ivm_row_number__\" OPERATOR(pg_catalog.<=) v.\"__ivm_count__\")", + matviewname, + keysbuf.data, + matviewname, deltaname_old, + match_cond);
`SELECT pg_catalog.row_number()` is too generic to my taste. Maybe
pg_catalog.immv_row_number() / pg_catalog.get_immv_row_number() ?
6)
+static void +apply_new_delta(const char *matviewname, const char *deltaname_new, + StringInfo target_list) +{ + StringInfoData querybuf; + + /* Search for matching tuples from the view and update or delete if found. */
Is this comment correct? we only insert tuples here?
7)
During patch development, one should pick OIDs from range 8000-9999
+# IVM +{ oid => '786', descr => 'ivm trigger (before)', + proname => 'IVM_immediate_before', provolatile => 'v', prorettype => 'trigger', + proargtypes => '', prosrc => 'IVM_immediate_before' }, +{ oid => '787', descr => 'ivm trigger (after)', + proname => 'IVM_immediate_maintenance', provolatile => 'v', prorettype => 'trigger', + proargtypes => '', prosrc => 'IVM_immediate_maintenance' }, +{ oid => '788', descr => 'ivm filetring ', + proname => 'ivm_visible_in_prestate', provolatile => 's', prorettype => 'bool', + proargtypes => 'oid tid oid', prosrc => 'ivm_visible_in_prestate' }, ]
--
Best regards,
Kirill Reshke
On Wed, 31 May 2023 at 20:14, Yugo NAGATA <nagata@sraoss.co.jp> wrote:
Hello hackers,
Here's a rebased version of the patch-set adding Incremental View
Maintenance support for PostgreSQL. That was discussed in [1].The patch-set consists of the following eleven patches.
- 0001: Add a syntax to create Incrementally Maintainable Materialized Views
- 0002: Add relisivm column to pg_class system catalog
- 0003: Allow to prolong life span of transition tables until transaction end
- 0004: Add Incremental View Maintenance support to pg_dum
- 0005: Add Incremental View Maintenance support to psql
- 0006: Add Incremental View Maintenance support
- 0007: Add DISTINCT support for IVM
- 0008: Add aggregates support in IVM
- 0009: Add support for min/max aggregates for IVM
- 0010: regression tests
- 0011: documentation[1] /messages/by-id/20181227215726.4d166b4874f8983a641123f5@sraoss.co.jp
Regards,
Yugo Nagata--
Yugo NAGATA <nagata@sraoss.co.jp>
Actually, this new MV delta-table calculation can be used to make
faster REFRESH MATERIALIZED VIEW even for non-IMMV. Specifically, we
can use our cost-based Optimizer to decide which way is cheaper:
regular query execution, or delta-table approach (if it is
applicable).
Is it worth another thread?
--
Best regards,
Kirill Reshke
On Tue, 30 Jul 2024 at 10:24, Yugo NAGATA <nagata@sraoss.co.jp> wrote:
Hi,
On Tue, 30 Jul 2024 03:32:19 +0500
Kirill Reshke <reshkekirill@gmail.com> wrote:On Sat, 27 Jul 2024 at 13:26, Kirill Reshke <reshkekirill@gmail.com> wrote:
Hi!
Cloudberry DB (Greenplum fork) uses IMMV feature for AQUMV (auto query
use matview) feature, so i got interested in how it is implemented.Thank you so much for a lot of comments!
I will respond to the comments soon.On Thu, 11 Jul 2024 at 09:24, Yugo NAGATA <nagata@sraoss.co.jp> wrote:
I updated the patch to bump up the version numbers in psql and pg_dump codes
from 17 to 18.Few suggestions:
1) `Add-relisivm-column-to-pg_class-system-catalog` commit message
should be fixed, there is "isimmv" in the last line.
2) I dont get why `Add-Incremental-View-Maintenance-support.patch`
goes after 0005 & 0004. Shoulndt we first implement feature server
side, only when client (psql & pg_dump) side?
3) Can we provide regression tests for each function separately? Test
for main feature in main patch, test for DISTINCT support in
v34-0007-Add-DISTINCT-support-for-IVM.patch etc? This way the patchset
will be easier to review, and can be committed separelety.
4) v34-0006-Add-Incremental-View-Maintenance-support.patch no longer
applies due to 4b74ebf726d444ba820830cad986a1f92f724649. After
resolving issues manually, it does not compile, because
4b74ebf726d444ba820830cad986a1f92f724649 also removes
save_userid/save_sec_context fields from ExecCreateTableAs.if (RelationIsIVM(matviewRel) && stmt->skipData)
Now this function accepts skipData param.
5) For DISTINCT support patch uses hidden __ivm* columns. Is this
design discussed anywhere? I wonder if this is a necessity (only
solution) or if there are alternatives.
6)
What are the caveats of supporting some simple cases for aggregation
funcs like in example?
```
regress=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_2 AS SELECT
sum(j) + sum(i) from mv_base_a;
ERROR: expression containing an aggregate in it is not supported on
incrementally maintainable materialized view
```
I can see some difficulties with division CREATE IMMV .... AS SELECT
1/sum(i) from mv_base_a; (sum(i) == 0 case), but adding &
multiplication should be ok, aren't they?Overall, patchset looks mature, however it is far from being
committable due to lack of testing/feedback/discussion. There is only
one way to fix this... Test and discuss it!Hi! Small update: I tried to run a regression test and all
IMMV-related tests failed on my vm. Maybe I'm doing something wrong, I
will try to investigate.Another suggestion: support for \d and \d+ commands in psql. With v34
patchset applied, psql does not show anything IMMV-related in \d mode.```
reshke=# \d m1
Materialized view "public.m1"
Column | Type | Collation | Nullable | Default
--------+---------+-----------+----------+---------
i | integer | | |
Distributed by: (i)reshke=# \d+ m1
Materialized view "public.m1"
Column | Type | Collation | Nullable | Default | Storage |
Compression | Stats target | Description
--------+---------+-----------+----------+---------+---------+-------------+--------------+-------------
i | integer | | | | plain |
| |
View definition:
SELECT t1.i
FROM t1;
Distributed by: (i)
Access method: heap```
Output should be 'Incrementally materialized view "public.m1"' IMO.
--
Yugo NAGATA <nagata@sraoss.co.jp>
So, I spent another 2 weeks on this patch. I have read the whole
'Incremental View Maintenance' thread (from 2018), this thread, some
related threads. Have studied some papers on this topic. I got a
better understanding of the theory this work is backed up with.
However, I still can add my 2c.
== Major suggestions.
1) At first glance, working with this IVM/IMMV infrastructure feels
really unintuitive about what servers actually do for query execution.
I do think It will be much better for user experience to add more
EXPLAIN about IVM work done inside IVM triggers. This way it is much
clearer which part is working slow, so which index should be created,
etc.
2) The kernel code for IVM lacks possibility to be extended for
further IVM optimizations. The one example is foreign key optimization
described here[1]https://assets.amazon.science/a2/57/a00ebcfc446a9d0bf827bb51c15a/foreign-keys-open-the-door-for-faster-incremental-view-maintenance.pdf. I'm not saying we should implement this within this
patchset, but we surely should pave the way for this. I don't have any
good suggestions for how to do this though.
3) I don't really think SQL design is good. CREATE [INCREMENTAL] M.V.
is too ad-hoc. I would prefer CREATE M.V. with (maintain_incr=true).
(reloption name is just an example).
This way we can change regular M.V. to IVM and vice versa via ALTER
M.V. SET *reloptions* - a type of syntax that is already present in
PostgreSQL core.
== Other thoughts
In OLAP databases (see [2]https://github.com/cloudberrydb/cloudberrydb), IVM opens the door for 'view
exploitation' feature. That is, use IVM (which is always up-to-date)
for query execution. But current IVM implementation is not compatible
with Cloudberry Append-optimized Table Access Method. The problem is
the 'table_tuple_fetch_row_version' call, which is used by
ivm_visible_in_prestate to check tuple visibility within a snapshot. I
am trying to solve this somehow. My current idea is the following:
multiple base table modification via single statement along with tuple
deletion from base tables are features. We can error-out these cases
(at M.V. creation time) all for some TAMs, and support only insert &
truncate. However, I don't know how to check if TAM supports
'tuple_fetch_row_version' other than calling it and receiving
ERROR[3]https://github.com/cloudberrydb/cloudberrydb/blob/b9aec75154d5bbecce7ce3a33e8bb2272ff61511/src/backend/access/appendonly/appendonlyam_handler.c#L828.
== Minor nitpicks and typos.
reshke=# insert into tt select * from generate_series(1, 1000090);
^CCancel request sent
ERROR: canceling statement due to user request
CONTEXT: SQL statement "INSERT INTO public.mv1 (i, j) SELECT i, j
FROM (SELECT diff.*, pg_catalog.generate_series(1,
diff."__ivm_count__") AS __ivm_generate_series__ FROM new_delta AS
diff) AS v"
Time: 18883.883 ms (00:18.884)
This is very surprising, isn't it? We can set HINT here, to indicate
where this query comes from.
2)
deleted/deleted -> updated/deleted
+ /*
+ * XXX: When using DELETE or UPDATE, we must use exclusive lock for now
+ * because apply_old_delta(_with_count) uses ctid to identify the tuple
+ * to be deleted/deleted, but doesn't work in concurrent situations.
3) Typo in rewrite_query_for_postupdate_state:
/* Retore the original RTE */
4) in apply_delta function has exactly one usage, so the 'use_count'
param is redundant, because we already pass the 'query' param, and
'use_count' is calculated from the 'query'.
5) in calc_delta:
ListCell *lc = list_nth_cell(query->rtable, rte_index - 1);
RangeTblEntry *rte = (RangeTblEntry *) lfirst(lc);
Should we add Assert(list_lenght(lc) == 1) here? Can there be multiple
items in this list?
6) In get_prestate_rte:
appendStringInfo(&str,
"SELECT t.* FROM %s t"
" WHERE pg_catalog.ivm_visible_in_prestate(t.tableoid, t.ctid ,%d::pg_catalog.oid)",
relname, matviewid);
Identitation issue. This will not be fixed via pg_ident run, because
this is str contant, so better so fix it by-hand.
7) in apply_new_delta_with_count:
appendStringInfo(&querybuf,
"WITH updt AS (" /* update a tuple if this exists in the view */
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.+) diff.%s "
SET % OPERATOR(pg_catalog.=) mv.%s ?
same for append_set_clause_for_count, append_set_clause_for_sum,
append_set_clause_for_minmax
/* avg = (mv.sum - t.sum)::aggtype / (mv.count - t.count) */
appendStringInfo(buf_old,
", %s = %s OPERATOR(pg_catalog./) %s",
should be
/* avg OPERATOR(pg_catalog.=) (mv.sum - t.sum)::aggtype / (mv.count -
t.count) */
appendStringInfo(buf_old,
", %s = %s OPERATOR(pg_catalog./) %s",
[1]: https://assets.amazon.science/a2/57/a00ebcfc446a9d0bf827bb51c15a/foreign-keys-open-the-door-for-faster-incremental-view-maintenance.pdf
[2]: https://github.com/cloudberrydb/cloudberrydb
[3]: https://github.com/cloudberrydb/cloudberrydb/blob/b9aec75154d5bbecce7ce3a33e8bb2272ff61511/src/backend/access/appendonly/appendonlyam_handler.c#L828
--
Best regards,
Kirill Reshke
On Tue, 20 Aug 2024 at 02:14, Kirill Reshke <reshkekirill@gmail.com> wrote:
== Other thoughts
In OLAP databases (see [2]), IVM opens the door for 'view
exploitation' feature. That is, use IVM (which is always up-to-date)
for query execution. But current IVM implementation is not compatible
with Cloudberry Append-optimized Table Access Method. The problem is
the 'table_tuple_fetch_row_version' call, which is used by
ivm_visible_in_prestate to check tuple visibility within a snapshot. I
am trying to solve this somehow. My current idea is the following:
multiple base table modification via single statement along with tuple
deletion from base tables are features. We can error-out these cases
(at M.V. creation time) all for some TAMs, and support only insert &
truncate. However, I don't know how to check if TAM supports
'tuple_fetch_row_version' other than calling it and receiving
ERROR[3].
I reread this and I find this a little bit unclear. What I'm proposing
here is specifying the type of operations IVM supports on creation
time. So, one can run
CREATE IVM immv1 WITH (support_deletion = true/false,
support_multiple_relation_change = true/false). Then, in the query
execution time, we just ERROR if the query leads to deletion from IVM
and support_deletion if false.
--
Best regards,
Kirill Reshke
On Tue, 20 Aug 2024 at 02:14, Kirill Reshke <reshkekirill@gmail.com> wrote:
== Major suggestions.
1) At first glance, working with this IVM/IMMV infrastructure feels
really unintuitive about what servers actually do for query execution.
I do think It will be much better for user experience to add more
EXPLAIN about IVM work done inside IVM triggers. This way it is much
clearer which part is working slow, so which index should be created,
etc.2) The kernel code for IVM lacks possibility to be extended for
further IVM optimizations. The one example is foreign key optimization
described here[1]. I'm not saying we should implement this within this
patchset, but we surely should pave the way for this. I don't have any
good suggestions for how to do this though.3) I don't really think SQL design is good. CREATE [INCREMENTAL] M.V.
is too ad-hoc. I would prefer CREATE M.V. with (maintain_incr=true).
(reloption name is just an example).
This way we can change regular M.V. to IVM and vice versa via ALTER
M.V. SET *reloptions* - a type of syntax that is already present in
PostgreSQL core.
One little follow-up here. Why do we do prepstate visibility the way
it is done? Can we instead export the snapshot in BEFORE trigger, save
it somewhere and use it after?
--
Best regards,
Kirill Reshke
Hello,
I apologize for the long silence.
I would like to resume working on this now.
Thank you, Kirill Reshke, for your many comments and suggestions.
Here are my (admittedly) late responses:
1) `Add-relisivm-column-to-pg_class-system-catalog` commit message
should be fixed, there is "isimmv" in the last line.
I'll fix it.
2) I dont get why `Add-Incremental-View-Maintenance-support.patch`
goes after 0005 & 0004. Shoulndt we first implement feature server
side, only when client (psql & pg_dump) side?
Makes sense. Perhaps they don’t even need to be separated.
I’ll plan to reorganize the patch set anyway.
3) Can we provide regression tests for each function separately? Test
for main feature in main patch, test for DISTINCT support in
v34-0007-Add-DISTINCT-support-for-IVM.patch etc? This way the patchset
will be easier to review, and can be committed separelety.
Makes sense. I'll do that while reorganizing the patch set.
4) v34-0006-Add-Incremental-View-Maintenance-support.patch no longer
applies due to 4b74ebf726d444ba820830cad986a1f92f724649. After
resolving issues manually, it does not compile, because
4b74ebf726d444ba820830cad986a1f92f724649 also removes
save_userid/save_sec_context fields from ExecCreateTableAs.if (RelationIsIVM(matviewRel) && stmt->skipData)
Now this function accepts skipData param.
Yeah, a rebase is definitely required for the patch set.
5) For DISTINCT support patch uses hidden __ivm* columns. Is this
design discussed anywhere? I wonder if this is a necessity (only
solution) or if there are alternatives.
I believe we need to store the counting information somehow.
More discussion on how hidden columns should be handled would still be
necessary, though.
6)
What are the caveats of supporting some simple cases for aggregation
funcs like in example?
```
regress=# CREATE INCREMENTAL MATERIALIZED VIEW mv_ivm_2 AS SELECT
sum(j) + sum(i) from mv_base_a;
ERROR: expression containing an aggregate in it is not supported on
incrementally maintainable materialized view
```
I can see some difficulties with division CREATE IMMV .... AS SELECT
1/sum(i) from mv_base_a; (sum(i) == 0 case), but adding &
multiplication should be ok, aren't they?
This could theoretically be supported. For example, for sum(j) + sum(i),
if the values of sum(j) and sum(i) are stored in the view respectively,
their new values could be incrementally calculated, and the new column
value could be derived from them. However, this logic is not yet implemented.
The current aggregate support, as you’ve seen, is implemented individually
for each supported aggregate using SQL via SPI, in a somewhat ad hoc manner.
Therefore, we may need more sophisticated infrastructure, as well as further
design discussion on this topic.
Another suggestion: support for \d and \d+ commands in psql. With v34
patchset applied, psql does not show anything IMMV-related in \d mode.
I'll fix it.
```
db2=# create incremental materialized view v2 as select * from v1;
ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally
maintainable materialized view
```
Error messaging is not true, create view v2 as select * from v1; works fine.
The current implementation does not handle situations in which a base table
of v1 is modified.
```
db2=# create incremental materialized view vv2 as select i,j2, i / j2
from t1 join t2 on true;
db2=# insert into t2 values(1,0);
ERROR: division by zero
```
It is very strange to receive `division by zero` while inserting into
relation, isn't it? Can we add some hints/CONTEXT here?
Hmm, the current behavior is similar to stored generated columns.
However, it is not as intuitive that a table is involved in incremental
maintenance as it is when the table has generated columns.
Therefore, it would be better to add CONTEXT to the error message,
although we may need to add some infrastructure for this in the logging system.
1) Provided patches do not set process title correctly:
```
reshke 2602433 18.7 0.1 203012 39760 ? Rs 20:41 1:58
postgres: reshke ivm [local] CREATE MATERIALIZED VIEW
```
Ok, it would be better if the process title reflected the actual syntax.
2) We allow to REFRESH IMMV. Why? IMMV should be always up to date.
Well, I can see that this utility command may be useful in case of
corruption of some base relation/view itself, so there will be a need
to rebuild the whole from scratch.
But we already have VACUUM FULL for this, aren't we?
Since REFRESH is already allowed for normal materialized views, I see no
reason to prohibit it for IMMVs. Moreover, incremental updates of numeric
aggregates may cause drift between the view and the actual data due
to accumulated error. REFRESH can be used to correct the discrepancy.
3) Triggers created for IMMV are not listed via \dS [tablename]
The triggers are not listed because they are internal. Likewise, triggers
created on tables with foreign key constraints are not displayed by \dS.
Still, it may be helpful to indicate that the table is involved in an IMMV.
There is also an alternative approach that implements IVM without relying
on triggers.
4) apply_old_delta_with_count executes non-trivial SQL statements for
IMMV. It would be really helpful to see this in EXPLAIN ANALYZE.
It would indeed be helpful if EXPLAIN ANALYZE provided some useful information
about incremental maintenance. That said, I don’t yet have a clear idea of the
best way to achieve this.
5) + "DELETE FROM %s WHERE ctid IN (" + "SELECT tid FROM (SELECT pg_catalog.row_number() over (partition by %s) AS \"__ivm_row_number__\"," + "mv.ctid AS tid," + "diff.\"__ivm_count__\"" + "FROM %s AS mv, %s AS diff " + "WHERE %s) v " + "WHERE v.\"__ivm_row_number__\" OPERATOR(pg_catalog.<=) v.\"__ivm_count__\")", + matviewname, + keysbuf.data, + matviewname, deltaname_old, + match_cond);`SELECT pg_catalog.row_number()` is too generic to my taste. Maybe
pg_catalog.immv_row_number() / pg_catalog.get_immv_row_number() ?
I personally think the current query is not ideal, and unless the new window
function can simplify or improve the logic, it might not be worth creating a
new function.
6) +static void +apply_new_delta(const char *matviewname, const char *deltaname_new, + StringInfo target_list) +{ + StringInfoData querybuf; + + /* Search for matching tuples from the view and update or delete if found. */Is this comment correct? we only insert tuples here?
Seems incorrect. I'll fix it.
7)
During patch development, one should pick OIDs from range 8000-9999
I'll fix it.
== Major suggestions.
1) At first glance, working with this IVM/IMMV infrastructure feels
really unintuitive about what servers actually do for query execution.
I do think It will be much better for user experience to add more
EXPLAIN about IVM work done inside IVM triggers. This way it is much
clearer which part is working slow, so which index should be created,
etc.
Yes, as mentioned above, it would be helpful if EXPLAIN ANALYZE provided
useful information about incremental maintenance, although I don’t yet have
a clear idea of the best way to achieve this.
2) The kernel code for IVM lacks possibility to be extended for
further IVM optimizations. The one example is foreign key optimization
described here[1]. I'm not saying we should implement this within this
patchset, but we surely should pave the way for this. I don't have any
good suggestions for how to do this though.
I have read the paper you mentioned. If I understood and remember correctly,
it is based on a counting algorithm and assumes that the count is always
stored in the view or that views do not have duplicate rows. This is different
from our current approach, which allows duplicate rows, so I’m not sure whether
this optimization could be directly applied to our implementation.
(Perhaps we might need to restrict the view so that it does not contain
duplicate rows.)
In any case, I will try to reconsider the design to improve extensibility,
so that future optimizations can be more easily supported.
3) I don't really think SQL design is good. CREATE [INCREMENTAL] M.V.
is too ad-hoc. I would prefer CREATE M.V. with (maintain_incr=true).
(reloption name is just an example).
This way we can change regular M.V. to IVM and vice versa via ALTER
M.V. SET *reloptions* - a type of syntax that is already present in
PostgreSQL core.
I like the idea of using a reloption rather than adding a new keyword
to the syntax. I’ll consider changing the interface accordingly.
== Other thoughts
In OLAP databases (see [2]), IVM opens the door for 'view
exploitation' feature. That is, use IVM (which is always up-to-date)
for query execution. But current IVM implementation is not compatible
with Cloudberry Append-optimized Table Access Method. The problem is
the 'table_tuple_fetch_row_version' call, which is used by
ivm_visible_in_prestate to check tuple visibility within a snapshot. I
am trying to solve this somehow. My current idea is the following:
multiple base table modification via single statement along with tuple
deletion from base tables are features. We can error-out these cases
(at M.V. creation time) all for some TAMs, and support only insert &
truncate. However, I don't know how to check if TAM supports
'tuple_fetch_row_version' other than calling it and receiving
ERROR[3].
Thank you for sharing the information about Apache cloudberry AM.
Hmm, I am not sure whether PostgreSQL expects table_tuple_fetch_row_version
to raise an error, but if this were allowed as a table access method behavior,
some consideration would be required.
I reread this and I find this a little bit unclear. What I'm proposing
here is specifying the type of operations IVM supports on creation
time. So, one can runCREATE IVM immv1 WITH (support_deletion = true/false,
support_multiple_relation_change = true/false). Then, in the query
execution time, we just ERROR if the query leads to deletion from IVM
and support_deletion if false.
Such options indeed might enable some optimizations for certain kinds
of table access methods.
== Minor nitpicks and typos.
reshke=# insert into tt select * from generate_series(1, 1000090);
^CCancel request sent
ERROR: canceling statement due to user request
CONTEXT: SQL statement "INSERT INTO public.mv1 (i, j) SELECT i, j
FROM (SELECT diff.*, pg_catalog.generate_series(1,
diff."__ivm_count__") AS __ivm_generate_series__ FROM new_delta AS
diff) AS v"
Time: 18883.883 ms (00:18.884)This is very surprising, isn't it? We can set HINT here, to indicate
where this query comes from.
I understand this concern. It would definitely be better to properly modify
the CONTEXT of the error message. As mentioned above, doing so would require
adding some infrastructure in the logging system.
2) deleted/deleted -> updated/deleted + /* + * XXX: When using DELETE or UPDATE, we must use exclusive lock for now + * because apply_old_delta(_with_count) uses ctid to identify the tuple + * to be deleted/deleted, but doesn't work in concurrent situations.
I'll fix it.
3) Typo in rewrite_query_for_postupdate_state:
/* Retore the original RTE */
I'll fix it.
4) in apply_delta function has exactly one usage, so the 'use_count'
param is redundant, because we already pass the 'query' param, and
'use_count' is calculated from the 'query'.
Right. I'll fix it.
5) in calc_delta:
ListCell *lc = list_nth_cell(query->rtable, rte_index - 1);
RangeTblEntry *rte = (RangeTblEntry *) lfirst(lc);Should we add Assert(list_lenght(lc) == 1) here? Can there be multiple
items in this list?
I’m sorry, I didn’t quite catch your point. I believe this is meaningless
since 'lc' is not a list.
6) In get_prestate_rte:
appendStringInfo(&str,
"SELECT t.* FROM %s t"
" WHERE pg_catalog.ivm_visible_in_prestate(t.tableoid, t.ctid ,%d::pg_catalog.oid)",
relname, matviewid);Identitation issue. This will not be fixed via pg_ident run, because
this is str contant, so better so fix it by-hand.
I'll fix it.
7) in apply_new_delta_with_count:
appendStringInfo(&querybuf,
"WITH updt AS (" /* update a tuple if this exists in the view */
"UPDATE %s AS mv SET %s = mv.%s OPERATOR(pg_catalog.+) diff.%s "SET % OPERATOR(pg_catalog.=) mv.%s ?
same for append_set_clause_for_count, append_set_clause_for_sum,
append_set_clause_for_minmax
/* avg = (mv.sum - t.sum)::aggtype / (mv.count - t.count) */
appendStringInfo(buf_old,
", %s = %s OPERATOR(pg_catalog./) %s",should be
/* avg OPERATOR(pg_catalog.=) (mv.sum - t.sum)::aggtype / (mv.count -
t.count) */
appendStringInfo(buf_old,
", %s = %s OPERATOR(pg_catalog./) %s",
Here, “=” denotes assignment in the UPDATE ... SET ... command, rather
than the equality operator in pg_catalog.
One little follow-up here. Why do we do prepstate visibility the way
it is done? Can we instead export the snapshot in BEFORE trigger, save
it somewhere and use it after?
We need the state of a table before it is updated. By importing the
snapshot exported in a BEFORE trigger, we can obtain the query results
from a past state, but this applies to the entire query, not to a specific
table within the query. What we really need is the result of the query
where only a specific table is seen in its past state.
Perhaps this could be done by modifying the executor (scan nodes?) to allow
using a specified snapshot for a specified table scan, which would be similar
to Oracle’s AS OF. However, such a change would not be trivial.
Thanks to your comments and suggestions, I made a poster about this patch [1]https://2025.pgconf.dev/static/posters/poster_incremental_view_maintenance.pdf
for PGConf.dev 2025. Below is a list of open questions highlighted there:
1. Trigger-based Design: Should we avoid relying on triggers like declarative
partitioning?
2. Features Scope: Exclude aggregate, DISTINCT, and tuple duplicate supports
in the first release to simplify the patch and improve its reviewability?
3. Hidden Columns: How should they be handled?
4. Pre-update State of Table: Need infrastructure to scan a table using a
specified snapshot, instead of using the crafted sub-query?
5. Syntax: “CREATE INCREMENTAL MATERIALIZED VIEW” is tentative. Is
"CREATE MATERIALIZED VIEW … WITH (reloptions)" preferable?.
6. Other issues: EXPLAIN outputs, CONTEXT in an error message, etc.
In particular, I wonder whether it would be better to limit the scope of
the patch so that the proposal and discussion can move forward (#2).
This could help avoid some of the debates around aggregates support, hidden
columns, etc., and allow us to focus more on the core design.
Anyway, I will start rebasing the patches, reorganizing the patch set,
and applying fixes made in pg_ivm [2]https://github.com/sraoss/pg_ivm -- Yugo Nagata <nagata@sraoss.co.jp>.
Regards,
Yugo Nagata
[1]: https://2025.pgconf.dev/static/posters/poster_incremental_view_maintenance.pdf
[2]: https://github.com/sraoss/pg_ivm -- Yugo Nagata <nagata@sraoss.co.jp>
--
Yugo Nagata <nagata@sraoss.co.jp>
Hi, all
On Aug 30, 2025 at 04:04 +0800, Yugo Nagata <nagata@sraoss.co.jp>, wrote:
Anyway, I will start rebasing the patches, reorganizing the patch set,
and applying fixes made in pg_ivm [2].
First of all, we would like to express our sincere gratitude for your continuous efforts and contributions to the IVM feature.
Our AQUMV (Answer Query Using Materialized Views) functionality in Apache Cloudberry is built directly upon your foundational work.
We recently encountered an issue in one of our customer's production environments.
The problem occurs in the function CreateIvmTriggersOnBaseTablesRecurse(), where a Bitmapset relidsis used to record rte->relid.
```
case T_RangeTblRef:
{
int rti = ((RangeTblRef *) node)->rtindex;
RangeTblEntry *rte = rt_fetch(rti, qry->rtable);
if (rte->rtekind == RTE_RELATION && !bms_is_member(rte->relid, *relids))
{
CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_INSERT, TRIGGER_TYPE_BEFORE, ex_lock);
CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_DELETE, TRIGGER_TYPE_BEFORE, ex_lock);
CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_UPDATE, TRIGGER_TYPE_BEFORE, ex_lock);
CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_TRUNCATE, TRIGGER_TYPE_BEFORE, true);
CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_INSERT, TRIGGER_TYPE_AFTER, ex_lock);
CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_DELETE, TRIGGER_TYPE_AFTER, ex_lock);
CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_UPDATE, TRIGGER_TYPE_AFTER, ex_lock);
CreateIvmTrigger(rte->relid, matviewOid, TRIGGER_TYPE_TRUNCATE, TRIGGER_TYPE_AFTER, true);
*relids = bms_add_member(*relids, rte->relid);
}
}
```
However, the Bitmapset structure is typically designed to store small integers (such as relation index), whereas rte->relidrepresents the Oid of a relation.
For instance, when a table is created immediately after initializing a new cluster, its Oid might be 17019. Storing such a value in a Bitmapset consumes approximately 0.2MB of memory when creating an IVM.
(gdb) p bmsToString(((Bitmapset *) relids))
$13 = 0x5643d7bbb070 "(b 17019)"
(gdb) p *((Bitmapset *) relids)
$14 = {nwords = 266, words = 0x5643d79d1bd8}
This memory usage becomes even more significant when dealing with larger Oids.
Moreover, a more critical issue arises when the Oid exceeds 0x7FFFFFFF. Since Oid is an unsigned integer, but the Bitmapset expects signed integers, an assertion failure will occur in such cases.
We have encountered similar requirements in our own scenarios and eventually switched to using a HTAB implementation. Hope this proves useful for your work.
--
Zhang Mingli
HashData