Fix for view using both DISTINCT and EXISTS

In previous commit, maintenance of views using EXISTS and containing
duplicated tuples was fixed, but it was insufficient because it
raised an error during maintenance of views using both DISTINCT
and EXISTS. The cause was that tuples were tried to be duplicated
even when DISTINCT was specified. In this commit, it is fixed not
to duplicate tuples when DISTINCT is used.
This commit is contained in:
Yugo Nagata 2024-02-27 19:32:45 +09:00 committed by thoshiai
parent 8c3b4ba9d7
commit 01f0ea0eb1
3 changed files with 27 additions and 6 deletions

View file

@ -828,6 +828,14 @@ 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;
@ -841,6 +849,15 @@ SELECT * FROM mv_ivm_exists_subquery ORDER BY i, j;
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;

View file

@ -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);
@ -2033,7 +2033,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);
}
@ -2517,7 +2518,7 @@ 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;
@ -2525,6 +2526,7 @@ apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
char *match_cond = "";
StringInfoData deltaname_new_for_insert;
/* build WHERE condition for searching tuples to be updated */
match_cond = get_matching_condition_string(keys);
@ -2551,10 +2553,10 @@ apply_new_delta_with_count(const char *matviewname, const char* deltaname_new,
* 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.
* inserting if DISTINCT is not used.
*/
initStringInfo(&deltaname_new_for_insert);
if (!strcmp(count_colname, "__ivm_count__"))
if (!strcmp(count_colname, "__ivm_count__") || distinct)
appendStringInfo(&deltaname_new_for_insert, "%s", deltaname_new);
else
appendStringInfo(&deltaname_new_for_insert,

View file

@ -269,9 +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
@ -295,7 +298,6 @@ SELECT create_immv('mv_ivm_subquery', 'SELECT a.j FROM mv_base_a a WHERE EXISTS(
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;
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');