diff --git a/Makefile b/Makefile index ab4f6ea..2083ff2 100644 --- a/Makefile +++ b/Makefile @@ -6,7 +6,8 @@ OBJS = \ createas.o \ matview.o \ pg_ivm.o \ - ruleutils.o + ruleutils.o \ + subselect.o PGFILEDESC = "pg_ivm - incremental view maintenance on PostgreSQL" EXTENSION = pg_ivm 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 31fd06b..937ebc8 100644 --- a/createas.c +++ b/createas.c @@ -522,8 +522,15 @@ CreateIvmTriggersOnBaseTablesRecurse(Query *qry, Node *node, Oid matviewOid, case T_Query: { Query *query = (Query *) node; + ListCell *lc; CreateIvmTriggersOnBaseTablesRecurse(qry, (Node *)query->jointree, matviewOid, relids, ex_lock); + foreach(lc, query->cteList) + { + CommonTableExpr *cte = (CommonTableExpr *) lfirst(lc); + Assert(IsA(cte->ctequery, Query)); + CreateIvmTriggersOnBaseTablesRecurse((Query *) cte->ctequery, cte->ctequery, matviewOid, relids, ex_lock); + } } break; @@ -706,11 +713,6 @@ check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context) ListCell *lc; List *vars; - /* if contained CTE, return error */ - if (qry->cteList != NIL) - ereport(ERROR, - (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), - errmsg("CTE is not supported on incrementally maintainable materialized view"))); if (qry->groupClause != NIL && !qry->hasAggs) ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), @@ -751,6 +753,10 @@ check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context) ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), errmsg("FOR UPDATE/SHARE clause is not supported on incrementally maintainable materialized view"))); + if (qry->hasRecursive) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("recursive query is not supported on incrementally maintainable materialized view"))); /* system column restrictions */ vars = pull_vars_of_level((Node *) qry, 0); @@ -835,6 +841,34 @@ check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context) query_tree_walker(qry, check_ivm_restriction_walker, (void *) context, QTW_IGNORE_RT_SUBQUERIES); + break; + } + case T_CommonTableExpr: + { + CommonTableExpr *cte = (CommonTableExpr *) node; + + if (isIvmName(cte->ctename)) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + 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); + context->sublevels_up--; break; } case T_TargetEntry: @@ -1315,6 +1349,21 @@ get_primary_key_attnos_from_query(Query *query, List **constraintList, bool is_c Bitmapset *keys = NULL; Relids rels_in_from; + /* convert CTEs to subqueries */ + query = copyObject(query); + foreach (lc, query->cteList) + { + PlannerInfo root; + CommonTableExpr *cte = (CommonTableExpr *) lfirst(lc); + + if (cte->cterefcount == 0) + continue; + + root.parse = query; + inline_cte(&root, cte); + } + query->cteList = NIL; + /* * Collect primary key attributes from all tables used in query. The key attributes * sets for each table are stored in key_attnos_list in order by RTE index. diff --git a/expected/pg_ivm.out b/expected/pg_ivm.out index e8f56f1..7f5ded0 100644 --- a/expected/pg_ivm.out +++ b/expected/pg_ivm.out @@ -740,6 +740,293 @@ SELECT * FROM mv_ivm_join_subquery ORDER BY i,j,k; (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; +SELECT 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'); +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. +HINT: Create an index on the immv for efficient incremental maintenance. + create_immv +------------- + 4 +(1 row) + +INSERT INTO mv_base_a VALUES(2,20); +INSERT INTO mv_base_b VALUES(3,300); +SELECT * FROM mv_cte ORDER BY i,j; + i | j +---+---- + 1 | 10 + 2 | 20 + 2 | 20 + 3 | 30 + 3 | 30 + 4 | 40 +(6 rows) + +ROLLBACK; +BEGIN; +SELECT 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'); +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. +HINT: Create an index on the immv for efficient incremental maintenance. + create_immv +------------- + 4 +(1 row) + +INSERT INTO mv_base_a VALUES(2,20); +INSERT INTO mv_base_b VALUES(3,300); +SELECT * FROM mv_cte ORDER BY i,j; + i | j +---+---- + 1 | 10 + 2 | 20 + 2 | 20 + 3 | 30 + 3 | 30 + 4 | 40 +(6 rows) + +ROLLBACK; +BEGIN; +SELECT 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'); +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. +HINT: Create an index on the immv for efficient incremental maintenance. + create_immv +------------- + 4 +(1 row) + +INSERT INTO mv_base_a VALUES(2,20); +INSERT INTO mv_base_b VALUES(3,300); +SELECT * FROM mv_cte ORDER BY i,j; + i | j +---+---- + 1 | 10 + 2 | 20 + 2 | 20 + 3 | 30 + 3 | 30 + 4 | 40 +(6 rows) + +ROLLBACK; +BEGIN; +SELECT 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'); +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. +HINT: Create an index on the immv for efficient incremental maintenance. + create_immv +------------- + 4 +(1 row) + +INSERT INTO mv_base_a VALUES(2,20); +INSERT INTO mv_base_b VALUES(3,300); +SELECT * FROM mv_cte ORDER BY i,j; + i | j +---+---- + 1 | 10 + 2 | 20 + 2 | 20 + 3 | 30 + 3 | 30 + 4 | 40 +(6 rows) + +ROLLBACK; +BEGIN; +SELECT 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'); +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. +HINT: Create an index on the immv for efficient incremental maintenance. + create_immv +------------- + 4 +(1 row) + +INSERT INTO mv_base_a VALUES(2,20); +INSERT INTO mv_base_b VALUES(3,300); +SELECT * FROM mv_cte ORDER BY i,j; + i | j +---+---- + 1 | 10 + 2 | 20 + 2 | 20 + 3 | 30 + 3 | 30 + 4 | 40 +(6 rows) + +ROLLBACK; +BEGIN; +SELECT 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'); +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. +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_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; +-- 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); @@ -917,10 +1204,6 @@ ROLLBACK; SELECT 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'); ERROR: OUTER JOIN is not supported on incrementally maintainable materialized view --- CTE is not supported -SELECT create_immv('mv', - 'WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i;'); -ERROR: CTE is not supported on incrementally maintainable materialized view -- contain system column SELECT create_immv('mv_ivm01', 'SELECT i,j,xmin FROM mv_base_a'); ERROR: system column is not supported on incrementally maintainable materialized view diff --git a/matview.c b/matview.c index ae2b02b..4a2d3e1 100644 --- a/matview.c +++ b/matview.c @@ -1125,6 +1125,20 @@ rewrite_query_for_preupdate_state(Query *query, List *tables, /* XXX: Is necessary? Is this right timing? */ AcquireRewriteLocks(query, true, false); + /* convert CTEs to subqueries */ + foreach (lc, query->cteList) + { + PlannerInfo root; + CommonTableExpr *cte = (CommonTableExpr *) lfirst(lc); + + if (cte->cterefcount == 0) + continue; + + root.parse = query; + inline_cte(&root, cte); + } + query->cteList = NIL; + i = 1; foreach(lc, query->rtable) { diff --git a/pg_ivm.h b/pg_ivm.h index dd9429a..d7d5759 100644 --- a/pg_ivm.h +++ b/pg_ivm.h @@ -15,6 +15,7 @@ #include "catalog/objectaddress.h" #include "fmgr.h" #include "nodes/params.h" +#include "nodes/pathnodes.h" #include "parser/parse_node.h" #include "tcop/dest.h" #include "utils/queryenvironment.h" @@ -59,4 +60,7 @@ extern bool isIvmName(const char *s); extern char *pg_ivm_get_viewdef(Relation immvrel, bool pretty); +/* subselect.c */ +extern void inline_cte(PlannerInfo *root, CommonTableExpr *cte); + #endif diff --git a/sql/pg_ivm.sql b/sql/pg_ivm.sql index 9c4dfec..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,8 +253,108 @@ 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 +BEGIN; +SELECT 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'); +INSERT INTO mv_base_a VALUES(2,20); +INSERT INTO mv_base_b VALUES(3,300); +SELECT * FROM mv_cte ORDER BY i,j; +ROLLBACK; + +BEGIN; +SELECT 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'); +INSERT INTO mv_base_a VALUES(2,20); +INSERT INTO mv_base_b VALUES(3,300); +SELECT * FROM mv_cte ORDER BY i,j; +ROLLBACK; + +BEGIN; +SELECT 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'); +INSERT INTO mv_base_a VALUES(2,20); +INSERT INTO mv_base_b VALUES(3,300); +SELECT * FROM mv_cte ORDER BY i,j; +ROLLBACK; + +BEGIN; +SELECT 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'); +INSERT INTO mv_base_a VALUES(2,20); +INSERT INTO mv_base_b VALUES(3,300); +SELECT * FROM mv_cte ORDER BY i,j; +ROLLBACK; + +BEGIN; +SELECT 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'); +INSERT INTO mv_base_a VALUES(2,20); +INSERT INTO mv_base_b VALUES(3,300); +SELECT * FROM mv_cte ORDER BY i,j; +ROLLBACK; + +BEGIN; +SELECT 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 + 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_cte ORDER BY i,j,k; +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; @@ -348,10 +447,6 @@ ROLLBACK; SELECT 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'); --- CTE is not supported -SELECT create_immv('mv', - 'WITH b AS ( SELECT * FROM mv_base_b) SELECT a.i,a.j FROM mv_base_a a, b WHERE a.i = b.i;'); - -- contain system column SELECT 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'''); diff --git a/subselect.c b/subselect.c new file mode 100644 index 0000000..9c88fea --- /dev/null +++ b/subselect.c @@ -0,0 +1,112 @@ +/*------------------------------------------------------------------------- + * + * subselect.c + * incremental view maintenance extension + * Routines for CTE support. + * + * Portions Copyright (c) 2023, IVM Development Group + * Portions Copyright (c) 1996-2022, PostgreSQL Global Development Group + * Portions Copyright (c) 1994, Regents of the University of California + * + *------------------------------------------------------------------------- + */ + +#include "postgres.h" + +#include "nodes/nodeFuncs.h" +#include "rewrite/rewriteManip.h" + +#include "pg_ivm.h" + +typedef struct inline_cte_walker_context +{ + const char *ctename; /* name and relative level of target CTE */ + int levelsup; + Query *ctequery; /* query to substitute */ +} inline_cte_walker_context; + +static bool inline_cte_walker(Node *node, inline_cte_walker_context *context); + +/* + * inline_cte: convert RTE_CTE references to given CTE into RTE_SUBQUERYs + */ +void +inline_cte(PlannerInfo *root, CommonTableExpr *cte) +{ + struct inline_cte_walker_context context; + + context.ctename = cte->ctename; + /* Start at levelsup = -1 because we'll immediately increment it */ + context.levelsup = -1; + context.ctequery = castNode(Query, cte->ctequery); + + (void) inline_cte_walker((Node *) root->parse, &context); +} + +static bool +inline_cte_walker(Node *node, inline_cte_walker_context *context) +{ + if (node == NULL) + return false; + if (IsA(node, Query)) + { + Query *query = (Query *) node; + + context->levelsup++; + + /* + * Visit the query's RTE nodes after their contents; otherwise + * query_tree_walker would descend into the newly inlined CTE query, + * which we don't want. + */ + (void) query_tree_walker(query, inline_cte_walker, context, + QTW_EXAMINE_RTES_AFTER); + + context->levelsup--; + + return false; + } + else if (IsA(node, RangeTblEntry)) + { + RangeTblEntry *rte = (RangeTblEntry *) node; + + if (rte->rtekind == RTE_CTE && + strcmp(rte->ctename, context->ctename) == 0 && + rte->ctelevelsup == context->levelsup) + { + /* + * Found a reference to replace. Generate a copy of the CTE query + * with appropriate level adjustment for outer references (e.g., + * to other CTEs). + */ + Query *newquery = copyObject(context->ctequery); + + if (context->levelsup > 0) + IncrementVarSublevelsUp((Node *) newquery, context->levelsup, 1); + + /* + * Convert the RTE_CTE RTE into a RTE_SUBQUERY. + * + * Historically, a FOR UPDATE clause has been treated as extending + * into views and subqueries, but not into CTEs. We preserve this + * distinction by not trying to push rowmarks into the new + * subquery. + */ + rte->rtekind = RTE_SUBQUERY; + rte->subquery = newquery; + rte->security_barrier = false; + + /* Zero out CTE-specific fields */ + rte->ctename = NULL; + rte->ctelevelsup = 0; + rte->self_reference = false; + rte->coltypes = NIL; + rte->coltypmods = NIL; + rte->colcollations = NIL; + } + + return false; + } + + return expression_tree_walker(node, inline_cte_walker, context); +}