diff --git a/README.md b/README.md index 252bb8d..8dc4a3b 100644 --- a/README.md +++ b/README.md @@ -188,7 +188,7 @@ Time: 3224.741 ms (00:03.225) ## Supported View Definitions and Restriction -Currently, IMMV's view definition can contain inner joins, DISTINCT clause, some built-in aggregate functions, and simple sub-queries in `FROM` clause. Inner joins including self-join are supported, but outer joins are not supported. Supported aggregate functions are count, sum, avg, min and max. Other aggregates, sub-queries which contain an aggregate or `DISTINCT` clause, sub-queries in other than `FROM` clause, CTEs, window functions, `HAVING`, `ORDER BY`, `LIMIT`/`OFFSET`, `UNION`/`INTERSECT`/`EXCEPT`, `DISTINCT ON`, `TABLESAMPLE`, `VALUES`, and `FOR UPDATE`/`SHARE` can not be used in view definition. +Currently, IMMV's view definition can contain inner joins, DISTINCT clause, some built-in aggregate functions, simple sub-queries in `FROM` clause, and simple CTE (`WITH` query). Inner joins including self-join are supported, but outer joins are not supported. Supported aggregate functions are count, sum, avg, min and max. Other aggregates, sub-queries which contain an aggregate or `DISTINCT` clause, sub-queries in other than `FROM` clause, window functions, `HAVING`, `ORDER BY`, `LIMIT`/`OFFSET`, `UNION`/`INTERSECT`/`EXCEPT`, `DISTINCT ON`, `TABLESAMPLE`, `VALUES`, and `FOR UPDATE`/`SHARE` can not be used in view definition. The base tables must be simple tables. Views, materialized views, inheritance parent tables, partitioned tables, partitions, and foreign tables can not be used. @@ -224,6 +224,16 @@ Subqueries can be used only in `FROM` clause. Subqueries in target list or `WHER Subqueries containing an aggregate function or `DISTINCT` are not supported. +### CTE + +Simple CTEs (`WITH` queries) are supported. + +#### Restrictions on Subqueries + +`WITH` queries containing an aggregate function or `DISTINCT` are not supported. + +Recursive queries (`WITH RECURSIVE`) are not allowed. Unreferenced CTEs are not allowed either, that is, a CTE must be referenced at least once in the view definition query. + ### DISTINCT `DISTINCT` is allowed in IMMV's definition queries. Suppose an IMMV defined with DISTINCT on a base table containing duplicate tuples. When tuples are deleted from the base table, a tuple in the view is deleted if and only if the multiplicity of the tuple becomes zero. Moreover, when tuples are inserted into the base table, a tuple is inserted into the view only if the same tuple doesn't already exist in it. diff --git a/createas.c b/createas.c index dd7eeaf..2ecc4f1 100644 --- a/createas.c +++ b/createas.c @@ -749,7 +749,7 @@ check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context) if (qry->hasRecursive) ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), - errmsg("recursive CTE is not supported on incrementally maintainable materialized view"))); + errmsg("recursive query is not supported on incrementally maintainable materialized view"))); /* system column restrictions */ vars = pull_vars_of_level((Node *) qry, 0); @@ -843,7 +843,21 @@ check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context) if (isIvmName(cte->ctename)) ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), - errmsg("CTE name %s is not supported on incrementally maintainable materialized view", cte->ctename))); + errmsg("WITH query name %s is not supported on incrementally maintainable materialized view", cte->ctename))); + + /* + * When a table in a unreferenced CTE is TRUNCATEd, the contents of the + * IMMV is not affected so it must not be truncated. For confirming it + * at the maintenance time, we have to check if the modified table used + * in a CTE is actually referenced. Although it would be possible, we + * just disallow to create such IMMVs for now since such unreferenced + * CTE is useless unless it doesn't contain modifying commands, that is + * already prohibited. + */ + if (cte->cterefcount == 0) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("Ureferenced WITH query is not supported on incrementally maintainable materialized view"))); context->sublevels_up++; check_ivm_restriction_walker(cte->ctequery, (void *) context); diff --git a/expected/pg_ivm.out b/expected/pg_ivm.out index 518547d..7f5ded0 100644 --- a/expected/pg_ivm.out +++ b/expected/pg_ivm.out @@ -739,6 +739,39 @@ SELECT * FROM mv_ivm_join_subquery ORDER BY i,j,k; 3 | 30 | 133 (8 rows) +ROLLBACK; +BEGIN; +-- 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'); +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. +HINT: Create an index on the immv for efficient incremental maintenance. + create_immv +------------- + 4 +(1 row) + +WITH + 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), + bd AS (DELETE FROM mv_base_b WHERE i = 4 RETURNING 0) +SELECT; +-- +(1 row) + +SELECT * FROM mv_ivm_join_subquery ORDER BY i,j,k; + i | j | k +---+----+----- + 1 | 10 | 101 + 1 | 10 | 111 + 1 | 11 | 101 + 1 | 11 | 111 + 2 | 20 | 102 + 2 | 22 | 102 + 3 | 30 | 103 + 3 | 30 | 133 +(8 rows) + ROLLBACK; -- support simple CTE BEGIN; @@ -898,12 +931,102 @@ SELECT * FROM mv_cte ORDER BY i,j,k; 3 | 30 | 133 (8 rows) -END; -- don't remove for get_immv_def test +ROLLBACK; +-- nested CTE +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'); +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. +HINT: Create an index on the immv for efficient incremental maintenance. + create_immv +------------- + 4 +(1 row) + +WITH + 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), + bd AS (DELETE FROM mv_base_b WHERE i = 4 RETURNING 0) +SELECT; +-- +(1 row) + +SELECT * FROM mv_ivm_nested_cte ORDER BY i,j,k; + i | j | k +---+----+----- + 1 | 10 | 101 + 1 | 10 | 111 + 1 | 11 | 101 + 1 | 11 | 111 + 2 | 20 | 102 + 2 | 22 | 102 + 3 | 30 | 103 + 3 | 30 | 133 +(8 rows) + +ROLLBACK; +-- Multiply-referenced CTE +BEGIN; +CREATE TABLE base_t (i int, v int); +INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30); +SELECT 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'); +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. +HINT: Create an index on the immv for efficient incremental maintenance. + create_immv +------------- + 3 +(1 row) + +SELECT * FROM mv_cte_multi ORDER BY v1; + v1 | v2 +----+---- + 10 | 10 + 20 | 20 + 30 | 30 +(3 rows) + +INSERT INTO base_t VALUES (4,40); +DELETE FROM base_t WHERE i = 1; +UPDATE base_t SET v = v*10 WHERE i=2; +SELECT * FROM mv_cte_multi ORDER BY v1; + v1 | v2 +-----+----- + 30 | 30 + 40 | 40 + 200 | 200 +(3 rows) + +WITH + ins_t1 AS (INSERT INTO base_t VALUES (5,50) RETURNING 1), + ins_t2 AS (INSERT INTO base_t VALUES (6,60) RETURNING 1), + upd_t AS (UPDATE base_t SET v = v + 100 RETURNING 1), + dlt_t AS (DELETE FROM base_t WHERE i IN (4,5) RETURNING 1) +SELECT NULL; + ?column? +---------- + +(1 row) + +SELECT * FROM mv_cte_multi ORDER BY v1; + v1 | v2 +-----+----- + 50 | 50 + 60 | 60 + 130 | 130 + 300 | 300 +(4 rows) + +ROLLBACK; --- 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'); 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'); ERROR: DISTINCT clause in nested query are not supported on incrementally maintainable materialized view +-- unreferenced CTE +SELECT 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 -- views including NULL BEGIN; CREATE TABLE base_t (i int, v int); @@ -1315,25 +1438,14 @@ TRUNCATE mv_ivm_1; ERROR: cannot change materialized view "mv_ivm_1" -- get_immv_def function SELECT immvrelid, get_immv_def(immvrelid) FROM pg_ivm_immv ORDER BY 1; - immvrelid | get_immv_def ------------+------------------------------------------ - mv_ivm_1 | SELECT a.i, + - | a.j, + - | b.k + - | FROM (mv_base_a a + + immvrelid | get_immv_def +-----------+---------------------------------- + mv_ivm_1 | SELECT a.i, + + | a.j, + + | b.k + + | FROM (mv_base_a a + | JOIN mv_base_b b USING (i)) - mv_cte | WITH x AS ( + - | SELECT b.i, + - | a.j, + - | b.k + - | FROM (mv_base_b b + - | JOIN mv_base_a a USING (i))+ - | ) + - | SELECT i, + - | j, + - | k + - | FROM x -(2 rows) +(1 row) -- mv_base_b is not immv SELECT 'mv_base_b'::regclass, get_immv_def('mv_base_b'); @@ -1343,9 +1455,8 @@ SELECT 'mv_base_b'::regclass, get_immv_def('mv_base_b'); (1 row) DROP TABLE mv_base_b CASCADE; -NOTICE: drop cascades to 4 other objects +NOTICE: drop cascades to 3 other objects DETAIL: drop cascades to table mv_ivm_1 -drop cascades to table mv_cte drop cascades to view b_view drop cascades to materialized view b_mview DROP TABLE mv_base_a CASCADE; diff --git a/sql/pg_ivm.sql b/sql/pg_ivm.sql index 564aa92..ac558e3 100644 --- a/sql/pg_ivm.sql +++ b/sql/pg_ivm.sql @@ -233,7 +233,6 @@ SELECT create_immv('mv_ivm_subquery', 'SELECT a.i,a.j FROM mv_base_a a,( SELECT INSERT INTO mv_base_a VALUES(2,20); INSERT INTO mv_base_b VALUES(3,300); SELECT * FROM mv_ivm_subquery ORDER BY i,j; - ROLLBACK; -- disallow non-simple subqueries @@ -254,7 +253,17 @@ WITH bd AS (DELETE FROM mv_base_b WHERE i = 4 RETURNING 0) SELECT; SELECT * FROM mv_ivm_join_subquery ORDER BY i,j,k; +ROLLBACK; +BEGIN; +-- 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'); +WITH + 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), + bd AS (DELETE FROM mv_base_b WHERE i = 4 RETURNING 0) +SELECT; +SELECT * FROM mv_ivm_join_subquery ORDER BY i,j,k; ROLLBACK; -- support simple CTE @@ -307,12 +316,46 @@ WITH bd AS (DELETE FROM mv_base_b WHERE i = 4 RETURNING 0) SELECT; SELECT * FROM mv_cte ORDER BY i,j,k; -END; -- don't remove for get_immv_def test +ROLLBACK; + +-- nested CTE +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'); +WITH + 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), + bd AS (DELETE FROM mv_base_b WHERE i = 4 RETURNING 0) +SELECT; +SELECT * FROM mv_ivm_nested_cte ORDER BY i,j,k; +ROLLBACK; + +-- Multiply-referenced CTE +BEGIN; +CREATE TABLE base_t (i int, v int); +INSERT INTO base_t VALUES (1, 10), (2, 20), (3, 30); +SELECT 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'); +SELECT * FROM mv_cte_multi ORDER BY v1; +INSERT INTO base_t VALUES (4,40); +DELETE FROM base_t WHERE i = 1; +UPDATE base_t SET v = v*10 WHERE i=2; +SELECT * FROM mv_cte_multi ORDER BY v1; +WITH + ins_t1 AS (INSERT INTO base_t VALUES (5,50) RETURNING 1), + ins_t2 AS (INSERT INTO base_t VALUES (6,60) RETURNING 1), + upd_t AS (UPDATE base_t SET v = v + 100 RETURNING 1), + dlt_t AS (DELETE FROM base_t WHERE i IN (4,5) RETURNING 1) +SELECT NULL; +SELECT * FROM mv_cte_multi ORDER BY v1; +ROLLBACK; --- 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 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'); +-- unreferenced CTE +SELECT create_immv('mv_cte_fail', 'WITH b AS (SELECT * FROM mv_base_b) SELECT * FROM mv_base_a a'); + -- views including NULL BEGIN; CREATE TABLE base_t (i int, v int);