Commit 6b70cc53 authored by unknown's avatar unknown

Fix bug lp:813473

The bug is a duplicate of MySQL's Bug#11764086,
however MySQL's fix is incomplete for MariaDB, so
this fix is slightly different.

In addition, this patch renames
Item_func_not_all::top_level() to is_top_level_item()
to make it in line with the analogous methods of
Item_in_optimizer, and Item_subselect.

Analysis:
It is possible to determine whether a predicate is
NULL-rejecting only if it is a top-level one. However,
this was not taken into account for Item_in_optimizer.
As a result, a NOT IN predicate was erroneously
considered as NULL-rejecting, and the NULL-complemented
rows generated by the outer join were rejected before
being checked by the NOT IN predicate.

Solution:
Change Item_in_optimizer to be considered as
NULL-rejecting only if it a top-level predicate.
parent f240aa4c
......@@ -5147,6 +5147,31 @@ NULL
NULL
5
DROP TABLE t1, t2, t3;
#
# BUG LP:813473: Wrong result with outer join + NOT IN subquery
# This bug is a duplicate of Bug#11764086 whose test case is added below
#
CREATE TABLE t1 (c int) ;
INSERT INTO t1 VALUES (5),(6);
CREATE TABLE t2 (a int, b int) ;
INSERT INTO t2 VALUES (20,9),(20,9);
create table t3 (d int, e int);
insert into t3 values (2, 9), (3,10);
EXPLAIN
SELECT t2.b , t1.c
FROM t2 LEFT JOIN t1 ON t1.c < 3
WHERE (t2.b , t1.c) NOT IN (SELECT * from t3);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 2
1 PRIMARY t1 ALL NULL NULL NULL NULL 2 Using where
2 DEPENDENT SUBQUERY t3 ALL NULL NULL NULL NULL 2 Using where
SELECT t2.b , t1.c
FROM t2 LEFT JOIN t1 ON t1.c < 3
WHERE (t2.b, t1.c) NOT IN (SELECT * from t3);
b c
9 NULL
9 NULL
drop table t1, t2, t3;
End of 5.3 tests
End of 5.5 tests.
#
......@@ -5175,6 +5200,54 @@ SELECT 1 FROM t1 WHERE 1 < SOME (SELECT a1 FROM t2);
SET SESSION sql_mode=@old_sql_mode;
DROP TABLE t1, t2;
#
# Bug#11764086: Null left operand to NOT IN in WHERE clause
# behaves differently than real NULL
#
CREATE TABLE parent (id int);
INSERT INTO parent VALUES (1), (2);
CREATE TABLE child (parent_id int, other int);
INSERT INTO child VALUES (1,NULL);
# Offending query (c.parent_id is NULL for null-complemented rows only)
SELECT p.id, c.parent_id
FROM parent p
LEFT JOIN child c
ON p.id = c.parent_id
WHERE c.parent_id NOT IN (
SELECT parent_id
FROM child
WHERE parent_id = 3
);
id parent_id
1 1
2 NULL
# Some syntactic variations with IS FALSE and IS NOT TRUE
SELECT p.id, c.parent_id
FROM parent p
LEFT JOIN child c
ON p.id = c.parent_id
WHERE c.parent_id IN (
SELECT parent_id
FROM child
WHERE parent_id = 3
) IS NOT TRUE;
id parent_id
1 1
2 NULL
SELECT p.id, c.parent_id
FROM parent p
LEFT JOIN child c
ON p.id = c.parent_id
WHERE c.parent_id IN (
SELECT parent_id
FROM child
WHERE parent_id = 3
) IS FALSE;
id parent_id
1 1
2 NULL
DROP TABLE parent, child;
# End of test for bug#11764086.
#
# BUG#50257: Missing info in REF column of the EXPLAIN
# lines for subselects
#
......
......@@ -5152,6 +5152,31 @@ NULL
NULL
5
DROP TABLE t1, t2, t3;
#
# BUG LP:813473: Wrong result with outer join + NOT IN subquery
# This bug is a duplicate of Bug#11764086 whose test case is added below
#
CREATE TABLE t1 (c int) ;
INSERT INTO t1 VALUES (5),(6);
CREATE TABLE t2 (a int, b int) ;
INSERT INTO t2 VALUES (20,9),(20,9);
create table t3 (d int, e int);
insert into t3 values (2, 9), (3,10);
EXPLAIN
SELECT t2.b , t1.c
FROM t2 LEFT JOIN t1 ON t1.c < 3
WHERE (t2.b , t1.c) NOT IN (SELECT * from t3);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 2
1 PRIMARY t1 ALL NULL NULL NULL NULL 2 Using where
2 DEPENDENT SUBQUERY t3 ALL NULL NULL NULL NULL 2 Using where
SELECT t2.b , t1.c
FROM t2 LEFT JOIN t1 ON t1.c < 3
WHERE (t2.b, t1.c) NOT IN (SELECT * from t3);
b c
9 NULL
9 NULL
drop table t1, t2, t3;
End of 5.3 tests
End of 5.5 tests.
#
......@@ -5180,6 +5205,54 @@ SELECT 1 FROM t1 WHERE 1 < SOME (SELECT a1 FROM t2);
SET SESSION sql_mode=@old_sql_mode;
DROP TABLE t1, t2;
#
# Bug#11764086: Null left operand to NOT IN in WHERE clause
# behaves differently than real NULL
#
CREATE TABLE parent (id int);
INSERT INTO parent VALUES (1), (2);
CREATE TABLE child (parent_id int, other int);
INSERT INTO child VALUES (1,NULL);
# Offending query (c.parent_id is NULL for null-complemented rows only)
SELECT p.id, c.parent_id
FROM parent p
LEFT JOIN child c
ON p.id = c.parent_id
WHERE c.parent_id NOT IN (
SELECT parent_id
FROM child
WHERE parent_id = 3
);
id parent_id
1 1
2 NULL
# Some syntactic variations with IS FALSE and IS NOT TRUE
SELECT p.id, c.parent_id
FROM parent p
LEFT JOIN child c
ON p.id = c.parent_id
WHERE c.parent_id IN (
SELECT parent_id
FROM child
WHERE parent_id = 3
) IS NOT TRUE;
id parent_id
1 1
2 NULL
SELECT p.id, c.parent_id
FROM parent p
LEFT JOIN child c
ON p.id = c.parent_id
WHERE c.parent_id IN (
SELECT parent_id
FROM child
WHERE parent_id = 3
) IS FALSE;
id parent_id
1 1
2 NULL
DROP TABLE parent, child;
# End of test for bug#11764086.
#
# BUG#50257: Missing info in REF column of the EXPLAIN
# lines for subselects
#
......
......@@ -5148,6 +5148,31 @@ NULL
NULL
5
DROP TABLE t1, t2, t3;
#
# BUG LP:813473: Wrong result with outer join + NOT IN subquery
# This bug is a duplicate of Bug#11764086 whose test case is added below
#
CREATE TABLE t1 (c int) ;
INSERT INTO t1 VALUES (5),(6);
CREATE TABLE t2 (a int, b int) ;
INSERT INTO t2 VALUES (20,9),(20,9);
create table t3 (d int, e int);
insert into t3 values (2, 9), (3,10);
EXPLAIN
SELECT t2.b , t1.c
FROM t2 LEFT JOIN t1 ON t1.c < 3
WHERE (t2.b , t1.c) NOT IN (SELECT * from t3);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 2
1 PRIMARY t1 ALL NULL NULL NULL NULL 2 Using where
2 DEPENDENT SUBQUERY t3 ALL NULL NULL NULL NULL 2 Using where
SELECT t2.b , t1.c
FROM t2 LEFT JOIN t1 ON t1.c < 3
WHERE (t2.b, t1.c) NOT IN (SELECT * from t3);
b c
9 NULL
9 NULL
drop table t1, t2, t3;
End of 5.3 tests
End of 5.5 tests.
#
......@@ -5176,6 +5201,54 @@ SELECT 1 FROM t1 WHERE 1 < SOME (SELECT a1 FROM t2);
SET SESSION sql_mode=@old_sql_mode;
DROP TABLE t1, t2;
#
# Bug#11764086: Null left operand to NOT IN in WHERE clause
# behaves differently than real NULL
#
CREATE TABLE parent (id int);
INSERT INTO parent VALUES (1), (2);
CREATE TABLE child (parent_id int, other int);
INSERT INTO child VALUES (1,NULL);
# Offending query (c.parent_id is NULL for null-complemented rows only)
SELECT p.id, c.parent_id
FROM parent p
LEFT JOIN child c
ON p.id = c.parent_id
WHERE c.parent_id NOT IN (
SELECT parent_id
FROM child
WHERE parent_id = 3
);
id parent_id
1 1
2 NULL
# Some syntactic variations with IS FALSE and IS NOT TRUE
SELECT p.id, c.parent_id
FROM parent p
LEFT JOIN child c
ON p.id = c.parent_id
WHERE c.parent_id IN (
SELECT parent_id
FROM child
WHERE parent_id = 3
) IS NOT TRUE;
id parent_id
1 1
2 NULL
SELECT p.id, c.parent_id
FROM parent p
LEFT JOIN child c
ON p.id = c.parent_id
WHERE c.parent_id IN (
SELECT parent_id
FROM child
WHERE parent_id = 3
) IS FALSE;
id parent_id
1 1
2 NULL
DROP TABLE parent, child;
# End of test for bug#11764086.
#
# BUG#50257: Missing info in REF column of the EXPLAIN
# lines for subselects
#
......
......@@ -5148,6 +5148,31 @@ NULL
NULL
5
DROP TABLE t1, t2, t3;
#
# BUG LP:813473: Wrong result with outer join + NOT IN subquery
# This bug is a duplicate of Bug#11764086 whose test case is added below
#
CREATE TABLE t1 (c int) ;
INSERT INTO t1 VALUES (5),(6);
CREATE TABLE t2 (a int, b int) ;
INSERT INTO t2 VALUES (20,9),(20,9);
create table t3 (d int, e int);
insert into t3 values (2, 9), (3,10);
EXPLAIN
SELECT t2.b , t1.c
FROM t2 LEFT JOIN t1 ON t1.c < 3
WHERE (t2.b , t1.c) NOT IN (SELECT * from t3);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 2
1 PRIMARY t1 ALL NULL NULL NULL NULL 2 Using where
2 DEPENDENT SUBQUERY t3 ALL NULL NULL NULL NULL 2 Using where
SELECT t2.b , t1.c
FROM t2 LEFT JOIN t1 ON t1.c < 3
WHERE (t2.b, t1.c) NOT IN (SELECT * from t3);
b c
9 NULL
9 NULL
drop table t1, t2, t3;
End of 5.3 tests
End of 5.5 tests.
#
......@@ -5176,6 +5201,54 @@ SELECT 1 FROM t1 WHERE 1 < SOME (SELECT a1 FROM t2);
SET SESSION sql_mode=@old_sql_mode;
DROP TABLE t1, t2;
#
# Bug#11764086: Null left operand to NOT IN in WHERE clause
# behaves differently than real NULL
#
CREATE TABLE parent (id int);
INSERT INTO parent VALUES (1), (2);
CREATE TABLE child (parent_id int, other int);
INSERT INTO child VALUES (1,NULL);
# Offending query (c.parent_id is NULL for null-complemented rows only)
SELECT p.id, c.parent_id
FROM parent p
LEFT JOIN child c
ON p.id = c.parent_id
WHERE c.parent_id NOT IN (
SELECT parent_id
FROM child
WHERE parent_id = 3
);
id parent_id
1 1
2 NULL
# Some syntactic variations with IS FALSE and IS NOT TRUE
SELECT p.id, c.parent_id
FROM parent p
LEFT JOIN child c
ON p.id = c.parent_id
WHERE c.parent_id IN (
SELECT parent_id
FROM child
WHERE parent_id = 3
) IS NOT TRUE;
id parent_id
1 1
2 NULL
SELECT p.id, c.parent_id
FROM parent p
LEFT JOIN child c
ON p.id = c.parent_id
WHERE c.parent_id IN (
SELECT parent_id
FROM child
WHERE parent_id = 3
) IS FALSE;
id parent_id
1 1
2 NULL
DROP TABLE parent, child;
# End of test for bug#11764086.
#
# BUG#50257: Missing info in REF column of the EXPLAIN
# lines for subselects
#
......
......@@ -5151,6 +5151,31 @@ NULL
NULL
5
DROP TABLE t1, t2, t3;
#
# BUG LP:813473: Wrong result with outer join + NOT IN subquery
# This bug is a duplicate of Bug#11764086 whose test case is added below
#
CREATE TABLE t1 (c int) ;
INSERT INTO t1 VALUES (5),(6);
CREATE TABLE t2 (a int, b int) ;
INSERT INTO t2 VALUES (20,9),(20,9);
create table t3 (d int, e int);
insert into t3 values (2, 9), (3,10);
EXPLAIN
SELECT t2.b , t1.c
FROM t2 LEFT JOIN t1 ON t1.c < 3
WHERE (t2.b , t1.c) NOT IN (SELECT * from t3);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 2
1 PRIMARY t1 ALL NULL NULL NULL NULL 2 Using where
2 DEPENDENT SUBQUERY t3 ALL NULL NULL NULL NULL 2 Using where
SELECT t2.b , t1.c
FROM t2 LEFT JOIN t1 ON t1.c < 3
WHERE (t2.b, t1.c) NOT IN (SELECT * from t3);
b c
9 NULL
9 NULL
drop table t1, t2, t3;
End of 5.3 tests
End of 5.5 tests.
#
......@@ -5179,6 +5204,54 @@ SELECT 1 FROM t1 WHERE 1 < SOME (SELECT a1 FROM t2);
SET SESSION sql_mode=@old_sql_mode;
DROP TABLE t1, t2;
#
# Bug#11764086: Null left operand to NOT IN in WHERE clause
# behaves differently than real NULL
#
CREATE TABLE parent (id int);
INSERT INTO parent VALUES (1), (2);
CREATE TABLE child (parent_id int, other int);
INSERT INTO child VALUES (1,NULL);
# Offending query (c.parent_id is NULL for null-complemented rows only)
SELECT p.id, c.parent_id
FROM parent p
LEFT JOIN child c
ON p.id = c.parent_id
WHERE c.parent_id NOT IN (
SELECT parent_id
FROM child
WHERE parent_id = 3
);
id parent_id
1 1
2 NULL
# Some syntactic variations with IS FALSE and IS NOT TRUE
SELECT p.id, c.parent_id
FROM parent p
LEFT JOIN child c
ON p.id = c.parent_id
WHERE c.parent_id IN (
SELECT parent_id
FROM child
WHERE parent_id = 3
) IS NOT TRUE;
id parent_id
1 1
2 NULL
SELECT p.id, c.parent_id
FROM parent p
LEFT JOIN child c
ON p.id = c.parent_id
WHERE c.parent_id IN (
SELECT parent_id
FROM child
WHERE parent_id = 3
) IS FALSE;
id parent_id
1 1
2 NULL
DROP TABLE parent, child;
# End of test for bug#11764086.
#
# BUG#50257: Missing info in REF column of the EXPLAIN
# lines for subselects
#
......
......@@ -4419,6 +4419,31 @@ INSERT INTO t3 VALUES (0),(0);
SELECT a1.f3 AS r FROM t2 AS a1 , t1 WHERE a1.f3 < ALL ( SELECT f3 FROM t3 WHERE f3 = 1 ) ;
DROP TABLE t1, t2, t3;
--echo #
--echo # BUG LP:813473: Wrong result with outer join + NOT IN subquery
--echo # This bug is a duplicate of Bug#11764086 whose test case is added below
--echo #
CREATE TABLE t1 (c int) ;
INSERT INTO t1 VALUES (5),(6);
CREATE TABLE t2 (a int, b int) ;
INSERT INTO t2 VALUES (20,9),(20,9);
create table t3 (d int, e int);
insert into t3 values (2, 9), (3,10);
EXPLAIN
SELECT t2.b , t1.c
FROM t2 LEFT JOIN t1 ON t1.c < 3
WHERE (t2.b , t1.c) NOT IN (SELECT * from t3);
SELECT t2.b , t1.c
FROM t2 LEFT JOIN t1 ON t1.c < 3
WHERE (t2.b, t1.c) NOT IN (SELECT * from t3);
drop table t1, t2, t3;
--echo End of 5.3 tests
--echo End of 5.5 tests.
......@@ -4447,6 +4472,55 @@ SET SESSION sql_mode=@old_sql_mode;
DROP TABLE t1, t2;
--echo #
--echo # Bug#11764086: Null left operand to NOT IN in WHERE clause
--echo # behaves differently than real NULL
--echo #
CREATE TABLE parent (id int);
INSERT INTO parent VALUES (1), (2);
CREATE TABLE child (parent_id int, other int);
INSERT INTO child VALUES (1,NULL);
--echo # Offending query (c.parent_id is NULL for null-complemented rows only)
SELECT p.id, c.parent_id
FROM parent p
LEFT JOIN child c
ON p.id = c.parent_id
WHERE c.parent_id NOT IN (
SELECT parent_id
FROM child
WHERE parent_id = 3
);
--echo # Some syntactic variations with IS FALSE and IS NOT TRUE
SELECT p.id, c.parent_id
FROM parent p
LEFT JOIN child c
ON p.id = c.parent_id
WHERE c.parent_id IN (
SELECT parent_id
FROM child
WHERE parent_id = 3
) IS NOT TRUE;
SELECT p.id, c.parent_id
FROM parent p
LEFT JOIN child c
ON p.id = c.parent_id
WHERE c.parent_id IN (
SELECT parent_id
FROM child
WHERE parent_id = 3
) IS FALSE;
DROP TABLE parent, child;
--echo # End of test for bug#11764086.
--echo #
--echo # BUG#50257: Missing info in REF column of the EXPLAIN
--echo # lines for subselects
......
......@@ -1399,6 +1399,26 @@ longlong Item_func_truth::val_int()
}
bool Item_in_optimizer::is_top_level_item()
{
return ((Item_in_subselect *)args[1])->is_top_level_item();
}
bool Item_in_optimizer::eval_not_null_tables(uchar *opt_arg)
{
not_null_tables_cache= 0;
if (is_top_level_item())
{
/*
It is possible to determine NULL-rejectedness of the left arguments
of IN only if it is a top-level predicate.
*/
not_null_tables_cache= args[0]->not_null_tables();
}
return FALSE;
}
bool Item_in_optimizer::fix_left(THD *thd, Item **ref)
{
if ((!args[0]->fixed && args[0]->fix_fields(thd, args)) ||
......@@ -1425,7 +1445,7 @@ bool Item_in_optimizer::fix_left(THD *thd, Item **ref)
}
used_tables_cache= args[0]->used_tables();
}
not_null_tables_cache= args[0]->not_null_tables();
eval_not_null_tables(NULL);
with_sum_func= args[0]->with_sum_func;
with_field= args[0]->with_field;
if ((const_item_cache= args[0]->const_item()))
......@@ -1458,7 +1478,6 @@ bool Item_in_optimizer::fix_fields(THD *thd, Item **ref)
with_sum_func= with_sum_func || args[1]->with_sum_func;
with_field= with_field || args[1]->with_field;
used_tables_cache|= args[1]->used_tables();
not_null_tables_cache|= args[1]->not_null_tables();
const_item_cache&= args[1]->const_item();
fixed= 1;
return FALSE;
......
......@@ -260,6 +260,8 @@ class Item_in_optimizer: public Item_bool_func
void set_join_tab_idx(uint join_tab_idx_arg)
{ args[1]->set_join_tab_idx(join_tab_idx_arg); }
virtual void get_cache_parameters(List<Item> &parameters);
bool is_top_level_item();
bool eval_not_null_tables(uchar *opt_arg);
};
class Comp_creator
......@@ -494,7 +496,7 @@ class Item_func_not_all :public Item_func_not
show(0)
{}
virtual void top_level_item() { abort_on_null= 1; }
bool top_level() { return abort_on_null; }
bool is_top_level_item() { return abort_on_null; }
longlong val_int();
enum Functype functype() const { return NOT_ALL_FUNC; }
const char *func_name() const { return "<not>"; }
......
......@@ -1701,7 +1701,7 @@ bool Item_allany_subselect::is_maxmin_applicable(JOIN *join)
Check if max/min optimization applicable: It is top item of
WHERE condition.
*/
return (abort_on_null || (upper_item && upper_item->top_level())) &&
return (abort_on_null || (upper_item && upper_item->is_top_level_item())) &&
!join->select_lex->master_unit()->uncacheable && !func->eqne_op();
}
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment