mirror of
https://github.com/postgres/postgres.git
synced 2025-05-30 00:02:11 -04:00
Fix right-anti-joins when the inner relation is proven unique
For an inner_unique join, we always assume that the executor will stop scanning for matches after the first match. Therefore, for a mergejoin that is inner_unique and whose mergeclauses are sufficient to identify a match, we set the skip_mark_restore flag to true, indicating that the executor need not do mark/restore calls. However, merge-right-anti-join did not get this memo and continues scanning the inner side for matches after the first match. If there are duplicates in the outer scan, we may incorrectly skip matching some inner tuples, which can lead to wrong results. Here we fix this issue by ensuring that merge-right-anti-join also advances to next outer tuple after the first match in inner_unique cases. This also saves cycles by avoiding unnecessary scanning of inner tuples after the first match. Although hash-right-anti-join does not suffer from this wrong results issue, we apply the same change to it as well, to help save cycles for the same reason. Per bug #18522 from Antti Lampinen, and bug #18526 from Feliphe Pozzer. Back-patch to v16 where right-anti-join was introduced. Author: Richard Guo Discussion: https://postgr.es/m/18522-c7a8956126afdfd0@postgresql.org
This commit is contained in:
parent
74b8e6a698
commit
0ffc0acaf3
@ -573,21 +573,22 @@ ExecHashJoinImpl(PlanState *pstate, bool parallel)
|
||||
}
|
||||
|
||||
/*
|
||||
* In a right-antijoin, we never return a matched tuple.
|
||||
* And we need to stay on the current outer tuple to
|
||||
* continue scanning the inner side for matches.
|
||||
*/
|
||||
if (node->js.jointype == JOIN_RIGHT_ANTI)
|
||||
continue;
|
||||
|
||||
/*
|
||||
* If we only need to join to the first matching inner
|
||||
* tuple, then consider returning this one, but after that
|
||||
* continue with next outer tuple.
|
||||
* If we only need to consider the first matching inner
|
||||
* tuple, then advance to next outer tuple after we've
|
||||
* processed this one.
|
||||
*/
|
||||
if (node->js.single_match)
|
||||
node->hj_JoinState = HJ_NEED_NEW_OUTER;
|
||||
|
||||
/*
|
||||
* In a right-antijoin, we never return a matched tuple.
|
||||
* If it's not an inner_unique join, we need to stay on
|
||||
* the current outer tuple to continue scanning the inner
|
||||
* side for matches.
|
||||
*/
|
||||
if (node->js.jointype == JOIN_RIGHT_ANTI)
|
||||
continue;
|
||||
|
||||
if (otherqual == NULL || ExecQual(otherqual, econtext))
|
||||
return ExecProject(node->js.ps.ps_ProjInfo);
|
||||
else
|
||||
|
@ -805,21 +805,22 @@ ExecMergeJoin(PlanState *pstate)
|
||||
}
|
||||
|
||||
/*
|
||||
* In a right-antijoin, we never return a matched tuple.
|
||||
* And we need to stay on the current outer tuple to
|
||||
* continue scanning the inner side for matches.
|
||||
*/
|
||||
if (node->js.jointype == JOIN_RIGHT_ANTI)
|
||||
break;
|
||||
|
||||
/*
|
||||
* If we only need to join to the first matching inner
|
||||
* tuple, then consider returning this one, but after that
|
||||
* continue with next outer tuple.
|
||||
* If we only need to consider the first matching inner
|
||||
* tuple, then advance to next outer tuple after we've
|
||||
* processed this one.
|
||||
*/
|
||||
if (node->js.single_match)
|
||||
node->mj_JoinState = EXEC_MJ_NEXTOUTER;
|
||||
|
||||
/*
|
||||
* In a right-antijoin, we never return a matched tuple.
|
||||
* If it's not an inner_unique join, we need to stay on
|
||||
* the current outer tuple to continue scanning the inner
|
||||
* side for matches.
|
||||
*/
|
||||
if (node->js.jointype == JOIN_RIGHT_ANTI)
|
||||
break;
|
||||
|
||||
qualResult = (otherqual == NULL ||
|
||||
ExecQual(otherqual, econtext));
|
||||
MJ_DEBUG_QUAL(otherqual, qualResult);
|
||||
|
@ -2924,6 +2924,60 @@ select tt1.*, tt2.* from tt2 right join tt1 on tt1.joincol = tt2.joincol;
|
||||
2 | | |
|
||||
(3 rows)
|
||||
|
||||
reset enable_hashjoin;
|
||||
reset enable_nestloop;
|
||||
--
|
||||
-- regression test for bug #18522 (merge-right-anti-join in inner_unique cases)
|
||||
--
|
||||
create temp table tbl_ra(a int unique, b int);
|
||||
insert into tbl_ra select i, i%100 from generate_series(1,1000)i;
|
||||
create index on tbl_ra (b);
|
||||
analyze tbl_ra;
|
||||
set enable_hashjoin to off;
|
||||
set enable_nestloop to off;
|
||||
-- ensure we get a merge right anti join
|
||||
explain (costs off)
|
||||
select * from tbl_ra t1
|
||||
where not exists (select 1 from tbl_ra t2 where t2.b = t1.a) and t1.b < 2;
|
||||
QUERY PLAN
|
||||
-------------------------------------------------------
|
||||
Merge Right Anti Join
|
||||
Merge Cond: (t2.b = t1.a)
|
||||
-> Index Only Scan using tbl_ra_b_idx on tbl_ra t2
|
||||
-> Sort
|
||||
Sort Key: t1.a
|
||||
-> Bitmap Heap Scan on tbl_ra t1
|
||||
Recheck Cond: (b < 2)
|
||||
-> Bitmap Index Scan on tbl_ra_b_idx
|
||||
Index Cond: (b < 2)
|
||||
(9 rows)
|
||||
|
||||
-- and check we get the expected results
|
||||
select * from tbl_ra t1
|
||||
where not exists (select 1 from tbl_ra t2 where t2.b = t1.a) and t1.b < 2;
|
||||
a | b
|
||||
------+---
|
||||
100 | 0
|
||||
101 | 1
|
||||
200 | 0
|
||||
201 | 1
|
||||
300 | 0
|
||||
301 | 1
|
||||
400 | 0
|
||||
401 | 1
|
||||
500 | 0
|
||||
501 | 1
|
||||
600 | 0
|
||||
601 | 1
|
||||
700 | 0
|
||||
701 | 1
|
||||
800 | 0
|
||||
801 | 1
|
||||
900 | 0
|
||||
901 | 1
|
||||
1000 | 0
|
||||
(19 rows)
|
||||
|
||||
reset enable_hashjoin;
|
||||
reset enable_nestloop;
|
||||
--
|
||||
|
@ -693,6 +693,30 @@ select tt1.*, tt2.* from tt2 right join tt1 on tt1.joincol = tt2.joincol;
|
||||
reset enable_hashjoin;
|
||||
reset enable_nestloop;
|
||||
|
||||
--
|
||||
-- regression test for bug #18522 (merge-right-anti-join in inner_unique cases)
|
||||
--
|
||||
|
||||
create temp table tbl_ra(a int unique, b int);
|
||||
insert into tbl_ra select i, i%100 from generate_series(1,1000)i;
|
||||
create index on tbl_ra (b);
|
||||
analyze tbl_ra;
|
||||
|
||||
set enable_hashjoin to off;
|
||||
set enable_nestloop to off;
|
||||
|
||||
-- ensure we get a merge right anti join
|
||||
explain (costs off)
|
||||
select * from tbl_ra t1
|
||||
where not exists (select 1 from tbl_ra t2 where t2.b = t1.a) and t1.b < 2;
|
||||
|
||||
-- and check we get the expected results
|
||||
select * from tbl_ra t1
|
||||
where not exists (select 1 from tbl_ra t2 where t2.b = t1.a) and t1.b < 2;
|
||||
|
||||
reset enable_hashjoin;
|
||||
reset enable_nestloop;
|
||||
|
||||
--
|
||||
-- regression test for bug #13908 (hash join with skew tuples & nbatch increase)
|
||||
--
|
||||
|
Loading…
x
Reference in New Issue
Block a user