List:Commits« Previous MessageNext Message »
From:Olav Sandstaa Date:February 9 2011 12:30pm
Subject:bzr commit into mysql-trunk branch (olav.sandstaa:3625) Bug#59696
View as plain text  
#At file:///export/home/tmp/mysql2/opt-bug59696/ based on revid:dmitry.shulga@stripped

 3625 Olav Sandstaa	2011-02-09
      Fix for Bug#59696 Optimizer fails to move WHERE condition on JOIN column 
                        when joining with a view
      
      When optimizing a JOIN of two tables the optimizer tries to move WHERE
      conditions on the join column(s) to the first table in the JOIN in
      order to reduce the number of records it has to read. If the second
      operand of the JOIN is a view that is identical to the underlying
      table the optimizer should be able to perform the same optimization.
      In this case it fails to move the WHERE condition on the join column
      to the first table.
      
      The cause for this is that when the second operand is a view then
      the conditions contain Item_ref objects that reference the real item
      field objects. The existing code fails to evaluate these since it
      only evaluates the Item_ref object and fails to look at the real
      objects. As a result it fails to detect that the equals predicate on
      the second join operand can be substituted by a corresponding equals
      predicate on the first operand.
      
      There are two places where we fail to handle Item_ref correctly and that
      causes the optimizer to fail to do this optimization:
      
      1. In optimize_cond() we call build_equal_items() which again calls
      build_equal_items_for_cond() where we in Item_func::compile() fail to
      evaluate the Item::equal_fields_propagator() for the condition on the
      view operand. As a result the field used in the condition for the view
      is not considered as an equal field to the join column of the first
      table when this later is evaluated in make_join_statistics().
      
      2. Later in JOIN::optimize() we call substitute_for_best_equal_field()
      which uses Item_func::transform() to select the best condition of the
      tables. Item_func::transform() fails to evaluate the different
      conditions that are equal due to these being stored in a Item_ref
      object.
      
      The fix for these problems is to implement compile() and transform()
      functions for the Item_ref class that compile/transform both the
      Item_ref object itself and the item object referenced by the 'ref'
      pointer. So when Item_func::compile() and Item_func::transform() 
      evaluate Item_ref object this fix ensures that both the Item_ref 
      object and the object it references are evaluated.
     @ mysql-test/r/join.result
        Test case for Bug#59696 Optimizer fails to move WHERE condition
        on JOIN column when joining with a view.
     @ mysql-test/r/subquery_sj_none.result
        Change in explain/query plan due to the fix for Bug#59696 "Optimizer
        fails to move WHERE condition on JOIN column when joining with a view"
        
        The change in query plan for the following query:
        
          select * from t2 where (b,a) in (select a,b from t1 where a=3);
        
        where the table t2 is defined as:
        
          create table t2 as select * from t1;
        
        is caused by that when the optimizer optimizes the subquery it will
        try to optimize the conditions (in optimize_cond()). One of the things
        it does it to call build_equal_items_for_cond() for the following
        condition:
        
          (<cache>(`test`.`t2`.`b`) = `test`.`t1`.`a`)
        
        When this is "compiled" in build_equal_items_for_cond() both the
        <cache>(`test`.`t2`.`b`) and `test`.`t1`.`a` are stored in Item_ref
        objects. So with the existing code the real items does not get
        "compiled" and are not considered for alternatives. So the result of
        the "compilation" is:
        
          (<cache>(`test`.`t2`.`b`) = `test`.`t1`.`a`)
        
        With the patch applied both of the real items get evaluated and the
        code is able to find that `test`.`t1`.`a` can be replaced by the
        constant "3". So the result from the "compilation" of this condition is
        
          <cache>(`test`.`t2`.`b`) = 3
        
        Which causes the execution plan for the subquery to change as it has.
     @ mysql-test/t/join.test
        Test case for Bug#59696 Optimizer fails to move WHERE condition
        on JOIN column when joining with a view.
     @ sql/item.cc
        Implement transform() and compile() member functions for the Item_ref
        class. These functionss will then do transform/compile for both the
        Item_ref object and the object it has a reference to.
     @ sql/item.h
        Implement transform() and compile() member functions for the
        Item_ref class.

    modified:
      mysql-test/r/join.result
      mysql-test/r/subquery_sj_none.result
      mysql-test/t/join.test
      sql/item.cc
      sql/item.h
=== modified file 'mysql-test/r/join.result'

=== modified file 'mysql-test/r/join.result'
--- a/mysql-test/r/join.result	2010-12-16 17:38:26 +0000
+++ b/mysql-test/r/join.result	2011-02-09 12:30:47 +0000
@@ -1222,3 +1222,40 @@
 DEALLOCATE PREPARE stmt;
 DROP TABLE t1;
 End of 5.1 tests
+#
+# Bug #59696 Optimizer fails to move WHERE condition on JOIN column 
+#            when joining with a view
+#
+CREATE TABLE t1 (
+c1 INTEGER NOT NULL
+);
+INSERT INTO t1 VALUES (1),(2),(3);
+CREATE TABLE t2 (
+pk INTEGER NOT NULL,
+c1 INTEGER NOT NULL,
+PRIMARY KEY (pk)
+);
+INSERT INTO t2 VALUES (1,4),(3,5),(2,6);
+EXPLAIN SELECT t2.pk, t2.c1 FROM t2, t1 
+WHERE t2.pk = t1.c1 AND t2.pk >= 2;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t1	ALL	NULL	NULL	NULL	NULL	3	Using where
+1	SIMPLE	t2	eq_ref	PRIMARY	PRIMARY	4	test.t1.c1	1	
+SELECT t2.pk, t2.c1 FROM t2, t1 
+WHERE t2.pk = t1.c1 AND t2.pk >= 2;
+pk	c1
+2	6
+3	5
+CREATE VIEW v_t2 AS SELECT * FROM t2;
+EXPLAIN SELECT v_t2.pk, v_t2.c1 FROM v_t2, t1 
+WHERE v_t2.pk = t1.c1 AND v_t2.pk >= 2;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
+1	SIMPLE	t1	ALL	NULL	NULL	NULL	NULL	3	Using where
+1	SIMPLE	t2	eq_ref	PRIMARY	PRIMARY	4	test.t1.c1	1	
+SELECT v_t2.pk, v_t2.c1 FROM v_t2, t1 
+WHERE v_t2.pk = t1.c1 AND v_t2.pk >= 2;
+pk	c1
+2	6
+3	5
+DROP VIEW v_t2;
+DROP TABLE t1, t2;

=== modified file 'mysql-test/r/subquery_sj_none.result'
--- a/mysql-test/r/subquery_sj_none.result	2011-01-27 11:38:22 +0000
+++ b/mysql-test/r/subquery_sj_none.result	2011-02-09 12:30:47 +0000
@@ -2543,7 +2543,7 @@
 explain select * from t2 where (b,a) in (select a,b from t1 where a=3);
 id	select_type	table	type	possible_keys	key	key_len	ref	rows	Extra
 1	PRIMARY	t2	ALL	NULL	NULL	NULL	NULL	100	Using where
-2	DEPENDENT SUBQUERY	t1	index_subquery	a	a	10	func,func	1	Using index; Using where
+2	DEPENDENT SUBQUERY	t1	ref	a	a	10	const,func	1	Using where; Using index
 drop table t1,t2;
 create table t1 (a int, b int);
 insert into t1 select a,a from t0;

=== modified file 'mysql-test/t/join.test'
--- a/mysql-test/t/join.test	2010-12-16 17:38:26 +0000
+++ b/mysql-test/t/join.test	2011-02-09 12:30:47 +0000
@@ -934,3 +934,43 @@
 DROP TABLE t1;
 
 --echo End of 5.1 tests
+
+--echo #
+--echo # Bug #59696 Optimizer fails to move WHERE condition on JOIN column 
+--echo #            when joining with a view
+--echo #
+
+CREATE TABLE t1 (
+  c1 INTEGER NOT NULL
+);
+
+INSERT INTO t1 VALUES (1),(2),(3);
+
+CREATE TABLE t2 (
+  pk INTEGER NOT NULL,
+  c1 INTEGER NOT NULL,
+  PRIMARY KEY (pk)
+);
+
+INSERT INTO t2 VALUES (1,4),(3,5),(2,6);
+
+let $query=
+SELECT t2.pk, t2.c1 FROM t2, t1 
+WHERE t2.pk = t1.c1 AND t2.pk >= 2;
+
+eval EXPLAIN $query;
+eval $query;
+
+# Create a view on one of the tables. The same query plan should
+# be used when joining with this view as with the underlying table.
+CREATE VIEW v_t2 AS SELECT * FROM t2;
+
+let $query=
+SELECT v_t2.pk, v_t2.c1 FROM v_t2, t1 
+WHERE v_t2.pk = t1.c1 AND v_t2.pk >= 2;
+
+eval EXPLAIN $query;
+eval $query;
+
+DROP VIEW v_t2;
+DROP TABLE t1, t2;

=== modified file 'sql/item.cc'
--- a/sql/item.cc	2011-01-31 10:37:16 +0000
+++ b/sql/item.cc	2011-02-09 12:30:47 +0000
@@ -6523,6 +6523,82 @@
 }
 
 
+/**
+  Transform an Item_ref object with a transformer callback function.
+
+  The function first applies the transform function to the item
+  referenced by this Item_ref object. If this returns a new item the
+  old 'ref' item is substituted by the new one. After this the transformer
+  is applied to the Item_ref object.
+
+  @param transformer   the transformer callback function to be applied to
+                       the nodes of the tree of the object
+  @param argument      parameter to be passed to the transformer
+
+  @return Item returned as the result of transformation of the Item_ref object
+    @retval !NULL The transformation was successful
+    @retval NULL  Out of memory error
+*/
+
+Item* Item_ref::transform(Item_transformer transformer, uchar *arg)
+{
+  DBUG_ASSERT(!current_thd->is_stmt_prepare());
+  DBUG_ASSERT((*ref) != NULL);
+
+  /* Transform the object we are referencing. */
+  Item *new_item= (*ref)->transform(transformer, arg);
+  if (!new_item)
+    return NULL;
+
+  /*
+    Record the new item in the 'ref' pointer, in a manner safe for 
+    prepared execution.
+  */
+  if (*ref != new_item)
+    current_thd->change_item_tree(ref, new_item);
+
+  /* Transform the item ref object. */
+  Item *transformed_item= (this->*transformer)(arg);
+  DBUG_ASSERT(transformed_item == this);
+  return transformed_item;
+}
+
+
+/**
+  Compile an Item_ref object with a processor and a transformer
+  callback function.
+
+  First the function applies the analyzer to the Item_ref
+  object. Second it applies the compile method to the object the
+  Item_ref object is referencing. If a new item is returned the old
+  item is substituted by the new one. After this the transformer is
+  applied to the Item_ref object itself.
+
+  @param analyzer      the analyzer callback function to be applied to the
+                       nodes of the tree of the object
+  @param[in,out] arg_p parameter to be passed to the processor
+  @param transformer   the transformer callback function to be applied to the
+                       nodes of the tree of the object
+  @param arg_t         parameter to be passed to the transformer
+
+  @return Item returned as the result of transformation of the Item_ref object
+*/
+
+Item* Item_ref::compile(Item_analyzer analyzer, uchar **arg_p,
+                        Item_transformer transformer, uchar *arg_t)
+{
+  if (!(this->*analyzer)(arg_p))
+    return NULL;
+
+  DBUG_ASSERT((*ref) != NULL);
+  Item *new_item= (*ref)->compile(analyzer, arg_p, transformer, arg_t);
+  if (new_item && *ref != new_item)
+    current_thd->change_item_tree(ref, new_item);
+  
+  return (this->*transformer)(arg_t);
+}
+
+
 void Item_ref::print(String *str, enum_query_type query_type)
 {
   if (ref)

=== modified file 'sql/item.h'
--- a/sql/item.h	2011-02-08 15:54:12 +0000
+++ b/sql/item.h	2011-02-09 12:30:47 +0000
@@ -2622,6 +2622,9 @@
     return (*ref)->walk(processor, walk_subquery, arg) ||
            (this->*processor)(arg);
   }
+  virtual Item* transform(Item_transformer, uchar *arg);
+  virtual Item* compile(Item_analyzer analyzer, uchar **arg_p,
+                        Item_transformer transformer, uchar *arg_t);
   virtual void print(String *str, enum_query_type query_type);
   bool result_as_longlong()
   {


Attachment: [text/bzr-bundle] bzr/olav.sandstaa@oracle.com-20110209123047-yzn52nb8oqxsdabk.bundle
Thread
bzr commit into mysql-trunk branch (olav.sandstaa:3625) Bug#59696Olav Sandstaa9 Feb