diff --git a/README.md b/README.md index 73dc171..1bd1d3d 100644 --- a/README.md +++ b/README.md @@ -80,7 +80,7 @@ When `pg_ivm` is installed, the following objects are created. ### Functions -#### create_imm +#### create_immv Use `create_immv` function to create IMMV. ``` diff --git a/expected/pg_ivm.out b/expected/pg_ivm.out index 33ba313..e8798ee 100644 --- a/expected/pg_ivm.out +++ b/expected/pg_ivm.out @@ -828,6 +828,36 @@ SELECT * FROM mv_ivm_exists_subquery2 ORDER BY i, j; 4 | 40 | 1 (4 rows) +--- 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)'); +NOTICE: created index "mv_ivm_exists_subquery_distinct_index" on immv "mv_ivm_exists_subquery_distinct" + create_immv +------------- + 4 +(1 row) + +DELETE FROM mv_base_b WHERE i = 1 or i = 3; +INSERT INTO mv_base_b VALUES (1,100), (3,300); +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_subquery_distinct ORDER BY i, j; + i | j | __ivm_exists_count_0__ | __ivm_count__ +---+-----+------------------------+--------------- + 1 | 10 | 1 | 2 + 3 | 30 | 1 | 2 + 3 | 300 | 1 | 1 + 4 | 40 | 1 | 1 +(4 rows) + ROLLBACK; -- support simple subquery in FROM clause BEGIN; diff --git a/matview.c b/matview.c index 6b8bd92..e89cb73 100644 --- a/matview.c +++ b/matview.c @@ -195,7 +195,7 @@ static void apply_new_delta(const char *matviewname, const char *deltaname_new, StringInfo target_list); static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new, List *keys, StringInfo target_list, StringInfo aggs_set, - const char* count_colname); + const char* count_colname, bool distinct); static char *get_matching_condition_string(List *keys); static char *get_returning_string(List *minmax_list, List *is_min_list, List *keys); static char *get_minmax_recalc_condition_string(List *minmax_list, List *is_min_list); @@ -2024,7 +2024,8 @@ apply_delta(Oid matviewOid, Tuplestorestate *old_tuplestores, Tuplestorestate *n /* apply new delta */ if (use_count) apply_new_delta_with_count(matviewname, NEW_DELTA_ENRNAME, - keys, aggs_set_new, &target_list_buf, count_colname); + keys, aggs_set_new, &target_list_buf, count_colname, + query->distinctClause != NULL); else apply_new_delta(matviewname, NEW_DELTA_ENRNAME, &target_list_buf); } @@ -2508,12 +2509,14 @@ apply_old_delta(const char *matviewname, const char *deltaname_old, static void apply_new_delta_with_count(const char *matviewname, const char* deltaname_new, List *keys, StringInfo aggs_set, StringInfo target_list, - const char* count_colname) + const char* count_colname, bool distinct) { StringInfoData querybuf; StringInfoData returning_keys; ListCell *lc; char *match_cond = ""; + StringInfoData deltaname_new_for_insert; + /* build WHERE condition for searching tuples to be updated */ match_cond = get_matching_condition_string(keys); @@ -2534,6 +2537,24 @@ apply_new_delta_with_count(const char *matviewname, const char* deltaname_new, else appendStringInfo(&returning_keys, "NULL"); + /* + * If count_colname is not "__ivm_count__", the view contains EXISTS + * subquery and the count column to be updated here is "__ivm_exists_count_*" + * that stores the number of columns generated by corresponding EXISTS + * subquery for each row in the view. In this case, __ivm_count__ in + * deltaname_new stores duplicity of rows, and each row need to be + * duplicated as much as __ivm_count__ by using generate_series at + * inserting if DISTINCT is not used. + */ + initStringInfo(&deltaname_new_for_insert); + if (!strcmp(count_colname, "__ivm_count__") || distinct) + appendStringInfo(&deltaname_new_for_insert, "%s", deltaname_new); + else + appendStringInfo(&deltaname_new_for_insert, + "(SELECT diff.* FROM %s diff," + "pg_catalog.generate_series(1, diff.\"__ivm_count__\"))", + deltaname_new); + /* Search for matching tuples from the view and update if found or insert if not. */ initStringInfo(&querybuf); appendStringInfo(&querybuf, @@ -2552,9 +2573,8 @@ apply_new_delta_with_count(const char *matviewname, const char* deltaname_new, match_cond, returning_keys.data, matviewname, target_list->data, - target_list->data, deltaname_new, + target_list->data, deltaname_new_for_insert.data, match_cond); - if (SPI_exec(querybuf.data, 0) != SPI_OK_INSERT) elog(ERROR, "SPI_exec failed: %s", querybuf.data); } diff --git a/pg_ivm.c b/pg_ivm.c index 33b99c6..a1e6f27 100644 --- a/pg_ivm.c +++ b/pg_ivm.c @@ -385,11 +385,25 @@ PgIvmObjectAccessHook(ObjectAccessType access, Oid classId, if (access == OAT_DROP && classId == RelationRelationId && !OidIsValid(subId)) { - Relation pgIvmImmv = table_open(PgIvmImmvRelationId(), AccessShareLock); + Relation pgIvmImmv; SysScanDesc scan; ScanKeyData key; HeapTuple tup; + Oid pgIvmImmvOid = PgIvmImmvRelationId(); + + /* pg_ivm_immv is not created yet, so there are no IMMVs, either. */ + if (pgIvmImmvOid == InvalidOid) + return; + /* + * When the dropped table is pg_ivm_immv, we don't need to continue + * any more. Also, in this case, the index on it is already dropped, + * so the index scan below will fail and raise an error. + */ + if (objectId == pgIvmImmOid) + return; + + pgIvmImmv = table_open(pgIvmImmvOid, AccessShareLock); ScanKeyInit(&key, Anum_pg_ivm_immv_immvrelid, BTEqualStrategyNumber, F_OIDEQ, diff --git a/sql/pg_ivm.sql b/sql/pg_ivm.sql index 8a9a66d..d3c1a01 100644 --- a/sql/pg_ivm.sql +++ b/sql/pg_ivm.sql @@ -269,6 +269,12 @@ 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; +--- 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)'); +DELETE FROM mv_base_b WHERE i = 1 or i = 3; +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_distinct ORDER BY i, j; ROLLBACK; -- support simple subquery in FROM clause