From 75a35277772968b3735e9703c00b82a990dd1bb5 Mon Sep 17 00:00:00 2001 From: Sergey Petrunya Date: Tue, 4 Feb 2014 13:27:10 +0400 Subject: [PATCH] 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. --- mysql-test/r/range.result | 31 ++++++++++++++++++++++++ mysql-test/r/range_mrr_icp.result | 31 ++++++++++++++++++++++++ mysql-test/t/range.test | 21 ++++++++++++++++ sql/opt_range.cc | 40 ++++++++++++++++++++++--------- 4 files changed, 112 insertions(+), 11 deletions(-) diff --git a/mysql-test/r/range.result b/mysql-test/r/range.result index e169dcb40b0..c0c67bd3e33 100644 --- a/mysql-test/r/range.result +++ b/mysql-test/r/range.result @@ -2046,3 +2046,34 @@ f1 f2 f3 f4 10 0 0 0 DROP TABLE t1; 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; diff --git a/mysql-test/r/range_mrr_icp.result b/mysql-test/r/range_mrr_icp.result index 0d6bfc2467b..0122fb15193 100644 --- a/mysql-test/r/range_mrr_icp.result +++ b/mysql-test/r/range_mrr_icp.result @@ -2048,4 +2048,35 @@ f1 f2 f3 f4 10 0 0 0 DROP TABLE t1; 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; diff --git a/mysql-test/t/range.test b/mysql-test/t/range.test index e346511db42..5d744dba77a 100644 --- a/mysql-test/t/range.test +++ b/mysql-test/t/range.test @@ -1639,3 +1639,24 @@ SELECT * FROM v3; DROP TABLE t1; 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; + diff --git a/sql/opt_range.cc b/sql/opt_range.cc index 6982db898fb..4dcddfdce1e 100644 --- a/sql/opt_range.cc +++ b/sql/opt_range.cc @@ -7684,7 +7684,8 @@ static SEL_TREE *get_func_mm_tree(RANGE_OPT_PARAM *param, Item_func *cond_func, param PARAM from SQL_SELECT::test_quick_select cond_func item for 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 IN it's always 0) inv TRUE <> NOT cond_func is considered @@ -7953,24 +7954,41 @@ static SEL_TREE *get_mm_tree(RANGE_OPT_PARAM *param,COND *cond) DBUG_RETURN(ftree); } default: + + DBUG_ASSERT (!ftree); if (cond_func->arguments()[0]->real_item()->type() == Item::FIELD_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() == - Item::FIELD_ITEM) + /* + Even if get_full_func_mm_tree() was executed above and did not + 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()); value= cond_func->arguments()[0]; + if (value && value->is_expensive()) + DBUG_RETURN(0); + ftree= get_full_func_mm_tree(param, cond_func, field_item, value, inv); } - else - DBUG_RETURN(0); - if (value && value->is_expensive()) - DBUG_RETURN(0); - - ftree= get_full_func_mm_tree(param, cond_func, field_item, value, inv); } DBUG_RETURN(ftree);