[Commits] b8b1b92: MDEV-8359: WHERE condition referring to inner table of left join can be sargable

Sergei Petrunia psergey at askmonty.org
Fri Oct 14 00:05:14 EEST 2016


revision-id: b8b1b928ffa9da49588eec4ebe05c864c9847be2
parent(s): 9208b87f18b3dc84bb22551957a8e2f709e768a8
committer: Sergei Petrunia
branch nick: 10.2
timestamp: 2016-10-14 00:05:13 +0300
message:

MDEV-8359: WHERE condition referring to inner table of left join can be sargable

Implement a technique mentioned in the MDEV. Under certain conditions,
cond(inner_table.col) can be substituted for cond(outer_table.col) for
the purpose of range analysis.

---
 mysql-test/r/join_outer.result |   23 ++++++++++++++++++++
 mysql-test/t/join_outer.test   |   22 ++++++++++++++++++++
 sql/opt_range.cc               |   45 ++++++++++++++++++++++++++++++++++++++++
 3 files changed, 90 insertions(+)

diff --git a/mysql-test/r/join_outer.result b/mysql-test/r/join_outer.result
index 8b4ee17..77932b6 100644
--- a/mysql-test/r/join_outer.result
+++ b/mysql-test/r/join_outer.result
@@ -2337,4 +2337,27 @@ id	select_type	table	type	possible_keys	key	key_len	ref	rows	filtered	Extra
 Warnings:
 Note	1003	select `test`.`t1`.`i1` AS `i1`,`test`.`t1`.`v1` AS `v1`,`test`.`t2`.`i2` AS `i2`,`test`.`t2`.`v2` AS `v2`,`test`.`t3`.`i3` AS `i3`,`test`.`t3`.`v3` AS `v3` from `test`.`t1` join `test`.`t2` join `test`.`t3` where ((`test`.`t3`.`v3` = 4) and (`test`.`t1`.`i1` = `test`.`t3`.`i3`) and (`test`.`t2`.`i2` = `test`.`t3`.`i3`))
 drop table t1,t2,t3;
+#
+# MDEV-8359: WHERE condition referring to inner table of left join can be sargable
+#
+create table t0 (a int);
+insert into t0 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
+create table t1 (a int, b int, key(a));
+insert into t1 select A.a+10*B.a+100*C.a, A.a+10*B.a+100*C.a from t0 A, t0 B, t0 C;
+create table t2 (a int, b int);
+insert into t2 select a,a from t0;
+# The following must remain an outer join
+# but it must be able to use range access on table t1:
+explain extended
+select * 
+from 
+t1 left join t2 on t2.a=t1.a
+where 
+t1.a<3 or t2.a<4;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	filtered	Extra
+1	SIMPLE	t1	range	a	a	5	NULL	4	100.00	Using index condition
+1	SIMPLE	t2	ALL	NULL	NULL	NULL	NULL	10	100.00	Using where
+Warnings:
+Note	1003	select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t1` left join `test`.`t2` on((`test`.`t2`.`a` = `test`.`t1`.`a`)) where ((`test`.`t1`.`a` < 3) or (`test`.`t2`.`a` < 4))
+drop table t0,t1, t2;
 SET optimizer_switch=@save_optimizer_switch;
diff --git a/mysql-test/t/join_outer.test b/mysql-test/t/join_outer.test
index a3a1278..f0ecbe2 100644
--- a/mysql-test/t/join_outer.test
+++ b/mysql-test/t/join_outer.test
@@ -1882,4 +1882,26 @@ WHERE v3 = 4;
 
 drop table t1,t2,t3;
 
+--echo #
+--echo # MDEV-8359: WHERE condition referring to inner table of left join can be sargable
+--echo #
+create table t0 (a int);
+insert into t0 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
+
+create table t1 (a int, b int, key(a));
+insert into t1 select A.a+10*B.a+100*C.a, A.a+10*B.a+100*C.a from t0 A, t0 B, t0 C;
+ 
+create table t2 (a int, b int);
+insert into t2 select a,a from t0;
+ 
+--echo # The following must remain an outer join
+--echo # but it must be able to use range access on table t1:
+explain extended
+select * 
+from 
+  t1 left join t2 on t2.a=t1.a
+where 
+  t1.a<3 or t2.a<4;
+
+drop table t0,t1, t2;
 SET optimizer_switch=@save_optimizer_switch;
diff --git a/sql/opt_range.cc b/sql/opt_range.cc
index 3ea9f4e..1713936 100644
--- a/sql/opt_range.cc
+++ b/sql/opt_range.cc
@@ -7328,6 +7328,51 @@ SEL_TREE *Item_bool_func::get_full_func_mm_tree(RANGE_OPT_PARAM *param,
       }
     }
   }
+  else
+  {
+    THD *thd= current_thd;
+    JOIN *join;
+    COND_EQUAL *cond_equal;
+    // todo: also check that the condition has abort_on_null set.
+    if ((field_item->used_tables() & ~OUTER_REF_TABLE_BIT) &&
+        thd->lex->current_select &&
+        (join= thd->lex->current_select->join) &&
+        (join->outer_join & field_item->used_tables()) &&
+        (cond_equal= field->table->pos_in_table_list->cond_equal) &&
+        field_item->used_tables() & not_null_tables())
+    {
+      // Ok this is a table that's inner w.r.t some outer join
+      // And it has a multiple equality
+      List_iterator<Item_equal> li(cond_equal->current_level);
+      Item_equal *cur_item_eq;
+      while ((cur_item_eq= li++))
+      {
+        // If the multiple equality contains fields from 
+        //   - the table we're doing range analysis for 
+        //   - the table that we have a field from
+        // and field that we have is also there
+        if ((cur_item_eq->used_tables() & (param->current_table | 
+                                           field->table->map)) &&
+            cur_item_eq->contains(field))
+        {
+          // Find fields in the table we're from
+          Item_equal_fields_iterator it(*cur_item_eq);
+          while (it++)
+          {
+            Field *f= it.get_curr_field();
+            if (f->table == param->table)
+            {
+              if (!((ref_tables | f->table->map) & param_comp))
+              {
+                tree= get_func_mm_tree(param, f, value);
+                ftree= !ftree ? tree : tree_and(param, ftree, tree);
+              }
+            }
+          }
+        }
+      }
+    }
+  }
   DBUG_RETURN(ftree);
 }
 


More information about the commits mailing list