Skip to content

Commit b21832e

Browse files
committed
MDEV-27624 Wrong result for nested left join using not_exists optimization
This bug affected queries with nested left joins having the same last inner table such that not_exists optimization could be applied to the most inner outer join when optimizer chose to use join buffers. The bug could lead to producing wrong a result set. If the WHERE condition a query contains a conjunctive IS NULL predicate over a non-nullable column of an inner table of a not nested outer join then not_exists optimization can be applied to tho the outer join. With this optimization when looking for matches for a certain record from the outer table of the join the records of the inner table can be ignored right after the first match satisfying the ON condition is found. In the case of nested outer joins having the same last inner table this optimization still can be applied but only if all ON conditions of the embedding outer joins are satisfied. Such check was missing in the code that tried to apply not_exists optimization when join buffers were used for outer join operations. This problem has been already fixed in the patch for bug MDEV-7992. Yet there it was resolved only for the cases when join buffers were not used for outer joins. Approved by Oleksandr Byelkin <sanja@mariadb.com>
1 parent af0ff8b commit b21832e

File tree

4 files changed

+171
-6
lines changed

4 files changed

+171
-6
lines changed

mysql-test/main/join_nested.result

Lines changed: 52 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1999,3 +1999,55 @@ Note 1003 select `test`.`t3`.`pk` AS `pk`,`test`.`t3`.`c1` AS `c1`,`test`.`t3`.`
19991999
DROP TABLE t1,t2,t3;
20002000
set join_cache_level= @save_join_cache_level;
20012001
set optimizer_switch=@save_optimizer_switch;
2002+
#
2003+
# MDEV-27624: Nested left joins with not_exists optimization
2004+
# for most inner left join
2005+
#
2006+
set @save_join_cache_level= @@join_cache_level;
2007+
CREATE TABLE t1 (a INT NOT NULL, b INT, c INT);
2008+
INSERT INTO t1 VALUES (1,1,1), (1,2,1), (1,3,1);
2009+
CREATE TABLE t2(a INT NOT NULL);
2010+
INSERT INTO t2 VALUES (1), (2);
2011+
CREATE TABLE t3(a INT not null, b INT);
2012+
INSERT INTO t3 VALUES (1, 1), (2, 1), (3, 1);
2013+
set join_cache_level = 0;
2014+
EXPLAIN SELECT *
2015+
FROM t1
2016+
LEFT JOIN
2017+
( t2 LEFT JOIN t3 ON t2.a = t3.b )
2018+
ON t2.a = 1 AND (t3.b = t1.a AND t3.a > t1.b OR t3.a is NULL)
2019+
WHERE t1.c = 1 AND t3.a is NULL;
2020+
id select_type table type possible_keys key key_len ref rows Extra
2021+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using where
2022+
1 SIMPLE t2 ALL NULL NULL NULL NULL 2 Using where
2023+
1 SIMPLE t3 ALL NULL NULL NULL NULL 3 Using where; Not exists
2024+
SELECT *
2025+
FROM t1
2026+
LEFT JOIN
2027+
( t2 LEFT JOIN t3 ON t2.a = t3.b )
2028+
ON t2.a = 1 AND (t3.b = t1.a AND t3.a > t1.b OR t3.a is NULL)
2029+
WHERE t1.c = 1 AND t3.a is NULL;
2030+
a b c a a b
2031+
1 3 1 NULL NULL NULL
2032+
set join_cache_level = 2;
2033+
EXPLAIN SELECT *
2034+
FROM t1
2035+
LEFT JOIN
2036+
( t2 LEFT JOIN t3 ON t2.a = t3.b )
2037+
ON t2.a = 1 AND (t3.b = t1.a AND t3.a > t1.b OR t3.a is NULL)
2038+
WHERE t1.c = 1 AND t3.a is NULL;
2039+
id select_type table type possible_keys key key_len ref rows Extra
2040+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using where
2041+
1 SIMPLE t2 ALL NULL NULL NULL NULL 2 Using where; Using join buffer (flat, BNL join)
2042+
1 SIMPLE t3 ALL NULL NULL NULL NULL 3 Using where; Not exists; Using join buffer (incremental, BNL join)
2043+
SELECT *
2044+
FROM t1
2045+
LEFT JOIN
2046+
( t2 LEFT JOIN t3 ON t2.a = t3.b )
2047+
ON t2.a = 1 AND (t3.b = t1.a AND t3.a > t1.b OR t3.a is NULL)
2048+
WHERE t1.c = 1 AND t3.a is NULL;
2049+
a b c a a b
2050+
1 3 1 NULL NULL NULL
2051+
DROP TABLE t1, t2, t3;
2052+
set join_cache_level= @save_join_cache_level;
2053+
# end of 10.3 tests

mysql-test/main/join_nested.test

Lines changed: 38 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1419,3 +1419,41 @@ DROP TABLE t1,t2,t3;
14191419
set join_cache_level= @save_join_cache_level;
14201420

14211421
set optimizer_switch=@save_optimizer_switch;
1422+
1423+
--echo #
1424+
--echo # MDEV-27624: Nested left joins with not_exists optimization
1425+
--echo # for most inner left join
1426+
--echo #
1427+
1428+
set @save_join_cache_level= @@join_cache_level;
1429+
1430+
CREATE TABLE t1 (a INT NOT NULL, b INT, c INT);
1431+
INSERT INTO t1 VALUES (1,1,1), (1,2,1), (1,3,1);
1432+
1433+
CREATE TABLE t2(a INT NOT NULL);
1434+
INSERT INTO t2 VALUES (1), (2);
1435+
1436+
CREATE TABLE t3(a INT not null, b INT);
1437+
INSERT INTO t3 VALUES (1, 1), (2, 1), (3, 1);
1438+
1439+
let $q=
1440+
SELECT *
1441+
FROM t1
1442+
LEFT JOIN
1443+
( t2 LEFT JOIN t3 ON t2.a = t3.b )
1444+
ON t2.a = 1 AND (t3.b = t1.a AND t3.a > t1.b OR t3.a is NULL)
1445+
WHERE t1.c = 1 AND t3.a is NULL;
1446+
1447+
set join_cache_level = 0;
1448+
eval EXPLAIN $q;
1449+
eval $q;
1450+
1451+
set join_cache_level = 2;
1452+
eval EXPLAIN $q;
1453+
eval $q;
1454+
1455+
DROP TABLE t1, t2, t3;
1456+
1457+
set join_cache_level= @save_join_cache_level;
1458+
1459+
--echo # end of 10.3 tests

mysql-test/main/join_nested_jcl6.result

Lines changed: 52 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2008,6 +2008,58 @@ Note 1003 select `test`.`t3`.`pk` AS `pk`,`test`.`t3`.`c1` AS `c1`,`test`.`t3`.`
20082008
DROP TABLE t1,t2,t3;
20092009
set join_cache_level= @save_join_cache_level;
20102010
set optimizer_switch=@save_optimizer_switch;
2011+
#
2012+
# MDEV-27624: Nested left joins with not_exists optimization
2013+
# for most inner left join
2014+
#
2015+
set @save_join_cache_level= @@join_cache_level;
2016+
CREATE TABLE t1 (a INT NOT NULL, b INT, c INT);
2017+
INSERT INTO t1 VALUES (1,1,1), (1,2,1), (1,3,1);
2018+
CREATE TABLE t2(a INT NOT NULL);
2019+
INSERT INTO t2 VALUES (1), (2);
2020+
CREATE TABLE t3(a INT not null, b INT);
2021+
INSERT INTO t3 VALUES (1, 1), (2, 1), (3, 1);
2022+
set join_cache_level = 0;
2023+
EXPLAIN SELECT *
2024+
FROM t1
2025+
LEFT JOIN
2026+
( t2 LEFT JOIN t3 ON t2.a = t3.b )
2027+
ON t2.a = 1 AND (t3.b = t1.a AND t3.a > t1.b OR t3.a is NULL)
2028+
WHERE t1.c = 1 AND t3.a is NULL;
2029+
id select_type table type possible_keys key key_len ref rows Extra
2030+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using where
2031+
1 SIMPLE t2 ALL NULL NULL NULL NULL 2 Using where
2032+
1 SIMPLE t3 ALL NULL NULL NULL NULL 3 Using where; Not exists
2033+
SELECT *
2034+
FROM t1
2035+
LEFT JOIN
2036+
( t2 LEFT JOIN t3 ON t2.a = t3.b )
2037+
ON t2.a = 1 AND (t3.b = t1.a AND t3.a > t1.b OR t3.a is NULL)
2038+
WHERE t1.c = 1 AND t3.a is NULL;
2039+
a b c a a b
2040+
1 3 1 NULL NULL NULL
2041+
set join_cache_level = 2;
2042+
EXPLAIN SELECT *
2043+
FROM t1
2044+
LEFT JOIN
2045+
( t2 LEFT JOIN t3 ON t2.a = t3.b )
2046+
ON t2.a = 1 AND (t3.b = t1.a AND t3.a > t1.b OR t3.a is NULL)
2047+
WHERE t1.c = 1 AND t3.a is NULL;
2048+
id select_type table type possible_keys key key_len ref rows Extra
2049+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using where
2050+
1 SIMPLE t2 ALL NULL NULL NULL NULL 2 Using where; Using join buffer (flat, BNL join)
2051+
1 SIMPLE t3 ALL NULL NULL NULL NULL 3 Using where; Not exists; Using join buffer (incremental, BNL join)
2052+
SELECT *
2053+
FROM t1
2054+
LEFT JOIN
2055+
( t2 LEFT JOIN t3 ON t2.a = t3.b )
2056+
ON t2.a = 1 AND (t3.b = t1.a AND t3.a > t1.b OR t3.a is NULL)
2057+
WHERE t1.c = 1 AND t3.a is NULL;
2058+
a b c a a b
2059+
1 3 1 NULL NULL NULL
2060+
DROP TABLE t1, t2, t3;
2061+
set join_cache_level= @save_join_cache_level;
2062+
# end of 10.3 tests
20112063
CREATE TABLE t5 (a int, b int, c int, PRIMARY KEY(a), KEY b_i (b));
20122064
CREATE TABLE t6 (a int, b int, c int, PRIMARY KEY(a), KEY b_i (b));
20132065
CREATE TABLE t7 (a int, b int, c int, PRIMARY KEY(a), KEY b_i (b));

sql/sql_join_cache.cc

Lines changed: 29 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -2287,11 +2287,7 @@ enum_nested_loop_state JOIN_CACHE::join_matching_records(bool skip_last)
22872287
int error;
22882288
enum_nested_loop_state rc= NESTED_LOOP_OK;
22892289
join_tab->table->null_row= 0;
2290-
bool check_only_first_match=
2291-
join_tab->check_only_first_match() &&
2292-
(!join_tab->first_inner || // semi-join case
2293-
join_tab->first_inner == join_tab->first_unmatched); // outer join case
2294-
bool outer_join_first_inner= join_tab->is_first_inner_for_outer_join();
2290+
bool check_only_first_match= join_tab->check_only_first_match();
22952291
DBUG_ENTER("JOIN_CACHE::join_matching_records");
22962292

22972293
/* Return at once if there are no records in the join buffer */
@@ -2355,7 +2351,34 @@ enum_nested_loop_state JOIN_CACHE::join_matching_records(bool skip_last)
23552351
Also those records that must be null complemented are not considered
23562352
as candidates for matches.
23572353
*/
2358-
if ((!check_only_first_match && !outer_join_first_inner) ||
2354+
2355+
bool not_exists_opt_is_applicable= true;
2356+
if (check_only_first_match && join_tab->first_inner)
2357+
{
2358+
/*
2359+
This is the case with not_exists optimization for nested outer join
2360+
when join_tab is the last inner table for one or more embedding outer
2361+
joins. To safely use 'not_exists' optimization in this case we have
2362+
to check that the match flags for all these embedding outer joins are
2363+
in the 'on' state.
2364+
(See also a similar check in evaluate_join_record() for the case when
2365+
join buffer are not used.)
2366+
*/
2367+
for (JOIN_TAB *tab= join_tab->first_inner;
2368+
tab && tab->first_inner && tab->last_inner == join_tab;
2369+
tab= tab->first_inner->first_upper)
2370+
{
2371+
if (get_match_flag_by_pos_from_join_buffer(rec_ptr, tab) !=
2372+
MATCH_FOUND)
2373+
{
2374+
not_exists_opt_is_applicable= false;
2375+
break;
2376+
}
2377+
}
2378+
}
2379+
2380+
if (!check_only_first_match ||
2381+
(join_tab->first_inner && !not_exists_opt_is_applicable) ||
23592382
!skip_next_candidate_for_match(rec_ptr))
23602383
{
23612384
read_next_candidate_for_match(rec_ptr);

0 commit comments

Comments
 (0)