Change the schema from pg_catalog to pgivm (#116)

Previously, pg_upgrade failed due to the permission denied
because the pg_ivm_immv catalog was in the pg_catalog catalog
(Issue #79). To fix this, all objects created by pg_ivm are
moved to theschema pgivm, which is also created by pg_ivm.

pg_ivm is still not relocatable and this must be installed
to the pgivm schema because the catalog and some internal
functions are referred to unqualified by the schema name
from the pg_ivm module. In future, this might be able to
relocatable during installation, though.

This commit affects compatibility with previous releases.
To allow to access objects like create_immv function as
previous, you need to qualify them with the schema name
or setup search_path properly.
This commit is contained in:
Yugo Nagata 2025-02-17 12:07:21 +09:00 committed by GitHub
parent be13c952c2
commit 417c291454
No known key found for this signature in database
GPG key ID: B5690EEEBB952194
15 changed files with 353 additions and 266 deletions

View file

@ -15,7 +15,8 @@ DATA = pg_ivm--1.0.sql \
pg_ivm--1.0--1.1.sql pg_ivm--1.1--1.2.sql pg_ivm--1.2--1.3.sql \ pg_ivm--1.0--1.1.sql pg_ivm--1.1--1.2.sql pg_ivm--1.2--1.3.sql \
pg_ivm--1.3--1.4.sql pg_ivm--1.4--1.5.sql pg_ivm--1.5--1.6.sql \ pg_ivm--1.3--1.4.sql pg_ivm--1.4--1.5.sql pg_ivm--1.5--1.6.sql \
pg_ivm--1.6--1.7.sql pg_ivm--1.7--1.8.sql pg_ivm--1.8--1.9.sql \ pg_ivm--1.6--1.7.sql pg_ivm--1.7--1.8.sql pg_ivm--1.8--1.9.sql \
pg_ivm--1.9--1.10.sql pg_ivm--1.9--1.10.sql \
pg_ivm--1.10.sql
REGRESS = pg_ivm create_immv refresh_immv REGRESS = pg_ivm create_immv refresh_immv

View file

@ -13,7 +13,7 @@ There are two approaches with regard to timing of view maintenance: immediate an
We call a materialized view supporting IVM an **Incrementally Maintainable Materialized View (IMMV)**. To create IMMV, you have to call `create_immv` function with a relation name and a view definition query. For example: We call a materialized view supporting IVM an **Incrementally Maintainable Materialized View (IMMV)**. To create IMMV, you have to call `create_immv` function with a relation name and a view definition query. For example:
```sql ```sql
SELECT create_immv('myview', 'SELECT * FROM mytab'); SELECT pgivm.create_immv('myview', 'SELECT * FROM mytab');
``` ```
creates an IMMV with name 'myview' defined as `SELECT * FROM mytab`. This is corresponding to the following command to create a normal materialized view; creates an IMMV with name 'myview' defined as `SELECT * FROM mytab`. This is corresponding to the following command to create a normal materialized view;
@ -25,7 +25,7 @@ CREATE MATERIALIZED VIEW myview AS SELECT * FROM mytab;
When an IMMV is created, some triggers are automatically created so that the view's contents are immediately updated when its base tables are modified. When an IMMV is created, some triggers are automatically created so that the view's contents are immediately updated when its base tables are modified.
```sql ```sql
postgres=# SELECT create_immv('m', 'SELECT * FROM t0'); postgres=# SELECT pgivm.create_immv('m', 'SELECT * FROM t0');
NOTICE: could not create an index on immv "m" automatically NOTICE: could not create an index on immv "m" automatically
DETAIL: This target list does not have all the primary key columns, or this view does not contain DISTINCT clause. DETAIL: This target list does not have all the primary key columns, or this view does not contain DISTINCT clause.
HINT: Create an index on the immv for efficient incremental maintenance. HINT: Create an index on the immv for efficient incremental maintenance.
@ -57,6 +57,7 @@ postgres=# SELECT * FROM m; -- automatically updated
Note that if you use PostgreSQL 17 or later, during automatic maintenance of an IMMV, the `search_path` is temporarily changed to `pg_catalog, pg_temp`. Note that if you use PostgreSQL 17 or later, during automatic maintenance of an IMMV, the `search_path` is temporarily changed to `pg_catalog, pg_temp`.
## Installation ## Installation
To install `pg_ivm`, execute this in the module's directory: To install `pg_ivm`, execute this in the module's directory:
```shell ```shell
@ -69,16 +70,17 @@ If you installed PostgreSQL from rpm or deb, you will need the devel package (fo
And, execute CREATE EXTENSION comand. And, execute CREATE EXTENSION comand.
``` ```sql
CREATE EXTENSION pg_ivm; CREATE EXTENSION pg_ivm;
``` ```
### RPM packages and yum repository ### RPM packages and yum repository
RPM packages of pg_ivm are available from the [PostgreSQL yum repository](https://yum.postgresql.org/). See the [instruction](https://yum.postgresql.org/howto/) for details. Note that we are not the maintainer of this yum repository and RPMs for pg_ivm in it may be not always latest. RPM packages of pg_ivm are available from the [PostgreSQL yum repository](https://yum.postgresql.org/). See the [instruction](https://yum.postgresql.org/howto/) for details. Note that we are not the maintainer of this yum repository and RPMs for pg_ivm in it may be not always latest.
## Objects ## Objects
When `pg_ivm` is installed, the following objects are created. When `pg_ivm` is installed, the following objects are created in the schema `pgivm`.
### Functions ### Functions
@ -86,7 +88,7 @@ When `pg_ivm` is installed, the following objects are created.
Use `create_immv` function to create IMMV. Use `create_immv` function to create IMMV.
``` ```
create_immv(immv_name text, view_definition text) RETURNS bigint pgivim.create_immv(immv_name text, view_definition text) RETURNS bigint
``` ```
`create_immv` defines a new IMMV of a query. A table of the name `immv_name` is created and a query specified by `view_definition` is executed and used to populate the IMMV. The query is stored in `pg_ivm_immv`, so that it can be refreshed later upon incremental view maintenance. `create_immv` returns the number of rows in the created IMMV. `create_immv` defines a new IMMV of a query. A table of the name `immv_name` is created and a query specified by `view_definition` is executed and used to populate the IMMV. The query is stored in `pg_ivm_immv`, so that it can be refreshed later upon incremental view maintenance. `create_immv` returns the number of rows in the created IMMV.
@ -98,7 +100,7 @@ Note that if you use PostgreSQL 17 or later, while `create_immv` is running, the
Use `refresh_immv` function to refresh IMMV. Use `refresh_immv` function to refresh IMMV.
``` ```
refresh_immv(immv_name text, with_data bool) RETURNS bigint pgivm.refresh_immv(immv_name text, with_data bool) RETURNS bigint
``` ```
`refresh_immv` completely replaces the contents of an IMMV as `REFRESH MATERIALIZED VIEW` command does for a materialized view. To execute this function you must be the owner of the IMMV (with PostgreSQL 16 or earlier) or have the `MAINTAIN` privilege on the IMMV (with PostgreSQL 17 or later). The old contents are discarded. `refresh_immv` completely replaces the contents of an IMMV as `REFRESH MATERIALIZED VIEW` command does for a materialized view. To execute this function you must be the owner of the IMMV (with PostgreSQL 16 or earlier) or have the `MAINTAIN` privilege on the IMMV (with PostgreSQL 17 or later). The old contents are discarded.
@ -111,12 +113,12 @@ Note that if you use PostgreSQL 17 or later, while `refresh_immv` is running, th
`get_immv_def` reconstructs the underlying SELECT command for an IMMV. (This is a decompiled reconstruction, not the original text of the command.) `get_immv_def` reconstructs the underlying SELECT command for an IMMV. (This is a decompiled reconstruction, not the original text of the command.)
``` ```
get_immv_def(immv regclass) RETURNS text pgivm.get_immv_def(immv regclass) RETURNS text
``` ```
### IMMV metadata catalog ### IMMV metadata catalog
The catalog `pg_ivm_immv` stores IMMV information. The catalog `pgivm.pg_ivm_immv` stores IMMV information.
|Name|Type|Description| |Name|Type|Description|
|:---|:---|:---| |:---|:---|:---|
@ -153,7 +155,7 @@ Time: 20575.721 ms (00:20.576)
On the other hand, after creating IMMV with the same view definition as below: On the other hand, after creating IMMV with the same view definition as below:
``` ```
test=# SELECT create_immv('immv', test=# SELECT pgivm.create_immv('immv',
'SELECT a.aid, b.bid, a.abalance, b.bbalance 'SELECT a.aid, b.bid, a.abalance, b.bbalance
FROM pgbench_accounts a JOIN pgbench_branches b USING(bid)'); FROM pgbench_accounts a JOIN pgbench_branches b USING(bid)');
NOTICE: created index "immv_index" on immv "immv" NOTICE: created index "immv_index" on immv "immv"

View file

@ -734,7 +734,8 @@ CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock
ex_lock = true; ex_lock = true;
ivm_trigger->funcname = ivm_trigger->funcname =
(timing == TRIGGER_TYPE_BEFORE ? SystemFuncName("IVM_immediate_before") : SystemFuncName("IVM_immediate_maintenance")); (timing == TRIGGER_TYPE_BEFORE ?
PgIvmFuncName("IVM_immediate_before") : PgIvmFuncName("IVM_immediate_maintenance"));
ivm_trigger->columns = NIL; ivm_trigger->columns = NIL;
ivm_trigger->transitionRels = transitionRels; ivm_trigger->transitionRels = transitionRels;

View file

@ -1,22 +1,22 @@
CREATE TABLE t (i int PRIMARY KEY); CREATE TABLE t (i int PRIMARY KEY);
INSERT INTO t SELECT generate_series(1, 100); INSERT INTO t SELECT generate_series(1, 100);
SELECT create_immv('mv', 'SELECT * FROM t'); SELECT pgivm.create_immv('mv', 'SELECT * FROM t');
NOTICE: created index "mv_index" on immv "mv" NOTICE: created index "mv_index" on immv "mv"
create_immv create_immv
------------- -------------
100 100
(1 row) (1 row)
SELECT create_immv(' mv2 ( x ) ', 'SELECT * FROM t WHERE i%2 = 0'); SELECT pgivm.create_immv(' mv2 ( x ) ', 'SELECT * FROM t WHERE i%2 = 0');
NOTICE: created index "mv2_index" on immv "mv2" NOTICE: created index "mv2_index" on immv "mv2"
create_immv create_immv
------------- -------------
50 50
(1 row) (1 row)
SELECT create_immv('mv3', 'WITH d AS (DELETE FROM t RETURNING NULL) SELECT * FROM t'); SELECT pgivm.create_immv('mv3', 'WITH d AS (DELETE FROM t RETURNING NULL) SELECT * FROM t');
ERROR: materialized views must not use data-modifying statements in WITH ERROR: materialized views must not use data-modifying statements in WITH
SELECT immvrelid, get_immv_def(immvrelid) FROM pg_ivm_immv ORDER BY 1; SELECT immvrelid, pgivm.get_immv_def(immvrelid) FROM pgivm.pg_ivm_immv ORDER BY 1;
immvrelid | get_immv_def immvrelid | get_immv_def
-----------+----------------------- -----------+-----------------------
mv | SELECT i + mv | SELECT i +
@ -27,20 +27,20 @@ SELECT immvrelid, get_immv_def(immvrelid) FROM pg_ivm_immv ORDER BY 1;
(2 rows) (2 rows)
-- contain immv -- contain immv
SELECT create_immv('mv_in_immv01', 'SELECT i FROM mv'); SELECT pgivm.create_immv('mv_in_immv01', 'SELECT i FROM mv');
ERROR: including IMMV in definition is not supported on incrementally maintainable materialized view ERROR: including IMMV in definition is not supported on incrementally maintainable materialized view
SELECT create_immv('mv_in_immv02', 'SELECT t.i FROM t INNER JOIN mv2 ON t.i = mv2.x'); SELECT pgivm.create_immv('mv_in_immv02', 'SELECT t.i FROM t INNER JOIN mv2 ON t.i = mv2.x');
ERROR: including IMMV in definition is not supported on incrementally maintainable materialized view ERROR: including IMMV in definition is not supported on incrementally maintainable materialized view
-- SQL other than SELECT -- SQL other than SELECT
SELECT create_immv('mv_in_create', 'CREATE TABLE in_create(i int)'); SELECT pgivm.create_immv('mv_in_create', 'CREATE TABLE in_create(i int)');
ERROR: view definition must specify SELECT statement ERROR: view definition must specify SELECT statement
SELECT create_immv('mv_in_insert', 'INSERT INTO t VALUES(10)'); SELECT pgivm.create_immv('mv_in_insert', 'INSERT INTO t VALUES(10)');
ERROR: view definition must specify SELECT statement ERROR: view definition must specify SELECT statement
SELECT create_immv('mv_in_update', 'UPDATE t SET i = 10'); SELECT pgivm.create_immv('mv_in_update', 'UPDATE t SET i = 10');
ERROR: view definition must specify SELECT statement ERROR: view definition must specify SELECT statement
SELECT create_immv('mv_in_delete', 'DELETE FROM t'); SELECT pgivm.create_immv('mv_in_delete', 'DELETE FROM t');
ERROR: view definition must specify SELECT statement ERROR: view definition must specify SELECT statement
SELECT create_immv('mv_in_drop', 'DROP TABLE t'); SELECT pgivm.create_immv('mv_in_drop', 'DROP TABLE t');
ERROR: view definition must specify SELECT statement ERROR: view definition must specify SELECT statement
DROP TABLE t; DROP TABLE t;
ERROR: cannot drop table t because other objects depend on it ERROR: cannot drop table t because other objects depend on it
@ -48,7 +48,7 @@ DETAIL: table mv depends on table t
table mv2 depends on table t table mv2 depends on table t
HINT: Use DROP ... CASCADE to drop the dependent objects too. HINT: Use DROP ... CASCADE to drop the dependent objects too.
DROP TABLE mv; DROP TABLE mv;
SELECT immvrelid, get_immv_def(immvrelid) FROM pg_ivm_immv ORDER BY 1; SELECT immvrelid, pgivm.get_immv_def(immvrelid) FROM pgivm.pg_ivm_immv ORDER BY 1;
immvrelid | get_immv_def immvrelid | get_immv_def
-----------+----------------------- -----------+-----------------------
mv2 | SELECT i AS x + mv2 | SELECT i AS x +
@ -57,7 +57,7 @@ SELECT immvrelid, get_immv_def(immvrelid) FROM pg_ivm_immv ORDER BY 1;
(1 row) (1 row)
DROP TABLE mv2; DROP TABLE mv2;
SELECT immvrelid, get_immv_def(immvrelid) FROM pg_ivm_immv ORDER BY 1; SELECT immvrelid, pgivm.get_immv_def(immvrelid) FROM pgivm.pg_ivm_immv ORDER BY 1;
immvrelid | get_immv_def immvrelid | get_immv_def
-----------+-------------- -----------+--------------
(0 rows) (0 rows)

View file

@ -14,7 +14,7 @@ INSERT INTO mv_base_b VALUES
(2,102), (2,102),
(3,103), (3,103),
(4,104); (4,104);
SELECT create_immv('mv_ivm_1', 'SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i)'); SELECT pgivm.create_immv('mv_ivm_1', 'SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i)');
NOTICE: could not create an index on immv "mv_ivm_1" automatically NOTICE: could not create an index on immv "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. 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 immv for efficient incremental maintenance. HINT: Create an index on the immv for efficient incremental maintenance.
@ -97,7 +97,7 @@ ROLLBACK;
BEGIN; BEGIN;
CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql' CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql'
AS 'SELECT 1' IMMUTABLE; AS 'SELECT 1' IMMUTABLE;
SELECT create_immv('mv_ivm_func', 'SELECT * FROM ivm_func()'); SELECT pgivm.create_immv('mv_ivm_func', 'SELECT * FROM ivm_func()');
NOTICE: could not create an index on immv "mv_ivm_func" automatically NOTICE: could not create an index on immv "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. 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 immv for efficient incremental maintenance. HINT: Create an index on the immv for efficient incremental maintenance.
@ -106,7 +106,7 @@ HINT: Create an index on the immv for efficient incremental maintenance.
1 1
(1 row) (1 row)
SELECT create_immv('mv_ivm_no_tbl', 'SELECT 1'); SELECT pgivm.create_immv('mv_ivm_no_tbl', 'SELECT 1');
NOTICE: could not create an index on immv "mv_ivm_no_tbl" automatically NOTICE: could not create an index on immv "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. 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 immv for efficient incremental maintenance. HINT: Create an index on the immv for efficient incremental maintenance.
@ -118,7 +118,7 @@ HINT: Create an index on the immv for efficient incremental maintenance.
ROLLBACK; ROLLBACK;
-- result of materialized view have DISTINCT clause or the duplicate result. -- result of materialized view have DISTINCT clause or the duplicate result.
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_duplicate', 'SELECT j FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm_duplicate', 'SELECT j FROM mv_base_a');
NOTICE: could not create an index on immv "mv_ivm_duplicate" automatically NOTICE: could not create an index on immv "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. 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 immv for efficient incremental maintenance. HINT: Create an index on the immv for efficient incremental maintenance.
@ -127,7 +127,7 @@ HINT: Create an index on the immv for efficient incremental maintenance.
5 5
(1 row) (1 row)
SELECT create_immv('mv_ivm_distinct', 'SELECT DISTINCT j FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm_distinct', 'SELECT DISTINCT j FROM mv_base_a');
NOTICE: created index "mv_ivm_distinct_index" on immv "mv_ivm_distinct" NOTICE: created index "mv_ivm_distinct_index" on immv "mv_ivm_distinct"
create_immv create_immv
------------- -------------
@ -180,7 +180,7 @@ SELECT * FROM mv_ivm_distinct ORDER BY 1;
ROLLBACK; ROLLBACK;
-- support SUM(), COUNT() and AVG() aggregate functions -- support SUM(), COUNT() and AVG() aggregate functions
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_agg', 'SELECT i, SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i'); SELECT pgivm.create_immv('mv_ivm_agg', 'SELECT i, SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i');
NOTICE: created index "mv_ivm_agg_index" on immv "mv_ivm_agg" NOTICE: created index "mv_ivm_agg_index" on immv "mv_ivm_agg"
create_immv create_immv
------------- -------------
@ -233,7 +233,7 @@ SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
ROLLBACK; ROLLBACK;
-- support COUNT(*) aggregate function -- support COUNT(*) aggregate function
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_agg', 'SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i'); SELECT pgivm.create_immv('mv_ivm_agg', 'SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i');
NOTICE: created index "mv_ivm_agg_index" on immv "mv_ivm_agg" NOTICE: created index "mv_ivm_agg_index" on immv "mv_ivm_agg"
create_immv create_immv
------------- -------------
@ -264,7 +264,7 @@ SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
ROLLBACK; ROLLBACK;
-- TRUNCATE a base table in aggregate views -- TRUNCATE a base table in aggregate views
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_agg', 'SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i'); SELECT pgivm.create_immv('mv_ivm_agg', 'SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i');
NOTICE: created index "mv_ivm_agg_index" on immv "mv_ivm_agg" NOTICE: created index "mv_ivm_agg_index" on immv "mv_ivm_agg"
create_immv create_immv
------------- -------------
@ -285,7 +285,7 @@ SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
ROLLBACK; ROLLBACK;
-- support aggregate functions without GROUP clause -- support aggregate functions without GROUP clause
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_group', 'SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm_group', 'SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a');
create_immv create_immv
------------- -------------
1 1
@ -314,7 +314,7 @@ SELECT * FROM mv_ivm_group ORDER BY 1;
ROLLBACK; ROLLBACK;
-- TRUNCATE a base table in aggregate views without GROUP clause -- TRUNCATE a base table in aggregate views without GROUP clause
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_group', 'SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm_group', 'SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a');
create_immv create_immv
------------- -------------
1 1
@ -336,7 +336,7 @@ SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
ROLLBACK; ROLLBACK;
-- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect. -- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect.
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_avg_bug', 'SELECT i, SUM(j), COUNT(j), AVG(j) FROM mv_base_A GROUP BY i'); SELECT pgivm.create_immv('mv_ivm_avg_bug', 'SELECT i, SUM(j), COUNT(j), AVG(j) FROM mv_base_A GROUP BY i');
NOTICE: created index "mv_ivm_avg_bug_index" on immv "mv_ivm_avg_bug" NOTICE: created index "mv_ivm_avg_bug_index" on immv "mv_ivm_avg_bug"
create_immv create_immv
------------- -------------
@ -383,7 +383,7 @@ SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
ROLLBACK; ROLLBACK;
-- support MIN(), MAX() aggregate functions -- support MIN(), MAX() aggregate functions
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_min_max(i, min_j, max_j)', 'SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i'); SELECT pgivm.create_immv('mv_ivm_min_max(i, min_j, max_j)', 'SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i');
NOTICE: created index "mv_ivm_min_max_index" on immv "mv_ivm_min_max" NOTICE: created index "mv_ivm_min_max_index" on immv "mv_ivm_min_max"
create_immv create_immv
------------- -------------
@ -430,7 +430,7 @@ SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
ROLLBACK; ROLLBACK;
-- support MIN(), MAX() aggregate functions without GROUP clause -- support MIN(), MAX() aggregate functions without GROUP clause
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_min_max(min_j, max_j)', 'SELECT MIN(j), MAX(j) FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm_min_max(min_j, max_j)', 'SELECT MIN(j), MAX(j) FROM mv_base_a');
create_immv create_immv
------------- -------------
1 1
@ -467,7 +467,7 @@ SELECT * FROM mv_ivm_min_max;
ROLLBACK; ROLLBACK;
-- Test MIN/MAX after search_path change -- Test MIN/MAX after search_path change
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_min', 'SELECT MIN(j) FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm_min', 'SELECT MIN(j) FROM mv_base_a');
create_immv create_immv
------------- -------------
1 1
@ -501,7 +501,7 @@ SELECT * FROM mv_ivm_min ORDER BY 1,2,3;
ROLLBACK; ROLLBACK;
-- aggregate views with column names specified -- aggregate views with column names specified
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_agg(a)', 'SELECT i, SUM(j) FROM mv_base_a GROUP BY i'); SELECT pgivm.create_immv('mv_ivm_agg(a)', 'SELECT i, SUM(j) FROM mv_base_a GROUP BY i');
NOTICE: created index "mv_ivm_agg_index" on immv "mv_ivm_agg" NOTICE: created index "mv_ivm_agg_index" on immv "mv_ivm_agg"
create_immv create_immv
------------- -------------
@ -523,7 +523,7 @@ SELECT * FROM mv_ivm_agg ORDER BY 1,2;
ROLLBACK; ROLLBACK;
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_agg(a,b)', 'SELECT i, SUM(j) FROM mv_base_a GROUP BY i'); SELECT pgivm.create_immv('mv_ivm_agg(a,b)', 'SELECT i, SUM(j) FROM mv_base_a GROUP BY i');
NOTICE: created index "mv_ivm_agg_index" on immv "mv_ivm_agg" NOTICE: created index "mv_ivm_agg_index" on immv "mv_ivm_agg"
create_immv create_immv
------------- -------------
@ -545,14 +545,14 @@ SELECT * FROM mv_ivm_agg ORDER BY 1,2;
ROLLBACK; ROLLBACK;
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_agg(a,b,c)', 'SELECT i, SUM(j) FROM mv_base_a GROUP BY i'); SELECT pgivm.create_immv('mv_ivm_agg(a,b,c)', 'SELECT i, SUM(j) FROM mv_base_a GROUP BY i');
ERROR: too many column names were specified ERROR: too many column names were specified
ROLLBACK; ROLLBACK;
-- support self join view and multiple change on the same table -- support self join view and multiple change on the same table
BEGIN; BEGIN;
CREATE TABLE base_t (i int, v int); CREATE TABLE base_t (i int, v int);
INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30); INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
SELECT create_immv('mv_self(v1, v2)', SELECT pgivm.create_immv('mv_self(v1, v2)',
'SELECT t1.v, t2.v FROM base_t AS t1 JOIN base_t AS t2 ON t1.i = t2.i'); '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 immv "mv_self" automatically NOTICE: could not create an index on immv "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. DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
@ -626,7 +626,7 @@ CREATE TABLE base_r (i int, v int);
CREATE TABLE base_s (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_r VALUES (1, 10), (2, 20), (3, 30);
INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300); INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300);
SELECT create_immv('mv(v1, v2)', 'SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i)');; SELECT pgivm.create_immv('mv(v1, v2)', 'SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i)');;
NOTICE: could not create an index on immv "mv" automatically NOTICE: could not create an index on immv "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. 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 immv for efficient incremental maintenance. HINT: Create an index on the immv for efficient incremental maintenance.
@ -671,7 +671,7 @@ 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); 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 ri1 VALUES (1),(2),(3);
INSERT INTO ri2 VALUES (1),(2),(3); INSERT INTO ri2 VALUES (1),(2),(3);
SELECT create_immv('mv_ri(i1, i2)', 'SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i)'); SELECT pgivm.create_immv('mv_ri(i1, i2)', 'SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i)');
NOTICE: created index "mv_ri_index" on immv "mv_ri" NOTICE: created index "mv_ri_index" on immv "mv_ri"
create_immv create_immv
------------- -------------
@ -698,7 +698,7 @@ SELECT * FROM mv_ri ORDER BY i2;
ROLLBACK; ROLLBACK;
-- support subquery for using EXISTS() -- support subquery for using EXISTS()
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_exists_subquery', 'SELECT a.i, a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i)'); SELECT pgivm.create_immv('mv_ivm_exists_subquery', 'SELECT a.i, a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i)');
NOTICE: could not create an index on immv "mv_ivm_exists_subquery" automatically NOTICE: could not create an index on immv "mv_ivm_exists_subquery" automatically
DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause. 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 immv for efficient incremental maintenance. HINT: Create an index on the immv for efficient incremental maintenance.
@ -707,7 +707,7 @@ HINT: Create an index on the immv for efficient incremental maintenance.
4 4
(1 row) (1 row)
SELECT create_immv('mv_ivm_exists_subquery2', 'SELECT a.i,a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) AND a.i > 2'); SELECT pgivm.create_immv('mv_ivm_exists_subquery2', 'SELECT a.i,a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) AND a.i > 2');
NOTICE: could not create an index on immv "mv_ivm_exists_subquery2" automatically NOTICE: could not create an index on immv "mv_ivm_exists_subquery2" automatically
DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause. 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 immv for efficient incremental maintenance. HINT: Create an index on the immv for efficient incremental maintenance.
@ -829,7 +829,7 @@ SELECT * FROM mv_ivm_exists_subquery2 ORDER BY i, j;
(4 rows) (4 rows)
--- EXISTS subquery with tuple duplication and DISTINCT --- EXISTS subquery with tuple duplication and DISTINCT
SELECT create_immv('mv_ivm_exists_subquery_distinct', 'SELECT DISTINCT a.i, a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i)'); SELECT pgivm.create_immv('mv_ivm_exists_subquery_distinct', 'SELECT DISTINCT a.i, a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i)');
NOTICE: created index "mv_ivm_exists_subquery_distinct_index" on immv "mv_ivm_exists_subquery_distinct" NOTICE: created index "mv_ivm_exists_subquery_distinct_index" on immv "mv_ivm_exists_subquery_distinct"
create_immv create_immv
------------- -------------
@ -861,7 +861,7 @@ SELECT * FROM mv_ivm_exists_subquery_distinct ORDER BY i, j;
ROLLBACK; ROLLBACK;
-- support simple subquery in FROM clause -- support simple subquery in FROM clause
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_subquery', 'SELECT a.i,a.j FROM mv_base_a a,( SELECT * FROM mv_base_b) b WHERE a.i = b.i'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT a.i,a.j FROM mv_base_a a,( SELECT * FROM mv_base_b) b WHERE a.i = b.i');
NOTICE: could not create an index on immv "mv_ivm_subquery" automatically NOTICE: could not create an index on immv "mv_ivm_subquery" automatically
DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause. 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 immv for efficient incremental maintenance. HINT: Create an index on the immv for efficient incremental maintenance.
@ -885,48 +885,48 @@ SELECT * FROM mv_ivm_subquery ORDER BY i,j;
ROLLBACK; ROLLBACK;
-- disallow non-simple subqueries -- disallow non-simple subqueries
SELECT create_immv('mv_ivm_subquery', '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'); SELECT pgivm.create_immv('mv_ivm_subquery', '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: aggregate functions in nested query are not supported on incrementally maintainable materialized view ERROR: aggregate functions in nested query are not supported on incrementally maintainable materialized view
SELECT create_immv('mv_ivm_subquery', 'SELECT a.i,a.j FROM mv_base_a a, (SELECT DISTINCT i FROM mv_base_b) b WHERE a.i = b.i'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT a.i,a.j FROM mv_base_a a, (SELECT DISTINCT i FROM mv_base_b) b WHERE a.i = b.i');
ERROR: DISTINCT clause in nested query are not supported on incrementally maintainable materialized view ERROR: DISTINCT clause in nested query are not supported on incrementally maintainable materialized view
SELECT create_immv('mv_ivm_subquery', 'SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 )'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 )');
ERROR: this query is not allowed on incrementally maintainable materialized view ERROR: this query is not allowed on incrementally maintainable materialized view
HINT: sublink only supports subquery with EXISTS clause in WHERE clause HINT: sublink only supports subquery with EXISTS clause in WHERE clause
SELECT create_immv('mv_ivm_subquery', 'SELECT i,j, (SELECT k FROM mv_base_b LIMIT 1) FROM mv_base_a a'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT i,j, (SELECT k FROM mv_base_b LIMIT 1) FROM mv_base_a a');
ERROR: this query is not allowed on incrementally maintainable materialized view ERROR: this query is not allowed on incrementally maintainable materialized view
HINT: sublink only supports subquery with EXISTS clause in WHERE clause HINT: sublink only supports subquery with EXISTS clause in WHERE clause
SELECT create_immv('mv_ivm_subquery', 'SELECT i,j, (SELECT k FROM mv_base_b LIMIT 1) + 1 FROM mv_base_a a'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT i,j, (SELECT k FROM mv_base_b LIMIT 1) + 1 FROM mv_base_a a');
ERROR: this query is not allowed on incrementally maintainable materialized view ERROR: this query is not allowed on incrementally maintainable materialized view
HINT: sublink only supports subquery with EXISTS clause in WHERE clause HINT: sublink only supports subquery with EXISTS clause in WHERE clause
SELECT create_immv('mv_ivm_subquery', 'SELECT * FROM generate_series(1, (SELECT k FROM mv_base_b LIMIT 1)) AS v'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT * FROM generate_series(1, (SELECT k FROM mv_base_b LIMIT 1)) AS v');
ERROR: this query is not allowed on incrementally maintainable materialized view ERROR: this query is not allowed on incrementally maintainable materialized view
HINT: sublink only supports subquery with EXISTS clause in WHERE clause HINT: sublink only supports subquery with EXISTS clause in WHERE clause
SELECT create_immv('mv_ivm_subquery', 'SELECT a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i)'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i)');
ERROR: this query is not allowed on incrementally maintainable materialized view ERROR: this query is not allowed on incrementally maintainable materialized view
HINT: targetlist must contain vars that are referred to in EXISTS subquery HINT: targetlist must contain vars that are referred to in EXISTS subquery
SELECT create_immv('mv_ivm_subquery', '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 > 2'); SELECT pgivm.create_immv('mv_ivm_subquery', '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 > 2');
ERROR: this query is not allowed on incrementally maintainable materialized view ERROR: this query is not allowed on incrementally maintainable materialized view
HINT: OR or NOT conditions and EXISTS condition can not be used together HINT: OR or NOT conditions and EXISTS condition can not be used together
SELECT create_immv('mv_ivm_subquery', 'SELECT a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_a a2 WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a2.i = b.i))'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_a a2 WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a2.i = b.i))');
ERROR: nested sublink is not supported on incrementally maintainable materialized view ERROR: nested sublink is not supported on incrementally maintainable materialized view
SELECT create_immv('mv_ivm_subquery', 'SELECT EXISTS(SELECT 1 from mv_base_b) FROM mv_base_a a'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT EXISTS(SELECT 1 from mv_base_b) FROM mv_base_a a');
ERROR: this query is not allowed on incrementally maintainable materialized view ERROR: this query is not allowed on incrementally maintainable materialized view
HINT: sublink only supports subquery with EXISTS clause in WHERE clause HINT: sublink only supports subquery with EXISTS clause in WHERE clause
SELECT create_immv('mv_ivm_subquery', 'SELECT false OR EXISTS(SELECT 1 FROM mv_base_a) FROM mv_base_b'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT false OR EXISTS(SELECT 1 FROM mv_base_a) FROM mv_base_b');
ERROR: this query is not allowed on incrementally maintainable materialized view ERROR: this query is not allowed on incrementally maintainable materialized view
HINT: OR or NOT conditions and EXISTS condition can not be used together HINT: OR or NOT conditions and EXISTS condition can not be used together
SELECT create_immv('mv_ivm_subquery', 'SELECT * FROM generate_series(1, CASE EXISTS(SELECT 1 FROM mv_base_a) WHEN true THEN 100 ELSE 10 END), mv_base_b'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT * FROM generate_series(1, CASE EXISTS(SELECT 1 FROM mv_base_a) WHEN true THEN 100 ELSE 10 END), mv_base_b');
ERROR: this query is not allowed on incrementally maintainable materialized view ERROR: this query is not allowed on incrementally maintainable materialized view
HINT: sublink only supports subquery with EXISTS clause in WHERE clause HINT: sublink only supports subquery with EXISTS clause in WHERE clause
SELECT create_immv('mv_ivm_subquery', 'SELECT * FROM mv_base_a a WHERE CASE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) WHEN true THEN false ELSE true END'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT * FROM mv_base_a a WHERE CASE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) WHEN true THEN false ELSE true END');
ERROR: this query is not allowed on incrementally maintainable materialized view ERROR: this query is not allowed on incrementally maintainable materialized view
HINT: sublink only supports subquery with EXISTS clause in WHERE clause HINT: sublink only supports subquery with EXISTS clause in WHERE clause
SELECT create_immv('mv_ivm_subquery', 'SELECT * FROM mv_base_a a WHERE true and CASE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) WHEN true THEN false ELSE true END'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT * FROM mv_base_a a WHERE true and CASE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) WHEN true THEN false ELSE true END');
ERROR: this query is not allowed on incrementally maintainable materialized view ERROR: this query is not allowed on incrementally maintainable materialized view
HINT: sublink only supports subquery with EXISTS clause in WHERE clause HINT: sublink only supports subquery with EXISTS clause in WHERE clause
-- support join subquery in FROM clause -- support join subquery in FROM clause
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_join_subquery', 'SELECT i, j, k FROM ( SELECT i, a.j, b.k FROM mv_base_b b INNER JOIN mv_base_a a USING(i)) tmp'); SELECT pgivm.create_immv('mv_ivm_join_subquery', 'SELECT i, j, k FROM ( SELECT i, a.j, b.k FROM mv_base_b b INNER JOIN mv_base_a a USING(i)) tmp');
NOTICE: could not create an index on immv "mv_ivm_join_subquery" automatically NOTICE: could not create an index on immv "mv_ivm_join_subquery" automatically
DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause. 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 immv for efficient incremental maintenance. HINT: Create an index on the immv for efficient incremental maintenance.
@ -959,7 +959,7 @@ SELECT * FROM mv_ivm_join_subquery ORDER BY i,j,k;
ROLLBACK; ROLLBACK;
BEGIN; BEGIN;
-- nested subquery -- nested subquery
SELECT create_immv('mv_ivm_join_subquery', 'SELECT i, j, k FROM ( SELECT i, a.j, b.k FROM mv_base_b b INNER JOIN (SELECT * FROM mv_base_a) a USING(i)) tmp'); SELECT pgivm.create_immv('mv_ivm_join_subquery', 'SELECT i, j, k FROM ( SELECT i, a.j, b.k FROM mv_base_b b INNER JOIN (SELECT * FROM mv_base_a) a USING(i)) tmp');
NOTICE: could not create an index on immv "mv_ivm_join_subquery" automatically NOTICE: could not create an index on immv "mv_ivm_join_subquery" automatically
DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause. 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 immv for efficient incremental maintenance. HINT: Create an index on the immv for efficient incremental maintenance.
@ -992,7 +992,7 @@ SELECT * FROM mv_ivm_join_subquery ORDER BY i,j,k;
ROLLBACK; ROLLBACK;
-- support simple CTE -- support simple CTE
BEGIN; BEGIN;
SELECT create_immv('mv_cte', SELECT pgivm.create_immv('mv_cte',
'WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i'); 'WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i');
NOTICE: could not create an index on immv "mv_cte" automatically NOTICE: could not create an index on immv "mv_cte" automatically
DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause. DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
@ -1017,7 +1017,7 @@ SELECT * FROM mv_cte ORDER BY i,j;
ROLLBACK; ROLLBACK;
BEGIN; BEGIN;
SELECT create_immv('mv_cte', SELECT pgivm.create_immv('mv_cte',
'WITH a AS (SELECT * FROM mv_base_a), b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM a, b WHERE a.i = b.i'); 'WITH a AS (SELECT * FROM mv_base_a), b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM a, b WHERE a.i = b.i');
NOTICE: could not create an index on immv "mv_cte" automatically NOTICE: could not create an index on immv "mv_cte" automatically
DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause. DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
@ -1042,7 +1042,7 @@ SELECT * FROM mv_cte ORDER BY i,j;
ROLLBACK; ROLLBACK;
BEGIN; BEGIN;
SELECT create_immv('mv_cte', SELECT pgivm.create_immv('mv_cte',
'WITH b AS ( SELECT * FROM mv_base_b) SELECT v.i,v.j FROM (WITH a AS (SELECT * FROM mv_base_a) SELECT a.i,a.j FROM a, b WHERE a.i = b.i) v'); 'WITH b AS ( SELECT * FROM mv_base_b) SELECT v.i,v.j FROM (WITH a AS (SELECT * FROM mv_base_a) SELECT a.i,a.j FROM a, b WHERE a.i = b.i) v');
NOTICE: could not create an index on immv "mv_cte" automatically NOTICE: could not create an index on immv "mv_cte" automatically
DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause. DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
@ -1067,7 +1067,7 @@ SELECT * FROM mv_cte ORDER BY i,j;
ROLLBACK; ROLLBACK;
BEGIN; BEGIN;
SELECT create_immv('mv_cte', SELECT pgivm.create_immv('mv_cte',
'SELECT * FROM (WITH a AS (SELECT * FROM mv_base_a), b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM a, b WHERE a.i = b.i) v'); 'SELECT * FROM (WITH a AS (SELECT * FROM mv_base_a), b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM a, b WHERE a.i = b.i) v');
NOTICE: could not create an index on immv "mv_cte" automatically NOTICE: could not create an index on immv "mv_cte" automatically
DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause. DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
@ -1092,7 +1092,7 @@ SELECT * FROM mv_cte ORDER BY i,j;
ROLLBACK; ROLLBACK;
BEGIN; BEGIN;
SELECT create_immv('mv_cte', SELECT pgivm.create_immv('mv_cte',
'WITH b AS ( SELECT * FROM (SELECT * FROM mv_base_b) b2) SELECT v.i,v.j FROM (WITH a AS (SELECT * FROM mv_base_a) SELECT a.i,a.j FROM a, b WHERE a.i = b.i) v'); 'WITH b AS ( SELECT * FROM (SELECT * FROM mv_base_b) b2) SELECT v.i,v.j FROM (WITH a AS (SELECT * FROM mv_base_a) SELECT a.i,a.j FROM a, b WHERE a.i = b.i) v');
NOTICE: could not create an index on immv "mv_cte" automatically NOTICE: could not create an index on immv "mv_cte" automatically
DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause. DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
@ -1117,7 +1117,7 @@ SELECT * FROM mv_cte ORDER BY i,j;
ROLLBACK; ROLLBACK;
BEGIN; BEGIN;
SELECT create_immv('mv_cte', SELECT pgivm.create_immv('mv_cte',
'WITH x AS ( SELECT i, a.j, b.k FROM mv_base_b b INNER JOIN mv_base_a a USING(i)) SELECT * FROM x'); 'WITH x AS ( SELECT i, a.j, b.k FROM mv_base_b b INNER JOIN mv_base_a a USING(i)) SELECT * FROM x');
NOTICE: could not create an index on immv "mv_cte" automatically NOTICE: could not create an index on immv "mv_cte" automatically
DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause. DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
@ -1151,7 +1151,7 @@ SELECT * FROM mv_cte ORDER BY i,j,k;
ROLLBACK; ROLLBACK;
-- nested CTE -- nested CTE
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_nested_cte', 'WITH v AS ( WITH a AS (SELECT * FROM mv_base_a) SELECT i, a.j, b.k FROM mv_base_b b INNER JOIN a USING(i)) SELECT * FROM v'); SELECT pgivm.create_immv('mv_ivm_nested_cte', 'WITH v AS ( WITH a AS (SELECT * FROM mv_base_a) SELECT i, a.j, b.k FROM mv_base_b b INNER JOIN a USING(i)) SELECT * FROM v');
NOTICE: could not create an index on immv "mv_ivm_nested_cte" automatically NOTICE: could not create an index on immv "mv_ivm_nested_cte" automatically
DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause. 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 immv for efficient incremental maintenance. HINT: Create an index on the immv for efficient incremental maintenance.
@ -1186,7 +1186,7 @@ ROLLBACK;
BEGIN; BEGIN;
CREATE TABLE base_t (i int, v int); CREATE TABLE base_t (i int, v int);
INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30); INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
SELECT create_immv('mv_cte_multi(v1, v2)', SELECT pgivm.create_immv('mv_cte_multi(v1, v2)',
'WITH t AS (SELECT * FROM base_t) SELECT t1.v, t2.v FROM t AS t1 JOIN t AS t2 ON t1.i = t2.i'); 'WITH t AS (SELECT * FROM base_t) SELECT t1.v, t2.v FROM t AS t1 JOIN t AS t2 ON t1.i = t2.i');
NOTICE: could not create an index on immv "mv_cte_multi" automatically NOTICE: could not create an index on immv "mv_cte_multi" automatically
DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause. DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
@ -1237,20 +1237,20 @@ SELECT * FROM mv_cte_multi ORDER BY v1;
ROLLBACK; ROLLBACK;
--- disallow not-simple CTE --- disallow not-simple CTE
SELECT create_immv('mv_cte_fail', 'WITH b AS (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i'); SELECT pgivm.create_immv('mv_cte_fail', 'WITH b AS (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i');
ERROR: aggregate functions in nested query are not supported on incrementally maintainable materialized view ERROR: aggregate functions in nested query are not supported on incrementally maintainable materialized view
SELECT create_immv('mv_cte_fail', 'WITH b AS (SELECT DISTINCT i FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i'); SELECT pgivm.create_immv('mv_cte_fail', 'WITH b AS (SELECT DISTINCT i FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i');
ERROR: DISTINCT clause in nested query are not supported on incrementally maintainable materialized view ERROR: DISTINCT clause in nested query are not supported on incrementally maintainable materialized view
SELECT create_immv('mv_cte_fail', 'WITH a AS (SELECT i, j FROM mv_base_a) SELECT a.i,a.j FROM a WHERE EXISTS(WITH b AS (SELECT i FROM mv_base_b) SELECT 1 FROM b WHERE a.i = b.i)'); SELECT pgivm.create_immv('mv_cte_fail', 'WITH a AS (SELECT i, j FROM mv_base_a) SELECT a.i,a.j FROM a WHERE EXISTS(WITH b AS (SELECT i FROM mv_base_b) SELECT 1 FROM b WHERE a.i = b.i)');
ERROR: CTE in EXIST clause is not supported on incrementally maintainable materialized view ERROR: CTE in EXIST clause is not supported on incrementally maintainable materialized view
-- unreferenced CTE -- unreferenced CTE
SELECT create_immv('mv_cte_fail', 'WITH b AS (SELECT * FROM mv_base_b) SELECT * FROM mv_base_a a'); SELECT pgivm.create_immv('mv_cte_fail', 'WITH b AS (SELECT * FROM mv_base_b) SELECT * FROM mv_base_a a');
ERROR: Ureferenced WITH query is not supported on incrementally maintainable materialized view ERROR: Ureferenced WITH query is not supported on incrementally maintainable materialized view
-- views including NULL -- views including NULL
BEGIN; BEGIN;
CREATE TABLE base_t (i int, v int); CREATE TABLE base_t (i int, v int);
INSERT INTO base_t VALUES (1,10),(2, NULL); INSERT INTO base_t VALUES (1,10),(2, NULL);
SELECT create_immv('mv', 'SELECT * FROM base_t'); SELECT pgivm.create_immv('mv', 'SELECT * FROM base_t');
NOTICE: could not create an index on immv "mv" automatically NOTICE: could not create an index on immv "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. 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 immv for efficient incremental maintenance. HINT: Create an index on the immv for efficient incremental maintenance.
@ -1277,7 +1277,7 @@ SELECT * FROM mv ORDER BY i;
ROLLBACK; ROLLBACK;
BEGIN; BEGIN;
CREATE TABLE base_t (i int); CREATE TABLE base_t (i int);
SELECT create_immv('mv', 'SELECT * FROM base_t'); SELECT pgivm.create_immv('mv', 'SELECT * FROM base_t');
NOTICE: could not create an index on immv "mv" automatically NOTICE: could not create an index on immv "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. 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 immv for efficient incremental maintenance. HINT: Create an index on the immv for efficient incremental maintenance.
@ -1303,7 +1303,7 @@ ROLLBACK;
BEGIN; BEGIN;
CREATE TABLE base_t (i int, v int); CREATE TABLE base_t (i int, v int);
INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20); INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20);
SELECT create_immv('mv', 'SELECT i, sum(v) FROM base_t GROUP BY i'); SELECT pgivm.create_immv('mv', 'SELECT i, sum(v) FROM base_t GROUP BY i');
NOTICE: created index "mv_index" on immv "mv" NOTICE: created index "mv_index" on immv "mv"
create_immv create_immv
------------- -------------
@ -1329,7 +1329,7 @@ ROLLBACK;
BEGIN; BEGIN;
CREATE TABLE base_t (i int, v int); CREATE TABLE base_t (i int, v int);
INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5); INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5);
SELECT create_immv('mv', 'SELECT i, min(v), max(v) FROM base_t GROUP BY i'); SELECT pgivm.create_immv('mv', 'SELECT i, min(v), max(v) FROM base_t GROUP BY i');
NOTICE: created index "mv_index" on immv "mv" NOTICE: created index "mv_index" on immv "mv"
create_immv create_immv
------------- -------------
@ -1401,7 +1401,7 @@ CREATE OPERATOR CLASS mytype_ops
OPERATOR 3 = , OPERATOR 3 = ,
FUNCTION 1 mytype_cmp(mytype,mytype); FUNCTION 1 mytype_cmp(mytype,mytype);
CREATE TABLE t_mytype (x mytype); CREATE TABLE t_mytype (x mytype);
SELECT create_immv('mv_mytype', SELECT pgivm.create_immv('mv_mytype',
'SELECT * FROM t_mytype'); 'SELECT * FROM t_mytype');
NOTICE: could not create an index on immv "mv_mytype" automatically NOTICE: could not create an index on immv "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. DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause.
@ -1420,95 +1420,95 @@ SELECT * FROM mv_mytype;
ROLLBACK; ROLLBACK;
-- outer join is not supported -- outer join is not supported
SELECT create_immv('mv(a,b)', SELECT pgivm.create_immv('mv(a,b)',
'SELECT a.i, b.i FROM mv_base_a a LEFT JOIN mv_base_b b ON a.i=b.i'); '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 ERROR: OUTER JOIN is not supported on incrementally maintainable materialized view
-- contain system column -- contain system column
SELECT create_immv('mv_ivm01', 'SELECT i,j,xmin FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm01', 'SELECT i,j,xmin FROM mv_base_a');
ERROR: system column is not supported on incrementally maintainable materialized view ERROR: system column is not supported on incrementally maintainable materialized view
SELECT create_immv('mv_ivm02', 'SELECT i,j FROM mv_base_a WHERE xmin = ''610'''); SELECT pgivm.create_immv('mv_ivm02', 'SELECT i,j FROM mv_base_a WHERE xmin = ''610''');
ERROR: system column is not supported on incrementally maintainable materialized view ERROR: system column is not supported on incrementally maintainable materialized view
SELECT create_immv('mv_ivm03', 'SELECT i,j,xmin::text AS x_min FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm03', 'SELECT i,j,xmin::text AS x_min FROM mv_base_a');
ERROR: system column is not supported on incrementally maintainable materialized view ERROR: system column is not supported on incrementally maintainable materialized view
SELECT create_immv('mv_ivm04', 'SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm04', 'SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a');
ERROR: system column is not supported on incrementally maintainable materialized view ERROR: system column is not supported on incrementally maintainable materialized view
-- contain ORDER BY -- contain ORDER BY
SELECT create_immv('mv_ivm07', 'SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) ORDER BY i,j,k'); SELECT pgivm.create_immv('mv_ivm07', '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 ERROR: ORDER BY clause is not supported on incrementally maintainable materialized view
-- contain HAVING -- contain HAVING
SELECT create_immv('mv_ivm08', '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'); SELECT pgivm.create_immv('mv_ivm08', '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 ERROR: HAVING clause is not supported on incrementally maintainable materialized view
-- contain GROUP BY without aggregate -- contain GROUP BY without aggregate
SELECT create_immv('mv_ivm08', 'SELECT i,j FROM mv_base_a GROUP BY i,j'); SELECT pgivm.create_immv('mv_ivm08', 'SELECT i,j FROM mv_base_a GROUP BY i,j');
ERROR: GROUP BY clause without aggregate is not supported on incrementally maintainable materialized view ERROR: GROUP BY clause without aggregate is not supported on incrementally maintainable materialized view
-- contain view or materialized view -- contain view or materialized view
CREATE VIEW b_view AS SELECT i,k FROM mv_base_b; 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 MATERIALIZED VIEW b_mview AS SELECT i,k FROM mv_base_b;
SELECT create_immv('mv_ivm07', 'SELECT a.i,a.j FROM mv_base_a a,b_view b WHERE a.i = b.i'); SELECT pgivm.create_immv('mv_ivm07', '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 ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view
SELECT create_immv('mv_ivm08', 'SELECT a.i,a.j FROM mv_base_a a,b_mview b WHERE a.i = b.i'); SELECT pgivm.create_immv('mv_ivm08', '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 ERROR: VIEW or MATERIALIZED VIEW is not supported on incrementally maintainable materialized view
-- contain mutable functions -- contain mutable functions
SELECT create_immv('mv_ivm12', 'SELECT i,j FROM mv_base_a WHERE i = random()::int'); SELECT pgivm.create_immv('mv_ivm12', 'SELECT i,j FROM mv_base_a WHERE i = random()::int');
ERROR: mutable function is not supported on incrementally maintainable materialized view ERROR: mutable function is not supported on incrementally maintainable materialized view
HINT: functions must be marked IMMUTABLE HINT: functions must be marked IMMUTABLE
-- LIMIT/OFFSET is not supported -- LIMIT/OFFSET is not supported
SELECT create_immv('mv_ivm13', 'SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5'); SELECT pgivm.create_immv('mv_ivm13', 'SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5');
ERROR: LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view ERROR: LIMIT/OFFSET clause is not supported on incrementally maintainable materialized view
-- DISTINCT ON is not supported -- DISTINCT ON is not supported
SELECT create_immv('mv_ivm14', 'SELECT DISTINCT ON(i) i, j FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm14', 'SELECT DISTINCT ON(i) i, j FROM mv_base_a');
ERROR: DISTINCT ON is not supported on incrementally maintainable materialized view ERROR: DISTINCT ON is not supported on incrementally maintainable materialized view
-- TABLESAMPLE clause is not supported -- TABLESAMPLE clause is not supported
SELECT create_immv('mv_ivm15', 'SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50)'); SELECT pgivm.create_immv('mv_ivm15', 'SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50)');
ERROR: TABLESAMPLE clause is not supported on incrementally maintainable materialized view ERROR: TABLESAMPLE clause is not supported on incrementally maintainable materialized view
-- window functions are not supported -- window functions are not supported
SELECT create_immv('mv_ivm16', 'SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm16', 'SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a');
ERROR: window functions are not supported on incrementally maintainable materialized view ERROR: window functions are not supported on incrementally maintainable materialized view
-- aggregate function with some options is not supported -- aggregate function with some options is not supported
SELECT create_immv('mv_ivm17', 'SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm17', 'SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a');
ERROR: aggregate function with FILTER clause is not supported on incrementally maintainable materialized view ERROR: aggregate function with FILTER clause is not supported on incrementally maintainable materialized view
SELECT create_immv('mv_ivm18', 'SELECT COUNT(DISTINCT i) FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm18', 'SELECT COUNT(DISTINCT i) FROM mv_base_a');
ERROR: aggregate function with DISTINCT arguments is not supported on incrementally maintainable materialized view ERROR: aggregate function with DISTINCT arguments is not supported on incrementally maintainable materialized view
SELECT create_immv('mv_ivm19', 'SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm19', '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 ERROR: aggregate function with ORDER clause is not supported on incrementally maintainable materialized view
SELECT create_immv('mv_ivm20', 'SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),())'); SELECT pgivm.create_immv('mv_ivm20', '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 ERROR: GROUPING SETS, ROLLUP, or CUBE clauses is not supported on incrementally maintainable materialized view
-- inheritance parent is not supported -- inheritance parent is not supported
BEGIN; BEGIN;
CREATE TABLE parent (i int, v int); CREATE TABLE parent (i int, v int);
CREATE TABLE child_a(options text) INHERITS(parent); CREATE TABLE child_a(options text) INHERITS(parent);
SELECT create_immv('mv_ivm21', 'SELECT * FROM parent'); SELECT pgivm.create_immv('mv_ivm21', 'SELECT * FROM parent');
ERROR: inheritance parent is not supported on incrementally maintainable materialized view ERROR: inheritance parent is not supported on incrementally maintainable materialized view
ROLLBACK; ROLLBACK;
-- UNION statement is not supported -- UNION statement is not supported
SELECT create_immv('mv_ivm22', 'SELECT i,j FROM mv_base_a UNION ALL SELECT i,k FROM mv_base_b'); SELECT pgivm.create_immv('mv_ivm22', '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 ERROR: UNION/INTERSECT/EXCEPT statements are not supported on incrementally maintainable materialized view
-- DISTINCT clause in nested query are not supported -- DISTINCT clause in nested query are not supported
SELECT create_immv('mv_ivm23', 'SELECT * FROM (SELECT DISTINCT i,j FROM mv_base_a) AS tmp');; SELECT pgivm.create_immv('mv_ivm23', 'SELECT * FROM (SELECT DISTINCT i,j FROM mv_base_a) AS tmp');;
ERROR: DISTINCT clause in nested query are not supported on incrementally maintainable materialized view ERROR: DISTINCT clause in nested query are not supported on incrementally maintainable materialized view
-- empty target list is not allowed with IVM -- empty target list is not allowed with IVM
SELECT create_immv('mv_ivm25', 'SELECT FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm25', 'SELECT FROM mv_base_a');
ERROR: empty target list is not supported on incrementally maintainable materialized view ERROR: empty target list is not supported on incrementally maintainable materialized view
-- FOR UPDATE/SHARE is not supported -- FOR UPDATE/SHARE is not supported
SELECT create_immv('mv_ivm26', 'SELECT i,j FROM mv_base_a FOR UPDATE'); SELECT pgivm.create_immv('mv_ivm26', 'SELECT i,j FROM mv_base_a FOR UPDATE');
ERROR: FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view ERROR: FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view
SELECT create_immv('mv_ivm27', 'SELECT * FROM (SELECT i,j FROM mv_base_a FOR UPDATE) AS tmp;'); SELECT pgivm.create_immv('mv_ivm27', 'SELECT * FROM (SELECT i,j FROM mv_base_a FOR UPDATE) AS tmp;');
ERROR: FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view ERROR: FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view
-- tartget list cannot contain ivm column that start with '__ivm' -- tartget list cannot contain ivm column that start with '__ivm'
SELECT create_immv('mv_ivm28', 'SELECT i AS "__ivm_count__" FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm28', 'SELECT i AS "__ivm_count__" FROM mv_base_a');
ERROR: column name __ivm_count__ is not supported on incrementally maintainable materialized view ERROR: column name __ivm_count__ is not supported on incrementally maintainable materialized view
-- expressions specified in GROUP BY must appear in the target list. -- expressions specified in GROUP BY must appear in the target list.
SELECT create_immv('mv_ivm29', 'SELECT COUNT(i) FROM mv_base_a GROUP BY i;'); SELECT pgivm.create_immv('mv_ivm29', '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 ERROR: GROUP BY expression not appearing in select list is not supported on incrementally maintainable materialized view
-- experssions containing an aggregate is not supported -- experssions containing an aggregate is not supported
SELECT create_immv('mv_ivm30', 'SELECT sum(i)*0.5 FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm30', 'SELECT sum(i)*0.5 FROM mv_base_a');
ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view
SELECT create_immv('mv_ivm31', 'SELECT sum(i)/sum(j) FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm31', 'SELECT sum(i)/sum(j) FROM mv_base_a');
ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view ERROR: expression containing an aggregate in it is not supported on incrementally maintainable materialized view
-- VALUES is not supported -- VALUES is not supported
SELECT create_immv('mv_ivm_only_values1', 'values(1)'); SELECT pgivm.create_immv('mv_ivm_only_values1', 'values(1)');
ERROR: VALUES is not supported on incrementally maintainable materialized view ERROR: VALUES is not supported on incrementally maintainable materialized view
SELECT create_immv('mv_ivm_only_values2', 'SELECT * FROM (values(1)) AS tmp'); SELECT pgivm.create_immv('mv_ivm_only_values2', 'SELECT * FROM (values(1)) AS tmp');
ERROR: VALUES is not supported on incrementally maintainable materialized view ERROR: VALUES is not supported on incrementally maintainable materialized view
-- views containing base tables with Row Level Security -- views containing base tables with Row Level Security
DROP USER IF EXISTS ivm_admin; DROP USER IF EXISTS ivm_admin;
@ -1538,7 +1538,7 @@ GRANT ALL on rls_tbl TO PUBLIC;
GRANT ALL on num_tbl TO PUBLIC; GRANT ALL on num_tbl TO PUBLIC;
--- create a view owned by ivm_user --- create a view owned by ivm_user
SET SESSION AUTHORIZATION ivm_user; SET SESSION AUTHORIZATION ivm_user;
SELECT create_immv('ivm_rls', 'SELECT * FROM rls_tbl'); SELECT pgivm.create_immv('ivm_rls', 'SELECT * FROM rls_tbl');
NOTICE: could not create an index on immv "ivm_rls" automatically NOTICE: could not create an index on immv "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. 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 immv for efficient incremental maintenance. HINT: Create an index on the immv for efficient incremental maintenance.
@ -1584,7 +1584,7 @@ SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
--- ---
SET SESSION AUTHORIZATION ivm_user; SET SESSION AUTHORIZATION ivm_user;
SELECT create_immv('ivm_rls2', 'SELECT * FROM rls_tbl JOIN num_tbl USING(id)'); SELECT pgivm.create_immv('ivm_rls2', 'SELECT * FROM rls_tbl JOIN num_tbl USING(id)');
NOTICE: could not create an index on immv "ivm_rls2" automatically NOTICE: could not create an index on immv "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. 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 immv for efficient incremental maintenance. HINT: Create an index on the immv for efficient incremental maintenance.
@ -1621,7 +1621,7 @@ BEGIN;
CREATE TABLE base_a (i int primary key, j int); CREATE TABLE base_a (i int primary key, j int);
CREATE TABLE base_b (i int primary key, j int); CREATE TABLE base_b (i int primary key, j int);
--- group by: create an index --- group by: create an index
SELECT create_immv('mv_idx1', 'SELECT i, sum(j) FROM base_a GROUP BY i'); SELECT pgivm.create_immv('mv_idx1', 'SELECT i, sum(j) FROM base_a GROUP BY i');
NOTICE: created index "mv_idx1_index" on immv "mv_idx1" NOTICE: created index "mv_idx1_index" on immv "mv_idx1"
create_immv create_immv
------------- -------------
@ -1629,7 +1629,7 @@ NOTICE: created index "mv_idx1_index" on immv "mv_idx1"
(1 row) (1 row)
--- distinct: create an index --- distinct: create an index
SELECT create_immv('mv_idx2', 'SELECT DISTINCT j FROM base_a'); SELECT pgivm.create_immv('mv_idx2', 'SELECT DISTINCT j FROM base_a');
NOTICE: created index "mv_idx2_index" on immv "mv_idx2" NOTICE: created index "mv_idx2_index" on immv "mv_idx2"
create_immv create_immv
------------- -------------
@ -1637,7 +1637,7 @@ NOTICE: created index "mv_idx2_index" on immv "mv_idx2"
(1 row) (1 row)
--- with all pkey columns: create an index --- with all pkey columns: create an index
SELECT create_immv('mv_idx3(i_a, i_b)', 'SELECT a.i, b.i FROM base_a a, base_b b'); SELECT pgivm.create_immv('mv_idx3(i_a, i_b)', 'SELECT a.i, b.i FROM base_a a, base_b b');
NOTICE: created index "mv_idx3_index" on immv "mv_idx3" NOTICE: created index "mv_idx3_index" on immv "mv_idx3"
create_immv create_immv
------------- -------------
@ -1645,7 +1645,7 @@ NOTICE: created index "mv_idx3_index" on immv "mv_idx3"
(1 row) (1 row)
--- missing some pkey columns: no index --- missing some pkey columns: no index
SELECT create_immv('mv_idx4', 'SELECT j FROM base_a'); SELECT pgivm.create_immv('mv_idx4', 'SELECT j FROM base_a');
NOTICE: could not create an index on immv "mv_idx4" automatically NOTICE: could not create an index on immv "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. 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 immv for efficient incremental maintenance. HINT: Create an index on the immv for efficient incremental maintenance.
@ -1654,7 +1654,7 @@ HINT: Create an index on the immv for efficient incremental maintenance.
0 0
(1 row) (1 row)
SELECT create_immv('mv_idx5', 'SELECT a.i, b.j FROM base_a a, base_b b'); SELECT pgivm.create_immv('mv_idx5', 'SELECT a.i, b.j FROM base_a a, base_b b');
NOTICE: could not create an index on immv "mv_idx5" automatically NOTICE: could not create an index on immv "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. 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 immv for efficient incremental maintenance. HINT: Create an index on the immv for efficient incremental maintenance.
@ -1664,7 +1664,7 @@ HINT: Create an index on the immv for efficient incremental maintenance.
(1 row) (1 row)
--- subqueries: create an index --- subqueries: create an index
SELECT create_immv('mv_idx6(i_a, i_b)', 'SELECT a.i, b.i FROM (SELECT * FROM base_a) a, (SELECT * FROM base_b) b'); SELECT pgivm.create_immv('mv_idx6(i_a, i_b)', 'SELECT a.i, b.i FROM (SELECT * FROM base_a) a, (SELECT * FROM base_b) b');
NOTICE: created index "mv_idx6_index" on immv "mv_idx6" NOTICE: created index "mv_idx6_index" on immv "mv_idx6"
create_immv create_immv
------------- -------------
@ -1672,7 +1672,7 @@ NOTICE: created index "mv_idx6_index" on immv "mv_idx6"
(1 row) (1 row)
--- with set-returning function: no index --- with set-returning function: no index
SELECT create_immv('mv_idx7', 'SELECT i FROM base_a, generate_series(1,10)'); SELECT pgivm.create_immv('mv_idx7', 'SELECT i FROM base_a, generate_series(1,10)');
NOTICE: could not create an index on immv "mv_idx7" automatically NOTICE: could not create an index on immv "mv_idx7" automatically
DETAIL: This target list does not have all the primary key columns, or this view does not contain GROUP BY or DISTINCT clause. 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 immv for efficient incremental maintenance. HINT: Create an index on the immv for efficient incremental maintenance.
@ -1685,7 +1685,7 @@ ROLLBACK;
-- type that doesn't have default operator class for access method btree -- type that doesn't have default operator class for access method btree
BEGIN; BEGIN;
CREATE TABLE table_json (j json); CREATE TABLE table_json (j json);
SELECT create_immv('mv_json', 'SELECT * from table_json'); SELECT pgivm.create_immv('mv_json', 'SELECT * from table_json');
ERROR: data type json has no default operator class for access method "btree" ERROR: data type json has no default operator class for access method "btree"
ROLLBACK; ROLLBACK;
-- prevent IMMV chanages -- prevent IMMV chanages
@ -1698,7 +1698,7 @@ ERROR: cannot change materialized view "mv_ivm_1"
TRUNCATE mv_ivm_1; TRUNCATE mv_ivm_1;
ERROR: cannot change materialized view "mv_ivm_1" ERROR: cannot change materialized view "mv_ivm_1"
-- get_immv_def function -- get_immv_def function
SELECT immvrelid, get_immv_def(immvrelid) FROM pg_ivm_immv ORDER BY 1; SELECT immvrelid, pgivm.get_immv_def(immvrelid) FROM pgivm.pg_ivm_immv ORDER BY 1;
immvrelid | get_immv_def immvrelid | get_immv_def
-----------+---------------------------------- -----------+----------------------------------
mv_ivm_1 | SELECT a.i, + mv_ivm_1 | SELECT a.i, +
@ -1709,7 +1709,7 @@ SELECT immvrelid, get_immv_def(immvrelid) FROM pg_ivm_immv ORDER BY 1;
(1 row) (1 row)
-- mv_base_b is not immv -- mv_base_b is not immv
SELECT 'mv_base_b'::regclass, get_immv_def('mv_base_b'); SELECT 'mv_base_b'::regclass, pgivm.get_immv_def('mv_base_b');
regclass | get_immv_def regclass | get_immv_def
-----------+-------------- -----------+--------------
mv_base_b | mv_base_b |

View file

@ -1,26 +1,26 @@
CREATE TABLE t (i int PRIMARY KEY); CREATE TABLE t (i int PRIMARY KEY);
INSERT INTO t SELECT generate_series(1, 5); INSERT INTO t SELECT generate_series(1, 5);
SELECT create_immv('mv', 'SELECT * FROM t'); SELECT pgivm.create_immv('mv', 'SELECT * FROM t');
NOTICE: created index "mv_index" on immv "mv" NOTICE: created index "mv_index" on immv "mv"
create_immv create_immv
------------- -------------
5 5
(1 row) (1 row)
SELECT immvrelid, ispopulated FROM pg_ivm_immv ORDER BY 1; SELECT immvrelid, ispopulated FROM pgivm.pg_ivm_immv ORDER BY 1;
immvrelid | ispopulated immvrelid | ispopulated
-----------+------------- -----------+-------------
mv | t mv | t
(1 row) (1 row)
-- Refresh IMMV with data -- Refresh IMMV with data
SELECT refresh_immv('mv', true); SELECT pgivm.refresh_immv('mv', true);
refresh_immv refresh_immv
-------------- --------------
5 5
(1 row) (1 row)
SELECT immvrelid, ispopulated FROM pg_ivm_immv ORDER BY 1; SELECT immvrelid, ispopulated FROM pgivm.pg_ivm_immv ORDER BY 1;
immvrelid | ispopulated immvrelid | ispopulated
-----------+------------- -----------+-------------
mv | t mv | t
@ -39,13 +39,13 @@ SELECT i FROM mv ORDER BY 1;
(6 rows) (6 rows)
-- Make IMMV unpopulated -- Make IMMV unpopulated
SELECT refresh_immv('mv', false); SELECT pgivm.refresh_immv('mv', false);
refresh_immv refresh_immv
-------------- --------------
0 0
(1 row) (1 row)
SELECT immvrelid, ispopulated FROM pg_ivm_immv ORDER BY 1; SELECT immvrelid, ispopulated FROM pgivm.pg_ivm_immv ORDER BY 1;
immvrelid | ispopulated immvrelid | ispopulated
-----------+------------- -----------+-------------
mv | f mv | f
@ -64,13 +64,13 @@ SELECT i FROM mv ORDER BY 1;
(0 rows) (0 rows)
-- Refresh the IMMV and make it populated. -- Refresh the IMMV and make it populated.
SELECT refresh_immv('mv', true); SELECT pgivm.refresh_immv('mv', true);
refresh_immv refresh_immv
-------------- --------------
7 7
(1 row) (1 row)
SELECT immvrelid, ispopulated FROM pg_ivm_immv ORDER BY 1; SELECT immvrelid, ispopulated FROM pgivm.pg_ivm_immv ORDER BY 1;
immvrelid | ispopulated immvrelid | ispopulated
-----------+------------- -----------+-------------
mv | t mv | t
@ -104,15 +104,15 @@ SELECT i FROM mv ORDER BY 1;
(8 rows) (8 rows)
-- Use qualified name -- Use qualified name
SELECT refresh_immv('public.mv', true); SELECT pgivm.refresh_immv('public.mv', true);
refresh_immv refresh_immv
-------------- --------------
8 8
(1 row) (1 row)
-- Use not existing IMMV -- Use not existing IMMV
SELECT refresh_immv('mv_not_existing', true); SELECT pgivm.refresh_immv('mv_not_existing', true);
ERROR: relation "mv_not_existing" does not exist ERROR: relation "mv_not_existing" does not exist
-- Try to refresh a normal table -- error -- Try to refresh a normal table -- error
SELECT refresh_immv('t', true); SELECT pgivm.refresh_immv('t', true);
ERROR: "t" is not an IMMV ERROR: "t" is not an IMMV

View file

@ -1426,7 +1426,7 @@ get_prestate_rte(RangeTblEntry *rte, MV_TriggerTable *table,
initStringInfo(&str); initStringInfo(&str);
appendStringInfo(&str, appendStringInfo(&str,
"SELECT t.* FROM %s t" "SELECT t.* FROM %s t"
" WHERE pg_catalog.ivm_visible_in_prestate(t.tableoid, t.ctid ,%d::pg_catalog.oid)", " WHERE pgivm.ivm_visible_in_prestate(t.tableoid, t.ctid, %d::pg_catalog.oid)",
relname, matviewid); relname, matviewid);
/* /*

View file

@ -11,8 +11,6 @@ CREATE TABLE __pg_ivm__.pg_ivm_immv(
ALTER TABLE __pg_ivm__.pg_ivm_immv SET SCHEMA pg_catalog; ALTER TABLE __pg_ivm__.pg_ivm_immv SET SCHEMA pg_catalog;
--CREATE UNIQUE INDEX ON pg_catalog.pg_ivm_immv USING btree (immvrelid);
SELECT pg_catalog.pg_extension_config_dump('pg_catalog.pg_ivm_immv', ''); SELECT pg_catalog.pg_extension_config_dump('pg_catalog.pg_ivm_immv', '');
-- functions -- functions
@ -44,7 +42,7 @@ LANGUAGE C;
/* /*
* DDL trigger that removes entry from pg_ivm_immv * DDL trigger that removes entry from pg_ivm_immv
*/ */
CREATE FUNCTION pg_ivm_sql_drop_trigger_func() CREATE FUNCTION pg_catalog.pg_ivm_sql_drop_trigger_func()
RETURNS event_trigger AS $$ RETURNS event_trigger AS $$
DECLARE DECLARE
pg_class_oid OID; pg_class_oid OID;

59
pg_ivm--1.10.sql Normal file
View file

@ -0,0 +1,59 @@
CREATE SCHEMA pgivm;
-- catalog
CREATE TABLE pgivm.pg_ivm_immv(
immvrelid regclass NOT NULL,
viewdef text NOT NULL,
ispopulated bool NOT NULL,
CONSTRAINT pg_ivm_immv_pkey PRIMARY KEY (immvrelid)
);
SELECT pg_catalog.pg_extension_config_dump('pgivm.pg_ivm_immv', '');
-- functions
CREATE FUNCTION pgivm.create_immv(text, text)
RETURNS bigint
STRICT
AS 'MODULE_PATHNAME', 'create_immv'
LANGUAGE C;
CREATE FUNCTION pgivm.refresh_immv(text, bool)
RETURNS bigint
STRICT
AS 'MODULE_PATHNAME', 'refresh_immv'
LANGUAGE C;
CREATE FUNCTION pgivm.get_immv_def(IN immvrelid regclass)
RETURNS text
STRICT
AS 'MODULE_PATHNAME', 'get_immv_def'
LANGUAGE C;
CREATE FUNCTION pgivm.ivm_visible_in_prestate(oid, tid, oid)
RETURNS bool
STABLE
AS 'MODULE_PATHNAME', 'ivm_visible_in_prestate'
LANGUAGE C;
-- trigger functions
CREATE FUNCTION pgivm."IVM_immediate_before"()
RETURNS trigger
AS 'MODULE_PATHNAME', 'IVM_immediate_before'
LANGUAGE C;
CREATE FUNCTION pgivm."IVM_immediate_maintenance"()
RETURNS trigger
AS 'MODULE_PATHNAME', 'IVM_immediate_maintenance'
LANGUAGE C;
CREATE FUNCTION pgivm."IVM_prevent_immv_change"()
RETURNS trigger
AS 'MODULE_PATHNAME', 'IVM_prevent_immv_change'
LANGUAGE C;
GRANT SELECT ON TABLE pgivm.pg_ivm_immv TO PUBLIC;
GRANT USAGE ON SCHEMA pgivm TO PUBLIC;

View file

@ -0,0 +1,16 @@
-- create a new schema pgivm and change the objects' schema to it
CREATE SCHEMA pgivm;
ALTER TABLE pg_ivm_immv SET SCHEMA pgivm;
ALTER FUNCTION create_immv(text, text) SET SCHEMA pgivm;
ALTER FUNCTION refresh_immv(text, bool) SET SCHEMA pgivm;
ALTER FUNCTION get_immv_def(regclass) SET SCHEMA pgivm;
ALTER FUNCTION ivm_visible_in_prestate(oid, tid, oid) SET SCHEMA pgivm;
ALTER FUNCTION "IVM_immediate_before"() SET SCHEMA pgivm;
ALTER FUNCTION "IVM_immediate_maintenance"() SET SCHEMA pgivm;
ALTER FUNCTION "IVM_prevent_immv_change"() SET SCHEMA pgivm;
GRANT USAGE ON SCHEMA pgivm TO PUBLIC;
-- drop a garbage
DROP SCHEMA __pg_ivm__;

View file

@ -297,7 +297,7 @@ CreateChangePreventTrigger(Oid matviewOid)
ivm_trigger->timing = TRIGGER_TYPE_BEFORE; ivm_trigger->timing = TRIGGER_TYPE_BEFORE;
ivm_trigger->trigname = "IVM_prevent_immv_change"; ivm_trigger->trigname = "IVM_prevent_immv_change";
ivm_trigger->funcname = SystemFuncName("IVM_prevent_immv_change"); ivm_trigger->funcname = PgIvmFuncName("IVM_prevent_immv_change");
ivm_trigger->columns = NIL; ivm_trigger->columns = NIL;
ivm_trigger->transitionRels = NIL; ivm_trigger->transitionRels = NIL;
ivm_trigger->whenClause = NULL; ivm_trigger->whenClause = NULL;
@ -327,7 +327,7 @@ Oid
PgIvmImmvRelationId(void) PgIvmImmvRelationId(void)
{ {
return RangeVarGetRelid( return RangeVarGetRelid(
makeRangeVar("pg_catalog", "pg_ivm_immv", -1), makeRangeVar("pgivm", "pg_ivm_immv", -1),
AccessShareLock, true); AccessShareLock, true);
} }
@ -338,7 +338,7 @@ Oid
PgIvmImmvPrimaryKeyIndexId(void) PgIvmImmvPrimaryKeyIndexId(void)
{ {
return RangeVarGetRelid( return RangeVarGetRelid(
makeRangeVar("pg_catalog", "pg_ivm_immv_pkey", -1), makeRangeVar("pgivm", "pg_ivm_immv_pkey", -1),
AccessShareLock, true); AccessShareLock, true);
} }
@ -447,3 +447,12 @@ isImmv(Oid immv_oid)
else else
return true; return true;
} }
/* PgIvmFuncName()
* Build a properly-qualified reference to a pg_ivm internal function.
*/
List *
PgIvmFuncName(char *name)
{
return list_make2(makeString("pgivm"), makeString(name));
}

View file

@ -32,6 +32,7 @@ extern void CreateChangePreventTrigger(Oid matviewOid);
extern Oid PgIvmImmvRelationId(void); extern Oid PgIvmImmvRelationId(void);
extern Oid PgIvmImmvPrimaryKeyIndexId(void); extern Oid PgIvmImmvPrimaryKeyIndexId(void);
extern bool isImmv(Oid immv_oid); extern bool isImmv(Oid immv_oid);
extern List *PgIvmFuncName(char *name);
/* createas.c */ /* createas.c */

View file

@ -1,30 +1,30 @@
CREATE TABLE t (i int PRIMARY KEY); CREATE TABLE t (i int PRIMARY KEY);
INSERT INTO t SELECT generate_series(1, 100); INSERT INTO t SELECT generate_series(1, 100);
SELECT create_immv('mv', 'SELECT * FROM t'); SELECT pgivm.create_immv('mv', 'SELECT * FROM t');
SELECT create_immv(' mv2 ( x ) ', 'SELECT * FROM t WHERE i%2 = 0'); SELECT pgivm.create_immv(' mv2 ( x ) ', 'SELECT * FROM t WHERE i%2 = 0');
SELECT create_immv('mv3', 'WITH d AS (DELETE FROM t RETURNING NULL) SELECT * FROM t'); SELECT pgivm.create_immv('mv3', 'WITH d AS (DELETE FROM t RETURNING NULL) SELECT * FROM t');
SELECT immvrelid, get_immv_def(immvrelid) FROM pg_ivm_immv ORDER BY 1; SELECT immvrelid, pgivm.get_immv_def(immvrelid) FROM pgivm.pg_ivm_immv ORDER BY 1;
-- contain immv -- contain immv
SELECT create_immv('mv_in_immv01', 'SELECT i FROM mv'); SELECT pgivm.create_immv('mv_in_immv01', 'SELECT i FROM mv');
SELECT create_immv('mv_in_immv02', 'SELECT t.i FROM t INNER JOIN mv2 ON t.i = mv2.x'); SELECT pgivm.create_immv('mv_in_immv02', 'SELECT t.i FROM t INNER JOIN mv2 ON t.i = mv2.x');
-- SQL other than SELECT -- SQL other than SELECT
SELECT create_immv('mv_in_create', 'CREATE TABLE in_create(i int)'); SELECT pgivm.create_immv('mv_in_create', 'CREATE TABLE in_create(i int)');
SELECT create_immv('mv_in_insert', 'INSERT INTO t VALUES(10)'); SELECT pgivm.create_immv('mv_in_insert', 'INSERT INTO t VALUES(10)');
SELECT create_immv('mv_in_update', 'UPDATE t SET i = 10'); SELECT pgivm.create_immv('mv_in_update', 'UPDATE t SET i = 10');
SELECT create_immv('mv_in_delete', 'DELETE FROM t'); SELECT pgivm.create_immv('mv_in_delete', 'DELETE FROM t');
SELECT create_immv('mv_in_drop', 'DROP TABLE t'); SELECT pgivm.create_immv('mv_in_drop', 'DROP TABLE t');
DROP TABLE t; DROP TABLE t;
DROP TABLE mv; DROP TABLE mv;
SELECT immvrelid, get_immv_def(immvrelid) FROM pg_ivm_immv ORDER BY 1; SELECT immvrelid, pgivm.get_immv_def(immvrelid) FROM pgivm.pg_ivm_immv ORDER BY 1;
DROP TABLE mv2; DROP TABLE mv2;
SELECT immvrelid, get_immv_def(immvrelid) FROM pg_ivm_immv ORDER BY 1; SELECT immvrelid, pgivm.get_immv_def(immvrelid) FROM pgivm.pg_ivm_immv ORDER BY 1;
DROP TABLE t; DROP TABLE t;

View file

@ -16,7 +16,7 @@ INSERT INTO mv_base_b VALUES
(3,103), (3,103),
(4,104); (4,104);
SELECT create_immv('mv_ivm_1', 'SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i)'); SELECT pgivm.create_immv('mv_ivm_1', 'SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i)');
SELECT * FROM mv_ivm_1 ORDER BY 1,2,3; SELECT * FROM mv_ivm_1 ORDER BY 1,2,3;
-- immediate maintenance -- immediate maintenance
@ -45,14 +45,14 @@ ROLLBACK;
BEGIN; BEGIN;
CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql' CREATE FUNCTION ivm_func() RETURNS int LANGUAGE 'sql'
AS 'SELECT 1' IMMUTABLE; AS 'SELECT 1' IMMUTABLE;
SELECT create_immv('mv_ivm_func', 'SELECT * FROM ivm_func()'); SELECT pgivm.create_immv('mv_ivm_func', 'SELECT * FROM ivm_func()');
SELECT create_immv('mv_ivm_no_tbl', 'SELECT 1'); SELECT pgivm.create_immv('mv_ivm_no_tbl', 'SELECT 1');
ROLLBACK; ROLLBACK;
-- result of materialized view have DISTINCT clause or the duplicate result. -- result of materialized view have DISTINCT clause or the duplicate result.
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_duplicate', 'SELECT j FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm_duplicate', 'SELECT j FROM mv_base_a');
SELECT create_immv('mv_ivm_distinct', 'SELECT DISTINCT j FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm_distinct', 'SELECT DISTINCT j FROM mv_base_a');
INSERT INTO mv_base_a VALUES(6,20); INSERT INTO mv_base_a VALUES(6,20);
SELECT * FROM mv_ivm_duplicate ORDER BY 1; SELECT * FROM mv_ivm_duplicate ORDER BY 1;
SELECT * FROM mv_ivm_distinct ORDER BY 1; SELECT * FROM mv_ivm_distinct ORDER BY 1;
@ -63,7 +63,7 @@ ROLLBACK;
-- support SUM(), COUNT() and AVG() aggregate functions -- support SUM(), COUNT() and AVG() aggregate functions
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_agg', 'SELECT i, SUM(j), COUNT(i), AVG(j) FROM mv_base_a GROUP BY i'); SELECT pgivm.create_immv('mv_ivm_agg', '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; SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
INSERT INTO mv_base_a VALUES(2,100); INSERT INTO mv_base_a VALUES(2,100);
SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4; SELECT * FROM mv_ivm_agg ORDER BY 1,2,3,4;
@ -75,7 +75,7 @@ ROLLBACK;
-- support COUNT(*) aggregate function -- support COUNT(*) aggregate function
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_agg', 'SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i'); SELECT pgivm.create_immv('mv_ivm_agg', 'SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i');
SELECT * FROM mv_ivm_agg ORDER BY 1,2,3; SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
INSERT INTO mv_base_a VALUES(2,100); INSERT INTO mv_base_a VALUES(2,100);
SELECT * FROM mv_ivm_agg ORDER BY 1,2,3; SELECT * FROM mv_ivm_agg ORDER BY 1,2,3;
@ -83,7 +83,7 @@ ROLLBACK;
-- TRUNCATE a base table in aggregate views -- TRUNCATE a base table in aggregate views
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_agg', 'SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i'); SELECT pgivm.create_immv('mv_ivm_agg', 'SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i');
TRUNCATE mv_base_a; TRUNCATE mv_base_a;
SELECT sum, count FROM mv_ivm_agg; SELECT sum, count FROM mv_ivm_agg;
SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i; SELECT i, SUM(j), COUNT(*) FROM mv_base_a GROUP BY i;
@ -91,7 +91,7 @@ ROLLBACK;
-- support aggregate functions without GROUP clause -- support aggregate functions without GROUP clause
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_group', 'SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm_group', 'SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a');
SELECT * FROM mv_ivm_group ORDER BY 1; SELECT * FROM mv_ivm_group ORDER BY 1;
INSERT INTO mv_base_a VALUES(6,60); INSERT INTO mv_base_a VALUES(6,60);
SELECT * FROM mv_ivm_group ORDER BY 1; SELECT * FROM mv_ivm_group ORDER BY 1;
@ -101,7 +101,7 @@ ROLLBACK;
-- TRUNCATE a base table in aggregate views without GROUP clause -- TRUNCATE a base table in aggregate views without GROUP clause
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_group', 'SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm_group', 'SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a');
TRUNCATE mv_base_a; TRUNCATE mv_base_a;
SELECT sum, count, avg FROM mv_ivm_group; SELECT sum, count, avg FROM mv_ivm_group;
SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a; SELECT SUM(j), COUNT(j), AVG(j) FROM mv_base_a;
@ -109,7 +109,7 @@ ROLLBACK;
-- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect. -- resolved issue: When use AVG() function and values is indivisible, result of AVG() is incorrect.
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_avg_bug', 'SELECT i, SUM(j), COUNT(j), AVG(j) FROM mv_base_A GROUP BY i'); SELECT pgivm.create_immv('mv_ivm_avg_bug', '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; SELECT * FROM mv_ivm_avg_bug ORDER BY 1,2,3;
INSERT INTO mv_base_a VALUES INSERT INTO mv_base_a VALUES
(1,0), (1,0),
@ -124,7 +124,7 @@ ROLLBACK;
-- support MIN(), MAX() aggregate functions -- support MIN(), MAX() aggregate functions
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_min_max(i, min_j, max_j)', 'SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i'); SELECT pgivm.create_immv('mv_ivm_min_max(i, min_j, max_j)', 'SELECT i, MIN(j), MAX(j) FROM mv_base_a GROUP BY i');
SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3; SELECT * FROM mv_ivm_min_max ORDER BY 1,2,3;
INSERT INTO mv_base_a VALUES INSERT INTO mv_base_a VALUES
(1,11), (1,12), (1,11), (1,12),
@ -139,7 +139,7 @@ ROLLBACK;
-- support MIN(), MAX() aggregate functions without GROUP clause -- support MIN(), MAX() aggregate functions without GROUP clause
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_min_max(min_j, max_j)', 'SELECT MIN(j), MAX(j) FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm_min_max(min_j, max_j)', 'SELECT MIN(j), MAX(j) FROM mv_base_a');
SELECT * FROM mv_ivm_min_max; SELECT * FROM mv_ivm_min_max;
INSERT INTO mv_base_a VALUES INSERT INTO mv_base_a VALUES
(0,0), (6,60), (7,70); (0,0), (6,60), (7,70);
@ -152,7 +152,7 @@ ROLLBACK;
-- Test MIN/MAX after search_path change -- Test MIN/MAX after search_path change
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_min', 'SELECT MIN(j) FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm_min', 'SELECT MIN(j) FROM mv_base_a');
SELECT * FROM mv_ivm_min ORDER BY 1,2,3; SELECT * FROM mv_ivm_min ORDER BY 1,2,3;
CREATE SCHEMA myschema; CREATE SCHEMA myschema;
@ -170,28 +170,28 @@ ROLLBACK;
-- aggregate views with column names specified -- aggregate views with column names specified
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_agg(a)', 'SELECT i, SUM(j) FROM mv_base_a GROUP BY i'); SELECT pgivm.create_immv('mv_ivm_agg(a)', 'SELECT i, SUM(j) FROM mv_base_a GROUP BY i');
INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300); INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20); UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
DELETE FROM mv_base_a WHERE (i,j) = (3,30); DELETE FROM mv_base_a WHERE (i,j) = (3,30);
SELECT * FROM mv_ivm_agg ORDER BY 1,2; SELECT * FROM mv_ivm_agg ORDER BY 1,2;
ROLLBACK; ROLLBACK;
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_agg(a,b)', 'SELECT i, SUM(j) FROM mv_base_a GROUP BY i'); SELECT pgivm.create_immv('mv_ivm_agg(a,b)', 'SELECT i, SUM(j) FROM mv_base_a GROUP BY i');
INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300); INSERT INTO mv_base_a VALUES (1,100), (2,200), (3,300);
UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20); UPDATE mv_base_a SET j = 2000 WHERE (i,j) = (2,20);
DELETE FROM mv_base_a WHERE (i,j) = (3,30); DELETE FROM mv_base_a WHERE (i,j) = (3,30);
SELECT * FROM mv_ivm_agg ORDER BY 1,2; SELECT * FROM mv_ivm_agg ORDER BY 1,2;
ROLLBACK; ROLLBACK;
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_agg(a,b,c)', 'SELECT i, SUM(j) FROM mv_base_a GROUP BY i'); SELECT pgivm.create_immv('mv_ivm_agg(a,b,c)', 'SELECT i, SUM(j) FROM mv_base_a GROUP BY i');
ROLLBACK; ROLLBACK;
-- support self join view and multiple change on the same table -- support self join view and multiple change on the same table
BEGIN; BEGIN;
CREATE TABLE base_t (i int, v int); CREATE TABLE base_t (i int, v int);
INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30); INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
SELECT create_immv('mv_self(v1, v2)', SELECT pgivm.create_immv('mv_self(v1, v2)',
'SELECT t1.v, t2.v FROM base_t AS t1 JOIN base_t AS t2 ON t1.i = t2.i'); '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; SELECT * FROM mv_self ORDER BY v1;
INSERT INTO base_t VALUES (4,40); INSERT INTO base_t VALUES (4,40);
@ -221,7 +221,7 @@ CREATE TABLE base_r (i int, v int);
CREATE TABLE base_s (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_r VALUES (1, 10), (2, 20), (3, 30);
INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300); INSERT INTO base_s VALUES (1, 100), (2, 200), (3, 300);
SELECT create_immv('mv(v1, v2)', 'SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i)');; SELECT pgivm.create_immv('mv(v1, v2)', 'SELECT r.v, s.v FROM base_r AS r JOIN base_s AS s USING(i)');;
SELECT * FROM mv ORDER BY v1; SELECT * FROM mv ORDER BY v1;
WITH WITH
ins_r AS (INSERT INTO base_r VALUES (1,11) RETURNING 1), ins_r AS (INSERT INTO base_r VALUES (1,11) RETURNING 1),
@ -238,7 +238,7 @@ 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); 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 ri1 VALUES (1),(2),(3);
INSERT INTO ri2 VALUES (1),(2),(3); INSERT INTO ri2 VALUES (1),(2),(3);
SELECT create_immv('mv_ri(i1, i2)', 'SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i)'); SELECT pgivm.create_immv('mv_ri(i1, i2)', 'SELECT ri1.i, ri2.i FROM ri1 JOIN ri2 USING(i)');
SELECT * FROM mv_ri ORDER BY i1; SELECT * FROM mv_ri ORDER BY i1;
UPDATE ri1 SET i=10 where i=1; UPDATE ri1 SET i=10 where i=1;
DELETE FROM ri1 WHERE i=2; DELETE FROM ri1 WHERE i=2;
@ -247,8 +247,8 @@ ROLLBACK;
-- support subquery for using EXISTS() -- support subquery for using EXISTS()
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_exists_subquery', 'SELECT a.i, a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i)'); SELECT pgivm.create_immv('mv_ivm_exists_subquery', 'SELECT a.i, a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i)');
SELECT create_immv('mv_ivm_exists_subquery2', 'SELECT a.i,a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) AND a.i > 2'); SELECT pgivm.create_immv('mv_ivm_exists_subquery2', 'SELECT a.i,a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) AND a.i > 2');
SELECT * FROM mv_ivm_exists_subquery ORDER BY i, j; SELECT * FROM mv_ivm_exists_subquery ORDER BY i, j;
SELECT * FROM mv_ivm_exists_subquery2 ORDER BY i, j; SELECT * FROM mv_ivm_exists_subquery2 ORDER BY i, j;
INSERT INTO mv_base_a VALUES(1,10),(6,60),(3,30),(3,300); INSERT INTO mv_base_a VALUES(1,10),(6,60),(3,30),(3,300);
@ -270,7 +270,7 @@ DELETE FROM mv_base_b WHERE i = 2;
SELECT * FROM mv_ivm_exists_subquery ORDER BY i, j; SELECT * FROM mv_ivm_exists_subquery ORDER BY i, j;
SELECT * FROM mv_ivm_exists_subquery2 ORDER BY i, j; SELECT * FROM mv_ivm_exists_subquery2 ORDER BY i, j;
--- EXISTS subquery with tuple duplication and DISTINCT --- EXISTS subquery with tuple duplication and DISTINCT
SELECT create_immv('mv_ivm_exists_subquery_distinct', 'SELECT DISTINCT a.i, a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i)'); SELECT pgivm.create_immv('mv_ivm_exists_subquery_distinct', 'SELECT DISTINCT a.i, a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i)');
DELETE FROM mv_base_b WHERE i = 1 or i = 3; DELETE FROM mv_base_b WHERE i = 1 or i = 3;
INSERT INTO mv_base_b VALUES (1,100), (3,300); INSERT INTO mv_base_b VALUES (1,100), (3,300);
SELECT * FROM mv_ivm_exists_subquery ORDER BY i, j; SELECT * FROM mv_ivm_exists_subquery ORDER BY i, j;
@ -279,31 +279,31 @@ ROLLBACK;
-- support simple subquery in FROM clause -- support simple subquery in FROM clause
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_subquery', 'SELECT a.i,a.j FROM mv_base_a a,( SELECT * FROM mv_base_b) b WHERE a.i = b.i'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT a.i,a.j FROM mv_base_a a,( SELECT * FROM mv_base_b) b WHERE a.i = b.i');
INSERT INTO mv_base_a VALUES(2,20); INSERT INTO mv_base_a VALUES(2,20);
INSERT INTO mv_base_b VALUES(3,300); INSERT INTO mv_base_b VALUES(3,300);
SELECT * FROM mv_ivm_subquery ORDER BY i,j; SELECT * FROM mv_ivm_subquery ORDER BY i,j;
ROLLBACK; ROLLBACK;
-- disallow non-simple subqueries -- disallow non-simple subqueries
SELECT create_immv('mv_ivm_subquery', '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'); SELECT pgivm.create_immv('mv_ivm_subquery', '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');
SELECT create_immv('mv_ivm_subquery', 'SELECT a.i,a.j FROM mv_base_a a, (SELECT DISTINCT i FROM mv_base_b) b WHERE a.i = b.i'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT a.i,a.j FROM mv_base_a a, (SELECT DISTINCT i FROM mv_base_b) b WHERE a.i = b.i');
SELECT create_immv('mv_ivm_subquery', 'SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 )'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT i,j FROM mv_base_a WHERE i IN (SELECT i FROM mv_base_b WHERE k < 103 )');
SELECT create_immv('mv_ivm_subquery', 'SELECT i,j, (SELECT k FROM mv_base_b LIMIT 1) FROM mv_base_a a'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT i,j, (SELECT k FROM mv_base_b LIMIT 1) FROM mv_base_a a');
SELECT create_immv('mv_ivm_subquery', 'SELECT i,j, (SELECT k FROM mv_base_b LIMIT 1) + 1 FROM mv_base_a a'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT i,j, (SELECT k FROM mv_base_b LIMIT 1) + 1 FROM mv_base_a a');
SELECT create_immv('mv_ivm_subquery', 'SELECT * FROM generate_series(1, (SELECT k FROM mv_base_b LIMIT 1)) AS v'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT * FROM generate_series(1, (SELECT k FROM mv_base_b LIMIT 1)) AS v');
SELECT create_immv('mv_ivm_subquery', 'SELECT a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i)'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i)');
SELECT create_immv('mv_ivm_subquery', '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 > 2'); SELECT pgivm.create_immv('mv_ivm_subquery', '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 > 2');
SELECT create_immv('mv_ivm_subquery', 'SELECT a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_a a2 WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a2.i = b.i))'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT a.j FROM mv_base_a a WHERE EXISTS(SELECT 1 FROM mv_base_a a2 WHERE EXISTS(SELECT 1 FROM mv_base_b b WHERE a2.i = b.i))');
SELECT create_immv('mv_ivm_subquery', 'SELECT EXISTS(SELECT 1 from mv_base_b) FROM mv_base_a a'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT EXISTS(SELECT 1 from mv_base_b) FROM mv_base_a a');
SELECT create_immv('mv_ivm_subquery', 'SELECT false OR EXISTS(SELECT 1 FROM mv_base_a) FROM mv_base_b'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT false OR EXISTS(SELECT 1 FROM mv_base_a) FROM mv_base_b');
SELECT create_immv('mv_ivm_subquery', 'SELECT * FROM generate_series(1, CASE EXISTS(SELECT 1 FROM mv_base_a) WHEN true THEN 100 ELSE 10 END), mv_base_b'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT * FROM generate_series(1, CASE EXISTS(SELECT 1 FROM mv_base_a) WHEN true THEN 100 ELSE 10 END), mv_base_b');
SELECT create_immv('mv_ivm_subquery', 'SELECT * FROM mv_base_a a WHERE CASE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) WHEN true THEN false ELSE true END'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT * FROM mv_base_a a WHERE CASE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) WHEN true THEN false ELSE true END');
SELECT create_immv('mv_ivm_subquery', 'SELECT * FROM mv_base_a a WHERE true and CASE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) WHEN true THEN false ELSE true END'); SELECT pgivm.create_immv('mv_ivm_subquery', 'SELECT * FROM mv_base_a a WHERE true and CASE EXISTS(SELECT 1 FROM mv_base_b b WHERE a.i = b.i) WHEN true THEN false ELSE true END');
-- support join subquery in FROM clause -- support join subquery in FROM clause
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_join_subquery', 'SELECT i, j, k FROM ( SELECT i, a.j, b.k FROM mv_base_b b INNER JOIN mv_base_a a USING(i)) tmp'); SELECT pgivm.create_immv('mv_ivm_join_subquery', 'SELECT i, j, k FROM ( SELECT i, a.j, b.k FROM mv_base_b b INNER JOIN mv_base_a a USING(i)) tmp');
WITH WITH
ai AS (INSERT INTO mv_base_a VALUES (1,11),(2,22) RETURNING 0), ai AS (INSERT INTO mv_base_a VALUES (1,11),(2,22) RETURNING 0),
bi AS (INSERT INTO mv_base_b VALUES (1,111),(3,133) RETURNING 0), bi AS (INSERT INTO mv_base_b VALUES (1,111),(3,133) RETURNING 0),
@ -314,7 +314,7 @@ ROLLBACK;
BEGIN; BEGIN;
-- nested subquery -- nested subquery
SELECT create_immv('mv_ivm_join_subquery', 'SELECT i, j, k FROM ( SELECT i, a.j, b.k FROM mv_base_b b INNER JOIN (SELECT * FROM mv_base_a) a USING(i)) tmp'); SELECT pgivm.create_immv('mv_ivm_join_subquery', 'SELECT i, j, k FROM ( SELECT i, a.j, b.k FROM mv_base_b b INNER JOIN (SELECT * FROM mv_base_a) a USING(i)) tmp');
WITH WITH
ai AS (INSERT INTO mv_base_a VALUES (1,11),(2,22) RETURNING 0), ai AS (INSERT INTO mv_base_a VALUES (1,11),(2,22) RETURNING 0),
bi AS (INSERT INTO mv_base_b VALUES (1,111),(3,133) RETURNING 0), bi AS (INSERT INTO mv_base_b VALUES (1,111),(3,133) RETURNING 0),
@ -325,7 +325,7 @@ ROLLBACK;
-- support simple CTE -- support simple CTE
BEGIN; BEGIN;
SELECT create_immv('mv_cte', SELECT pgivm.create_immv('mv_cte',
'WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i'); 'WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i');
INSERT INTO mv_base_a VALUES(2,20); INSERT INTO mv_base_a VALUES(2,20);
INSERT INTO mv_base_b VALUES(3,300); INSERT INTO mv_base_b VALUES(3,300);
@ -333,7 +333,7 @@ SELECT * FROM mv_cte ORDER BY i,j;
ROLLBACK; ROLLBACK;
BEGIN; BEGIN;
SELECT create_immv('mv_cte', SELECT pgivm.create_immv('mv_cte',
'WITH a AS (SELECT * FROM mv_base_a), b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM a, b WHERE a.i = b.i'); 'WITH a AS (SELECT * FROM mv_base_a), b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM a, b WHERE a.i = b.i');
INSERT INTO mv_base_a VALUES(2,20); INSERT INTO mv_base_a VALUES(2,20);
INSERT INTO mv_base_b VALUES(3,300); INSERT INTO mv_base_b VALUES(3,300);
@ -341,7 +341,7 @@ SELECT * FROM mv_cte ORDER BY i,j;
ROLLBACK; ROLLBACK;
BEGIN; BEGIN;
SELECT create_immv('mv_cte', SELECT pgivm.create_immv('mv_cte',
'WITH b AS ( SELECT * FROM mv_base_b) SELECT v.i,v.j FROM (WITH a AS (SELECT * FROM mv_base_a) SELECT a.i,a.j FROM a, b WHERE a.i = b.i) v'); 'WITH b AS ( SELECT * FROM mv_base_b) SELECT v.i,v.j FROM (WITH a AS (SELECT * FROM mv_base_a) SELECT a.i,a.j FROM a, b WHERE a.i = b.i) v');
INSERT INTO mv_base_a VALUES(2,20); INSERT INTO mv_base_a VALUES(2,20);
INSERT INTO mv_base_b VALUES(3,300); INSERT INTO mv_base_b VALUES(3,300);
@ -349,7 +349,7 @@ SELECT * FROM mv_cte ORDER BY i,j;
ROLLBACK; ROLLBACK;
BEGIN; BEGIN;
SELECT create_immv('mv_cte', SELECT pgivm.create_immv('mv_cte',
'SELECT * FROM (WITH a AS (SELECT * FROM mv_base_a), b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM a, b WHERE a.i = b.i) v'); 'SELECT * FROM (WITH a AS (SELECT * FROM mv_base_a), b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM a, b WHERE a.i = b.i) v');
INSERT INTO mv_base_a VALUES(2,20); INSERT INTO mv_base_a VALUES(2,20);
INSERT INTO mv_base_b VALUES(3,300); INSERT INTO mv_base_b VALUES(3,300);
@ -357,7 +357,7 @@ SELECT * FROM mv_cte ORDER BY i,j;
ROLLBACK; ROLLBACK;
BEGIN; BEGIN;
SELECT create_immv('mv_cte', SELECT pgivm.create_immv('mv_cte',
'WITH b AS ( SELECT * FROM (SELECT * FROM mv_base_b) b2) SELECT v.i,v.j FROM (WITH a AS (SELECT * FROM mv_base_a) SELECT a.i,a.j FROM a, b WHERE a.i = b.i) v'); 'WITH b AS ( SELECT * FROM (SELECT * FROM mv_base_b) b2) SELECT v.i,v.j FROM (WITH a AS (SELECT * FROM mv_base_a) SELECT a.i,a.j FROM a, b WHERE a.i = b.i) v');
INSERT INTO mv_base_a VALUES(2,20); INSERT INTO mv_base_a VALUES(2,20);
INSERT INTO mv_base_b VALUES(3,300); INSERT INTO mv_base_b VALUES(3,300);
@ -365,7 +365,7 @@ SELECT * FROM mv_cte ORDER BY i,j;
ROLLBACK; ROLLBACK;
BEGIN; BEGIN;
SELECT create_immv('mv_cte', SELECT pgivm.create_immv('mv_cte',
'WITH x AS ( SELECT i, a.j, b.k FROM mv_base_b b INNER JOIN mv_base_a a USING(i)) SELECT * FROM x'); 'WITH x AS ( SELECT i, a.j, b.k FROM mv_base_b b INNER JOIN mv_base_a a USING(i)) SELECT * FROM x');
WITH WITH
ai AS (INSERT INTO mv_base_a VALUES (1,11),(2,22) RETURNING 0), ai AS (INSERT INTO mv_base_a VALUES (1,11),(2,22) RETURNING 0),
@ -377,7 +377,7 @@ ROLLBACK;
-- nested CTE -- nested CTE
BEGIN; BEGIN;
SELECT create_immv('mv_ivm_nested_cte', 'WITH v AS ( WITH a AS (SELECT * FROM mv_base_a) SELECT i, a.j, b.k FROM mv_base_b b INNER JOIN a USING(i)) SELECT * FROM v'); SELECT pgivm.create_immv('mv_ivm_nested_cte', 'WITH v AS ( WITH a AS (SELECT * FROM mv_base_a) SELECT i, a.j, b.k FROM mv_base_b b INNER JOIN a USING(i)) SELECT * FROM v');
WITH WITH
ai AS (INSERT INTO mv_base_a VALUES (1,11),(2,22) RETURNING 0), ai AS (INSERT INTO mv_base_a VALUES (1,11),(2,22) RETURNING 0),
bi AS (INSERT INTO mv_base_b VALUES (1,111),(3,133) RETURNING 0), bi AS (INSERT INTO mv_base_b VALUES (1,111),(3,133) RETURNING 0),
@ -390,7 +390,7 @@ ROLLBACK;
BEGIN; BEGIN;
CREATE TABLE base_t (i int, v int); CREATE TABLE base_t (i int, v int);
INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30); INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30);
SELECT create_immv('mv_cte_multi(v1, v2)', SELECT pgivm.create_immv('mv_cte_multi(v1, v2)',
'WITH t AS (SELECT * FROM base_t) SELECT t1.v, t2.v FROM t AS t1 JOIN t AS t2 ON t1.i = t2.i'); 'WITH t AS (SELECT * FROM base_t) SELECT t1.v, t2.v FROM t AS t1 JOIN t AS t2 ON t1.i = t2.i');
SELECT * FROM mv_cte_multi ORDER BY v1; SELECT * FROM mv_cte_multi ORDER BY v1;
INSERT INTO base_t VALUES (4,40); INSERT INTO base_t VALUES (4,40);
@ -407,18 +407,18 @@ SELECT * FROM mv_cte_multi ORDER BY v1;
ROLLBACK; ROLLBACK;
--- disallow not-simple CTE --- disallow not-simple CTE
SELECT create_immv('mv_cte_fail', 'WITH b AS (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i'); SELECT pgivm.create_immv('mv_cte_fail', 'WITH b AS (SELECT i, COUNT(*) FROM mv_base_b GROUP BY i) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i');
SELECT create_immv('mv_cte_fail', 'WITH b AS (SELECT DISTINCT i FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i'); SELECT pgivm.create_immv('mv_cte_fail', 'WITH b AS (SELECT DISTINCT i FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i');
SELECT create_immv('mv_cte_fail', 'WITH a AS (SELECT i, j FROM mv_base_a) SELECT a.i,a.j FROM a WHERE EXISTS(WITH b AS (SELECT i FROM mv_base_b) SELECT 1 FROM b WHERE a.i = b.i)'); SELECT pgivm.create_immv('mv_cte_fail', 'WITH a AS (SELECT i, j FROM mv_base_a) SELECT a.i,a.j FROM a WHERE EXISTS(WITH b AS (SELECT i FROM mv_base_b) SELECT 1 FROM b WHERE a.i = b.i)');
-- unreferenced CTE -- unreferenced CTE
SELECT create_immv('mv_cte_fail', 'WITH b AS (SELECT * FROM mv_base_b) SELECT * FROM mv_base_a a'); SELECT pgivm.create_immv('mv_cte_fail', 'WITH b AS (SELECT * FROM mv_base_b) SELECT * FROM mv_base_a a');
-- views including NULL -- views including NULL
BEGIN; BEGIN;
CREATE TABLE base_t (i int, v int); CREATE TABLE base_t (i int, v int);
INSERT INTO base_t VALUES (1,10),(2, NULL); INSERT INTO base_t VALUES (1,10),(2, NULL);
SELECT create_immv('mv', 'SELECT * FROM base_t'); SELECT pgivm.create_immv('mv', 'SELECT * FROM base_t');
SELECT * FROM mv ORDER BY i; SELECT * FROM mv ORDER BY i;
UPDATE base_t SET v = 20 WHERE i = 2; UPDATE base_t SET v = 20 WHERE i = 2;
SELECT * FROM mv ORDER BY i; SELECT * FROM mv ORDER BY i;
@ -426,7 +426,7 @@ ROLLBACK;
BEGIN; BEGIN;
CREATE TABLE base_t (i int); CREATE TABLE base_t (i int);
SELECT create_immv('mv', 'SELECT * FROM base_t'); SELECT pgivm.create_immv('mv', 'SELECT * FROM base_t');
SELECT * FROM mv ORDER BY i; SELECT * FROM mv ORDER BY i;
INSERT INTO base_t VALUES (1),(NULL); INSERT INTO base_t VALUES (1),(NULL);
SELECT * FROM mv ORDER BY i; SELECT * FROM mv ORDER BY i;
@ -435,7 +435,7 @@ ROLLBACK;
BEGIN; BEGIN;
CREATE TABLE base_t (i int, v int); CREATE TABLE base_t (i int, v int);
INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20); INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (1, 10), (1, 20);
SELECT create_immv('mv', 'SELECT i, sum(v) FROM base_t GROUP BY i'); SELECT pgivm.create_immv('mv', 'SELECT i, sum(v) FROM base_t GROUP BY i');
SELECT * FROM mv ORDER BY i; SELECT * FROM mv ORDER BY i;
UPDATE base_t SET v = v * 10; UPDATE base_t SET v = v * 10;
SELECT * FROM mv ORDER BY i; SELECT * FROM mv ORDER BY i;
@ -444,7 +444,7 @@ ROLLBACK;
BEGIN; BEGIN;
CREATE TABLE base_t (i int, v int); CREATE TABLE base_t (i int, v int);
INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5); INSERT INTO base_t VALUES (NULL, 1), (NULL, 2), (NULL, 3), (NULL, 4), (NULL, 5);
SELECT create_immv('mv', 'SELECT i, min(v), max(v) FROM base_t GROUP BY i'); SELECT pgivm.create_immv('mv', 'SELECT i, min(v), max(v) FROM base_t GROUP BY i');
SELECT * FROM mv ORDER BY i; SELECT * FROM mv ORDER BY i;
DELETE FROM base_t WHERE v = 1; DELETE FROM base_t WHERE v = 1;
SELECT * FROM mv ORDER BY i; SELECT * FROM mv ORDER BY i;
@ -494,7 +494,7 @@ CREATE OPERATOR CLASS mytype_ops
FUNCTION 1 mytype_cmp(mytype,mytype); FUNCTION 1 mytype_cmp(mytype,mytype);
CREATE TABLE t_mytype (x mytype); CREATE TABLE t_mytype (x mytype);
SELECT create_immv('mv_mytype', SELECT pgivm.create_immv('mv_mytype',
'SELECT * FROM t_mytype'); 'SELECT * FROM t_mytype');
INSERT INTO t_mytype VALUES ('1'::mytype); INSERT INTO t_mytype VALUES ('1'::mytype);
SELECT * FROM mv_mytype; SELECT * FROM mv_mytype;
@ -502,82 +502,82 @@ SELECT * FROM mv_mytype;
ROLLBACK; ROLLBACK;
-- outer join is not supported -- outer join is not supported
SELECT create_immv('mv(a,b)', SELECT pgivm.create_immv('mv(a,b)',
'SELECT a.i, b.i FROM mv_base_a a LEFT JOIN mv_base_b b ON a.i=b.i'); 'SELECT a.i, b.i FROM mv_base_a a LEFT JOIN mv_base_b b ON a.i=b.i');
-- contain system column -- contain system column
SELECT create_immv('mv_ivm01', 'SELECT i,j,xmin FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm01', 'SELECT i,j,xmin FROM mv_base_a');
SELECT create_immv('mv_ivm02', 'SELECT i,j FROM mv_base_a WHERE xmin = ''610'''); SELECT pgivm.create_immv('mv_ivm02', 'SELECT i,j FROM mv_base_a WHERE xmin = ''610''');
SELECT create_immv('mv_ivm03', 'SELECT i,j,xmin::text AS x_min FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm03', 'SELECT i,j,xmin::text AS x_min FROM mv_base_a');
SELECT create_immv('mv_ivm04', 'SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm04', 'SELECT i,j,xidsend(xmin) AS x_min FROM mv_base_a');
-- contain ORDER BY -- contain ORDER BY
SELECT create_immv('mv_ivm07', 'SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) ORDER BY i,j,k'); SELECT pgivm.create_immv('mv_ivm07', 'SELECT i,j,k FROM mv_base_a a INNER JOIN mv_base_b b USING(i) ORDER BY i,j,k');
-- contain HAVING -- contain HAVING
SELECT create_immv('mv_ivm08', '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'); SELECT pgivm.create_immv('mv_ivm08', '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 GROUP BY without aggregate -- contain GROUP BY without aggregate
SELECT create_immv('mv_ivm08', 'SELECT i,j FROM mv_base_a GROUP BY i,j'); SELECT pgivm.create_immv('mv_ivm08', 'SELECT i,j FROM mv_base_a GROUP BY i,j');
-- contain view or materialized view -- contain view or materialized view
CREATE VIEW b_view AS SELECT i,k FROM mv_base_b; 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 MATERIALIZED VIEW b_mview AS SELECT i,k FROM mv_base_b;
SELECT create_immv('mv_ivm07', 'SELECT a.i,a.j FROM mv_base_a a,b_view b WHERE a.i = b.i'); SELECT pgivm.create_immv('mv_ivm07', 'SELECT a.i,a.j FROM mv_base_a a,b_view b WHERE a.i = b.i');
SELECT create_immv('mv_ivm08', 'SELECT a.i,a.j FROM mv_base_a a,b_mview b WHERE a.i = b.i'); SELECT pgivm.create_immv('mv_ivm08', 'SELECT a.i,a.j FROM mv_base_a a,b_mview b WHERE a.i = b.i');
-- contain mutable functions -- contain mutable functions
SELECT create_immv('mv_ivm12', 'SELECT i,j FROM mv_base_a WHERE i = random()::int'); SELECT pgivm.create_immv('mv_ivm12', 'SELECT i,j FROM mv_base_a WHERE i = random()::int');
-- LIMIT/OFFSET is not supported -- LIMIT/OFFSET is not supported
SELECT create_immv('mv_ivm13', 'SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5'); SELECT pgivm.create_immv('mv_ivm13', 'SELECT i,j FROM mv_base_a LIMIT 10 OFFSET 5');
-- DISTINCT ON is not supported -- DISTINCT ON is not supported
SELECT create_immv('mv_ivm14', 'SELECT DISTINCT ON(i) i, j FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm14', 'SELECT DISTINCT ON(i) i, j FROM mv_base_a');
-- TABLESAMPLE clause is not supported -- TABLESAMPLE clause is not supported
SELECT create_immv('mv_ivm15', 'SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50)'); SELECT pgivm.create_immv('mv_ivm15', 'SELECT i, j FROM mv_base_a TABLESAMPLE SYSTEM(50)');
-- window functions are not supported -- window functions are not supported
SELECT create_immv('mv_ivm16', 'SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm16', 'SELECT *, cume_dist() OVER (ORDER BY i) AS rank FROM mv_base_a');
-- aggregate function with some options is not supported -- aggregate function with some options is not supported
SELECT create_immv('mv_ivm17', 'SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm17', 'SELECT COUNT(*) FILTER(WHERE i < 3) FROM mv_base_a');
SELECT create_immv('mv_ivm18', 'SELECT COUNT(DISTINCT i) FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm18', 'SELECT COUNT(DISTINCT i) FROM mv_base_a');
SELECT create_immv('mv_ivm19', 'SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm19', 'SELECT array_agg(j ORDER BY i DESC) FROM mv_base_a');
SELECT create_immv('mv_ivm20', 'SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),())'); SELECT pgivm.create_immv('mv_ivm20', 'SELECT i,SUM(j) FROM mv_base_a GROUP BY GROUPING SETS((i),())');
-- inheritance parent is not supported -- inheritance parent is not supported
BEGIN; BEGIN;
CREATE TABLE parent (i int, v int); CREATE TABLE parent (i int, v int);
CREATE TABLE child_a(options text) INHERITS(parent); CREATE TABLE child_a(options text) INHERITS(parent);
SELECT create_immv('mv_ivm21', 'SELECT * FROM parent'); SELECT pgivm.create_immv('mv_ivm21', 'SELECT * FROM parent');
ROLLBACK; ROLLBACK;
-- UNION statement is not supported -- UNION statement is not supported
SELECT create_immv('mv_ivm22', 'SELECT i,j FROM mv_base_a UNION ALL SELECT i,k FROM mv_base_b'); SELECT pgivm.create_immv('mv_ivm22', 'SELECT i,j FROM mv_base_a UNION ALL SELECT i,k FROM mv_base_b');
-- DISTINCT clause in nested query are not supported -- DISTINCT clause in nested query are not supported
SELECT create_immv('mv_ivm23', 'SELECT * FROM (SELECT DISTINCT i,j FROM mv_base_a) AS tmp');; SELECT pgivm.create_immv('mv_ivm23', 'SELECT * FROM (SELECT DISTINCT i,j FROM mv_base_a) AS tmp');;
-- empty target list is not allowed with IVM -- empty target list is not allowed with IVM
SELECT create_immv('mv_ivm25', 'SELECT FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm25', 'SELECT FROM mv_base_a');
-- FOR UPDATE/SHARE is not supported -- FOR UPDATE/SHARE is not supported
SELECT create_immv('mv_ivm26', 'SELECT i,j FROM mv_base_a FOR UPDATE'); SELECT pgivm.create_immv('mv_ivm26', 'SELECT i,j FROM mv_base_a FOR UPDATE');
SELECT create_immv('mv_ivm27', 'SELECT * FROM (SELECT i,j FROM mv_base_a FOR UPDATE) AS tmp;'); SELECT pgivm.create_immv('mv_ivm27', 'SELECT * FROM (SELECT i,j FROM mv_base_a FOR UPDATE) AS tmp;');
-- tartget list cannot contain ivm column that start with '__ivm' -- tartget list cannot contain ivm column that start with '__ivm'
SELECT create_immv('mv_ivm28', 'SELECT i AS "__ivm_count__" FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm28', 'SELECT i AS "__ivm_count__" FROM mv_base_a');
-- expressions specified in GROUP BY must appear in the target list. -- expressions specified in GROUP BY must appear in the target list.
SELECT create_immv('mv_ivm29', 'SELECT COUNT(i) FROM mv_base_a GROUP BY i;'); SELECT pgivm.create_immv('mv_ivm29', 'SELECT COUNT(i) FROM mv_base_a GROUP BY i;');
-- experssions containing an aggregate is not supported -- experssions containing an aggregate is not supported
SELECT create_immv('mv_ivm30', 'SELECT sum(i)*0.5 FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm30', 'SELECT sum(i)*0.5 FROM mv_base_a');
SELECT create_immv('mv_ivm31', 'SELECT sum(i)/sum(j) FROM mv_base_a'); SELECT pgivm.create_immv('mv_ivm31', 'SELECT sum(i)/sum(j) FROM mv_base_a');
-- VALUES is not supported -- VALUES is not supported
SELECT create_immv('mv_ivm_only_values1', 'values(1)'); SELECT pgivm.create_immv('mv_ivm_only_values1', 'values(1)');
SELECT create_immv('mv_ivm_only_values2', 'SELECT * FROM (values(1)) AS tmp'); SELECT pgivm.create_immv('mv_ivm_only_values2', 'SELECT * FROM (values(1)) AS tmp');
-- views containing base tables with Row Level Security -- views containing base tables with Row Level Security
@ -609,7 +609,7 @@ GRANT ALL on num_tbl TO PUBLIC;
--- create a view owned by ivm_user --- create a view owned by ivm_user
SET SESSION AUTHORIZATION ivm_user; SET SESSION AUTHORIZATION ivm_user;
SELECT create_immv('ivm_rls', 'SELECT * FROM rls_tbl'); SELECT pgivm.create_immv('ivm_rls', 'SELECT * FROM rls_tbl');
SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3; SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
RESET SESSION AUTHORIZATION; RESET SESSION AUTHORIZATION;
@ -629,7 +629,7 @@ SELECT id, data, owner FROM ivm_rls ORDER BY 1,2,3;
--- ---
SET SESSION AUTHORIZATION ivm_user; SET SESSION AUTHORIZATION ivm_user;
SELECT create_immv('ivm_rls2', 'SELECT * FROM rls_tbl JOIN num_tbl USING(id)'); SELECT pgivm.create_immv('ivm_rls2', 'SELECT * FROM rls_tbl JOIN num_tbl USING(id)');
RESET SESSION AUTHORIZATION; RESET SESSION AUTHORIZATION;
WITH WITH
@ -650,30 +650,30 @@ CREATE TABLE base_a (i int primary key, j int);
CREATE TABLE base_b (i int primary key, j int); CREATE TABLE base_b (i int primary key, j int);
--- group by: create an index --- group by: create an index
SELECT create_immv('mv_idx1', 'SELECT i, sum(j) FROM base_a GROUP BY i'); SELECT pgivm.create_immv('mv_idx1', 'SELECT i, sum(j) FROM base_a GROUP BY i');
--- distinct: create an index --- distinct: create an index
SELECT create_immv('mv_idx2', 'SELECT DISTINCT j FROM base_a'); SELECT pgivm.create_immv('mv_idx2', 'SELECT DISTINCT j FROM base_a');
--- with all pkey columns: create an index --- with all pkey columns: create an index
SELECT create_immv('mv_idx3(i_a, i_b)', 'SELECT a.i, b.i FROM base_a a, base_b b'); SELECT pgivm.create_immv('mv_idx3(i_a, i_b)', 'SELECT a.i, b.i FROM base_a a, base_b b');
--- missing some pkey columns: no index --- missing some pkey columns: no index
SELECT create_immv('mv_idx4', 'SELECT j FROM base_a'); SELECT pgivm.create_immv('mv_idx4', 'SELECT j FROM base_a');
SELECT create_immv('mv_idx5', 'SELECT a.i, b.j FROM base_a a, base_b b'); SELECT pgivm.create_immv('mv_idx5', 'SELECT a.i, b.j FROM base_a a, base_b b');
--- subqueries: create an index --- subqueries: create an index
SELECT create_immv('mv_idx6(i_a, i_b)', 'SELECT a.i, b.i FROM (SELECT * FROM base_a) a, (SELECT * FROM base_b) b'); SELECT pgivm.create_immv('mv_idx6(i_a, i_b)', 'SELECT a.i, b.i FROM (SELECT * FROM base_a) a, (SELECT * FROM base_b) b');
--- with set-returning function: no index --- with set-returning function: no index
SELECT create_immv('mv_idx7', 'SELECT i FROM base_a, generate_series(1,10)'); SELECT pgivm.create_immv('mv_idx7', 'SELECT i FROM base_a, generate_series(1,10)');
ROLLBACK; ROLLBACK;
-- type that doesn't have default operator class for access method btree -- type that doesn't have default operator class for access method btree
BEGIN; BEGIN;
CREATE TABLE table_json (j json); CREATE TABLE table_json (j json);
SELECT create_immv('mv_json', 'SELECT * from table_json'); SELECT pgivm.create_immv('mv_json', 'SELECT * from table_json');
ROLLBACK; ROLLBACK;
-- prevent IMMV chanages -- prevent IMMV chanages
@ -683,9 +683,9 @@ DELETE FROM mv_ivm_1;
TRUNCATE mv_ivm_1; TRUNCATE mv_ivm_1;
-- get_immv_def function -- get_immv_def function
SELECT immvrelid, get_immv_def(immvrelid) FROM pg_ivm_immv ORDER BY 1; SELECT immvrelid, pgivm.get_immv_def(immvrelid) FROM pgivm.pg_ivm_immv ORDER BY 1;
-- mv_base_b is not immv -- mv_base_b is not immv
SELECT 'mv_base_b'::regclass, get_immv_def('mv_base_b'); SELECT 'mv_base_b'::regclass, pgivm.get_immv_def('mv_base_b');
DROP TABLE mv_base_b CASCADE; DROP TABLE mv_base_b CASCADE;
DROP TABLE mv_base_a CASCADE; DROP TABLE mv_base_a CASCADE;

View file

@ -1,19 +1,19 @@
CREATE TABLE t (i int PRIMARY KEY); CREATE TABLE t (i int PRIMARY KEY);
INSERT INTO t SELECT generate_series(1, 5); INSERT INTO t SELECT generate_series(1, 5);
SELECT create_immv('mv', 'SELECT * FROM t'); SELECT pgivm.create_immv('mv', 'SELECT * FROM t');
SELECT immvrelid, ispopulated FROM pg_ivm_immv ORDER BY 1; SELECT immvrelid, ispopulated FROM pgivm.pg_ivm_immv ORDER BY 1;
-- Refresh IMMV with data -- Refresh IMMV with data
SELECT refresh_immv('mv', true); SELECT pgivm.refresh_immv('mv', true);
SELECT immvrelid, ispopulated FROM pg_ivm_immv ORDER BY 1; SELECT immvrelid, ispopulated FROM pgivm.pg_ivm_immv ORDER BY 1;
INSERT INTO t VALUES(6); INSERT INTO t VALUES(6);
SELECT i FROM mv ORDER BY 1; SELECT i FROM mv ORDER BY 1;
-- Make IMMV unpopulated -- Make IMMV unpopulated
SELECT refresh_immv('mv', false); SELECT pgivm.refresh_immv('mv', false);
SELECT immvrelid, ispopulated FROM pg_ivm_immv ORDER BY 1; SELECT immvrelid, ispopulated FROM pgivm.pg_ivm_immv ORDER BY 1;
SELECT i FROM mv ORDER BY 1; SELECT i FROM mv ORDER BY 1;
-- Immediate maintenance is disabled. IMMV can be scannable and is empty. -- Immediate maintenance is disabled. IMMV can be scannable and is empty.
@ -21,8 +21,8 @@ INSERT INTO t VALUES(7);
SELECT i FROM mv ORDER BY 1; SELECT i FROM mv ORDER BY 1;
-- Refresh the IMMV and make it populated. -- Refresh the IMMV and make it populated.
SELECT refresh_immv('mv', true); SELECT pgivm.refresh_immv('mv', true);
SELECT immvrelid, ispopulated FROM pg_ivm_immv ORDER BY 1; SELECT immvrelid, ispopulated FROM pgivm.pg_ivm_immv ORDER BY 1;
SELECT i FROM mv ORDER BY 1; SELECT i FROM mv ORDER BY 1;
-- Immediate maintenance is enabled. -- Immediate maintenance is enabled.
@ -30,10 +30,10 @@ INSERT INTO t VALUES(8);
SELECT i FROM mv ORDER BY 1; SELECT i FROM mv ORDER BY 1;
-- Use qualified name -- Use qualified name
SELECT refresh_immv('public.mv', true); SELECT pgivm.refresh_immv('public.mv', true);
-- Use not existing IMMV -- Use not existing IMMV
SELECT refresh_immv('mv_not_existing', true); SELECT pgivm.refresh_immv('mv_not_existing', true);
-- Try to refresh a normal table -- error -- Try to refresh a normal table -- error
SELECT refresh_immv('t', true); SELECT pgivm.refresh_immv('t', true);