Commit a2ae17b1 authored by unknown's avatar unknown

BUG#20420: optimizer reports wrong keys on left join with IN

 The optimizer needs to evaluate whether predicates are better
 evaluated using an index. IN is one such predicate.
 To qualify an IN predicate must involve a field of the index
 on the left and constant arguments on the right.
 However whether an expression is a constant can be determined only
 by knowing the preceding tables in the join order. 
 Assuming that only IN predicates with expressions on the right that
 are constant for the whole query qualify limits the scope of 
 possible optimizations of the IN predicate (more specifically it
 doesn't allow the "Range checked for each record" optimization for
 such an IN predicate.
 Fixed by not pre-determining the optimizability of the IN predicate
 in the case when all right IN operands are not SQL constant expressions


mysql-test/r/func_in.result:
  BUG#20420: optimizer reports wrong keys on left join with IN
   - test case
mysql-test/t/func_in.test:
  BUG#20420: optimizer reports wrong keys on left join with IN
   - test case
sql/item_cmpfunc.h:
  BUG#20420: optimizer reports wrong keys on left join with IN
   - cannot decide on the optimizability of a function without
     knowing the tables before it in the join order
parent 42e31f7a
...@@ -351,4 +351,47 @@ some_id ...@@ -351,4 +351,47 @@ some_id
1 1
2 2
drop table t1; drop table t1;
CREATE TABLE t1 (a int, b int, PRIMARY KEY (a));
INSERT INTO t1 VALUES (1,1),(2,1),(3,1),(4,1),(5,1),(6,1);
CREATE TABLE t2 (a int, b int, PRIMARY KEY (a));
INSERT INTO t2 VALUES (3,2),(4,2);
CREATE TABLE t3 (a int PRIMARY KEY);
INSERT INTO t3 VALUES (1),(2),(3),(4);
CREATE TABLE t4 (a int PRIMARY KEY);
INSERT INTO t4 VALUES (1),(2);
EXPLAIN SELECT STRAIGHT_JOIN * FROM t3
JOIN t1 ON t3.a=t1.a
JOIN t2 ON t3.a=t2.a
JOIN t4 WHERE t4.a IN (t1.b, t2.b);
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 index PRIMARY PRIMARY 4 NULL 4 Using index
1 SIMPLE t1 eq_ref PRIMARY PRIMARY 4 test.t3.a 1
1 SIMPLE t2 eq_ref PRIMARY PRIMARY 4 test.t3.a 1
1 SIMPLE t4 ALL PRIMARY NULL NULL NULL 2 Range checked for each record (index map: 0x1)
SELECT STRAIGHT_JOIN * FROM t3
JOIN t1 ON t3.a=t1.a
JOIN t2 ON t3.a=t2.a
JOIN t4 WHERE t4.a IN (t1.b, t2.b);
a a b a b a
3 3 1 3 2 1
3 3 1 3 2 2
4 4 1 4 2 1
4 4 1 4 2 2
EXPLAIN SELECT STRAIGHT_JOIN
(SELECT SUM(t4.a) FROM t4 WHERE t4.a IN (t1.b, t2.b))
FROM t3, t1, t2
WHERE t3.a=t1.a AND t3.a=t2.a;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t3 index PRIMARY PRIMARY 4 NULL 4 Using index
1 PRIMARY t1 eq_ref PRIMARY PRIMARY 4 test.t3.a 1
1 PRIMARY t2 eq_ref PRIMARY PRIMARY 4 test.t3.a 1
2 DEPENDENT SUBQUERY t4 index NULL PRIMARY 4 NULL 2 Using where; Using index
SELECT STRAIGHT_JOIN
(SELECT SUM(t4.a) FROM t4 WHERE t4.a IN (t1.b, t2.b))
FROM t3, t1, t2
WHERE t3.a=t1.a AND t3.a=t2.a;
(SELECT SUM(t4.a) FROM t4 WHERE t4.a IN (t1.b, t2.b))
3
3
DROP TABLE t1,t2,t3,t4;
End of 5.0 tests End of 5.0 tests
...@@ -254,5 +254,41 @@ select some_id from t1 where some_id not in(-4,-1,-4); ...@@ -254,5 +254,41 @@ select some_id from t1 where some_id not in(-4,-1,-4);
select some_id from t1 where some_id not in(-4,-1,3423534,2342342); select some_id from t1 where some_id not in(-4,-1,3423534,2342342);
drop table t1; drop table t1;
#
# BUG#20420: optimizer reports wrong keys on left join with IN
#
CREATE TABLE t1 (a int, b int, PRIMARY KEY (a));
INSERT INTO t1 VALUES (1,1),(2,1),(3,1),(4,1),(5,1),(6,1);
CREATE TABLE t2 (a int, b int, PRIMARY KEY (a));
INSERT INTO t2 VALUES (3,2),(4,2);
CREATE TABLE t3 (a int PRIMARY KEY);
INSERT INTO t3 VALUES (1),(2),(3),(4);
CREATE TABLE t4 (a int PRIMARY KEY);
INSERT INTO t4 VALUES (1),(2);
EXPLAIN SELECT STRAIGHT_JOIN * FROM t3
JOIN t1 ON t3.a=t1.a
JOIN t2 ON t3.a=t2.a
JOIN t4 WHERE t4.a IN (t1.b, t2.b);
SELECT STRAIGHT_JOIN * FROM t3
JOIN t1 ON t3.a=t1.a
JOIN t2 ON t3.a=t2.a
JOIN t4 WHERE t4.a IN (t1.b, t2.b);
EXPLAIN SELECT STRAIGHT_JOIN
(SELECT SUM(t4.a) FROM t4 WHERE t4.a IN (t1.b, t2.b))
FROM t3, t1, t2
WHERE t3.a=t1.a AND t3.a=t2.a;
SELECT STRAIGHT_JOIN
(SELECT SUM(t4.a) FROM t4 WHERE t4.a IN (t1.b, t2.b))
FROM t3, t1, t2
WHERE t3.a=t1.a AND t3.a=t2.a;
DROP TABLE t1,t2,t3,t4;
--echo End of 5.0 tests --echo End of 5.0 tests
...@@ -965,6 +965,10 @@ class Item_func_in :public Item_func_opt_neg ...@@ -965,6 +965,10 @@ class Item_func_in :public Item_func_opt_neg
{ {
public: public:
Item_result cmp_type; Item_result cmp_type;
/*
an array of values when the right hand arguments of IN
are all SQL constant and there are no nulls
*/
in_vector *array; in_vector *array;
cmp_item *in_item; cmp_item *in_item;
bool have_null; bool have_null;
...@@ -990,7 +994,7 @@ public: ...@@ -990,7 +994,7 @@ public:
DBUG_VOID_RETURN; DBUG_VOID_RETURN;
} }
optimize_type select_optimize() const optimize_type select_optimize() const
{ return array ? OPTIMIZE_KEY : OPTIMIZE_NONE; } { return OPTIMIZE_KEY; }
void print(String *str); void print(String *str);
enum Functype functype() const { return IN_FUNC; } enum Functype functype() const { return IN_FUNC; }
const char *func_name() const { return " IN "; } const char *func_name() const { return " IN "; }
......
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