Skip to content

Commit 167da05

Browse files
committed
MDEV-19790 Wrong result for query with outer join and IS NOT TRUE predicate
in where clause The classes Item_func_isnottrue and Item_func_isnotfalse inherited the implementation of the eval_not_null_tables method from the Item_func class. As a result the not_null_tables_cache was set incorrectly for the objects of these classes. It led to improper conversion of outer joins to inner joins when the where clause of the processed query contained IS NOT TRUE or IS NOT FALSE predicates. The coverted query in many cases produced a wrong result set.
1 parent 039b878 commit 167da05

File tree

4 files changed

+98
-3
lines changed

4 files changed

+98
-3
lines changed

mysql-test/r/join_outer.result

Lines changed: 35 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -2353,7 +2353,7 @@ t1.b1+'0' t2.b2 + '0'
23532353
0 0
23542354
1 1
23552355
DROP TABLE t1, t2;
2356-
set @join_cache_level= @save_join_cache_level;
2356+
set @@join_cache_level= @save_join_cache_level;
23572357
#
23582358
# MDEV-14779: using left join causes incorrect results with materialization and derived tables
23592359
#
@@ -2418,5 +2418,39 @@ WHERE tb1.pk = 40
24182418
ORDER BY tb1.i1;
24192419
v2
24202420
DROP TABLE t1,t2;
2421+
#
2422+
# MDEV-19790 : IS NOT TRUE / IS NOT FALSE predicates over
2423+
# inner tables of outer joins
2424+
#
2425+
create table t1 (a int);
2426+
create table t2 (b int);
2427+
insert into t1 values (3), (7), (1);
2428+
insert into t2 values (7), (4), (3);
2429+
select * from t1 left join t2 on a=b;
2430+
a b
2431+
3 3
2432+
7 7
2433+
1 NULL
2434+
select * from t1 left join t2 on a=b where (b > 3) is not true;
2435+
a b
2436+
3 3
2437+
1 NULL
2438+
explain extended select * from t1 left join t2 on a=b where (b > 3) is not true;
2439+
id select_type table type possible_keys key key_len ref rows filtered Extra
2440+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00
2441+
1 SIMPLE t2 ALL NULL NULL NULL NULL 3 100.00 Using where
2442+
Warnings:
2443+
Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t1` left join `test`.`t2` on((`test`.`t2`.`b` = `test`.`t1`.`a`)) where ((`test`.`t2`.`b` > 3) is not true)
2444+
select * from t1 left join t2 on a=b where (b > 3) is not false;
2445+
a b
2446+
7 7
2447+
1 NULL
2448+
explain extended select * from t1 left join t2 on a=b where (b > 3) is not false;
2449+
id select_type table type possible_keys key key_len ref rows filtered Extra
2450+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00
2451+
1 SIMPLE t2 ALL NULL NULL NULL NULL 3 100.00 Using where
2452+
Warnings:
2453+
Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t1` left join `test`.`t2` on((`test`.`t2`.`b` = `test`.`t1`.`a`)) where ((`test`.`t2`.`b` > 3) is not false)
2454+
drop table t1,t2;
24212455
# end of 5.5 tests
24222456
SET optimizer_switch=@save_optimizer_switch;

mysql-test/r/join_outer_jcl6.result

Lines changed: 35 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -2364,7 +2364,7 @@ t1.b1+'0' t2.b2 + '0'
23642364
0 0
23652365
1 1
23662366
DROP TABLE t1, t2;
2367-
set @join_cache_level= @save_join_cache_level;
2367+
set @@join_cache_level= @save_join_cache_level;
23682368
#
23692369
# MDEV-14779: using left join causes incorrect results with materialization and derived tables
23702370
#
@@ -2429,6 +2429,40 @@ WHERE tb1.pk = 40
24292429
ORDER BY tb1.i1;
24302430
v2
24312431
DROP TABLE t1,t2;
2432+
#
2433+
# MDEV-19790 : IS NOT TRUE / IS NOT FALSE predicates over
2434+
# inner tables of outer joins
2435+
#
2436+
create table t1 (a int);
2437+
create table t2 (b int);
2438+
insert into t1 values (3), (7), (1);
2439+
insert into t2 values (7), (4), (3);
2440+
select * from t1 left join t2 on a=b;
2441+
a b
2442+
7 7
2443+
3 3
2444+
1 NULL
2445+
select * from t1 left join t2 on a=b where (b > 3) is not true;
2446+
a b
2447+
3 3
2448+
1 NULL
2449+
explain extended select * from t1 left join t2 on a=b where (b > 3) is not true;
2450+
id select_type table type possible_keys key key_len ref rows filtered Extra
2451+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00
2452+
1 SIMPLE t2 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (flat, BNL join)
2453+
Warnings:
2454+
Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t1` left join `test`.`t2` on((`test`.`t2`.`b` = `test`.`t1`.`a`)) where ((`test`.`t2`.`b` > 3) is not true)
2455+
select * from t1 left join t2 on a=b where (b > 3) is not false;
2456+
a b
2457+
7 7
2458+
1 NULL
2459+
explain extended select * from t1 left join t2 on a=b where (b > 3) is not false;
2460+
id select_type table type possible_keys key key_len ref rows filtered Extra
2461+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00
2462+
1 SIMPLE t2 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (flat, BNL join)
2463+
Warnings:
2464+
Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t1` left join `test`.`t2` on((`test`.`t2`.`b` = `test`.`t1`.`a`)) where ((`test`.`t2`.`b` > 3) is not false)
2465+
drop table t1,t2;
24322466
# end of 5.5 tests
24332467
SET optimizer_switch=@save_optimizer_switch;
24342468
set join_cache_level=default;

mysql-test/t/join_outer.test

Lines changed: 24 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1895,7 +1895,7 @@ set @save_join_cache_level= @@join_cache_level;
18951895
SET @@join_cache_level = 3;
18961896
SELECT t1.b1+'0' , t2.b2 + '0' FROM t1 LEFT JOIN t2 ON b1 = b2;
18971897
DROP TABLE t1, t2;
1898-
set @join_cache_level= @save_join_cache_level;
1898+
set @@join_cache_level= @save_join_cache_level;
18991899

19001900
--echo #
19011901
--echo # MDEV-14779: using left join causes incorrect results with materialization and derived tables
@@ -1959,6 +1959,29 @@ ORDER BY tb1.i1;
19591959

19601960
DROP TABLE t1,t2;
19611961

1962+
--echo #
1963+
--echo # MDEV-19790 : IS NOT TRUE / IS NOT FALSE predicates over
1964+
--echo # inner tables of outer joins
1965+
--echo #
1966+
1967+
create table t1 (a int);
1968+
create table t2 (b int);
1969+
insert into t1 values (3), (7), (1);
1970+
insert into t2 values (7), (4), (3);
1971+
select * from t1 left join t2 on a=b;
1972+
1973+
let $q=
1974+
select * from t1 left join t2 on a=b where (b > 3) is not true;
1975+
eval $q;
1976+
eval explain extended $q;
1977+
1978+
let $q=
1979+
select * from t1 left join t2 on a=b where (b > 3) is not false;
1980+
eval $q;
1981+
eval explain extended $q;
1982+
1983+
drop table t1,t2;
1984+
19621985
--echo # end of 5.5 tests
19631986

19641987
SET optimizer_switch=@save_optimizer_switch;

sql/item_cmpfunc.h

Lines changed: 4 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -183,6 +183,8 @@ class Item_func_isnottrue : public Item_func_truth
183183
Item_func_isnottrue(Item *a) : Item_func_truth(a, true, false) {}
184184
~Item_func_isnottrue() {}
185185
virtual const char* func_name() const { return "isnottrue"; }
186+
bool eval_not_null_tables(uchar *opt_arg)
187+
{ not_null_tables_cache= 0; return false; }
186188
};
187189

188190

@@ -209,6 +211,8 @@ class Item_func_isnotfalse : public Item_func_truth
209211
Item_func_isnotfalse(Item *a) : Item_func_truth(a, false, false) {}
210212
~Item_func_isnotfalse() {}
211213
virtual const char* func_name() const { return "isnotfalse"; }
214+
bool eval_not_null_tables(uchar *opt_arg)
215+
{ not_null_tables_cache= 0; return false; }
212216
};
213217

214218

0 commit comments

Comments
 (0)