Commit 1fdd365c authored by Igor Babaev's avatar Igor Babaev

Fixed LP bug #729039.

If join condition is of the form <t2.key>=<t1.no_key> then the server
performs no index look-ups when looking for matching rows of t2 for
the rows from t1 with t1.no_key=NULL. It happens because the function
add_not_null_conds() injects an additional condition of the form 
IS NOT NULL(<t1.no_key>) into the WHERE condition.
However if the join condition was of the form <t.key>=<outer_ref> no
additional null rejecting predicate was generated. This could lead
to extra records in the result set if the value of <outer_ref> happened
to be NULL.
The new code injects null rejecting predicates of the form 
IS NOT NULL(<outer_ref>) and evaluates them before the first row
the subquery is constructed.
parent 3c8b2ad5
...@@ -5018,3 +5018,31 @@ id select_type table type possible_keys key key_len ref rows Extra ...@@ -5018,3 +5018,31 @@ id select_type table type possible_keys key key_len ref rows Extra
2 SUBQUERY it2 ALL NULL NULL NULL NULL 4 2 SUBQUERY it2 ALL NULL NULL NULL NULL 4
2 SUBQUERY it3 ALL NULL NULL NULL NULL 6 Using join buffer (flat, BNL join) 2 SUBQUERY it3 ALL NULL NULL NULL NULL 6 Using join buffer (flat, BNL join)
DROP TABLE IF EXISTS ot1, ot4, it2, it3; DROP TABLE IF EXISTS ot1, ot4, it2, it3;
#
# Bug#729039: NULL keys used to evaluate subquery
#
CREATE TABLE t1 (a int) ;
INSERT INTO t1 VALUES (NULL), (1), (NULL), (2);
CREATE TABLE t2 (a int, INDEX idx(a)) ;
INSERT INTO t2 VALUES (NULL), (1), (NULL);
SELECT * FROM t1
WHERE EXISTS (SELECT a FROM t2 USE INDEX () WHERE t2.a = t1.a);
a
1
EXPLAIN
SELECT * FROM t1
WHERE EXISTS (SELECT a FROM t2 USE INDEX() WHERE t2.a = t1.a);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 4 Using where
2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 3 Using where
SELECT * FROM t1
WHERE EXISTS (SELECT a FROM t2 WHERE t2.a = t1.a);
a
1
EXPLAIN
SELECT * FROM t1
WHERE EXISTS (SELECT a FROM t2 WHERE t2.a = t1.a);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 4 Using where
2 DEPENDENT SUBQUERY t2 ref idx idx 5 test.t1.a 2 Using index
DROP TABLE t1,t2;
...@@ -5020,6 +5020,34 @@ id select_type table type possible_keys key key_len ref rows Extra ...@@ -5020,6 +5020,34 @@ id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY it3 ALL NULL NULL NULL NULL 6 Using join buffer (flat, BNL join) 1 PRIMARY it3 ALL NULL NULL NULL NULL 6 Using join buffer (flat, BNL join)
1 PRIMARY ot4 ALL NULL NULL NULL NULL 8 Using where; End temporary; Using join buffer (flat, BNL join) 1 PRIMARY ot4 ALL NULL NULL NULL NULL 8 Using where; End temporary; Using join buffer (flat, BNL join)
DROP TABLE IF EXISTS ot1, ot4, it2, it3; DROP TABLE IF EXISTS ot1, ot4, it2, it3;
#
# Bug#729039: NULL keys used to evaluate subquery
#
CREATE TABLE t1 (a int) ;
INSERT INTO t1 VALUES (NULL), (1), (NULL), (2);
CREATE TABLE t2 (a int, INDEX idx(a)) ;
INSERT INTO t2 VALUES (NULL), (1), (NULL);
SELECT * FROM t1
WHERE EXISTS (SELECT a FROM t2 USE INDEX () WHERE t2.a = t1.a);
a
1
EXPLAIN
SELECT * FROM t1
WHERE EXISTS (SELECT a FROM t2 USE INDEX() WHERE t2.a = t1.a);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 4 Using where
2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 3 Using where
SELECT * FROM t1
WHERE EXISTS (SELECT a FROM t2 WHERE t2.a = t1.a);
a
1
EXPLAIN
SELECT * FROM t1
WHERE EXISTS (SELECT a FROM t2 WHERE t2.a = t1.a);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 4 Using where
2 DEPENDENT SUBQUERY t2 ref idx idx 5 test.t1.a 2 Using index
DROP TABLE t1,t2;
set optimizer_switch=default; set optimizer_switch=default;
select @@optimizer_switch like '%materialization=on%'; select @@optimizer_switch like '%materialization=on%';
@@optimizer_switch like '%materialization=on%' @@optimizer_switch like '%materialization=on%'
......
...@@ -5017,4 +5017,32 @@ id select_type table type possible_keys key key_len ref rows Extra ...@@ -5017,4 +5017,32 @@ id select_type table type possible_keys key key_len ref rows Extra
2 DEPENDENT SUBQUERY it2 ALL NULL NULL NULL NULL 4 Using where 2 DEPENDENT SUBQUERY it2 ALL NULL NULL NULL NULL 4 Using where
2 DEPENDENT SUBQUERY it3 ALL NULL NULL NULL NULL 6 Using where; Using join buffer (flat, BNL join) 2 DEPENDENT SUBQUERY it3 ALL NULL NULL NULL NULL 6 Using where; Using join buffer (flat, BNL join)
DROP TABLE IF EXISTS ot1, ot4, it2, it3; DROP TABLE IF EXISTS ot1, ot4, it2, it3;
#
# Bug#729039: NULL keys used to evaluate subquery
#
CREATE TABLE t1 (a int) ;
INSERT INTO t1 VALUES (NULL), (1), (NULL), (2);
CREATE TABLE t2 (a int, INDEX idx(a)) ;
INSERT INTO t2 VALUES (NULL), (1), (NULL);
SELECT * FROM t1
WHERE EXISTS (SELECT a FROM t2 USE INDEX () WHERE t2.a = t1.a);
a
1
EXPLAIN
SELECT * FROM t1
WHERE EXISTS (SELECT a FROM t2 USE INDEX() WHERE t2.a = t1.a);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 4 Using where
2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 3 Using where
SELECT * FROM t1
WHERE EXISTS (SELECT a FROM t2 WHERE t2.a = t1.a);
a
1
EXPLAIN
SELECT * FROM t1
WHERE EXISTS (SELECT a FROM t2 WHERE t2.a = t1.a);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 4 Using where
2 DEPENDENT SUBQUERY t2 ref idx idx 5 test.t1.a 2 Using index
DROP TABLE t1,t2;
set optimizer_switch=default; set optimizer_switch=default;
...@@ -5017,4 +5017,32 @@ id select_type table type possible_keys key key_len ref rows Extra ...@@ -5017,4 +5017,32 @@ id select_type table type possible_keys key key_len ref rows Extra
2 SUBQUERY it2 ALL NULL NULL NULL NULL 4 2 SUBQUERY it2 ALL NULL NULL NULL NULL 4
2 SUBQUERY it3 ALL NULL NULL NULL NULL 6 Using join buffer (flat, BNL join) 2 SUBQUERY it3 ALL NULL NULL NULL NULL 6 Using join buffer (flat, BNL join)
DROP TABLE IF EXISTS ot1, ot4, it2, it3; DROP TABLE IF EXISTS ot1, ot4, it2, it3;
#
# Bug#729039: NULL keys used to evaluate subquery
#
CREATE TABLE t1 (a int) ;
INSERT INTO t1 VALUES (NULL), (1), (NULL), (2);
CREATE TABLE t2 (a int, INDEX idx(a)) ;
INSERT INTO t2 VALUES (NULL), (1), (NULL);
SELECT * FROM t1
WHERE EXISTS (SELECT a FROM t2 USE INDEX () WHERE t2.a = t1.a);
a
1
EXPLAIN
SELECT * FROM t1
WHERE EXISTS (SELECT a FROM t2 USE INDEX() WHERE t2.a = t1.a);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 4 Using where
2 DEPENDENT SUBQUERY t2 ALL NULL NULL NULL NULL 3 Using where
SELECT * FROM t1
WHERE EXISTS (SELECT a FROM t2 WHERE t2.a = t1.a);
a
1
EXPLAIN
SELECT * FROM t1
WHERE EXISTS (SELECT a FROM t2 WHERE t2.a = t1.a);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 4 Using where
2 DEPENDENT SUBQUERY t2 ref idx idx 5 test.t1.a 2 Using index
DROP TABLE t1,t2;
set optimizer_switch=default; set optimizer_switch=default;
...@@ -4293,3 +4293,26 @@ eval explain $query; ...@@ -4293,3 +4293,26 @@ eval explain $query;
DROP TABLE IF EXISTS ot1, ot4, it2, it3; DROP TABLE IF EXISTS ot1, ot4, it2, it3;
--echo #
--echo # Bug#729039: NULL keys used to evaluate subquery
--echo #
CREATE TABLE t1 (a int) ;
INSERT INTO t1 VALUES (NULL), (1), (NULL), (2);
CREATE TABLE t2 (a int, INDEX idx(a)) ;
INSERT INTO t2 VALUES (NULL), (1), (NULL);
SELECT * FROM t1
WHERE EXISTS (SELECT a FROM t2 USE INDEX () WHERE t2.a = t1.a);
EXPLAIN
SELECT * FROM t1
WHERE EXISTS (SELECT a FROM t2 USE INDEX() WHERE t2.a = t1.a);
SELECT * FROM t1
WHERE EXISTS (SELECT a FROM t2 WHERE t2.a = t1.a);
EXPLAIN
SELECT * FROM t1
WHERE EXISTS (SELECT a FROM t2 WHERE t2.a = t1.a);
DROP TABLE t1,t2;
...@@ -6891,7 +6891,7 @@ static void add_not_null_conds(JOIN *join) ...@@ -6891,7 +6891,7 @@ static void add_not_null_conds(JOIN *join)
UPDATE t1 SET t1.f2=(SELECT MAX(t2.f4) FROM t2 WHERE t2.f3=t1.f1); UPDATE t1 SET t1.f2=(SELECT MAX(t2.f4) FROM t2 WHERE t2.f3=t1.f1);
not_null_item is the t1.f1, but it's referred_tab is 0. not_null_item is the t1.f1, but it's referred_tab is 0.
*/ */
if (!referred_tab || referred_tab->join != join) if (!referred_tab)
continue; continue;
if (!(notnull= new Item_func_isnotnull(not_null_item))) if (!(notnull= new Item_func_isnotnull(not_null_item)))
DBUG_VOID_RETURN; DBUG_VOID_RETURN;
...@@ -6908,9 +6908,14 @@ static void add_not_null_conds(JOIN *join) ...@@ -6908,9 +6908,14 @@ static void add_not_null_conds(JOIN *join)
QT_ORDINARY);); QT_ORDINARY););
if (!tab->first_inner) if (!tab->first_inner)
{ {
COND *new_cond= referred_tab->select_cond; COND *new_cond= referred_tab->join == join ?
referred_tab->select_cond :
join->outer_ref_cond;
add_cond_and_fix(&new_cond, notnull); add_cond_and_fix(&new_cond, notnull);
referred_tab->set_select_cond(new_cond, __LINE__); if (referred_tab->join == join)
referred_tab->set_select_cond(new_cond, __LINE__);
else
join->outer_ref_cond= new_cond;
} }
else else
add_cond_and_fix(tab->first_inner->on_expr_ref, notnull); add_cond_and_fix(tab->first_inner->on_expr_ref, notnull);
...@@ -7127,6 +7132,15 @@ make_join_select(JOIN *join,SQL_SELECT *select,COND *cond) ...@@ -7127,6 +7132,15 @@ make_join_select(JOIN *join,SQL_SELECT *select,COND *cond)
DBUG_PRINT("info",("Found impossible WHERE condition")); DBUG_PRINT("info",("Found impossible WHERE condition"));
DBUG_RETURN(1); // Impossible const condition DBUG_RETURN(1); // Impossible const condition
} }
COND *outer_ref_cond= make_cond_for_table(cond,
OUTER_REF_TABLE_BIT,
(table_map) 0, FALSE, FALSE);
if (outer_ref_cond)
{
add_cond_and_fix(&outer_ref_cond, join->outer_ref_cond);
join->outer_ref_cond= outer_ref_cond;
}
} }
} }
...@@ -13393,7 +13407,10 @@ do_select(JOIN *join,List<Item> *fields,TABLE *table,Procedure *procedure) ...@@ -13393,7 +13407,10 @@ do_select(JOIN *join,List<Item> *fields,TABLE *table,Procedure *procedure)
else else
{ {
DBUG_ASSERT(join->tables); DBUG_ASSERT(join->tables);
error= join->first_select(join,join_tab,0); if (join->outer_ref_cond && !join->outer_ref_cond->val_int())
error= NESTED_LOOP_NO_MORE_ROWS;
else
error= join->first_select(join,join_tab,0);
if (error == NESTED_LOOP_OK || error == NESTED_LOOP_NO_MORE_ROWS) if (error == NESTED_LOOP_OK || error == NESTED_LOOP_NO_MORE_ROWS)
error= join->first_select(join,join_tab,1); error= join->first_select(join,join_tab,1);
if (error == NESTED_LOOP_QUERY_LIMIT) if (error == NESTED_LOOP_QUERY_LIMIT)
......
...@@ -798,6 +798,7 @@ class JOIN :public Sql_alloc ...@@ -798,6 +798,7 @@ class JOIN :public Sql_alloc
ORDER *order, *group_list, *proc_param; //hold parameters of mysql_select ORDER *order, *group_list, *proc_param; //hold parameters of mysql_select
COND *conds; // ---"--- COND *conds; // ---"---
Item *conds_history; // store WHERE for explain Item *conds_history; // store WHERE for explain
COND *outer_ref_cond; ///<part of conds containing only outer references
TABLE_LIST *tables_list; ///<hold 'tables' parameter of mysql_select TABLE_LIST *tables_list; ///<hold 'tables' parameter of mysql_select
List<TABLE_LIST> *join_list; ///< list of joined tables in reverse order List<TABLE_LIST> *join_list; ///< list of joined tables in reverse order
COND_EQUAL *cond_equal; COND_EQUAL *cond_equal;
...@@ -903,6 +904,7 @@ class JOIN :public Sql_alloc ...@@ -903,6 +904,7 @@ class JOIN :public Sql_alloc
no_const_tables= FALSE; no_const_tables= FALSE;
first_select= sub_select; first_select= sub_select;
outer_ref_cond= 0;
} }
int prepare(Item ***rref_pointer_array, TABLE_LIST *tables, uint wind_num, int prepare(Item ***rref_pointer_array, TABLE_LIST *tables, uint wind_num,
......
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