From e58314d4829246bf7ea7b15f8c3e3fec3f09a71a Mon Sep 17 00:00:00 2001 From: "sergefp@mysql.com" <> Date: Fri, 13 Jan 2006 23:55:30 +0300 Subject: [PATCH 1/4] BUG#16393: Let the 'ref' optimizer use ON condition of nested join to construct 'ref' accesses to all tables that are direct children of the nested join and are not inner wrt their siblings. --- mysql-test/r/join_nested.result | 20 +++++++-- mysql-test/t/join_nested.test | 14 ++++++ sql/sql_select.cc | 80 ++++++++++++++++++++++++++++----- 3 files changed, 99 insertions(+), 15 deletions(-) diff --git a/mysql-test/r/join_nested.result b/mysql-test/r/join_nested.result index 6b7293d46bc..faad969fcd1 100644 --- a/mysql-test/r/join_nested.result +++ b/mysql-test/r/join_nested.result @@ -960,7 +960,7 @@ id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t2 ALL NULL NULL NULL NULL 3 Using where 1 SIMPLE t3 ALL NULL NULL NULL NULL 2 Using where 1 SIMPLE t4 ref idx_b idx_b 5 test.t2.b 2 Using where -1 SIMPLE t5 ALL NULL NULL NULL NULL 3 Using where +1 SIMPLE t5 ALL idx_b NULL NULL NULL 3 Using where 1 SIMPLE t7 ALL NULL NULL NULL NULL 2 Using where 1 SIMPLE t6 ALL NULL NULL NULL NULL 3 Using where 1 SIMPLE t8 ALL NULL NULL NULL NULL 2 Using where @@ -1009,7 +1009,7 @@ id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t2 ALL NULL NULL NULL NULL 3 Using where 1 SIMPLE t3 ALL NULL NULL NULL NULL 2 Using where 1 SIMPLE t4 ref idx_b idx_b 5 test.t2.b 2 Using where -1 SIMPLE t5 ALL NULL NULL NULL NULL 3 Using where +1 SIMPLE t5 ALL idx_b NULL NULL NULL 3 Using where 1 SIMPLE t7 ALL NULL NULL NULL NULL 2 Using where 1 SIMPLE t6 ALL NULL NULL NULL NULL 3 Using where 1 SIMPLE t8 ref idx_b idx_b 5 test.t5.b 2 Using where @@ -1059,7 +1059,7 @@ id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t2 ALL NULL NULL NULL NULL 3 Using where 1 SIMPLE t3 ALL NULL NULL NULL NULL 2 Using where 1 SIMPLE t4 ref idx_b idx_b 5 test.t2.b 2 Using where -1 SIMPLE t5 ALL NULL NULL NULL NULL 3 Using where +1 SIMPLE t5 ALL idx_b NULL NULL NULL 3 Using where 1 SIMPLE t7 ALL NULL NULL NULL NULL 2 Using where 1 SIMPLE t6 ALL NULL NULL NULL NULL 3 Using where 1 SIMPLE t8 ref idx_b idx_b 5 test.t5.b 2 Using where @@ -1467,3 +1467,17 @@ id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t6 ref a a 5 test.t4.b X 1 SIMPLE t5 ref a a 5 test.t3.b X drop table t0, t1, t2, t3, t4, t5, t6, t7; +create table t1 (a int); +insert into t1 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9); +create table t2 (a int, filler char(100), key(a)); +insert into t2 select A.a + 10*B.a, '' from t1 A, t1 B; +create table t3 like t2; +insert into t3 select * from t2; +explain select * from t1 left join +(t2 left join t3 on (t2.a = t3.a)) +on (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 ref a a 5 test.t1.a 1 +1 SIMPLE t3 ref a a 5 test.t2.a 1 +drop table t1, t2, t3; diff --git a/mysql-test/t/join_nested.test b/mysql-test/t/join_nested.test index 9f23e2d0e2f..145edded486 100644 --- a/mysql-test/t/join_nested.test +++ b/mysql-test/t/join_nested.test @@ -900,3 +900,17 @@ explain select * from t2 left join join t5 on t5.a=t3.b) on t3.a=t2.b; drop table t0, t1, t2, t3, t4, t5, t6, t7; + +# BUG#16393 +create table t1 (a int); +insert into t1 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9); +create table t2 (a int, filler char(100), key(a)); +insert into t2 select A.a + 10*B.a, '' from t1 A, t1 B; +create table t3 like t2; +insert into t3 select * from t2; + +explain select * from t1 left join + (t2 left join t3 on (t2.a = t3.a)) + on (t1.a = t2.a); +drop table t1, t2, t3; + diff --git a/sql/sql_select.cc b/sql/sql_select.cc index ad6375290cd..9436ad7e840 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -2917,6 +2917,64 @@ sort_keyuse(KEYUSE *a,KEYUSE *b) } +/* + Add to KEY_FIELD array all 'ref' access candidates within nested join + + SYNPOSIS + add_key_fields_for_nj() + nested_join_table IN Nested join pseudo-table to process + end INOUT End of the key field array + and_level INOUT And-level + + DESCRIPTION + This function populates KEY_FIELD array with entries generated from the + ON condition of the given nested join, and does the same for nested joins + contained within this nested join. + + IMPLEMENTATION + We can add accesses to the tables that are direct children of this nested + join (1), and are not inner tables w.r.t their neighbours (2). + + Example for #1 (outer brackets pair denotes nested join this function is + invoked for): + + ... LEFT JOIN (t1 LEFT JOIN (t2 ... ) ) ON cond + + Example for #2: + + ... LEFT JOIN (t1 LEFT JOIN t2 ) ON cond + + In examples 1-2 for condition cond, we can add 'ref' access candidates to + t1 only. + + Example #3: + + ... LEFT JOIN (t1, t2 JOIN t3 ON inner_cond) ON cond + + Here we can add 'ref' access candidates for t1 and t2, but not for t3. + +*/ + +static void add_key_fields_for_nj(TABLE_LIST *nested_join_table, + KEY_FIELD **end, uint *and_level) +{ + List_iterator li(nested_join_table->nested_join->join_list); + table_map tables= 0; + TABLE_LIST *table; + DBUG_ASSERT(nested_join_table->nested_join); + + while ((table= li++)) + { + if (table->nested_join) + add_key_fields_for_nj(table, end, and_level); + else + if (!table->on_expr) + tables |= table->table->map; + } + add_key_fields(end, and_level, nested_join_table->on_expr, tables); +} + + /* Update keyuse array with all possible keys we can use to fetch rows @@ -2981,23 +3039,21 @@ update_ref_and_keys(THD *thd, DYNAMIC_ARRAY *keyuse,JOIN_TAB *join_tab, into account as well. */ if (*join_tab[i].on_expr_ref) - { add_key_fields(&end,&and_level,*join_tab[i].on_expr_ref, join_tab[i].table->map); - } - else + } + + /* Process ON conditions for the nested joins */ + { + List_iterator li(*join_tab->join->join_list); + TABLE_LIST *table; + while ((table= li++)) { - TABLE_LIST *tab= join_tab[i].table->pos_in_table_list; - TABLE_LIST *embedding= tab->embedding; - if (embedding) - { - NESTED_JOIN *nested_join= embedding->nested_join; - if (nested_join->join_list.head() == tab) - add_key_fields(&end, &and_level, embedding->on_expr, - nested_join->used_tables); - } + if (table->nested_join) + add_key_fields_for_nj(table, &end, &and_level); } } + /* fill keyuse with found key parts */ for ( ; field != end ; field++) add_key_part(keyuse,field); From dc14d007dba793e5366e258460fe6e34be024af8 Mon Sep 17 00:00:00 2001 From: "sergefp@mysql.com" <> Date: Sat, 14 Jan 2006 01:26:42 +0300 Subject: [PATCH 2/4] BUG#16393: post-review fixes: fix comments. --- sql/sql_select.cc | 18 +++++------------- 1 file changed, 5 insertions(+), 13 deletions(-) diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 9436ad7e840..1c7293fd89d 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -2925,34 +2925,26 @@ sort_keyuse(KEYUSE *a,KEYUSE *b) nested_join_table IN Nested join pseudo-table to process end INOUT End of the key field array and_level INOUT And-level - + DESCRIPTION This function populates KEY_FIELD array with entries generated from the ON condition of the given nested join, and does the same for nested joins contained within this nested join. - - IMPLEMENTATION + + NOTES We can add accesses to the tables that are direct children of this nested join (1), and are not inner tables w.r.t their neighbours (2). Example for #1 (outer brackets pair denotes nested join this function is invoked for): - ... LEFT JOIN (t1 LEFT JOIN (t2 ... ) ) ON cond - Example for #2: - ... LEFT JOIN (t1 LEFT JOIN t2 ) ON cond - In examples 1-2 for condition cond, we can add 'ref' access candidates to t1 only. - Example #3: - - ... LEFT JOIN (t1, t2 JOIN t3 ON inner_cond) ON cond - + ... LEFT JOIN (t1, t2 LEFT JOIN t3 ON inner_cond) ON cond Here we can add 'ref' access candidates for t1 and t2, but not for t3. - */ static void add_key_fields_for_nj(TABLE_LIST *nested_join_table, @@ -2969,7 +2961,7 @@ static void add_key_fields_for_nj(TABLE_LIST *nested_join_table, add_key_fields_for_nj(table, end, and_level); else if (!table->on_expr) - tables |= table->table->map; + tables |= table->table->map; } add_key_fields(end, and_level, nested_join_table->on_expr, tables); } From 48d48bc93603d9f77db4e86907f84103d45c5709 Mon Sep 17 00:00:00 2001 From: "konstantin@mysql.com" <> Date: Sat, 14 Jan 2006 04:55:07 +0300 Subject: [PATCH 3/4] A fix and a test case for Bug#12734 " prepared statement may return incorrect result set for a select SQL request" --- mysql-test/r/ps.result | 34 ++++++++++++++++++++++++++++++++++ mysql-test/t/ps.test | 30 ++++++++++++++++++++++++++++++ sql/item_cmpfunc.cc | 6 ++++++ sql/item_cmpfunc.h | 1 + 4 files changed, 71 insertions(+) diff --git a/mysql-test/r/ps.result b/mysql-test/r/ps.result index d46c2d5b3d5..aa9ff083cbb 100644 --- a/mysql-test/r/ps.result +++ b/mysql-test/r/ps.result @@ -718,3 +718,37 @@ execute stmt; drop table t1; set names default; deallocate prepare stmt; +create table t1 ( +word_id mediumint(8) unsigned not null default '0', +formatted varchar(20) not null default '' +); +insert into t1 values +(80,'pendant'), (475,'pretendants'), (989,'tendances'), +(1019,'cependant'),(1022,'abondance'),(1205,'independants'), +(13,'lessiver'),(25,'lambiner'),(46,'situer'),(71,'terminer'), +(82,'decrocher'); +select count(*) from t1 where formatted like '%NDAN%'; +count(*) +6 +select count(*) from t1 where formatted like '%ER'; +count(*) +5 +prepare stmt from "select count(*) from t1 where formatted like ?"; +set @like="%NDAN%"; +execute stmt using @like; +count(*) +6 +set @like="%ER"; +execute stmt using @like; +count(*) +5 +set @like="%NDAN%"; +execute stmt using @like; +count(*) +6 +set @like="%ER"; +execute stmt using @like; +count(*) +5 +deallocate prepare stmt; +drop table t1; diff --git a/mysql-test/t/ps.test b/mysql-test/t/ps.test index 82dfc643801..23eb2e11ae3 100644 --- a/mysql-test/t/ps.test +++ b/mysql-test/t/ps.test @@ -746,5 +746,35 @@ drop table t1; set names default; deallocate prepare stmt; +# +# A test case for Bug#12734 "prepared statement may return incorrect result +# set for a select SQL request": test that canDoTurboBM is reset for each +# execute of a prepared statement. +# +create table t1 ( + word_id mediumint(8) unsigned not null default '0', + formatted varchar(20) not null default '' +); + +insert into t1 values + (80,'pendant'), (475,'pretendants'), (989,'tendances'), + (1019,'cependant'),(1022,'abondance'),(1205,'independants'), + (13,'lessiver'),(25,'lambiner'),(46,'situer'),(71,'terminer'), + (82,'decrocher'); + +select count(*) from t1 where formatted like '%NDAN%'; +select count(*) from t1 where formatted like '%ER'; +prepare stmt from "select count(*) from t1 where formatted like ?"; +set @like="%NDAN%"; +execute stmt using @like; +set @like="%ER"; +execute stmt using @like; +set @like="%NDAN%"; +execute stmt using @like; +set @like="%ER"; +execute stmt using @like; +deallocate prepare stmt; +drop table t1; + # End of 4.1 tests diff --git a/sql/item_cmpfunc.cc b/sql/item_cmpfunc.cc index 2c76c7ec7b3..f9aa220c181 100644 --- a/sql/item_cmpfunc.cc +++ b/sql/item_cmpfunc.cc @@ -2524,6 +2524,12 @@ bool Item_func_like::fix_fields(THD *thd, TABLE_LIST *tlist, Item ** ref) return 0; } +void Item_func_like::cleanup() +{ + canDoTurboBM= FALSE; + Item_bool_func2::cleanup(); +} + #ifdef USE_REGEX bool diff --git a/sql/item_cmpfunc.h b/sql/item_cmpfunc.h index 045566a46d5..ade09113c63 100644 --- a/sql/item_cmpfunc.h +++ b/sql/item_cmpfunc.h @@ -911,6 +911,7 @@ public: cond_result eq_cmp_result() const { return COND_TRUE; } const char *func_name() const { return "like"; } bool fix_fields(THD *thd, struct st_table_list *tlist, Item **ref); + void cleanup(); }; #ifdef USE_REGEX From 750f9fee90b0214c9be52051cd92cd6b2aba6e85 Mon Sep 17 00:00:00 2001 From: "konstantin@mysql.com" <> Date: Sat, 14 Jan 2006 21:20:42 +0300 Subject: [PATCH 4/4] A post-merge fix (Bug#12734) --- mysql-test/r/ps.result | 34 ++++++++++++++++++++++++++++++++++ 1 file changed, 34 insertions(+) diff --git a/mysql-test/r/ps.result b/mysql-test/r/ps.result index bc3d2a6108c..a7c05e9acad 100644 --- a/mysql-test/r/ps.result +++ b/mysql-test/r/ps.result @@ -825,6 +825,40 @@ execute stmt; drop table t1; set names default; deallocate prepare stmt; +create table t1 ( +word_id mediumint(8) unsigned not null default '0', +formatted varchar(20) not null default '' +); +insert into t1 values +(80,'pendant'), (475,'pretendants'), (989,'tendances'), +(1019,'cependant'),(1022,'abondance'),(1205,'independants'), +(13,'lessiver'),(25,'lambiner'),(46,'situer'),(71,'terminer'), +(82,'decrocher'); +select count(*) from t1 where formatted like '%NDAN%'; +count(*) +6 +select count(*) from t1 where formatted like '%ER'; +count(*) +5 +prepare stmt from "select count(*) from t1 where formatted like ?"; +set @like="%NDAN%"; +execute stmt using @like; +count(*) +6 +set @like="%ER"; +execute stmt using @like; +count(*) +5 +set @like="%NDAN%"; +execute stmt using @like; +count(*) +6 +set @like="%ER"; +execute stmt using @like; +count(*) +5 +deallocate prepare stmt; +drop table t1; create table t1 (id int); prepare ins_call from "insert into t1 (id) values (1)"; execute ins_call;