From a2d4a042d098fb01183c9b47e9ac6194997007ba Mon Sep 17 00:00:00 2001 From: "igor@olga.mysql.com" <> Date: Wed, 14 Feb 2007 22:06:41 -0800 Subject: [PATCH 1/4] Fixed bug #25971: indexes on text columns were ignored when ref accesses were evaluated. According to the new rules for string comparison partial indexes on text columns can be used in the same cases when partial indexes on varchar columns can be used. --- mysql-test/r/endspace.result | 2 +- mysql-test/r/innodb.result | 2 +- mysql-test/r/myisam.result | 2 +- mysql-test/r/select.result | 148 ++++++++++++++++++++++++++++++++++ mysql-test/r/type_blob.result | 4 +- mysql-test/t/select.test | 46 +++++++++++ sql/sql_select.cc | 8 +- 7 files changed, 200 insertions(+), 12 deletions(-) diff --git a/mysql-test/r/endspace.result b/mysql-test/r/endspace.result index 0e68418a80f..003ee7ffd5e 100644 --- a/mysql-test/r/endspace.result +++ b/mysql-test/r/endspace.result @@ -98,7 +98,7 @@ concat('|', text1, '|') |teststring | explain select concat('|', text1, '|') from t1 where text1='teststring '; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 range key1 key1 22 NULL 2 Using where +1 SIMPLE t1 ref key1 key1 22 const 2 Using where select concat('|', text1, '|') from t1 where text1 like 'teststring_%'; concat('|', text1, '|') |teststring | diff --git a/mysql-test/r/innodb.result b/mysql-test/r/innodb.result index 38d71ac7a42..496c8aa90d2 100644 --- a/mysql-test/r/innodb.result +++ b/mysql-test/r/innodb.result @@ -1991,7 +1991,7 @@ id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t1 ref c c 11 const # Using where; Using index explain select count(*) from t1 where t='a '; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 range t t 13 NULL # Using where +1 SIMPLE t1 ref t t 13 const # Using where explain select count(*) from t1 where v like 'a%'; id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t1 range v v 13 NULL # Using where; Using index diff --git a/mysql-test/r/myisam.result b/mysql-test/r/myisam.result index 0f6e0ad537a..83359048a8c 100644 --- a/mysql-test/r/myisam.result +++ b/mysql-test/r/myisam.result @@ -1071,7 +1071,7 @@ id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t1 ref c c 11 const # Using where; Using index explain select count(*) from t1 where t='a '; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 range t t 13 NULL # Using where +1 SIMPLE t1 ref t t 13 const # Using where explain select count(*) from t1 where v like 'a%'; id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t1 range v v 13 NULL # Using where; Using index diff --git a/mysql-test/r/select.result b/mysql-test/r/select.result index f50f4859d48..c3132a1b5f6 100644 --- a/mysql-test/r/select.result +++ b/mysql-test/r/select.result @@ -3785,4 +3785,152 @@ case when 1 then cast(1111111111111111111 as unsigned) else 1 end c, coalesce(cast(1111111111111111111 as unsigned), 1) co; i c co 1111111111111111111 1111111111111111111 1111111111111111111 +CREATE TABLE t1 (name varchar(255)); +CREATE TABLE t2 (name varchar(255), n int, KEY (name(3))); +INSERT INTO t1 VALUES ('ccc'), ('bb'), ('cc '), ('aa '), ('aa'); +INSERT INTO t2 VALUES ('bb',1), ('aa',2), ('cc ',3); +INSERT INTO t2 VALUES (concat('cc ', 0x06), 4); +INSERT INTO t2 VALUES ('cc',5), ('bb ',6), ('cc ',7); +SELECT * FROM t2; +name n +bb 1 +aa 2 +cc 3 +cc  4 +cc 5 +bb 6 +cc 7 +SELECT * FROM t2 ORDER BY name; +name n +aa 2 +bb 1 +bb 6 +cc  4 +cc 3 +cc 5 +cc 7 +SELECT name, LENGTH(name), n FROM t2 ORDER BY name; +name LENGTH(name) n +aa 2 2 +bb 2 1 +bb 3 6 +cc  4 4 +cc 5 3 +cc 2 5 +cc 3 7 +EXPLAIN SELECT name, LENGTH(name), n FROM t2 WHERE name='cc '; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t2 ref name name 6 const 3 Using where +SELECT name, LENGTH(name), n FROM t2 WHERE name='cc '; +name LENGTH(name) n +cc 5 3 +cc 2 5 +cc 3 7 +EXPLAIN SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%'; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t2 range name name 6 NULL 3 Using where +SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%'; +name LENGTH(name) n +cc 5 3 +cc  4 4 +cc 2 5 +cc 3 7 +EXPLAIN SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%' ORDER BY name; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t2 range name name 6 NULL 3 Using where; Using filesort +SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%' ORDER BY name; +name LENGTH(name) n +cc  4 4 +cc 5 3 +cc 2 5 +cc 3 7 +EXPLAIN SELECT * FROM t1 LEFT JOIN t2 ON t1.name=t2.name; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 +1 SIMPLE t2 ref name name 6 test.t1.name 2 +SELECT * FROM t1 LEFT JOIN t2 ON t1.name=t2.name; +name name n +ccc NULL NULL +bb bb 1 +bb bb 6 +cc cc 3 +cc cc 5 +cc cc 7 +aa aa 2 +aa aa 2 +DROP TABLE t1,t2; +CREATE TABLE t1 (name text); +CREATE TABLE t2 (name text, n int, KEY (name(3))); +INSERT INTO t1 VALUES ('ccc'), ('bb'), ('cc '), ('aa '), ('aa'); +INSERT INTO t2 VALUES ('bb',1), ('aa',2), ('cc ',3); +INSERT INTO t2 VALUES (concat('cc ', 0x06), 4); +INSERT INTO t2 VALUES ('cc',5), ('bb ',6), ('cc ',7); +SELECT * FROM t2; +name n +bb 1 +aa 2 +cc 3 +cc  4 +cc 5 +bb 6 +cc 7 +SELECT * FROM t2 ORDER BY name; +name n +aa 2 +bb 1 +bb 6 +cc  4 +cc 3 +cc 5 +cc 7 +SELECT name, LENGTH(name), n FROM t2 ORDER BY name; +name LENGTH(name) n +aa 2 2 +bb 2 1 +bb 3 6 +cc  4 4 +cc 5 3 +cc 2 5 +cc 3 7 +EXPLAIN SELECT name, LENGTH(name), n FROM t2 WHERE name='cc '; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t2 ref name name 6 const 3 Using where +SELECT name, LENGTH(name), n FROM t2 WHERE name='cc '; +name LENGTH(name) n +cc 5 3 +cc 2 5 +cc 3 7 +EXPLAIN SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%'; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t2 range name name 6 NULL 3 Using where +SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%'; +name LENGTH(name) n +cc 5 3 +cc  4 4 +cc 2 5 +cc 3 7 +EXPLAIN SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%' ORDER BY name; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t2 range name name 6 NULL 3 Using where; Using filesort +SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%' ORDER BY name; +name LENGTH(name) n +cc  4 4 +cc 5 3 +cc 2 5 +cc 3 7 +EXPLAIN SELECT * FROM t1 LEFT JOIN t2 ON t1.name=t2.name; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 +1 SIMPLE t2 ref name name 6 test.t1.name 2 +SELECT * FROM t1 LEFT JOIN t2 ON t1.name=t2.name; +name name n +ccc NULL NULL +bb bb 1 +bb bb 6 +cc cc 3 +cc cc 5 +cc cc 7 +aa aa 2 +aa aa 2 +DROP TABLE t1,t2; End of 5.0 tests diff --git a/mysql-test/r/type_blob.result b/mysql-test/r/type_blob.result index 73b67a2241e..b28f404c641 100644 --- a/mysql-test/r/type_blob.result +++ b/mysql-test/r/type_blob.result @@ -610,12 +610,12 @@ create table t1 (id integer primary key auto_increment, txt text, index txt_inde insert into t1 (txt) values ('Chevy'), ('Chevy '), (NULL); select * from t1 where txt='Chevy' or txt is NULL; id txt -3 NULL 1 Chevy 2 Chevy +3 NULL explain select * from t1 where txt='Chevy' or txt is NULL; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 range txt_index txt_index 23 NULL 2 Using where +1 SIMPLE t1 ref_or_null txt_index txt_index 23 const 2 Using where select * from t1 where txt='Chevy '; id txt 1 Chevy diff --git a/mysql-test/t/select.test b/mysql-test/t/select.test index c4737814137..ea5fadb2e1b 100644 --- a/mysql-test/t/select.test +++ b/mysql-test/t/select.test @@ -3253,4 +3253,50 @@ select case when 1 then cast(1111111111111111111 as unsigned) else 1 end c, coalesce(cast(1111111111111111111 as unsigned), 1) co; +# +# Bug #22971: indexes on text columns are ignored for ref accesses +# + +CREATE TABLE t1 (name varchar(255)); +CREATE TABLE t2 (name varchar(255), n int, KEY (name(3))); +INSERT INTO t1 VALUES ('ccc'), ('bb'), ('cc '), ('aa '), ('aa'); +INSERT INTO t2 VALUES ('bb',1), ('aa',2), ('cc ',3); +INSERT INTO t2 VALUES (concat('cc ', 0x06), 4); +INSERT INTO t2 VALUES ('cc',5), ('bb ',6), ('cc ',7); +SELECT * FROM t2; +SELECT * FROM t2 ORDER BY name; +SELECT name, LENGTH(name), n FROM t2 ORDER BY name; + +EXPLAIN SELECT name, LENGTH(name), n FROM t2 WHERE name='cc '; +SELECT name, LENGTH(name), n FROM t2 WHERE name='cc '; +EXPLAIN SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%'; +SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%'; +EXPLAIN SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%' ORDER BY name; +SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%' ORDER BY name; +EXPLAIN SELECT * FROM t1 LEFT JOIN t2 ON t1.name=t2.name; +SELECT * FROM t1 LEFT JOIN t2 ON t1.name=t2.name; + +DROP TABLE t1,t2; + +CREATE TABLE t1 (name text); +CREATE TABLE t2 (name text, n int, KEY (name(3))); +INSERT INTO t1 VALUES ('ccc'), ('bb'), ('cc '), ('aa '), ('aa'); +INSERT INTO t2 VALUES ('bb',1), ('aa',2), ('cc ',3); +INSERT INTO t2 VALUES (concat('cc ', 0x06), 4); +INSERT INTO t2 VALUES ('cc',5), ('bb ',6), ('cc ',7); +SELECT * FROM t2; +SELECT * FROM t2 ORDER BY name; +SELECT name, LENGTH(name), n FROM t2 ORDER BY name; + +EXPLAIN SELECT name, LENGTH(name), n FROM t2 WHERE name='cc '; +SELECT name, LENGTH(name), n FROM t2 WHERE name='cc '; +EXPLAIN SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%'; +SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%'; +EXPLAIN SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%' ORDER BY name; +SELECT name , LENGTH(name), n FROM t2 WHERE name LIKE 'cc%' ORDER BY name; +EXPLAIN SELECT * FROM t1 LEFT JOIN t2 ON t1.name=t2.name; +SELECT * FROM t1 LEFT JOIN t2 ON t1.name=t2.name; + +DROP TABLE t1,t2; + --echo End of 5.0 tests diff --git a/sql/sql_select.cc b/sql/sql_select.cc index ed108828909..93f5092fd60 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -2854,15 +2854,9 @@ add_key_field(KEY_FIELD **key_fields,uint and_level, Item_func *cond, /* We can't use indexes if the effective collation of the operation differ from the field collation. - - We also cannot use index on a text column, as the column may - contain 'x' 'x\t' 'x ' and 'read_next_same' will stop after - 'x' when searching for WHERE col='x ' */ if (field->cmp_type() == STRING_RESULT && - (((Field_str*)field)->charset() != cond->compare_collation() || - ((*value)->type() != Item::NULL_ITEM && - (field->flags & BLOB_FLAG) && !field->binary()))) + ((Field_str*)field)->charset() != cond->compare_collation()) return; } } From 7916d9e965fb8ddf62fde4ed1db849d3b49c37cc Mon Sep 17 00:00:00 2001 From: "evgen@moonbone.local" <> Date: Fri, 16 Feb 2007 19:39:28 +0300 Subject: [PATCH 2/4] Bug#16630: The update fields of the INSERT .. SELECT .. ON DUPLICATE KEY UPDATE contains wrong data if the SELECT employs a temporary table. If the UPDATE values of the INSERT .. SELECT .. ON DUPLICATE KEY UPDATE statement contains fields from the SELECT part and the select employs a temporary table then those fields will contain wrong values because they aren't corrected to get data from the temporary table. The solution is to add these fields to the selects all_fields list, to store pointers to those fields in the selects ref_pointer_array and to access them via Item_ref objects. The substitution for Item_ref objects is done in the new function called Item_field::update_value_transformer(). It is called through the item->transform() mechanism at the end of the select_insert::prepare() function. --- mysql-test/r/insert_select.result | 13 +++++++++ mysql-test/t/insert_select.test | 15 +++++++++++ sql/item.cc | 45 +++++++++++++++++++++++++++++++ sql/item.h | 2 ++ sql/sql_insert.cc | 16 +++++++++++ sql/sql_select.cc | 6 ++--- 6 files changed, 94 insertions(+), 3 deletions(-) diff --git a/mysql-test/r/insert_select.result b/mysql-test/r/insert_select.result index 2e0acf303c2..92b3ea0e42b 100644 --- a/mysql-test/r/insert_select.result +++ b/mysql-test/r/insert_select.result @@ -731,3 +731,16 @@ select @@identity; @@identity 0 drop table t1; +CREATE TABLE t1 (f1 INT, f2 INT ); +CREATE TABLE t2 (f1 INT PRIMARY KEY, f2 INT); +INSERT INTO t1 VALUES (1,1),(2,2),(10,10); +INSERT INTO t2 (f1, f2) SELECT f1, f2 FROM t1; +INSERT INTO t2 (f1, f2) +SELECT f1, f1 FROM t2 src WHERE f1 < 2 +ON DUPLICATE KEY UPDATE f1 = 100 + src.f1; +SELECT * FROM t2; +f1 f2 +101 1 +2 2 +10 10 +DROP TABLE t1, t2; diff --git a/mysql-test/t/insert_select.test b/mysql-test/t/insert_select.test index 5c60fc8e1f0..31508b3d6c4 100644 --- a/mysql-test/t/insert_select.test +++ b/mysql-test/t/insert_select.test @@ -292,3 +292,18 @@ select @@identity; insert ignore t1(f2) select 1; select @@identity; drop table t1; + +# +# Bug#16630: wrong result, when INSERT t1 SELECT ... FROM t1 ON DUPLICATE +# +CREATE TABLE t1 (f1 INT, f2 INT ); +CREATE TABLE t2 (f1 INT PRIMARY KEY, f2 INT); +INSERT INTO t1 VALUES (1,1),(2,2),(10,10); +INSERT INTO t2 (f1, f2) SELECT f1, f2 FROM t1; +INSERT INTO t2 (f1, f2) + SELECT f1, f1 FROM t2 src WHERE f1 < 2 + ON DUPLICATE KEY UPDATE f1 = 100 + src.f1; +SELECT * FROM t2; +DROP TABLE t1, t2; + + diff --git a/sql/item.cc b/sql/item.cc index 95001809e9a..23193e0990c 100644 --- a/sql/item.cc +++ b/sql/item.cc @@ -4809,6 +4809,51 @@ void Item_field::update_null_value() } +/* + Add the field to the select list and substitute it for the reference to + the field. + + SYNOPSIS + Item_field::update_value_transformer() + select_arg current select + + DESCRIPTION + If the field doesn't belong to the table being inserted into then it is + added to the select list, pointer to it is stored in the ref_pointer_array + of the select and the field itself is substituted for the Item_ref object. + This is done in order to get correct values from update fields that + belongs to the SELECT part in the INSERT .. SELECT .. ON DUPLICATE KEY + UPDATE statement. + + RETURN + 0 if error occured + ref if all conditions are met + this field otherwise +*/ + +Item *Item_field::update_value_transformer(byte *select_arg) +{ + SELECT_LEX *select= (SELECT_LEX*)select_arg; + DBUG_ASSERT(fixed); + + if (field->table != select->context.table_list->table && + type() != Item::TRIGGER_FIELD_ITEM) + { + List *all_fields= &select->join->all_fields; + Item **ref_pointer_array= select->ref_pointer_array; + int el= all_fields->elements; + Item_ref *ref; + + ref_pointer_array[el]= (Item*)this; + all_fields->push_front((Item*)this); + ref= new Item_ref(&select->context, ref_pointer_array + el, + table_name, field_name); + return ref; + } + return this; +} + + Item_ref::Item_ref(Name_resolution_context *context_arg, Item **item, const char *table_name_arg, const char *field_name_arg) diff --git a/sql/item.h b/sql/item.h index 6c41aa09f80..c254578f780 100644 --- a/sql/item.h +++ b/sql/item.h @@ -817,6 +817,7 @@ public: virtual Item_field *filed_for_view_update() { return 0; } virtual Item *neg_transformer(THD *thd) { return NULL; } + virtual Item *update_value_transformer(byte *select_arg) { return this; } virtual Item *safe_charset_converter(CHARSET_INFO *tocs); void delete_self() { @@ -1295,6 +1296,7 @@ public: Item_field *filed_for_view_update() { return this; } Item *safe_charset_converter(CHARSET_INFO *tocs); int fix_outer_field(THD *thd, Field **field, Item **reference); + virtual Item *update_value_transformer(byte *select_arg); friend class Item_default_value; friend class Item_insert_value; friend class st_select_lex_unit; diff --git a/sql/sql_insert.cc b/sql/sql_insert.cc index 39d7f8e9b58..542f47294e5 100644 --- a/sql/sql_insert.cc +++ b/sql/sql_insert.cc @@ -2388,7 +2388,23 @@ select_insert::prepare(List &values, SELECT_LEX_UNIT *u) next_name_resolution_table= ctx_state.save_next_local; } res= res || setup_fields(thd, 0, *info.update_values, 1, 0, 0); + if (!res) + { + /* + Traverse the update values list and substitute fields from the + select for references (Item_ref objects) to them. This is done in + order to get correct values from those fields when the select + employs a temporary table. + */ + List_iterator li(*info.update_values); + Item *item; + while ((item= li++)) + { + item->transform(&Item::update_value_transformer, + (byte*)lex->current_select); + } + } /* Restore the current context. */ ctx_state.restore_state(context, table_list); } diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 05ee0d77c1f..f4fec36aa53 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -482,6 +482,9 @@ JOIN::prepare(Item ***rref_pointer_array, } } + if (!procedure && result && result->prepare(fields_list, unit_arg)) + goto err; /* purecov: inspected */ + /* Init join struct */ count_field_types(&tmp_table_param, all_fields, 0); ref_pointer_array_size= all_fields.elements*sizeof(Item*); @@ -495,9 +498,6 @@ JOIN::prepare(Item ***rref_pointer_array, goto err; } #endif - if (!procedure && result && result->prepare(fields_list, unit_arg)) - goto err; /* purecov: inspected */ - if (select_lex->olap == ROLLUP_TYPE && rollup_init()) goto err; if (alloc_func_list()) From 0cc8643cac91d0f9617ed3e7990b617bb951bd00 Mon Sep 17 00:00:00 2001 From: "igor@olga.mysql.com" <> Date: Fri, 16 Feb 2007 14:30:25 -0800 Subject: [PATCH 3/4] Adjusted results after fix for bug 25971. --- mysql-test/r/bdb.result | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/mysql-test/r/bdb.result b/mysql-test/r/bdb.result index 33398d1ddd7..382fbf750c4 100644 --- a/mysql-test/r/bdb.result +++ b/mysql-test/r/bdb.result @@ -1442,7 +1442,7 @@ id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t1 ref c c 11 const # Using where explain select count(*) from t1 where t='a '; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 range t t 13 NULL # Using where +1 SIMPLE t1 ref t t 13 NULL # Using where explain select count(*) from t1 where v like 'a%'; id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t1 range v v 13 NULL # Using where From 53d93fc30e8188621be1bca573e4ba27e8853ede Mon Sep 17 00:00:00 2001 From: "igor@olga.mysql.com" <> Date: Fri, 16 Feb 2007 15:43:50 -0800 Subject: [PATCH 4/4] Adjusted results after fix for bug 25971. --- mysql-test/r/bdb.result | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/mysql-test/r/bdb.result b/mysql-test/r/bdb.result index 382fbf750c4..91c385112b4 100644 --- a/mysql-test/r/bdb.result +++ b/mysql-test/r/bdb.result @@ -1442,7 +1442,7 @@ id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t1 ref c c 11 const # Using where explain select count(*) from t1 where t='a '; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 ref t t 13 NULL # Using where +1 SIMPLE t1 ref t t 13 const # Using where explain select count(*) from t1 where v like 'a%'; id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t1 range v v 13 NULL # Using where