Support exists_subquery (#53)

Add EXISTS clause support in IVM
   
Correlated subqueries using EXISTS in WHERE clause are supported.
   
An EXISTS subquery in WHERE clause is rewritten to LATERAL subquery
in FROM clause, and IVM' process can handle this like as a normal join. 
Also, hidden columns "ivm_exists_count_X__"  are added to check if 
EXISTS condition is satisfied.  This column stores the count of how many 
rows in the subquery are correlated to (joined to) each row of the main 
query. When a base table contained in EXISTS clause is modified, this 
count value in IMMV is updated, and a row whose count becomes zero 
is deleted.

restrictions :
- EXISTS subqueries are allowed only in WHERE clause.
- aggregate functions are not supported together with EXISTS.
- EXISTS subqueries in a subquery are not supported.
- EXISTS condition can use only with AND Expr
This commit is contained in:
thoshiai 2023-08-31 11:51:36 +09:00 committed by GitHub
parent 1f729c842a
commit c355f4003b
No known key found for this signature in database
GPG key ID: 4AEE18F83AFDEB23
6 changed files with 599 additions and 26 deletions

View file

@ -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, 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.
Currently, IMMV's view definition can contain inner joins, DISTINCT clause, some built-in aggregate functions, simple sub-queries in `FROM` clause, EXISTS sub-queries, 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.
@ -210,18 +210,19 @@ Also, note that using `sum` or `avg` on `real` (`float4`) type or `double precis
#### Restrictions on Aggregate
If we have a `GROUP BY` clause, expressions specified in `GROUP BY` must appear in the target list. This is how tuples to be updated in the IMMV are identified. These attributes are used as scan keys for searching tuples in the IMMV, so indexes on them are required for efficient IVM.
If we have a `GROUP BY` clause, expressions specified in `GROUP BY` must appear in the target list. This is how tuples to be updated in the IMMV are identified. These attributes are used as scan keys for searching tuples in the IMMV, so indexes on them are required for efficient IVM.
Targetlist cannot contain expressions which contain an aggregate in it.
### Subqueries
Simple subqueries in `FROM` clause are supported.
Simple subqueries in `FROM` clause and EXISTS subqueries in 'WHERE' clause are supported.
#### Restrictions on Subqueries
Subqueries can be used only in `FROM` clause. Subqueries in target list or `WHERE` clause are not supported.
Subqueries using EXISTS and simple subqueries in FROM clause are supported. EXISTS subqueries with condition other than 'AND' and Subqueries in targetlist are not supported. EXISTS subquery is supported only in WHERE but not in the targetlist.
If EXISTS contains columns that refer to columns in tables in the outer query, such columns must be included in the targetlist.
Subqueries containing an aggregate function or `DISTINCT` are not supported.
### CTE

View file

@ -66,6 +66,9 @@ typedef struct
{
bool has_agg;
bool has_subquery;
bool in_exists_subquery; /* true, if it is in a exists subquery */
bool in_jointree; /* true, if it is in a join tree */
List *exists_qual_vars;
int sublevels_up;
} check_ivm_restriction_context;
@ -164,7 +167,7 @@ ExecCreateImmv(ParseState *pstate, CreateTableAsStmt *stmt,
check_ivm_restriction((Node *) query);
/* For IMMV, we need to rewrite matview query */
query = rewriteQueryForIMMV(query, into->colNames);
query = rewriteQueryForIMMV(viewQuery, into->colNames);
}
@ -260,8 +263,12 @@ ExecCreateImmv(ParseState *pstate, CreateTableAsStmt *stmt,
/* Create an index on incremental maintainable materialized view, if possible */
CreateIndexOnIMMV(viewQuery, matviewRel, true);
/* Create triggers on incremental maintainable materialized view */
CreateIvmTriggersOnBaseTables(viewQuery, matviewOid, true);
/*
* Create triggers on incremental maintainable materialized view
* This argument should use 'query'. This needs to use a rewritten query,
* because a sublink in jointree is not supported by this function.
*/
CreateIvmTriggersOnBaseTables(query, matviewOid, true);
/* Create triggers to prevent IMMV from beeing changed */
CreateChangePreventTrigger(matviewOid);
@ -278,6 +285,11 @@ ExecCreateImmv(ParseState *pstate, CreateTableAsStmt *stmt,
*
* count(*) is added for counting distinct tuples in views.
* Also, additional hidden columns are added for aggregate values.
*
* EXISTS sublink is rewritten to LATERAL subquery with HAVING
* clause to check count(*) > 0. In addition, a counting column
* referring to count(*) in this subquery is added to the original
* target list.
*/
Query *
rewriteQueryForIMMV(Query *query, List *colNames)
@ -301,6 +313,50 @@ rewriteQueryForIMMV(Query *query, List *colNames)
rewritten = copyObject(query);
pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
/*
* If this query has EXISTS clause, rewrite query and
* add __ivm_exists_count_X__ column.
*/
if (rewritten->hasSubLinks)
{
ListCell *lc;
RangeTblEntry *rte;
int varno = 0;
/* rewrite EXISTS sublink to LATERAL subquery */
rewrite_query_for_exists_subquery(rewritten);
/* Add counting column referring to count(*) in EXISTS clause */
foreach(lc, rewritten->rtable)
{
char *columnName;
int attnum;
Node *countCol = NULL;
varno++;
rte = (RangeTblEntry *) lfirst(lc);
if (!rte->subquery || !rte->lateral)
continue;
pstate->p_rtable = rewritten->rtable;
columnName = getColumnNameStartWith(rte, "__ivm_exists", &attnum);
if (columnName == NULL)
continue;
countCol = (Node *) makeVar(varno, attnum,
INT8OID, -1, InvalidOid, 0);
if (countCol != NULL)
{
tle = makeTargetEntry((Expr *) countCol,
list_length(rewritten->targetList) + 1,
pstrdup(columnName),
false);
rewritten->targetList = list_concat(rewritten->targetList, list_make1(tle));
}
}
}
/* group keys must be in targetlist */
if (rewritten->groupClause)
{
@ -691,7 +747,7 @@ CreateIvmTrigger(Oid relOid, Oid viewOid, int16 type, int16 timing, bool ex_lock
static void
check_ivm_restriction(Node *node)
{
check_ivm_restriction_context context = {false, false};
check_ivm_restriction_context context = {false, false, false, false, NIL, 0};
check_ivm_restriction_walker(node, &context);
}
@ -841,6 +897,45 @@ 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);
/*
* additional restriction checks for exists subquery
*
* If the query has any EXISTS clauses and columns in them refer to
* columns in tables in the output query, those columns must be
* included in the target list.
*/
if (context->exists_qual_vars != NIL && context->sublevels_up == 0)
{
ListCell *lc;
foreach (lc, context->exists_qual_vars)
{
Var *var = (Var *) lfirst(lc);
ListCell *lc2;
bool found = false;
foreach(lc2, qry->targetList)
{
TargetEntry *tle = lfirst(lc2);
Var *var2;
if (!IsA(tle->expr, Var))
continue;
var2 = (Var *) tle->expr;
if (var->varno == var2->varno && var->varattno == var2->varattno)
{
found = true;
break;
}
}
if (!found)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("this query is not allowed on incrementally maintainable materialized view"),
errhint("targetlist must contain vars that are referred to in EXISTS subquery")));
}
}
break;
}
case T_CommonTableExpr:
@ -874,6 +969,7 @@ check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context)
case T_TargetEntry:
{
TargetEntry *tle = (TargetEntry *)node;
if (isIvmName(tle->resname))
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
@ -886,6 +982,16 @@ check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context)
expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
break;
}
case T_FromExpr:
{
FromExpr *from = (FromExpr *) node;
check_ivm_restriction_walker((Node *)from->fromlist, context);
context->in_jointree = true;
check_ivm_restriction_walker(from->quals, context);
context->in_jointree = false;
break;
}
case T_JoinExpr:
{
JoinExpr *joinexpr = (JoinExpr *)node;
@ -927,12 +1033,44 @@ check_ivm_restriction_walker(Node *node, check_ivm_restriction_context *context)
expression_tree_walker(node, check_ivm_restriction_walker, (void *) context);
break;
}
case T_Var:
{
Var *variable = (Var *) node;
/*
* Currently, only EXISTS clause is allowed here.
* If EXISTS subquery refers to vars of the upper query, collect these vars.
*/
if (variable->varlevelsup > 0 && context->in_exists_subquery)
context->exists_qual_vars = lappend(context->exists_qual_vars, node);
break;
}
case T_SubLink:
{
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("unsupported subquery on incrementally maintainable materialized view"),
errhint("Only simple subquery in FROM clause is supported.")));
/* Currently, EXISTS clause is supported only */
Query *subselect;
SubLink *sublink = (SubLink *) node;
if (!context->in_jointree || sublink->subLinkType != EXISTS_SUBLINK)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("this query is not allowed on incrementally maintainable materialized view"),
errhint("sublink only supports subquery with EXISTS clause in WHERE clause")));
if (context->sublevels_up > 0)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("nested sublink is not supported on incrementally maintainable materialized view")));
subselect = (Query *)sublink->subselect;
/* raise ERROR if the sublink has CTE */
if (subselect->cteList)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("CTE in EXIST clause is not supported on incrementally maintainable materialized view")));
context->in_exists_subquery = true;
context->sublevels_up++;
check_ivm_restriction_walker(sublink->subselect, context);
context->sublevels_up--;
context->in_exists_subquery = false;
break;
}
default:

View file

@ -695,6 +695,139 @@ SELECT * FROM mv_ri ORDER BY i2;
10 | 10
(2 rows)
ROLLBACK;
-- support subquery for using EXISTS()
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)');
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.
HINT: Create an index on the immv for efficient incremental maintenance.
create_immv
-------------
4
(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');
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.
HINT: Create an index on the immv for efficient incremental maintenance.
create_immv
-------------
2
(1 row)
SELECT * FROM mv_ivm_exists_subquery ORDER BY i, j;
i | j | __ivm_exists_count_0__
---+----+------------------------
1 | 10 | 1
2 | 20 | 1
3 | 30 | 1
4 | 40 | 1
(4 rows)
SELECT * FROM mv_ivm_exists_subquery2 ORDER BY i, j;
i | j | __ivm_exists_count_0__
---+----+------------------------
3 | 30 | 1
4 | 40 | 1
(2 rows)
INSERT INTO mv_base_a VALUES(1,10),(6,60),(3,30),(3,300);
SELECT * FROM mv_ivm_exists_subquery ORDER BY i, j;
i | j | __ivm_exists_count_0__
---+-----+------------------------
1 | 10 | 1
1 | 10 | 1
2 | 20 | 1
3 | 30 | 1
3 | 30 | 1
3 | 300 | 1
4 | 40 | 1
(7 rows)
SELECT * FROM mv_ivm_exists_subquery2 ORDER BY i, j;
i | j | __ivm_exists_count_0__
---+-----+------------------------
3 | 30 | 1
3 | 30 | 1
3 | 300 | 1
4 | 40 | 1
(4 rows)
INSERT INTO mv_base_b VALUES(1,101);
INSERT INTO mv_base_b VALUES(1,111);
INSERT INTO mv_base_b VALUES(2,102);
INSERT INTO mv_base_b VALUES(6,106);
SELECT * FROM mv_ivm_exists_subquery ORDER BY i, j;
i | j | __ivm_exists_count_0__
---+-----+------------------------
1 | 10 | 3
1 | 10 | 3
2 | 20 | 2
3 | 30 | 1
3 | 30 | 1
3 | 300 | 1
4 | 40 | 1
6 | 60 | 1
(8 rows)
SELECT * FROM mv_ivm_exists_subquery2 ORDER BY i, j;
i | j | __ivm_exists_count_0__
---+-----+------------------------
3 | 30 | 1
3 | 30 | 1
3 | 300 | 1
4 | 40 | 1
6 | 60 | 1
(5 rows)
UPDATE mv_base_a SET i = 1 WHERE j =60;
UPDATE mv_base_b SET i = 10 WHERE k = 101;
UPDATE mv_base_b SET k = 1002 WHERE k = 102;
SELECT * FROM mv_ivm_exists_subquery ORDER BY i, j;
i | j | __ivm_exists_count_0__
---+-----+------------------------
1 | 10 | 1
1 | 10 | 1
1 | 60 | 1
2 | 20 | 2
3 | 30 | 1
3 | 30 | 1
3 | 300 | 1
4 | 40 | 1
(8 rows)
SELECT * FROM mv_ivm_exists_subquery2 ORDER BY i, j;
i | j | __ivm_exists_count_0__
---+-----+------------------------
3 | 30 | 1
3 | 30 | 1
3 | 300 | 1
4 | 40 | 1
(4 rows)
DELETE FROM mv_base_a WHERE (i,j) = (1,60);
DELETE FROM mv_base_b WHERE i = 2;
SELECT * FROM mv_ivm_exists_subquery ORDER BY i, j;
i | j | __ivm_exists_count_0__
---+-----+------------------------
1 | 10 | 1
1 | 10 | 1
3 | 30 | 1
3 | 30 | 1
3 | 300 | 1
4 | 40 | 1
(6 rows)
SELECT * FROM mv_ivm_exists_subquery2 ORDER BY i, j;
i | j | __ivm_exists_count_0__
---+-----+------------------------
3 | 30 | 1
3 | 30 | 1
3 | 300 | 1
4 | 40 | 1
(4 rows)
ROLLBACK;
-- support simple subquery in FROM clause
BEGIN;
@ -722,25 +855,39 @@ SELECT * FROM mv_ivm_subquery ORDER BY i,j;
ROLLBACK;
-- disallow non-simple subqueries
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)');
ERROR: unsupported subquery on incrementally maintainable materialized view
HINT: Only simple subquery in FROM clause is supported.
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');
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');
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 )');
ERROR: unsupported subquery on incrementally maintainable materialized view
HINT: Only simple subquery in FROM clause is supported.
ERROR: this query is not allowed on incrementally maintainable materialized view
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');
ERROR: unsupported subquery on incrementally maintainable materialized view
HINT: Only simple subquery in FROM clause is supported.
ERROR: this query is not allowed on incrementally maintainable materialized view
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');
ERROR: unsupported subquery on incrementally maintainable materialized view
HINT: Only simple subquery in FROM clause is supported.
ERROR: this query is not allowed on incrementally maintainable materialized view
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');
ERROR: unsupported subquery on incrementally maintainable materialized view
HINT: Only simple subquery in FROM clause is supported.
ERROR: this query is not allowed on incrementally maintainable materialized view
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)');
ERROR: this query is not allowed on incrementally maintainable materialized view
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');
ERROR: this query is not allowed on incrementally maintainable materialized view
HINT: OR or NOT conditions and EXISTS condition are not 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))');
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');
ERROR: this query is not allowed on incrementally maintainable materialized view
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');
ERROR: this query is not allowed on incrementally maintainable materialized view
HINT: sublink only supports subquery with EXISTS clause in WHERE clause
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');
ERROR: this query is not allowed on incrementally maintainable materialized view
HINT: sublink only supports subquery with EXISTS clause in WHERE clause
-- support join subquery in FROM clause
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');
@ -1058,6 +1205,8 @@ SELECT create_immv('mv_cte_fail', 'WITH b AS (SELECT i, COUNT(*) FROM mv_base_b
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
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)');
ERROR: CTE in EXIST clause is 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

255
matview.c
View file

@ -29,6 +29,7 @@
#include "executor/tstoreReceiver.h"
#include "miscadmin.h"
#include "nodes/makefuncs.h"
#include "nodes/nodeFuncs.h"
#include "optimizer/optimizer.h"
#include "parser/analyze.h"
#include "parser/parse_clause.h"
@ -37,6 +38,7 @@
#include "parser/parser.h"
#include "pgstat.h"
#include "rewrite/rewriteHandler.h"
#include "rewrite/rewriteManip.h"
#include "rewrite/rowsecurity.h"
#include "storage/lmgr.h"
#include "tcop/tcopprot.h"
@ -974,6 +976,10 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
i++;
}
/* Rewrite for the EXISTS clause */
if (rewritten->hasSubLinks)
rewrite_query_for_exists_subquery(rewritten);
/* Set all tables in the query to pre-update state */
rewritten = rewrite_query_for_preupdate_state(rewritten, entry->tables,
pstate, NIL, matviewOid);
@ -1035,15 +1041,40 @@ IVM_immediate_maintenance(PG_FUNCTION_ARGS)
foreach(lc2, table->rte_paths)
{
List *rte_path = lfirst(lc2);
int i;
Query *querytree = rewritten;
RangeTblEntry *rte;
TupleDesc tupdesc_old;
TupleDesc tupdesc_new;
bool use_count = false;
char *count_colname = NULL;
count_colname = pstrdup("__ivm_count__");
/* check if the modified table is in EXISTS clause. */
for (i = 0; i < list_length(rte_path); i++)
{
int index = lfirst_int(list_nth_cell(rte_path, i));
rte = (RangeTblEntry *) lfirst(list_nth_cell(querytree->rtable, index - 1));
if (query->hasAggs || query->distinctClause)
if (rte != NULL && rte->rtekind == RTE_SUBQUERY)
{
querytree = rte->subquery;
if (rte->lateral)
{
int attnum;
count_colname = getColumnNameStartWith(rte, "__ivm_exists", &attnum);
if (count_colname)
{
use_count = true;
}
}
}
}
if (count_colname == NULL && (query->hasAggs || query->distinctClause))
{
count_colname = pstrdup("__ivm_count__");
use_count = true;
}
/* calculate delta tables */
calc_delta(table, rte_path, rewritten, dest_old, dest_new,
@ -1475,6 +1506,8 @@ rewrite_query_for_distinct_and_aggregates(Query *query, ParseState *pstate)
TargetEntry *tle_count;
FuncCall *fn;
Node *node;
int varno = 0;
ListCell *tbl_lc;
/* For aggregate views */
if (query->hasAggs)
@ -1493,6 +1526,34 @@ rewrite_query_for_distinct_and_aggregates(Query *query, ParseState *pstate)
query->targetList = list_concat(query->targetList, aggs);
}
/* Add count(*) used for EXISTS clause */
foreach(tbl_lc, query->rtable)
{
RangeTblEntry *rte = (RangeTblEntry *) lfirst(tbl_lc);
varno++;
if (rte->subquery)
{
char *columnName;
int attnum;
/* search ivm_exists_count_X__ column in RangeTblEntry */
columnName = getColumnNameStartWith(rte, "__ivm_exists", &attnum);
if (columnName == NULL)
continue;
node = (Node *)makeVar(varno ,attnum,
INT8OID, -1, InvalidOid, 0);
if (node == NULL)
continue;
tle_count = makeTargetEntry((Expr *) node,
list_length(query->targetList) + 1,
pstrdup(columnName),
false);
query->targetList = lappend(query->targetList, tle_count);
}
}
/* Add count(*) for counting distinct tuples in views */
#if defined(PG_VERSION_NUM) && (PG_VERSION_NUM >= 140000)
fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
@ -1515,6 +1576,170 @@ rewrite_query_for_distinct_and_aggregates(Query *query, ParseState *pstate)
return query;
}
static Query *
rewrite_exists_subquery_walker(Query *query, Node *node, int *count)
{
/* This can recurse, so check for excessive recursion */
check_stack_depth();
switch (nodeTag(node))
{
case T_Query:
{
FromExpr *fromexpr;
/* get subquery in WHERE clause */
fromexpr = (FromExpr *) query->jointree;
if (fromexpr->quals != NULL)
{
query = rewrite_exists_subquery_walker(query, fromexpr->quals, count);
/* drop subquery in WHERE clause */
if (IsA(fromexpr->quals, SubLink))
fromexpr->quals = NULL;
}
break;
}
case T_BoolExpr:
{
BoolExprType type;
type = ((BoolExpr *) node)->boolop;
switch (type)
{
ListCell *lc;
case AND_EXPR:
foreach(lc, ((BoolExpr *)node)->args)
{
/* If simple EXISTS subquery is used, rewrite LATERAL subquery */
Node *opnode = (Node *)lfirst(lc);
query = rewrite_exists_subquery_walker(query, opnode, count);
/*
* overwrite SubLink node to true condition if it is contained in AND_EXPR.
* EXISTS clause have already overwritten to LATERAL, so original EXISTS clause
* is not necessory.
*/
if (IsA(opnode, SubLink))
lfirst(lc) = makeConst(BOOLOID, -1, InvalidOid, sizeof(bool), BoolGetDatum(true), false, true);
}
break;
case OR_EXPR:
case NOT_EXPR:
if (checkExprHasSubLink(node))
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("this query is not allowed on incrementally maintainable materialized view"),
errhint("OR or NOT conditions and EXISTS condition are not used together")));
break;
}
break;
}
case T_SubLink:
{
char aliasName[NAMEDATALEN];
char columnName[NAMEDATALEN];
Query *subselect;
ParseState *pstate;
RangeTblEntry *rte;
RangeTblRef *rtr;
Alias *alias;
Oid opId;
ParseNamespaceItem *nsitem;
TargetEntry *tle_count;
FuncCall *fn;
Node *fn_node;
Expr *opexpr;
SubLink *sublink = (SubLink *)node;
subselect = (Query *)sublink->subselect;
pstate = make_parsestate(NULL);
pstate->p_expr_kind = EXPR_KIND_SELECT_TARGET;
/*
* convert EXISTS subquery into LATERAL subquery in FROM clause.
*/
snprintf(aliasName, sizeof(aliasName), "__ivm_exists_subquery_%d__", *count);
snprintf(columnName, sizeof(columnName), "__ivm_exists_count_%d__", *count);
/* add COUNT(*) for counting rows that meet exists condition */
#if defined(PG_VERSION_NUM) && (PG_VERSION_NUM >= 140000)
fn = makeFuncCall(SystemFuncName("count"), NIL, COERCE_EXPLICIT_CALL, -1);
#else
fn = makeFuncCall(SystemFuncName("count"), NIL, -1);
#endif
fn->agg_star = true;
fn_node = ParseFuncOrColumn(pstate, fn->funcname, NIL, NULL, fn, false, -1);
tle_count = makeTargetEntry((Expr *) fn_node,
list_length(subselect->targetList) + 1,
columnName,
false);
/* add __ivm_exists_count__ column */
subselect->targetList = list_concat(subselect->targetList, list_make1(tle_count));
subselect->hasAggs = true;
/* add a sub-query whth LATERAL into from clause */
alias = makeAlias(aliasName, NIL);
nsitem = addRangeTableEntryForSubquery(pstate, subselect, alias, true, true);
rte = nsitem->p_rte;
query->rtable = lappend(query->rtable, rte);
/* assume the new RTE is at the end */
rtr = makeNode(RangeTblRef);
rtr->rtindex = list_length(query->rtable);
((FromExpr *)query->jointree)->fromlist = lappend(((FromExpr *)query->jointree)->fromlist, rtr);
/*
* EXISTS condition is converted to HAVING count(*) > 0.
* We use make_opcllause() to get int84gt( '>' operator). We might be able to use make_op().
*/
opId = OpernameGetOprid(list_make2(makeString("pg_catalog"), makeString(">")), INT8OID, INT4OID);
opexpr = make_opclause(opId, BOOLOID, false,
(Expr *)fn_node,
(Expr *)makeConst(INT4OID, -1, InvalidOid, sizeof(int32), Int32GetDatum(0), false, true),
InvalidOid, InvalidOid);
fix_opfuncids((Node *) opexpr);
query->hasSubLinks = false;
subselect->havingQual = (Node *)opexpr;
(*count)++;
break;
}
default:
break;
}
return query;
}
/*
* rewrite_query_for_exists_subquery
*
* Rewrite EXISTS sublink in WHERE to LATERAL subquery
* For example, rewrite
* SELECT t1.* FROM t1
* WHERE EXISTS(SELECT 1 FROM t2 WHERE t1.key = t2.key)
* to
* SELECT t1.*, ex.__ivm_exists_count_0__
* FROM t1, LATERAL(
* SELECT 1, COUNT(*) AS __ivm_exists_count_0__
* FROM t2
* WHERE t1.key = t2.key
* HAVING __ivm_exists_count_0__ > 0) AS ex
*/
Query *
rewrite_query_for_exists_subquery(Query *query)
{
int count = 0;
if (query->hasAggs)
ereport(ERROR,
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("this query is not allowed on incrementally maintainable materialized view"),
errhint("aggregate function and EXISTS condition are not supported at the same time")));
return rewrite_exists_subquery_walker(query, (Node *)query, &count);
}
/*
* calc_delta
*
@ -2947,6 +3172,32 @@ clean_up_IVM_hash_entry(MV_TriggerHashEntry *entry, bool is_abort)
hash_search(mv_trigger_info, (void *) &entry->matview_id, HASH_REMOVE, &found);
}
/*
* getColumnNameStartWith
*
* Search a column name which starts with the given string from the given RTE,
* and return the first found one or NULL if not found.
*/
char *
getColumnNameStartWith(RangeTblEntry *rte, char *str, int *attnum)
{
char *colname;
ListCell *lc;
Alias *alias = rte->eref;
(*attnum) = 0;
foreach(lc, alias->colnames)
{
(*attnum)++;
if (strncmp(strVal(lfirst(lc)), str, strlen(str)) == 0)
{
colname = pstrdup(strVal(lfirst(lc)));
return colname;
}
}
return NULL;
}
/*
* isIvmName
*

View file

@ -52,8 +52,10 @@ extern bool ImmvIncrementalMaintenanceIsEnabled(void);
extern Query *get_immv_query(Relation matviewRel);
extern Datum IVM_immediate_before(PG_FUNCTION_ARGS);
extern Datum IVM_immediate_maintenance(PG_FUNCTION_ARGS);
extern Query* rewrite_query_for_exists_subquery(Query *query);
extern Datum ivm_visible_in_prestate(PG_FUNCTION_ARGS);
extern void AtAbort_IVM(void);
extern char *getColumnNameStartWith(RangeTblEntry *rte, char *str, int *attnum);
extern bool isIvmName(const char *s);
/* ruleutils.c */

View file

@ -245,6 +245,32 @@ DELETE FROM ri1 WHERE i=2;
SELECT * FROM mv_ri ORDER BY i2;
ROLLBACK;
-- support subquery for using EXISTS()
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 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_subquery2 ORDER BY i, j;
INSERT INTO mv_base_a VALUES(1,10),(6,60),(3,30),(3,300);
SELECT * FROM mv_ivm_exists_subquery ORDER BY i, j;
SELECT * FROM mv_ivm_exists_subquery2 ORDER BY i, j;
INSERT INTO mv_base_b VALUES(1,101);
INSERT INTO mv_base_b VALUES(1,111);
INSERT INTO mv_base_b VALUES(2,102);
INSERT INTO mv_base_b VALUES(6,106);
SELECT * FROM mv_ivm_exists_subquery ORDER BY i, j;
SELECT * FROM mv_ivm_exists_subquery2 ORDER BY i, j;
UPDATE mv_base_a SET i = 1 WHERE j =60;
UPDATE mv_base_b SET i = 10 WHERE k = 101;
UPDATE mv_base_b SET k = 1002 WHERE k = 102;
SELECT * FROM mv_ivm_exists_subquery ORDER BY i, j;
SELECT * FROM mv_ivm_exists_subquery2 ORDER BY i, j;
DELETE FROM mv_base_a WHERE (i,j) = (1,60);
DELETE FROM mv_base_b WHERE i = 2;
SELECT * FROM mv_ivm_exists_subquery ORDER BY i, j;
SELECT * FROM mv_ivm_exists_subquery2 ORDER BY i, j;
ROLLBACK;
-- support simple subquery in FROM clause
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');
@ -254,13 +280,18 @@ SELECT * FROM mv_ivm_subquery ORDER BY i,j;
ROLLBACK;
-- disallow non-simple subqueries
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 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 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 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 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 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 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');
-- support join subquery in FROM clause
BEGIN;
@ -370,6 +401,7 @@ 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');
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)');
-- unreferenced CTE
SELECT create_immv('mv_cte_fail', 'WITH b AS (SELECT * FROM mv_base_b) SELECT * FROM mv_base_a a');