Commit 2f22e85d authored by Sergey Petrunya's avatar Sergey Petrunya

Backport from 10.0 to 10.0-base the following:

revision-id: psergey@askmonty.org-20140204092710-2yt5ysa5ej3l2c03
MDEV-5606: range optimizer: "x < y" is sargable, while "y > x" is not
Port to mariadb-1.0 the following fix from mysql-5.6:
      
Revision ID: jorgen.loland@oracle.com-20120314131055-ml54x9deueqfsff4
BUG#13701206: WHERE A>=B DOES NOT GIVE SAME EXECUTION PLAN
              AS WHERE B<=A (RANGE OPTIMIZER)
       
that fix didn't have a public testcase, so I created one.
parent 80a38b92
...@@ -2046,3 +2046,34 @@ f1 f2 f3 f4 ...@@ -2046,3 +2046,34 @@ f1 f2 f3 f4
10 0 0 0 10 0 0 0
DROP TABLE t1; DROP TABLE t1;
DROP VIEW v3; DROP VIEW v3;
#
# MDEV-5606: range optimizer: "x < y" is sargable, while "y > x" is not
#
create table t1(a int);
insert into t1 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
create table t2(a int);
insert into t2 select A.a + B.a* 10 + C.a * 100 from t1 A, t1 B, t1 C;
alter table t2 add key(a);
# Should have "range checked for each table" for second table:
explain select * from t1, t2 where t2.a < t1.a;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 10
1 SIMPLE t2 ALL a NULL NULL NULL 1000 Range checked for each record (index map: 0x1)
# Should have "range checked for each table" for second table:
explain select * from t1, t2 where t1.a > t2.a;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 10
1 SIMPLE t2 ALL a NULL NULL NULL 1000 Range checked for each record (index map: 0x1)
create table t3 (a int primary key, b int);
insert into t3 select a,a from t1;
# The second table should use 'range':
explain select * from t3, t2 where t2.a < t3.b and t3.a=1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 const PRIMARY PRIMARY 4 const 1
1 SIMPLE t2 range a a 5 NULL 1 Using where; Using index
# The second table should use 'range':
explain select * from t3, t2 where t3.b > t2.a and t3.a=1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 const PRIMARY PRIMARY 4 const 1
1 SIMPLE t2 range a a 5 NULL 1 Using where; Using index
drop table t1,t2,t3;
...@@ -2048,4 +2048,35 @@ f1 f2 f3 f4 ...@@ -2048,4 +2048,35 @@ f1 f2 f3 f4
10 0 0 0 10 0 0 0
DROP TABLE t1; DROP TABLE t1;
DROP VIEW v3; DROP VIEW v3;
#
# MDEV-5606: range optimizer: "x < y" is sargable, while "y > x" is not
#
create table t1(a int);
insert into t1 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
create table t2(a int);
insert into t2 select A.a + B.a* 10 + C.a * 100 from t1 A, t1 B, t1 C;
alter table t2 add key(a);
# Should have "range checked for each table" for second table:
explain select * from t1, t2 where t2.a < t1.a;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 10
1 SIMPLE t2 ALL a NULL NULL NULL 1000 Range checked for each record (index map: 0x1)
# Should have "range checked for each table" for second table:
explain select * from t1, t2 where t1.a > t2.a;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 10
1 SIMPLE t2 ALL a NULL NULL NULL 1000 Range checked for each record (index map: 0x1)
create table t3 (a int primary key, b int);
insert into t3 select a,a from t1;
# The second table should use 'range':
explain select * from t3, t2 where t2.a < t3.b and t3.a=1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 const PRIMARY PRIMARY 4 const 1
1 SIMPLE t2 range a a 5 NULL 1 Using where; Using index
# The second table should use 'range':
explain select * from t3, t2 where t3.b > t2.a and t3.a=1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t3 const PRIMARY PRIMARY 4 const 1
1 SIMPLE t2 range a a 5 NULL 1 Using where; Using index
drop table t1,t2,t3;
set optimizer_switch=@mrr_icp_extra_tmp; set optimizer_switch=@mrr_icp_extra_tmp;
...@@ -1638,3 +1638,25 @@ UPDATE v3 SET f3=0, f4=4 WHERE f2=68 ORDER BY f1; ...@@ -1638,3 +1638,25 @@ UPDATE v3 SET f3=0, f4=4 WHERE f2=68 ORDER BY f1;
SELECT * FROM v3; SELECT * FROM v3;
DROP TABLE t1; DROP TABLE t1;
DROP VIEW v3; DROP VIEW v3;
--echo #
--echo # MDEV-5606: range optimizer: "x < y" is sargable, while "y > x" is not
--echo #
create table t1(a int);
insert into t1 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
create table t2(a int);
insert into t2 select A.a + B.a* 10 + C.a * 100 from t1 A, t1 B, t1 C;
alter table t2 add key(a);
--echo # Should have "range checked for each table" for second table:
explain select * from t1, t2 where t2.a < t1.a;
--echo # Should have "range checked for each table" for second table:
explain select * from t1, t2 where t1.a > t2.a;
create table t3 (a int primary key, b int);
insert into t3 select a,a from t1;
--echo # The second table should use 'range':
explain select * from t3, t2 where t2.a < t3.b and t3.a=1;
--echo # The second table should use 'range':
explain select * from t3, t2 where t3.b > t2.a and t3.a=1;
drop table t1,t2,t3;
...@@ -7663,7 +7663,8 @@ static SEL_TREE *get_func_mm_tree(RANGE_OPT_PARAM *param, Item_func *cond_func, ...@@ -7663,7 +7663,8 @@ static SEL_TREE *get_func_mm_tree(RANGE_OPT_PARAM *param, Item_func *cond_func,
param PARAM from SQL_SELECT::test_quick_select param PARAM from SQL_SELECT::test_quick_select
cond_func item for the predicate cond_func item for the predicate
field_item field in the predicate field_item field in the predicate
value constant in the predicate value constant in the predicate (or a field already read from
a table in the case of dynamic range access)
(for BETWEEN it contains the number of the field argument, (for BETWEEN it contains the number of the field argument,
for IN it's always 0) for IN it's always 0)
inv TRUE <> NOT cond_func is considered inv TRUE <> NOT cond_func is considered
...@@ -7932,25 +7933,42 @@ static SEL_TREE *get_mm_tree(RANGE_OPT_PARAM *param,COND *cond) ...@@ -7932,25 +7933,42 @@ static SEL_TREE *get_mm_tree(RANGE_OPT_PARAM *param,COND *cond)
DBUG_RETURN(ftree); DBUG_RETURN(ftree);
} }
default: default:
DBUG_ASSERT (!ftree);
if (cond_func->arguments()[0]->real_item()->type() == Item::FIELD_ITEM) if (cond_func->arguments()[0]->real_item()->type() == Item::FIELD_ITEM)
{ {
field_item= (Item_field*) (cond_func->arguments()[0]->real_item()); field_item= (Item_field*) (cond_func->arguments()[0]->real_item());
value= cond_func->arg_count > 1 ? cond_func->arguments()[1] : 0; value= cond_func->arg_count > 1 ? cond_func->arguments()[1] : NULL;
if (value && value->is_expensive())
DBUG_RETURN(0);
ftree= get_full_func_mm_tree(param, cond_func, field_item, value, inv);
} }
else if (cond_func->have_rev_func() && /*
cond_func->arguments()[1]->real_item()->type() == Even if get_full_func_mm_tree() was executed above and did not
Item::FIELD_ITEM) return a range predicate it may still be possible to create one
by reversing the order of the operands. Note that this only
applies to predicates where both operands are fields. Example: A
query of the form
WHERE t1.a OP t2.b
In this case, arguments()[0] == t1.a and arguments()[1] == t2.b.
When creating range predicates for t2, get_full_func_mm_tree()
above will return NULL because 'field' belongs to t1 and only
predicates that applies to t2 are of interest. In this case a
call to get_full_func_mm_tree() with reversed operands (see
below) may succeed.
*/
if (!ftree && cond_func->have_rev_func() &&
cond_func->arguments()[1]->real_item()->type() == Item::FIELD_ITEM)
{ {
field_item= (Item_field*) (cond_func->arguments()[1]->real_item()); field_item= (Item_field*) (cond_func->arguments()[1]->real_item());
value= cond_func->arguments()[0]; value= cond_func->arguments()[0];
}
else
DBUG_RETURN(0);
if (value && value->is_expensive()) if (value && value->is_expensive())
DBUG_RETURN(0); DBUG_RETURN(0);
ftree= get_full_func_mm_tree(param, cond_func, field_item, value, inv); ftree= get_full_func_mm_tree(param, cond_func, field_item, value, inv);
} }
}
DBUG_RETURN(ftree); DBUG_RETURN(ftree);
} }
......
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