From c17bf5cb239fa8bb3039aef13203e9d99242442a Mon Sep 17 00:00:00 2001 From: "evgen@moonbone.local" <> Date: Thu, 11 Jan 2007 16:05:03 +0300 Subject: [PATCH 01/22] Bug#17711: DELETE doesn't use index when ORDER BY, LIMIT and non-restricting WHERE is present. If a DELETE statement with ORDER BY and LIMIT contains a WHERE clause with conditions that for sure cannot be used for index access (like in WHERE @var:= field) the execution always follows the filesort path. It happens currently even when for the above case there is an index that can be used to speedup sorting by the order by list. Now if a DELETE statement with ORDER BY and LIMIT contains such WHERE clause conditions that cannot be used to build any quick select then the mysql_delete() tries to use an index like there is no WHERE clause at all. --- mysql-test/r/delete.result | 7 +++++++ mysql-test/t/delete.test | 10 ++++++++++ sql/sql_delete.cc | 2 +- 3 files changed, 18 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/delete.result b/mysql-test/r/delete.result index 7a6af8fd905..a5c22e66569 100644 --- a/mysql-test/r/delete.result +++ b/mysql-test/r/delete.result @@ -186,4 +186,11 @@ select count(*) from t1; count(*) 0 drop table t1; +create table t1(f1 int primary key); +insert into t1 values (4),(3),(1),(2); +delete from t1 where (@a:= f1) order by f1 limit 1; +select @a; +@a +1 +drop table t1; End of 4.1 tests diff --git a/mysql-test/t/delete.test b/mysql-test/t/delete.test index 2036b59d810..301b2cdbb99 100644 --- a/mysql-test/t/delete.test +++ b/mysql-test/t/delete.test @@ -174,4 +174,14 @@ delete from t1 where a is null; select count(*) from t1; drop table t1; +# +# Bug#17711: DELETE doesn't use index when ORDER BY, LIMIT and +# non-restricting WHERE is present. +# +create table t1(f1 int primary key); +insert into t1 values (4),(3),(1),(2); +delete from t1 where (@a:= f1) order by f1 limit 1; +select @a; +drop table t1; + --echo End of 4.1 tests diff --git a/sql/sql_delete.cc b/sql/sql_delete.cc index 1b00539ed71..b84b2f7eef4 100644 --- a/sql/sql_delete.cc +++ b/sql/sql_delete.cc @@ -142,7 +142,7 @@ int mysql_delete(THD *thd, TABLE_LIST *table_list, COND *conds, DBUG_RETURN(-1); // This will force out message } - if (!select && limit != HA_POS_ERROR) + if ((!select || table->quick_keys.is_clear_all()) && limit != HA_POS_ERROR) usable_index= get_index_for_order(table, (ORDER*)(order->first), limit); if (usable_index == MAX_KEY) From fc0e206cb538d622abf1854a50a14836ac275b74 Mon Sep 17 00:00:00 2001 From: "evgen@moonbone.local" <> Date: Thu, 11 Jan 2007 16:45:38 +0300 Subject: [PATCH 02/22] Bug#23409: Arguments of the ENCODE() and the DECODE() functions were not printed correctly. The Item_func::print method was used to print the Item_func_encode and the Item_func_decode objects. The last argument to ENCODE and DECODE functions is a plain C string and thus Item_func::print wasn't able to print it. The print() method is added to the Item_func_encode class. It correctly prints the Item_func_encode and the Item_func_decode objects. --- mysql-test/r/func_str.result | 14 +++++++++++++- mysql-test/t/func_str.test | 8 ++++++++ sql/item_strfunc.cc | 13 +++++++++++++ sql/item_strfunc.h | 11 ++++++++--- 4 files changed, 42 insertions(+), 4 deletions(-) diff --git a/mysql-test/r/func_str.result b/mysql-test/r/func_str.result index 2c15e5581e8..af6a4d20cff 100644 --- a/mysql-test/r/func_str.result +++ b/mysql-test/r/func_str.result @@ -806,7 +806,7 @@ explain extended select md5('hello'), sha('abc'), sha1('abc'), soundex(''), 'moo id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE NULL NULL NULL NULL NULL NULL NULL No tables used Warnings: -Note 1003 select md5(_latin1'hello') AS `md5('hello')`,sha(_latin1'abc') AS `sha('abc')`,sha(_latin1'abc') AS `sha1('abc')`,soundex(_latin1'') AS `soundex('')`,(soundex(_latin1'mood') = soundex(_latin1'mud')) AS `'mood' sounds like 'mud'`,aes_decrypt(aes_encrypt(_latin1'abc',_latin1'1'),_latin1'1') AS `aes_decrypt(aes_encrypt('abc','1'),'1')`,concat(_latin1'*',repeat(_latin1' ',5),_latin1'*') AS `concat('*',space(5),'*')`,reverse(_latin1'abc') AS `reverse('abc')`,rpad(_latin1'a',4,_latin1'1') AS `rpad('a',4,'1')`,lpad(_latin1'a',4,_latin1'1') AS `lpad('a',4,'1')`,concat_ws(_latin1',',_latin1'',NULL,_latin1'a') AS `concat_ws(',','',NULL,'a')`,make_set(255,_latin2'a',_latin2'b',_latin2'c') AS `make_set(255,_latin2'a',_latin2'b',_latin2'c')`,elt(2,1) AS `elt(2,1)`,locate(_latin1'a',_latin1'b',2) AS `locate("a","b",2)`,format(130,10) AS `format(130,10)`,char(0) AS `char(0)`,conv(130,16,10) AS `conv(130,16,10)`,hex(130) AS `hex(130)`,cast(_latin1'HE' as char charset binary) AS `binary 'HE'`,export_set(255,_latin2'y',_latin2'n',_latin2' ') AS `export_set(255,_latin2'y',_latin2'n',_latin2' ')`,field((_latin1'b' collate _latin1'latin1_bin'),_latin1'A',_latin1'B') AS `FIELD('b' COLLATE latin1_bin,'A','B')`,find_in_set(_latin1'B',_latin1'a,b,c,d') AS `FIND_IN_SET(_latin1'B',_latin1'a,b,c,d')`,collation(conv(130,16,10)) AS `collation(conv(130,16,10))`,coercibility(conv(130,16,10)) AS `coercibility(conv(130,16,10))`,length(_latin1'\n \r\0\\_\\%\\') AS `length('\n\t\r\b\0\_\%\\')`,bit_length(_latin1'\n \r\0\\_\\%\\') AS `bit_length('\n\t\r\b\0\_\%\\')`,bit_length(_latin1'\n \r\0\\_\\%\\') AS `bit_length('\n\t\r\b\0\_\%\\')`,concat(_latin1'monty',_latin1' was here ',_latin1'again') AS `concat('monty',' was here ','again')`,length(_latin1'hello') AS `length('hello')`,char(ascii(_latin1'h')) AS `char(ascii('h'))`,ord(_latin1'h') AS `ord('h')`,quote((1 / 0)) AS `quote(1/0)`,crc32(_latin1'123') AS `crc32("123")`,replace(_latin1'aaaa',_latin1'a',_latin1'b') AS `replace('aaaa','a','b')`,insert(_latin1'txs',2,1,_latin1'hi') AS `insert('txs',2,1,'hi')`,left(_latin2'a',1) AS `left(_latin2'a',1)`,right(_latin2'a',1) AS `right(_latin2'a',1)`,lcase(_latin2'a') AS `lcase(_latin2'a')`,ucase(_latin2'a') AS `ucase(_latin2'a')`,substr(_latin1'abcdefg',3,2) AS `SUBSTR('abcdefg',3,2)`,substr_index(_latin1'1abcd;2abcd;3abcd;4abcd',_latin1';',2) AS `substring_index("1abcd;2abcd;3abcd;4abcd", ';', 2)`,trim(_latin2' a ') AS `trim(_latin2' a ')`,ltrim(_latin2' a ') AS `ltrim(_latin2' a ')`,rtrim(_latin2' a ') AS `rtrim(_latin2' a ')`,decode(encode(repeat(_latin1'a',100000))) AS `decode(encode(repeat("a",100000),"monty"),"monty")` +Note 1003 select md5(_latin1'hello') AS `md5('hello')`,sha(_latin1'abc') AS `sha('abc')`,sha(_latin1'abc') AS `sha1('abc')`,soundex(_latin1'') AS `soundex('')`,(soundex(_latin1'mood') = soundex(_latin1'mud')) AS `'mood' sounds like 'mud'`,aes_decrypt(aes_encrypt(_latin1'abc',_latin1'1'),_latin1'1') AS `aes_decrypt(aes_encrypt('abc','1'),'1')`,concat(_latin1'*',repeat(_latin1' ',5),_latin1'*') AS `concat('*',space(5),'*')`,reverse(_latin1'abc') AS `reverse('abc')`,rpad(_latin1'a',4,_latin1'1') AS `rpad('a',4,'1')`,lpad(_latin1'a',4,_latin1'1') AS `lpad('a',4,'1')`,concat_ws(_latin1',',_latin1'',NULL,_latin1'a') AS `concat_ws(',','',NULL,'a')`,make_set(255,_latin2'a',_latin2'b',_latin2'c') AS `make_set(255,_latin2'a',_latin2'b',_latin2'c')`,elt(2,1) AS `elt(2,1)`,locate(_latin1'a',_latin1'b',2) AS `locate("a","b",2)`,format(130,10) AS `format(130,10)`,char(0) AS `char(0)`,conv(130,16,10) AS `conv(130,16,10)`,hex(130) AS `hex(130)`,cast(_latin1'HE' as char charset binary) AS `binary 'HE'`,export_set(255,_latin2'y',_latin2'n',_latin2' ') AS `export_set(255,_latin2'y',_latin2'n',_latin2' ')`,field((_latin1'b' collate _latin1'latin1_bin'),_latin1'A',_latin1'B') AS `FIELD('b' COLLATE latin1_bin,'A','B')`,find_in_set(_latin1'B',_latin1'a,b,c,d') AS `FIND_IN_SET(_latin1'B',_latin1'a,b,c,d')`,collation(conv(130,16,10)) AS `collation(conv(130,16,10))`,coercibility(conv(130,16,10)) AS `coercibility(conv(130,16,10))`,length(_latin1'\n \r\0\\_\\%\\') AS `length('\n\t\r\b\0\_\%\\')`,bit_length(_latin1'\n \r\0\\_\\%\\') AS `bit_length('\n\t\r\b\0\_\%\\')`,bit_length(_latin1'\n \r\0\\_\\%\\') AS `bit_length('\n\t\r\b\0\_\%\\')`,concat(_latin1'monty',_latin1' was here ',_latin1'again') AS `concat('monty',' was here ','again')`,length(_latin1'hello') AS `length('hello')`,char(ascii(_latin1'h')) AS `char(ascii('h'))`,ord(_latin1'h') AS `ord('h')`,quote((1 / 0)) AS `quote(1/0)`,crc32(_latin1'123') AS `crc32("123")`,replace(_latin1'aaaa',_latin1'a',_latin1'b') AS `replace('aaaa','a','b')`,insert(_latin1'txs',2,1,_latin1'hi') AS `insert('txs',2,1,'hi')`,left(_latin2'a',1) AS `left(_latin2'a',1)`,right(_latin2'a',1) AS `right(_latin2'a',1)`,lcase(_latin2'a') AS `lcase(_latin2'a')`,ucase(_latin2'a') AS `ucase(_latin2'a')`,substr(_latin1'abcdefg',3,2) AS `SUBSTR('abcdefg',3,2)`,substr_index(_latin1'1abcd;2abcd;3abcd;4abcd',_latin1';',2) AS `substring_index("1abcd;2abcd;3abcd;4abcd", ';', 2)`,trim(_latin2' a ') AS `trim(_latin2' a ')`,ltrim(_latin2' a ') AS `ltrim(_latin2' a ')`,rtrim(_latin2' a ') AS `rtrim(_latin2' a ')`,decode(encode(repeat(_latin1'a',100000),'monty'),'monty') AS `decode(encode(repeat("a",100000),"monty"),"monty")` SELECT lpad(12345, 5, "#"); lpad(12345, 5, "#") 12345 @@ -1064,4 +1064,16 @@ id select_type table type possible_keys key key_len ref rows Extra Warnings: Note 1003 select test.t1.s AS `s` from test.t1 where (trim(both _latin1'y' from test.t1.s) > _latin1'ab') DROP TABLE t1; +create table t1(f1 varchar(4)); +explain extended select encode(f1,'zxcv') as 'enc' from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 system NULL NULL NULL NULL 0 const row not found +Warnings: +Note 1003 select encode(test.t1.f1,'zxcv') AS `enc` from test.t1 +explain extended select decode(f1,'zxcv') as 'enc' from t1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 system NULL NULL NULL NULL 0 const row not found +Warnings: +Note 1003 select decode(test.t1.f1,'zxcv') AS `enc` from test.t1 +drop table t1; End of 4.1 tests diff --git a/mysql-test/t/func_str.test b/mysql-test/t/func_str.test index 3c855a32eed..5897674d1d4 100644 --- a/mysql-test/t/func_str.test +++ b/mysql-test/t/func_str.test @@ -713,4 +713,12 @@ EXPLAIN EXTENDED SELECT s FROM t1 WHERE TRIM(BOTH 'y' FROM s) > 'ab'; DROP TABLE t1; +# +# Bug#23409: ENCODE() and DECODE() functions aren't printed correctly +# +create table t1(f1 varchar(4)); +explain extended select encode(f1,'zxcv') as 'enc' from t1; +explain extended select decode(f1,'zxcv') as 'enc' from t1; +drop table t1; + --echo End of 4.1 tests diff --git a/sql/item_strfunc.cc b/sql/item_strfunc.cc index f7408cb5e9f..7c98f0c6380 100644 --- a/sql/item_strfunc.cc +++ b/sql/item_strfunc.cc @@ -1583,6 +1583,19 @@ String *Item_func_encode::val_str(String *str) return res; } +void Item_func_encode::print(String *str) +{ + str->append(func_name()); + str->append('('); + args[0]->print(str); + str->append(','); + str->append('\''); + str->append(seed); + str->append('\''); + str->append(')'); +} + + String *Item_func_decode::val_str(String *str) { DBUG_ASSERT(fixed == 1); diff --git a/sql/item_strfunc.h b/sql/item_strfunc.h index b7cecad9516..4bd8574ff04 100644 --- a/sql/item_strfunc.h +++ b/sql/item_strfunc.h @@ -343,19 +343,24 @@ class Item_func_encode :public Item_str_func { protected: SQL_CRYPT sql_crypt; + String seed; public: - Item_func_encode(Item *a, char *seed): - Item_str_func(a),sql_crypt(seed) {} + Item_func_encode(Item *a, char *seed_arg): + Item_str_func(a), sql_crypt(seed_arg) + { + seed.copy(seed_arg, strlen(seed_arg), default_charset_info); + } String *val_str(String *); void fix_length_and_dec(); const char *func_name() const { return "encode"; } + void print(String *str); }; class Item_func_decode :public Item_func_encode { public: - Item_func_decode(Item *a, char *seed): Item_func_encode(a,seed) {} + Item_func_decode(Item *a, char *seed_arg): Item_func_encode(a, seed_arg) {} String *val_str(String *); const char *func_name() const { return "decode"; } }; From 19ee0a94fee5bfe1109689a4ccfd4a847ae61ac4 Mon Sep 17 00:00:00 2001 From: "evgen@moonbone.local" <> Date: Thu, 11 Jan 2007 23:18:01 +0300 Subject: [PATCH 03/22] Bug#23417: Too strict checks against GROUP BY in the ONLY_FULL_GROUP_BY mode. Currently in the ONLY_FULL_GROUP_BY mode no hidden fields are allowed in the select list. To ensure this each expression in the select list is checked to be a constant, an aggregate function or to occur in the GROUP BY list. The last two requirements are wrong and doesn't allow valid expressions like "MAX(b) - MIN(b)" or "a + 1" in a query with grouping by a. The correct check implemented by the patch will ensure that: any field reference in the [sub]expressions of the select list is under an aggregate function or is mentioned as member of the group list or is an outer reference or is part of the select list element that coincide with a grouping element. The Item_field objects now can contain the position of the select list expression which they belong to. The position is saved during the field's Item_field::fix_fields() call. The non_agg_fields list for non-aggregated fields is added to the SELECT_LEX class. The SELECT_LEX::cur_pos_in_select_list now contains the position in the select list of the expression being currently fixed. --- mysql-test/r/group_by.result | 102 +++++++++++++++++++++++++++++++++++ mysql-test/t/group_by.test | 51 ++++++++++++++++++ sql/item.cc | 23 +++++++- sql/item.h | 3 +- sql/mysql_priv.h | 3 +- sql/sql_base.cc | 4 ++ sql/sql_lex.cc | 2 + sql/sql_lex.h | 4 ++ sql/sql_select.cc | 82 +++++++++++++++++++--------- sql/sql_union.cc | 1 + 10 files changed, 247 insertions(+), 28 deletions(-) diff --git a/mysql-test/r/group_by.result b/mysql-test/r/group_by.result index 7d1e8832069..97375898f41 100644 --- a/mysql-test/r/group_by.result +++ b/mysql-test/r/group_by.result @@ -933,3 +933,105 @@ b sum(1) 18 6 19 6 DROP TABLE t1; +CREATE TABLE t1 (a INT PRIMARY KEY, b INT); +INSERT INTO t1 VALUES (1,1),(2,1),(3,2),(4,2),(5,3),(6,3); +SET SQL_MODE = 'ONLY_FULL_GROUP_BY'; +SELECT MAX(a)-MIN(a) FROM t1 GROUP BY b; +MAX(a)-MIN(a) +1 +1 +1 +SELECT CEILING(MIN(a)) FROM t1 GROUP BY b; +CEILING(MIN(a)) +1 +3 +5 +SELECT CASE WHEN AVG(a)>=0 THEN 'Positive' ELSE 'Negative' END FROM t1 +GROUP BY b; +CASE WHEN AVG(a)>=0 THEN 'Positive' ELSE 'Negative' END +Positive +Positive +Positive +SELECT a + 1 FROM t1 GROUP BY a; +a + 1 +2 +3 +4 +5 +6 +7 +SELECT a + b FROM t1 GROUP BY b; +ERROR 42000: 'test.t1.a' isn't in GROUP BY +SELECT (SELECT t1_outer.a FROM t1 AS t1_inner GROUP BY b LIMIT 1) +FROM t1 AS t1_outer; +(SELECT t1_outer.a FROM t1 AS t1_inner GROUP BY b LIMIT 1) +1 +2 +3 +4 +5 +6 +SELECT 1 FROM t1 as t1_outer GROUP BY a +HAVING (SELECT t1_outer.a FROM t1 AS t1_inner GROUP BY b LIMIT 1); +1 +1 +1 +1 +1 +1 +1 +SELECT (SELECT t1_outer.a FROM t1 AS t1_inner LIMIT 1) +FROM t1 AS t1_outer GROUP BY t1_outer.b; +ERROR 42000: 'test.t1_outer.a' isn't in GROUP BY +SELECT 1 FROM t1 as t1_outer GROUP BY a +HAVING (SELECT t1_outer.b FROM t1 AS t1_inner LIMIT 1); +ERROR 42S22: Unknown column 'test.t1_outer.b' in 'field list' +SELECT (SELECT SUM(t1_inner.a) FROM t1 AS t1_inner LIMIT 1) +FROM t1 AS t1_outer GROUP BY t1_outer.b; +(SELECT SUM(t1_inner.a) FROM t1 AS t1_inner LIMIT 1) +21 +21 +21 +SELECT (SELECT SUM(t1_inner.a) FROM t1 AS t1_inner GROUP BY t1_inner.b LIMIT 1) +FROM t1 AS t1_outer; +(SELECT SUM(t1_inner.a) FROM t1 AS t1_inner GROUP BY t1_inner.b LIMIT 1) +3 +3 +3 +3 +3 +3 +SELECT (SELECT SUM(t1_outer.a) FROM t1 AS t1_inner LIMIT 1) +FROM t1 AS t1_outer GROUP BY t1_outer.b; +ERROR 42000: 'test.t1_outer.a' isn't in GROUP BY +SELECT 1 FROM t1 as t1_outer +WHERE (SELECT t1_outer.b FROM t1 AS t1_inner GROUP BY t1_inner.b LIMIT 1); +1 +1 +1 +1 +1 +1 +1 +SELECT b FROM t1 GROUP BY b HAVING CEILING(b) > 0; +b +1 +2 +3 +SELECT 1 FROM t1 GROUP BY b HAVING b = 2 OR b = 3 OR SUM(a) > 12; +1 +1 +1 +SELECT 1 FROM t1 GROUP BY b HAVING ROW (b,b) = ROW (1,1); +1 +1 +SELECT 1 FROM t1 GROUP BY b HAVING a = 2; +ERROR 42S22: Unknown column 'a' in 'having clause' +SELECT 1 FROM t1 GROUP BY SUM(b); +ERROR HY000: Invalid use of group function +SELECT b FROM t1 AS t1_outer GROUP BY a HAVING t1_outer.a IN +(SELECT SUM(t1_inner.b)+t1_outer.b FROM t1 AS t1_inner GROUP BY t1_inner.a +HAVING SUM(t1_inner.b)+t1_outer.b > 5); +ERROR 42000: 'test.t1_outer.b' isn't in GROUP BY +DROP TABLE t1; +SET SQL_MODE = ''; diff --git a/mysql-test/t/group_by.test b/mysql-test/t/group_by.test index 3e926fba0c6..92c92bf3957 100644 --- a/mysql-test/t/group_by.test +++ b/mysql-test/t/group_by.test @@ -701,3 +701,54 @@ EXPLAIN SELECT SQL_BIG_RESULT b, sum(1) FROM t1 GROUP BY b; SELECT b, sum(1) FROM t1 GROUP BY b; SELECT SQL_BIG_RESULT b, sum(1) FROM t1 GROUP BY b; DROP TABLE t1; + +# +# Bug #23417: Too strict checks against GROUP BY in the ONLY_FULL_GROUP_BY mode +# +CREATE TABLE t1 (a INT PRIMARY KEY, b INT); +INSERT INTO t1 VALUES (1,1),(2,1),(3,2),(4,2),(5,3),(6,3); + +SET SQL_MODE = 'ONLY_FULL_GROUP_BY'; +SELECT MAX(a)-MIN(a) FROM t1 GROUP BY b; +SELECT CEILING(MIN(a)) FROM t1 GROUP BY b; +SELECT CASE WHEN AVG(a)>=0 THEN 'Positive' ELSE 'Negative' END FROM t1 + GROUP BY b; +SELECT a + 1 FROM t1 GROUP BY a; +--error ER_WRONG_FIELD_WITH_GROUP +SELECT a + b FROM t1 GROUP BY b; +SELECT (SELECT t1_outer.a FROM t1 AS t1_inner GROUP BY b LIMIT 1) + FROM t1 AS t1_outer; +SELECT 1 FROM t1 as t1_outer GROUP BY a + HAVING (SELECT t1_outer.a FROM t1 AS t1_inner GROUP BY b LIMIT 1); +--error ER_WRONG_FIELD_WITH_GROUP +SELECT (SELECT t1_outer.a FROM t1 AS t1_inner LIMIT 1) + FROM t1 AS t1_outer GROUP BY t1_outer.b; +--error ER_BAD_FIELD_ERROR +SELECT 1 FROM t1 as t1_outer GROUP BY a + HAVING (SELECT t1_outer.b FROM t1 AS t1_inner LIMIT 1); +SELECT (SELECT SUM(t1_inner.a) FROM t1 AS t1_inner LIMIT 1) + FROM t1 AS t1_outer GROUP BY t1_outer.b; +SELECT (SELECT SUM(t1_inner.a) FROM t1 AS t1_inner GROUP BY t1_inner.b LIMIT 1) + FROM t1 AS t1_outer; +--error ER_WRONG_FIELD_WITH_GROUP +SELECT (SELECT SUM(t1_outer.a) FROM t1 AS t1_inner LIMIT 1) + FROM t1 AS t1_outer GROUP BY t1_outer.b; + +SELECT 1 FROM t1 as t1_outer + WHERE (SELECT t1_outer.b FROM t1 AS t1_inner GROUP BY t1_inner.b LIMIT 1); + +SELECT b FROM t1 GROUP BY b HAVING CEILING(b) > 0; + +SELECT 1 FROM t1 GROUP BY b HAVING b = 2 OR b = 3 OR SUM(a) > 12; +SELECT 1 FROM t1 GROUP BY b HAVING ROW (b,b) = ROW (1,1); + +--error ER_BAD_FIELD_ERROR +SELECT 1 FROM t1 GROUP BY b HAVING a = 2; +--error ER_INVALID_GROUP_FUNC_USE +SELECT 1 FROM t1 GROUP BY SUM(b); +--error ER_WRONG_FIELD_WITH_GROUP +SELECT b FROM t1 AS t1_outer GROUP BY a HAVING t1_outer.a IN + (SELECT SUM(t1_inner.b)+t1_outer.b FROM t1 AS t1_inner GROUP BY t1_inner.a + HAVING SUM(t1_inner.b)+t1_outer.b > 5); +DROP TABLE t1; +SET SQL_MODE = ''; diff --git a/sql/item.cc b/sql/item.cc index cc653a7db14..f1423a87837 100644 --- a/sql/item.cc +++ b/sql/item.cc @@ -3469,6 +3469,16 @@ Item_field::fix_outer_field(THD *thd, Field **from_field, Item **reference) { if (*from_field) { + if (thd->variables.sql_mode & MODE_ONLY_FULL_GROUP_BY && + select->cur_pos_in_select_list != UNDEF_POS) + { + /* + As this is an outer field it should be added to the list of + non aggregated fields of the outer select. + */ + marker= select->cur_pos_in_select_list; + select->non_agg_fields.push_back(this); + } if (*from_field != view_ref_found) { prev_subselect_item->used_tables_cache|= (*from_field)->table->map; @@ -3671,10 +3681,11 @@ Item_field::fix_outer_field(THD *thd, Field **from_field, Item **reference) bool Item_field::fix_fields(THD *thd, Item **reference) { DBUG_ASSERT(fixed == 0); + Field *from_field= (Field *)not_found_field; + bool outer_fixed= false; + if (!field) // If field is not checked { - Field *from_field= (Field *)not_found_field; - bool outer_fixed= false; /* In case of view, find_field_in_tables() write pointer to view field expression to 'reference', i.e. it substitute that expression instead @@ -3766,6 +3777,7 @@ bool Item_field::fix_fields(THD *thd, Item **reference) goto error; else if (!ret) return FALSE; + outer_fixed= 1; } set_field(from_field); @@ -3809,6 +3821,13 @@ bool Item_field::fix_fields(THD *thd, Item **reference) } #endif fixed= 1; + if (thd->variables.sql_mode & MODE_ONLY_FULL_GROUP_BY && + !outer_fixed && !thd->lex->in_sum_func && + thd->lex->current_select->cur_pos_in_select_list != UNDEF_POS) + { + thd->lex->current_select->non_agg_fields.push_back(this); + marker= thd->lex->current_select->cur_pos_in_select_list; + } return FALSE; error: diff --git a/sql/item.h b/sql/item.h index 13f0b95c1d1..6065e385a6c 100644 --- a/sql/item.h +++ b/sql/item.h @@ -452,7 +452,8 @@ public: Item *next; uint32 max_length; uint name_length; /* Length of name */ - uint8 marker, decimals; + int8 marker; + uint8 decimals; my_bool maybe_null; /* If item may be null */ my_bool null_value; /* if item is null */ my_bool unsigned_flag; diff --git a/sql/mysql_priv.h b/sql/mysql_priv.h index 534d42e1c17..caf3e6479f9 100644 --- a/sql/mysql_priv.h +++ b/sql/mysql_priv.h @@ -410,7 +410,8 @@ MY_LOCALE *my_locale_by_name(const char *name); #define UNCACHEABLE_EXPLAIN 8 /* Don't evaluate subqueries in prepare even if they're not correlated */ #define UNCACHEABLE_PREPARE 16 - +/* Used to chack GROUP BY list in the MODE_ONLY_FULL_GROUP_BY mode */ +#define UNDEF_POS (-1) #ifdef EXTRA_DEBUG /* Sync points allow us to force the server to reach a certain line of code diff --git a/sql/sql_base.cc b/sql/sql_base.cc index 5dcd596f6c2..8ed8526f143 100644 --- a/sql/sql_base.cc +++ b/sql/sql_base.cc @@ -4393,6 +4393,7 @@ bool setup_fields(THD *thd, Item **ref_pointer_array, bzero(ref_pointer_array, sizeof(Item *) * fields.elements); Item **ref= ref_pointer_array; + thd->lex->current_select->cur_pos_in_select_list= 0; while ((item= it++)) { if (!item->fixed && item->fix_fields(thd, it.ref()) || @@ -4408,7 +4409,10 @@ bool setup_fields(THD *thd, Item **ref_pointer_array, sum_func_list) item->split_sum_func(thd, ref_pointer_array, *sum_func_list); thd->used_tables|= item->used_tables(); + thd->lex->current_select->cur_pos_in_select_list++; } + thd->lex->current_select->cur_pos_in_select_list= UNDEF_POS; + thd->lex->allow_sum_func= save_allow_sum_func; thd->set_query_id= save_set_query_id; DBUG_RETURN(test(thd->net.report_error)); diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index 45272645633..3ae95ef9036 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -1180,6 +1180,8 @@ void st_select_lex::init_select() offset_limit= 0; /* denotes the default offset = 0 */ with_sum_func= 0; is_correlated= 0; + cur_pos_in_select_list= UNDEF_POS; + non_agg_fields.empty(); } /* diff --git a/sql/sql_lex.h b/sql/sql_lex.h index db119d527d9..1bf37c92b85 100644 --- a/sql/sql_lex.h +++ b/sql/sql_lex.h @@ -581,6 +581,10 @@ public: bool no_wrap_view_item; /* exclude this select from check of unique_table() */ bool exclude_from_table_unique_test; + /* List of fields that aren't under an aggregate function */ + List non_agg_fields; + /* index in the select list of the expression currently being fixed */ + int cur_pos_in_select_list; List udf_list; /* udf function calls stack */ diff --git a/sql/sql_select.cc b/sql/sql_select.cc index abb949ae473..fb4e2c3ab30 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -13214,49 +13214,83 @@ setup_group(THD *thd, Item **ref_pointer_array, TABLE_LIST *tables, bool *hidden_group_fields) { *hidden_group_fields=0; + ORDER *ord; + if (!order) return 0; /* Everything is ok */ - if (thd->variables.sql_mode & MODE_ONLY_FULL_GROUP_BY) - { - Item *item; - List_iterator li(fields); - while ((item=li++)) - item->marker=0; /* Marker that field is not used */ - } uint org_fields=all_fields.elements; thd->where="group statement"; - for (; order; order=order->next) + for (ord= order; ord; ord= ord->next) { - if (find_order_in_list(thd, ref_pointer_array, tables, order, fields, + if (find_order_in_list(thd, ref_pointer_array, tables, ord, fields, all_fields, TRUE)) return 1; - (*order->item)->marker=1; /* Mark found */ - if ((*order->item)->with_sum_func) + (*ord->item)->marker= UNDEF_POS; /* Mark found */ + if ((*ord->item)->with_sum_func) { - my_error(ER_WRONG_GROUP_FIELD, MYF(0), (*order->item)->full_name()); + my_error(ER_WRONG_GROUP_FIELD, MYF(0), (*ord->item)->full_name()); return 1; } } if (thd->variables.sql_mode & MODE_ONLY_FULL_GROUP_BY) { - /* Don't allow one to use fields that is not used in GROUP BY */ - Item *item; - List_iterator li(fields); + /* + Don't allow one to use fields that is not used in GROUP BY + For each select a list of field references that aren't under an + aggregate function is created. Each field in this list keeps the + position of the select list expression which it belongs to. - while ((item=li++)) + First we check an expression from the select list against the GROUP BY + list. If it's found there then it's ok. It's also ok if this expression + is a constant or an aggregate function. Otherwise we scan the list + of non-aggregated fields and if we'll find at least one field reference + that belongs to this expression and doesn't occur in the GROUP BY list + we throw an error. If there are no fields in the created list for a + select list expression this means that all fields in it are used under + aggregate functions. + */ + Item *item; + Item_field *field; + int cur_pos_in_select_list= 0; + List_iterator li(fields); + List_iterator naf_it(thd->lex->current_select->non_agg_fields); + + field= naf_it++; + while (field && (item=li++)) { - if (item->type() != Item::SUM_FUNC_ITEM && !item->marker && - !item->const_item()) + if (item->type() != Item::SUM_FUNC_ITEM && item->marker >= 0 && + !item->const_item() && + !(item->real_item()->type() == Item::FIELD_ITEM && + item->used_tables() & OUTER_REF_TABLE_BIT)) { - /* - TODO: change ER_WRONG_FIELD_WITH_GROUP to more detailed - ER_NON_GROUPING_FIELD_USED - */ - my_error(ER_WRONG_FIELD_WITH_GROUP, MYF(0), item->full_name()); - return 1; + while (field) + { + /* Skip fields from previous expressions. */ + if (field->marker < cur_pos_in_select_list) + goto next_field; + /* Found a field from the next expression. */ + if (field->marker > cur_pos_in_select_list) + break; + /* + Check whether the field occur in the GROUP BY list. + Throw the error later if the field isn't found. + */ + for (ord= order; ord; ord= ord->next) + if ((*ord->item)->eq((Item*)field, 0)) + goto next_field; + /* + TODO: change ER_WRONG_FIELD_WITH_GROUP to more detailed + ER_NON_GROUPING_FIELD_USED + */ + my_error(ER_WRONG_FIELD_WITH_GROUP, MYF(0), field->full_name()); + return 1; +next_field: + field= naf_it++; + } } + cur_pos_in_select_list++; } } if (org_fields != all_fields.elements) diff --git a/sql/sql_union.cc b/sql/sql_union.cc index 55e52389a83..8b7dde2f818 100644 --- a/sql/sql_union.cc +++ b/sql/sql_union.cc @@ -732,6 +732,7 @@ bool st_select_lex::cleanup() { error= (bool) ((uint) error | (uint) lex_unit->cleanup()); } + non_agg_fields.empty(); DBUG_RETURN(error); } From 3fd278c9d3a652afcda00be5e2a4a7938db73e35 Mon Sep 17 00:00:00 2001 From: "holyfoot/hf@mysql.com/deer.(none)" <> Date: Fri, 12 Jan 2007 15:46:20 +0400 Subject: [PATCH 04/22] bug #24186 (nested query across partitions returns fewer records) Subselect's engine checks table->status field to determine if the record was properly found when we use keyread upon the table. Partition engine checks all the partitions for given key before return. So if matching record was found in the first partition and no matching records were found in the second, we have table->status == NOT_FOUND after the function, what makes subselects to skip matching records. The patch adds table->status= 0 if we actually found something. --- mysql-test/r/partition.result | 81 ++++++++++++++++++++++++++++++ mysql-test/t/partition.test | 93 +++++++++++++++++++++++++++++++++++ sql/ha_partition.cc | 3 ++ 3 files changed, 177 insertions(+) diff --git a/mysql-test/r/partition.result b/mysql-test/r/partition.result index 55ba8380665..f7eda649dd2 100644 --- a/mysql-test/r/partition.result +++ b/mysql-test/r/partition.result @@ -1138,4 +1138,85 @@ PARTITION p_100 VALUES LESS THAN (100), PARTITION p_X VALUES LESS THAN MAXVALUE ); drop table t1; +CREATE TABLE t2 ( +taken datetime NOT NULL DEFAULT '0000-00-00 00:00:00', +id int(11) NOT NULL DEFAULT '0', +PRIMARY KEY (id,taken), +KEY taken (taken) +) ENGINE=MyISAM DEFAULT CHARSET=latin1; +INSERT INTO t2 VALUES +('2006-09-27 21:50:01',16421), +('2006-10-02 21:50:01',16421), +('2006-09-27 21:50:01',19092), +('2006-09-28 21:50:01',19092), +('2006-09-29 21:50:01',19092), +('2006-09-30 21:50:01',19092), +('2006-10-01 21:50:01',19092), +('2006-10-02 21:50:01',19092), +('2006-09-27 21:50:01',22589), +('2006-09-29 21:50:01',22589); +CREATE TABLE t1 ( +id int(8) NOT NULL, +PRIMARY KEY (id) +) ENGINE=MyISAM DEFAULT CHARSET=latin1; +INSERT INTO t1 VALUES +(16421), +(19092), +(22589); +CREATE TABLE t4 ( +taken datetime NOT NULL DEFAULT '0000-00-00 00:00:00', +id int(11) NOT NULL DEFAULT '0', +PRIMARY KEY (id,taken), +KEY taken (taken) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +PARTITION BY RANGE (to_days(taken)) +( +PARTITION p01 VALUES LESS THAN (732920) , +PARTITION p02 VALUES LESS THAN (732950) , +PARTITION p03 VALUES LESS THAN MAXVALUE ) ; +INSERT INTO t4 select * from t2; +set @f_date='2006-09-28'; +set @t_date='2006-10-02'; +SELECT t1.id AS MyISAM_part +FROM t1 +WHERE t1.id IN ( +SELECT distinct id +FROM t4 +WHERE taken BETWEEN @f_date AND date_add(@t_date, INTERVAL 1 DAY)) +ORDER BY t1.id +; +MyISAM_part +16421 +19092 +22589 +drop table t1, t2, t4; +CREATE TABLE t1 ( +taken datetime NOT NULL DEFAULT '0000-00-00 00:00:00', +id int(11) NOT NULL DEFAULT '0', +status varchar(20) NOT NULL DEFAULT '', +PRIMARY KEY (id,taken) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +PARTITION BY RANGE (to_days(taken)) +( +PARTITION p15 VALUES LESS THAN (732950) , +PARTITION p16 VALUES LESS THAN MAXVALUE ) ; +INSERT INTO t1 VALUES +('2006-09-27 21:50:01',22589,'Open'), +('2006-09-29 21:50:01',22589,'Verified'); +DROP TABLE IF EXISTS t2; +Warnings: +Note 1051 Unknown table 't2' +CREATE TABLE t2 ( +id int(8) NOT NULL, +severity tinyint(4) NOT NULL DEFAULT '0', +priority tinyint(4) NOT NULL DEFAULT '0', +status varchar(20) DEFAULT NULL, +alien tinyint(4) NOT NULL +) ENGINE=MyISAM DEFAULT CHARSET=latin1; +INSERT INTO t2 VALUES +(22589,1,1,'Need Feedback',0); +SELECT t2.id FROM t2 WHERE t2.id IN (SELECT id FROM t1 WHERE status = 'Verified'); +id +22589 +drop table t1, t2; End of 5.1 tests diff --git a/mysql-test/t/partition.test b/mysql-test/t/partition.test index 02c7ca0b05c..7d7ef95626a 100644 --- a/mysql-test/t/partition.test +++ b/mysql-test/t/partition.test @@ -1370,4 +1370,97 @@ REORGANIZE PARTITION p_X INTO ( drop table t1; +# +# Bug #24186 (nested query across partitions returns fewer records) +# + +CREATE TABLE t2 ( + taken datetime NOT NULL DEFAULT '0000-00-00 00:00:00', + id int(11) NOT NULL DEFAULT '0', + PRIMARY KEY (id,taken), + KEY taken (taken) +) ENGINE=MyISAM DEFAULT CHARSET=latin1; + +INSERT INTO t2 VALUES +('2006-09-27 21:50:01',16421), +('2006-10-02 21:50:01',16421), +('2006-09-27 21:50:01',19092), +('2006-09-28 21:50:01',19092), +('2006-09-29 21:50:01',19092), +('2006-09-30 21:50:01',19092), +('2006-10-01 21:50:01',19092), +('2006-10-02 21:50:01',19092), +('2006-09-27 21:50:01',22589), +('2006-09-29 21:50:01',22589); + +CREATE TABLE t1 ( + id int(8) NOT NULL, + PRIMARY KEY (id) +) ENGINE=MyISAM DEFAULT CHARSET=latin1; + +INSERT INTO t1 VALUES +(16421), +(19092), +(22589); + +CREATE TABLE t4 ( + taken datetime NOT NULL DEFAULT '0000-00-00 00:00:00', + id int(11) NOT NULL DEFAULT '0', + PRIMARY KEY (id,taken), + KEY taken (taken) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +PARTITION BY RANGE (to_days(taken)) +( +PARTITION p01 VALUES LESS THAN (732920) , +PARTITION p02 VALUES LESS THAN (732950) , +PARTITION p03 VALUES LESS THAN MAXVALUE ) ; + +INSERT INTO t4 select * from t2; + +set @f_date='2006-09-28'; +set @t_date='2006-10-02'; + +SELECT t1.id AS MyISAM_part +FROM t1 +WHERE t1.id IN ( + SELECT distinct id + FROM t4 + WHERE taken BETWEEN @f_date AND date_add(@t_date, INTERVAL 1 DAY)) +ORDER BY t1.id +; + +drop table t1, t2, t4; + +CREATE TABLE t1 ( + taken datetime NOT NULL DEFAULT '0000-00-00 00:00:00', + id int(11) NOT NULL DEFAULT '0', + status varchar(20) NOT NULL DEFAULT '', + PRIMARY KEY (id,taken) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 +PARTITION BY RANGE (to_days(taken)) +( +PARTITION p15 VALUES LESS THAN (732950) , +PARTITION p16 VALUES LESS THAN MAXVALUE ) ; + + +INSERT INTO t1 VALUES +('2006-09-27 21:50:01',22589,'Open'), +('2006-09-29 21:50:01',22589,'Verified'); + +DROP TABLE IF EXISTS t2; +CREATE TABLE t2 ( + id int(8) NOT NULL, + severity tinyint(4) NOT NULL DEFAULT '0', + priority tinyint(4) NOT NULL DEFAULT '0', + status varchar(20) DEFAULT NULL, + alien tinyint(4) NOT NULL +) ENGINE=MyISAM DEFAULT CHARSET=latin1; + +INSERT INTO t2 VALUES +(22589,1,1,'Need Feedback',0); + +SELECT t2.id FROM t2 WHERE t2.id IN (SELECT id FROM t1 WHERE status = 'Verified'); + +drop table t1, t2; + --echo End of 5.1 tests diff --git a/sql/ha_partition.cc b/sql/ha_partition.cc index feb08f474b7..9d4cd69be12 100644 --- a/sql/ha_partition.cc +++ b/sql/ha_partition.cc @@ -4015,6 +4015,7 @@ int ha_partition::handle_ordered_index_scan(byte *buf, bool reverse_order) m_queue.elements= j; queue_fix(&m_queue); return_top_record(buf); + table->status= 0; DBUG_PRINT("info", ("Record returned from partition %d", m_top_entry)); DBUG_RETURN(0); } @@ -4083,6 +4084,7 @@ int ha_partition::handle_ordered_next(byte *buf, bool is_next_same) DBUG_PRINT("info", ("Record returned from partition %u (2)", m_top_entry)); return_top_record(buf); + table->status= 0; error= 0; } } @@ -4126,6 +4128,7 @@ int ha_partition::handle_ordered_prev(byte *buf) DBUG_PRINT("info", ("Record returned from partition %d (2)", m_top_entry)); error= 0; + table->status= 0; } } DBUG_RETURN(error); From 12c6e9d2b0a048db845bb72e0102fef0dfaf999f Mon Sep 17 00:00:00 2001 From: "evgen@moonbone.local" <> Date: Fri, 12 Jan 2007 17:35:24 +0300 Subject: [PATCH 05/22] func_str.result: After merge fix --- mysql-test/r/func_str.result | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/mysql-test/r/func_str.result b/mysql-test/r/func_str.result index c922f57d820..052451f8c54 100644 --- a/mysql-test/r/func_str.result +++ b/mysql-test/r/func_str.result @@ -817,7 +817,7 @@ explain extended select md5('hello'), sha('abc'), sha1('abc'), soundex(''), 'moo id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE NULL NULL NULL NULL NULL NULL NULL No tables used Warnings: -Note 1003 select md5(_latin1'hello') AS `md5('hello')`,sha(_latin1'abc') AS `sha('abc')`,sha(_latin1'abc') AS `sha1('abc')`,soundex(_latin1'') AS `soundex('')`,(soundex(_latin1'mood') = soundex(_latin1'mud')) AS `'mood' sounds like 'mud'`,aes_decrypt(aes_encrypt(_latin1'abc',_latin1'1'),_latin1'1') AS `aes_decrypt(aes_encrypt('abc','1'),'1')`,concat(_latin1'*',repeat(_latin1' ',5),_latin1'*') AS `concat('*',space(5),'*')`,reverse(_latin1'abc') AS `reverse('abc')`,rpad(_latin1'a',4,_latin1'1') AS `rpad('a',4,'1')`,lpad(_latin1'a',4,_latin1'1') AS `lpad('a',4,'1')`,concat_ws(_latin1',',_latin1'',NULL,_latin1'a') AS `concat_ws(',','',NULL,'a')`,make_set(255,_latin2'a',_latin2'b',_latin2'c') AS `make_set(255,_latin2'a',_latin2'b',_latin2'c')`,elt(2,1) AS `elt(2,1)`,locate(_latin1'a',_latin1'b',2) AS `locate("a","b",2)`,format(130,10) AS `format(130,10)`,char(0) AS `char(0)`,conv(130,16,10) AS `conv(130,16,10)`,hex(130) AS `hex(130)`,cast(_latin1'HE' as char charset binary) AS `binary 'HE'`,export_set(255,_latin2'y',_latin2'n',_latin2' ') AS `export_set(255,_latin2'y',_latin2'n',_latin2' ')`,field((_latin1'b' collate latin1_bin),_latin1'A',_latin1'B') AS `FIELD('b' COLLATE latin1_bin,'A','B')`,find_in_set(_latin1'B',_latin1'a,b,c,d') AS `FIND_IN_SET(_latin1'B',_latin1'a,b,c,d')`,collation(conv(130,16,10)) AS `collation(conv(130,16,10))`,coercibility(conv(130,16,10)) AS `coercibility(conv(130,16,10))`,length(_latin1'\n \r\0\\_\\%\\') AS `length('\n\t\r\b\0\_\%\\')`,bit_length(_latin1'\n \r\0\\_\\%\\') AS `bit_length('\n\t\r\b\0\_\%\\')`,bit_length(_latin1'\n \r\0\\_\\%\\') AS `bit_length('\n\t\r\b\0\_\%\\')`,concat(_latin1'monty',_latin1' was here ',_latin1'again') AS `concat('monty',' was here ','again')`,length(_latin1'hello') AS `length('hello')`,char(ascii(_latin1'h')) AS `char(ascii('h'))`,ord(_latin1'h') AS `ord('h')`,quote((1 / 0)) AS `quote(1/0)`,crc32(_latin1'123') AS `crc32("123")`,replace(_latin1'aaaa',_latin1'a',_latin1'b') AS `replace('aaaa','a','b')`,insert(_latin1'txs',2,1,_latin1'hi') AS `insert('txs',2,1,'hi')`,left(_latin2'a',1) AS `left(_latin2'a',1)`,right(_latin2'a',1) AS `right(_latin2'a',1)`,lcase(_latin2'a') AS `lcase(_latin2'a')`,ucase(_latin2'a') AS `ucase(_latin2'a')`,substr(_latin1'abcdefg',3,2) AS `SUBSTR('abcdefg',3,2)`,substring_index(_latin1'1abcd;2abcd;3abcd;4abcd',_latin1';',2) AS `substring_index("1abcd;2abcd;3abcd;4abcd", ';', 2)`,trim(_latin2' a ') AS `trim(_latin2' a ')`,ltrim(_latin2' a ') AS `ltrim(_latin2' a ')`,rtrim(_latin2' a ') AS `rtrim(_latin2' a ')`,decode(encode(repeat(_latin1'a',100000))) AS `decode(encode(repeat("a",100000),"monty"),"monty")` +Note 1003 select md5(_latin1'hello') AS `md5('hello')`,sha(_latin1'abc') AS `sha('abc')`,sha(_latin1'abc') AS `sha1('abc')`,soundex(_latin1'') AS `soundex('')`,(soundex(_latin1'mood') = soundex(_latin1'mud')) AS `'mood' sounds like 'mud'`,aes_decrypt(aes_encrypt(_latin1'abc',_latin1'1'),_latin1'1') AS `aes_decrypt(aes_encrypt('abc','1'),'1')`,concat(_latin1'*',repeat(_latin1' ',5),_latin1'*') AS `concat('*',space(5),'*')`,reverse(_latin1'abc') AS `reverse('abc')`,rpad(_latin1'a',4,_latin1'1') AS `rpad('a',4,'1')`,lpad(_latin1'a',4,_latin1'1') AS `lpad('a',4,'1')`,concat_ws(_latin1',',_latin1'',NULL,_latin1'a') AS `concat_ws(',','',NULL,'a')`,make_set(255,_latin2'a',_latin2'b',_latin2'c') AS `make_set(255,_latin2'a',_latin2'b',_latin2'c')`,elt(2,1) AS `elt(2,1)`,locate(_latin1'a',_latin1'b',2) AS `locate("a","b",2)`,format(130,10) AS `format(130,10)`,char(0) AS `char(0)`,conv(130,16,10) AS `conv(130,16,10)`,hex(130) AS `hex(130)`,cast(_latin1'HE' as char charset binary) AS `binary 'HE'`,export_set(255,_latin2'y',_latin2'n',_latin2' ') AS `export_set(255,_latin2'y',_latin2'n',_latin2' ')`,field((_latin1'b' collate latin1_bin),_latin1'A',_latin1'B') AS `FIELD('b' COLLATE latin1_bin,'A','B')`,find_in_set(_latin1'B',_latin1'a,b,c,d') AS `FIND_IN_SET(_latin1'B',_latin1'a,b,c,d')`,collation(conv(130,16,10)) AS `collation(conv(130,16,10))`,coercibility(conv(130,16,10)) AS `coercibility(conv(130,16,10))`,length(_latin1'\n \r\0\\_\\%\\') AS `length('\n\t\r\b\0\_\%\\')`,bit_length(_latin1'\n \r\0\\_\\%\\') AS `bit_length('\n\t\r\b\0\_\%\\')`,bit_length(_latin1'\n \r\0\\_\\%\\') AS `bit_length('\n\t\r\b\0\_\%\\')`,concat(_latin1'monty',_latin1' was here ',_latin1'again') AS `concat('monty',' was here ','again')`,length(_latin1'hello') AS `length('hello')`,char(ascii(_latin1'h')) AS `char(ascii('h'))`,ord(_latin1'h') AS `ord('h')`,quote((1 / 0)) AS `quote(1/0)`,crc32(_latin1'123') AS `crc32("123")`,replace(_latin1'aaaa',_latin1'a',_latin1'b') AS `replace('aaaa','a','b')`,insert(_latin1'txs',2,1,_latin1'hi') AS `insert('txs',2,1,'hi')`,left(_latin2'a',1) AS `left(_latin2'a',1)`,right(_latin2'a',1) AS `right(_latin2'a',1)`,lcase(_latin2'a') AS `lcase(_latin2'a')`,ucase(_latin2'a') AS `ucase(_latin2'a')`,substr(_latin1'abcdefg',3,2) AS `SUBSTR('abcdefg',3,2)`,substring_index(_latin1'1abcd;2abcd;3abcd;4abcd',_latin1';',2) AS `substring_index("1abcd;2abcd;3abcd;4abcd", ';', 2)`,trim(_latin2' a ') AS `trim(_latin2' a ')`,ltrim(_latin2' a ') AS `ltrim(_latin2' a ')`,rtrim(_latin2' a ') AS `rtrim(_latin2' a ')`,decode(encode(repeat(_latin1'a',100000),'monty'),'monty') AS `decode(encode(repeat("a",100000),"monty"),"monty")` SELECT lpad(12345, 5, "#"); lpad(12345, 5, "#") 12345 @@ -1089,12 +1089,12 @@ explain extended select encode(f1,'zxcv') as 'enc' from t1; id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t1 system NULL NULL NULL NULL 0 const row not found Warnings: -Note 1003 select encode(test.t1.f1,'zxcv') AS `enc` from test.t1 +Note 1003 select encode(`test`.`t1`.`f1`,'zxcv') AS `enc` from `test`.`t1` explain extended select decode(f1,'zxcv') as 'enc' from t1; id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t1 system NULL NULL NULL NULL 0 const row not found Warnings: -Note 1003 select decode(test.t1.f1,'zxcv') AS `enc` from test.t1 +Note 1003 select decode(`test`.`t1`.`f1`,'zxcv') AS `enc` from `test`.`t1` drop table t1; End of 4.1 tests create table t1 (d decimal default null); From 86ef1cbf92e14ede58eab2e6f0e8d52bead23ab9 Mon Sep 17 00:00:00 2001 From: "igor@olga.mysql.com" <> Date: Fri, 12 Jan 2007 13:43:25 -0800 Subject: [PATCH 06/22] Fixed bug #25398: crash in a trigger when using trigger fields in a select list. The objects of the Item_trigger_field class inherited the implementations of the methods copy_or_same, get_tmp_table_item and get_tmp_table_field from the class Item_field while they rather should have used the default implementations defined for the base class Item. It could cause catastrophic problems for triggers that used SELECTs with select list containing trigger fields such as NEW. under DISTINCT. --- mysql-test/r/trigger.result | 32 ++++++++++++++++++++++++++ mysql-test/t/trigger.test | 46 +++++++++++++++++++++++++++++++++++++ sql/item.h | 3 +++ 3 files changed, 81 insertions(+) diff --git a/mysql-test/r/trigger.result b/mysql-test/r/trigger.result index 9f34f60eb1a..3d40a2d05df 100644 --- a/mysql-test/r/trigger.result +++ b/mysql-test/r/trigger.result @@ -1278,4 +1278,36 @@ a b 2 b 3 c drop table t1; +CREATE TABLE t1 ( +id int NOT NULL DEFAULT '0', +a varchar(10) NOT NULL, +b varchar(10), +c varchar(10), +d timestamp NOT NULL, +PRIMARY KEY (id, a) +); +CREATE TABLE t2 ( +fubar_id int unsigned NOT NULL DEFAULT '0', +last_change_time datetime NOT NULL DEFAULT '0000-00-00 00:00:00', +PRIMARY KEY (fubar_id) +); +CREATE TRIGGER fubar_change +AFTER UPDATE ON t1 +FOR EACH ROW +BEGIN +INSERT INTO t2 (fubar_id, last_change_time) +SELECT DISTINCT NEW.id AS fubar_id, NOW() AS last_change_time +FROM t1 WHERE (id = NEW.id) AND (OLD.c != NEW.c) +ON DUPLICATE KEY UPDATE +last_change_time = +IF((fubar_id = NEW.id)AND(OLD.c != NEW.c),NOW(),last_change_time); +END +| +INSERT INTO t1 (id,a, b,c,d) VALUES +(1,'a','b','c',now()),(2,'a','b','c',now()); +UPDATE t1 SET c='Bang!' WHERE id=1; +SELECT fubar_id FROM t2; +fubar_id +1 +DROP TABLE t1,t2; End of 5.0 tests diff --git a/mysql-test/t/trigger.test b/mysql-test/t/trigger.test index ae01a4b2c3d..ea569f4ce09 100644 --- a/mysql-test/t/trigger.test +++ b/mysql-test/t/trigger.test @@ -1548,4 +1548,50 @@ select * from t1; drop table t1; +# +# Bug#25398: crash when a trigger contains a SELECT with +# trigger fields in the select list under DISTINCT +# + +CREATE TABLE t1 ( + id int NOT NULL DEFAULT '0', + a varchar(10) NOT NULL, + b varchar(10), + c varchar(10), + d timestamp NOT NULL, + PRIMARY KEY (id, a) +); + +CREATE TABLE t2 ( + fubar_id int unsigned NOT NULL DEFAULT '0', + last_change_time datetime NOT NULL DEFAULT '0000-00-00 00:00:00', + PRIMARY KEY (fubar_id) +); + +DELIMITER |; + +CREATE TRIGGER fubar_change + AFTER UPDATE ON t1 + FOR EACH ROW + BEGIN + INSERT INTO t2 (fubar_id, last_change_time) + SELECT DISTINCT NEW.id AS fubar_id, NOW() AS last_change_time + FROM t1 WHERE (id = NEW.id) AND (OLD.c != NEW.c) + ON DUPLICATE KEY UPDATE + last_change_time = + IF((fubar_id = NEW.id)AND(OLD.c != NEW.c),NOW(),last_change_time); + END +| + +DELIMITER ;| + +INSERT INTO t1 (id,a, b,c,d) VALUES + (1,'a','b','c',now()),(2,'a','b','c',now()); + +UPDATE t1 SET c='Bang!' WHERE id=1; + +SELECT fubar_id FROM t2; + +DROP TABLE t1,t2; + --echo End of 5.0 tests diff --git a/sql/item.h b/sql/item.h index 6065e385a6c..62d6127f10b 100644 --- a/sql/item.h +++ b/sql/item.h @@ -2269,6 +2269,9 @@ public: bool fix_fields(THD *, Item **); void print(String *str); table_map used_tables() const { return (table_map)0L; } + Field *get_tmp_table_field() { return 0; } + Item *copy_or_same(THD *thd) { return this; } + Item *get_tmp_table_item(THD *thd) { return copy_or_same(thd); } void cleanup(); private: From 34eea49eb7efa21ea2d4b8daffa370b5bf701f6c Mon Sep 17 00:00:00 2001 From: "igor@olga.mysql.com" <> Date: Sat, 13 Jan 2007 10:49:26 -0800 Subject: [PATCH 07/22] Fixed bug #24776: an assertion abort in handler::ha_index_init for queries using 'range checked for each record'. The problem was fixed in 5.0 by the patch for bug 12291. This patch down-ported the corresponding code from 5.0 into QUICK_SELECT::init() and added a new test case. --- mysql-test/r/range.result | 43 +++++++++++++++++++++++++++++++++++++++ mysql-test/t/range.test | 43 +++++++++++++++++++++++++++++++++++++++ sql/opt_range.h | 2 ++ 3 files changed, 88 insertions(+) diff --git a/mysql-test/r/range.result b/mysql-test/r/range.result index f25d94f8066..2125f237d0e 100644 --- a/mysql-test/r/range.result +++ b/mysql-test/r/range.result @@ -658,4 +658,47 @@ select a from t1 where a > 'x'; a xx drop table t1; +CREATE TABLE t1 ( +OXID varchar(32) COLLATE latin1_german2_ci NOT NULL DEFAULT '', +OXPARENTID varchar(32) COLLATE latin1_german2_ci NOT NULL DEFAULT 'oxrootid', +OXLEFT int NOT NULL DEFAULT '0', +OXRIGHT int NOT NULL DEFAULT '0', +OXROOTID varchar(32) COLLATE latin1_german2_ci NOT NULL DEFAULT '', +PRIMARY KEY (OXID), +KEY OXNID (OXID), +KEY OXLEFT (OXLEFT), +KEY OXRIGHT (OXRIGHT), +KEY OXROOTID (OXROOTID) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_german2_ci; +INSERT INTO t1 VALUES +('d8c4177d09f8b11f5.52725521','oxrootid',1,40,'d8c4177d09f8b11f5.52725521'), +('d8c4177d151affab2.81582770','d8c4177d09f8b11f5.52725521',2,3, +'d8c4177d09f8b11f5.52725521'), +('d8c4177d206a333d2.74422679','d8c4177d09f8b11f5.52725521',4,5, +'d8c4177d09f8b11f5.52725521'), +('d8c4177d225791924.30714720','d8c4177d09f8b11f5.52725521',6,7, +'d8c4177d09f8b11f5.52725521'), +('d8c4177d2380fc201.39666693','d8c4177d09f8b11f5.52725521',8,9, +'d8c4177d09f8b11f5.52725521'), +('d8c4177d24ccef970.14957924','d8c4177d09f8b11f5.52725521',10,11, +'d8c4177d09f8b11f5.52725521'); +EXPLAIN +SELECT s.oxid FROM t1 v, t1 s +WHERE s.oxrootid = 'd8c4177d09f8b11f5.52725521' AND +v.oxrootid ='d8c4177d09f8b11f5.52725521' AND +s.oxleft > v.oxleft AND s.oxleft < v.oxright; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE v ref OXLEFT,OXRIGHT,OXROOTID OXROOTID 32 const 5 Using where +1 SIMPLE s ALL OXLEFT NULL NULL NULL 5 Range checked for each record (index map: 0x4) +SELECT s.oxid FROM t1 v, t1 s +WHERE s.oxrootid = 'd8c4177d09f8b11f5.52725521' AND +v.oxrootid ='d8c4177d09f8b11f5.52725521' AND +s.oxleft > v.oxleft AND s.oxleft < v.oxright; +oxid +d8c4177d151affab2.81582770 +d8c4177d206a333d2.74422679 +d8c4177d225791924.30714720 +d8c4177d2380fc201.39666693 +d8c4177d24ccef970.14957924 +DROP TABLE t1; End of 4.1 tests diff --git a/mysql-test/t/range.test b/mysql-test/t/range.test index 245178d7d4a..16cbcd754f6 100644 --- a/mysql-test/t/range.test +++ b/mysql-test/t/range.test @@ -520,4 +520,47 @@ explain select a from t1 where a > 'x'; select a from t1 where a > 'x'; drop table t1; +# +# Bug #24776: assertion abort for 'range checked for each record' +# + +CREATE TABLE t1 ( + OXID varchar(32) COLLATE latin1_german2_ci NOT NULL DEFAULT '', + OXPARENTID varchar(32) COLLATE latin1_german2_ci NOT NULL DEFAULT 'oxrootid', + OXLEFT int NOT NULL DEFAULT '0', + OXRIGHT int NOT NULL DEFAULT '0', + OXROOTID varchar(32) COLLATE latin1_german2_ci NOT NULL DEFAULT '', + PRIMARY KEY (OXID), + KEY OXNID (OXID), + KEY OXLEFT (OXLEFT), + KEY OXRIGHT (OXRIGHT), + KEY OXROOTID (OXROOTID) +) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_german2_ci; + +INSERT INTO t1 VALUES +('d8c4177d09f8b11f5.52725521','oxrootid',1,40,'d8c4177d09f8b11f5.52725521'), +('d8c4177d151affab2.81582770','d8c4177d09f8b11f5.52725521',2,3, + 'd8c4177d09f8b11f5.52725521'), +('d8c4177d206a333d2.74422679','d8c4177d09f8b11f5.52725521',4,5, + 'd8c4177d09f8b11f5.52725521'), +('d8c4177d225791924.30714720','d8c4177d09f8b11f5.52725521',6,7, + 'd8c4177d09f8b11f5.52725521'), +('d8c4177d2380fc201.39666693','d8c4177d09f8b11f5.52725521',8,9, + 'd8c4177d09f8b11f5.52725521'), +('d8c4177d24ccef970.14957924','d8c4177d09f8b11f5.52725521',10,11, + 'd8c4177d09f8b11f5.52725521'); + +EXPLAIN +SELECT s.oxid FROM t1 v, t1 s + WHERE s.oxrootid = 'd8c4177d09f8b11f5.52725521' AND + v.oxrootid ='d8c4177d09f8b11f5.52725521' AND + s.oxleft > v.oxleft AND s.oxleft < v.oxright; + +SELECT s.oxid FROM t1 v, t1 s + WHERE s.oxrootid = 'd8c4177d09f8b11f5.52725521' AND + v.oxrootid ='d8c4177d09f8b11f5.52725521' AND + s.oxleft > v.oxleft AND s.oxleft < v.oxright; + +DROP TABLE t1; + --echo End of 4.1 tests diff --git a/sql/opt_range.h b/sql/opt_range.h index 4d425604921..4b20d1fe0fe 100644 --- a/sql/opt_range.h +++ b/sql/opt_range.h @@ -90,6 +90,8 @@ public: int init() { key_part_info= head->key_info[index].key_part; + if (file->inited != handler::NONE) + file->ha_index_or_rnd_end(); return error=file->ha_index_init(index); } virtual int get_next(); From a5a43da10eb3acce08804b649e5ec4e7fc18ee10 Mon Sep 17 00:00:00 2001 From: "gluh@mysql.com/eagle.(none)" <> Date: Mon, 15 Jan 2007 13:39:28 +0400 Subject: [PATCH 08/22] Bug#21713 incorrect value for the REFERENTIAL_CONSTRAINTS.UNIQUE_CONSTRAINT_NAME column added new field 'REFERENCED_TABLE_NAME' to 'referential_constraints' table field 'UNIQUE_CONSTRAINT_NAME' contains the name of the referenced index --- mysql-test/r/information_schema_inno.result | 16 ++++++++-------- mysql-test/t/information_schema_inno.test | 7 +++---- sql/sql_show.cc | 5 ++++- sql/table.h | 1 + storage/innobase/handler/ha_innodb.cc | 10 ++++++++-- 5 files changed, 24 insertions(+), 15 deletions(-) diff --git a/mysql-test/r/information_schema_inno.result b/mysql-test/r/information_schema_inno.result index b9c0cae5efb..2ea2a0bec0b 100644 --- a/mysql-test/r/information_schema_inno.result +++ b/mysql-test/r/information_schema_inno.result @@ -31,11 +31,11 @@ CREATE TABLE t2(b1 INT, b2 INT, INDEX (b1, b2), CONSTRAINT A1 FOREIGN KEY (b1, b2) REFERENCES t1(a1, a2) ON UPDATE CASCADE ON DELETE NO ACTION) ENGINE=INNODB; -CREATE TABLE t3(b1 INT, b2 INT, INDEX (b1, b2), +CREATE TABLE t3(b1 INT, b2 INT, INDEX t3_indx (b1, b2), CONSTRAINT A2 FOREIGN KEY (b1, b2) REFERENCES t2(b1, b2) ON UPDATE SET NULL ON DELETE RESTRICT) ENGINE=INNODB; -CREATE TABLE t4(b1 INT, b2 INT, INDEX (b1, b2), +CREATE TABLE t4(b1 INT, b2 INT, UNIQUE KEY t4_ukey (b1, b2), CONSTRAINT A3 FOREIGN KEY (b1, b2) REFERENCES t3(b1, b2) ON UPDATE NO ACTION ON DELETE SET NULL) ENGINE=INNODB; @@ -45,16 +45,16 @@ FOREIGN KEY (b1, b2) REFERENCES t4(b1, b2) ON UPDATE RESTRICT ON DELETE CASCADE) ENGINE=INNODB; select a.CONSTRAINT_SCHEMA, b.TABLE_NAME, CONSTRAINT_TYPE, b.CONSTRAINT_NAME, UNIQUE_CONSTRAINT_SCHEMA, UNIQUE_CONSTRAINT_NAME, -MATCH_OPTION, UPDATE_RULE, DELETE_RULE +MATCH_OPTION, UPDATE_RULE, DELETE_RULE, b.REFERENCED_TABLE_NAME from information_schema.TABLE_CONSTRAINTS a, information_schema.REFERENTIAL_CONSTRAINTS b where a.CONSTRAINT_SCHEMA = 'test' and a.CONSTRAINT_SCHEMA = b.CONSTRAINT_SCHEMA and a.CONSTRAINT_NAME = b.CONSTRAINT_NAME; -CONSTRAINT_SCHEMA TABLE_NAME CONSTRAINT_TYPE CONSTRAINT_NAME UNIQUE_CONSTRAINT_SCHEMA UNIQUE_CONSTRAINT_NAME MATCH_OPTION UPDATE_RULE DELETE_RULE -test t2 FOREIGN KEY A1 test t1 NONE CASCADE NO ACTION -test t3 FOREIGN KEY A2 test t2 NONE SET NULL RESTRICT -test t4 FOREIGN KEY A3 test t3 NONE NO ACTION SET NULL -test t5 FOREIGN KEY A4 test t4 NONE RESTRICT CASCADE +CONSTRAINT_SCHEMA TABLE_NAME CONSTRAINT_TYPE CONSTRAINT_NAME UNIQUE_CONSTRAINT_SCHEMA UNIQUE_CONSTRAINT_NAME MATCH_OPTION UPDATE_RULE DELETE_RULE REFERENCED_TABLE_NAME +test t2 FOREIGN KEY A1 test PRIMARY NONE CASCADE NO ACTION t1 +test t3 FOREIGN KEY A2 test b1 NONE SET NULL RESTRICT t2 +test t4 FOREIGN KEY A3 test t3_indx NONE NO ACTION SET NULL t3 +test t5 FOREIGN KEY A4 test t4_ukey NONE RESTRICT CASCADE t4 drop tables t5, t4, t3, t2, t1; create database `db-1`; use `db-1`; diff --git a/mysql-test/t/information_schema_inno.test b/mysql-test/t/information_schema_inno.test index 014bdacfeea..e73f4ba2792 100644 --- a/mysql-test/t/information_schema_inno.test +++ b/mysql-test/t/information_schema_inno.test @@ -32,11 +32,11 @@ CREATE TABLE t2(b1 INT, b2 INT, INDEX (b1, b2), CONSTRAINT A1 FOREIGN KEY (b1, b2) REFERENCES t1(a1, a2) ON UPDATE CASCADE ON DELETE NO ACTION) ENGINE=INNODB; -CREATE TABLE t3(b1 INT, b2 INT, INDEX (b1, b2), +CREATE TABLE t3(b1 INT, b2 INT, INDEX t3_indx (b1, b2), CONSTRAINT A2 FOREIGN KEY (b1, b2) REFERENCES t2(b1, b2) ON UPDATE SET NULL ON DELETE RESTRICT) ENGINE=INNODB; -CREATE TABLE t4(b1 INT, b2 INT, INDEX (b1, b2), +CREATE TABLE t4(b1 INT, b2 INT, UNIQUE KEY t4_ukey (b1, b2), CONSTRAINT A3 FOREIGN KEY (b1, b2) REFERENCES t3(b1, b2) ON UPDATE NO ACTION ON DELETE SET NULL) ENGINE=INNODB; @@ -45,10 +45,9 @@ CREATE TABLE t5(b1 INT, b2 INT, INDEX (b1, b2), FOREIGN KEY (b1, b2) REFERENCES t4(b1, b2) ON UPDATE RESTRICT ON DELETE CASCADE) ENGINE=INNODB; - select a.CONSTRAINT_SCHEMA, b.TABLE_NAME, CONSTRAINT_TYPE, b.CONSTRAINT_NAME, UNIQUE_CONSTRAINT_SCHEMA, UNIQUE_CONSTRAINT_NAME, - MATCH_OPTION, UPDATE_RULE, DELETE_RULE + MATCH_OPTION, UPDATE_RULE, DELETE_RULE, b.REFERENCED_TABLE_NAME from information_schema.TABLE_CONSTRAINTS a, information_schema.REFERENTIAL_CONSTRAINTS b where a.CONSTRAINT_SCHEMA = 'test' and a.CONSTRAINT_SCHEMA = b.CONSTRAINT_SCHEMA and diff --git a/sql/sql_show.cc b/sql/sql_show.cc index c4bb6a8fc92..a895bf14ce0 100644 --- a/sql/sql_show.cc +++ b/sql/sql_show.cc @@ -4497,8 +4497,10 @@ get_referential_constraints_record(THD *thd, struct st_table_list *tables, f_key_info->forein_id->length, cs); table->field[4]->store(f_key_info->referenced_db->str, f_key_info->referenced_db->length, cs); - table->field[5]->store(f_key_info->referenced_table->str, + table->field[10]->store(f_key_info->referenced_table->str, f_key_info->referenced_table->length, cs); + table->field[5]->store(f_key_info->referenced_key_name->str, + f_key_info->referenced_key_name->length, cs); table->field[6]->store(STRING_WITH_LEN("NONE"), cs); table->field[7]->store(f_key_info->update_method->str, f_key_info->update_method->length, cs); @@ -5668,6 +5670,7 @@ ST_FIELD_INFO referential_constraints_fields_info[]= {"UPDATE_RULE", NAME_LEN, MYSQL_TYPE_STRING, 0, 0, 0}, {"DELETE_RULE", NAME_LEN, MYSQL_TYPE_STRING, 0, 0, 0}, {"TABLE_NAME", NAME_LEN, MYSQL_TYPE_STRING, 0, 0, 0}, + {"REFERENCED_TABLE_NAME", NAME_LEN, MYSQL_TYPE_STRING, 0, 0, 0}, {0, 0, MYSQL_TYPE_STRING, 0, 0, 0} }; diff --git a/sql/table.h b/sql/table.h index 80add0e0b91..82083d79570 100644 --- a/sql/table.h +++ b/sql/table.h @@ -460,6 +460,7 @@ typedef struct st_foreign_key_info LEX_STRING *referenced_table; LEX_STRING *update_method; LEX_STRING *delete_method; + LEX_STRING *referenced_key_name; List foreign_fields; List referenced_fields; } FOREIGN_KEY_INFO; diff --git a/storage/innobase/handler/ha_innodb.cc b/storage/innobase/handler/ha_innodb.cc index ee74fce322e..b5b354d4b39 100644 --- a/storage/innobase/handler/ha_innodb.cc +++ b/storage/innobase/handler/ha_innodb.cc @@ -6003,8 +6003,14 @@ ha_innobase::get_foreign_key_list(THD *thd, List *f_key_list) } f_key_info.update_method= make_lex_string(thd, f_key_info.update_method, tmp_buff, length, 1); - - + if (foreign->referenced_index && + foreign->referenced_index->name) + { + f_key_info.referenced_key_name= + make_lex_string(thd, f_key_info.referenced_key_name, + foreign->referenced_index->name, + strlen(foreign->referenced_index->name), 1); + } FOREIGN_KEY_INFO *pf_key_info= ((FOREIGN_KEY_INFO *) thd->memdup((gptr) &f_key_info, From 134e94931793d7b5ff891d0e684d6b126bf2a39d Mon Sep 17 00:00:00 2001 From: "gkodinov/kgeorge@macbook.gmz" <> Date: Mon, 15 Jan 2007 19:15:52 +0200 Subject: [PATCH 09/22] BUG#20420: optimizer reports wrong keys on left join with IN The optimizer needs to evaluate whether predicates are better evaluated using an index. IN is one such predicate. To qualify an IN predicate must involve a field of the index on the left and constant arguments on the right. However whether an expression is a constant can be determined only by knowing the preceding tables in the join order. Assuming that only IN predicates with expressions on the right that are constant for the whole query qualify limits the scope of possible optimizations of the IN predicate (more specifically it doesn't allow the "Range checked for each record" optimization for such an IN predicate. Fixed by not pre-determining the optimizability of the IN predicate in the case when all right IN operands are not SQL constant expressions --- mysql-test/r/func_in.result | 43 +++++++++++++++++++++++++++++++++++++ mysql-test/t/func_in.test | 36 +++++++++++++++++++++++++++++++ sql/item_cmpfunc.h | 6 +++++- 3 files changed, 84 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/func_in.result b/mysql-test/r/func_in.result index a172d04d880..98e39917f04 100644 --- a/mysql-test/r/func_in.result +++ b/mysql-test/r/func_in.result @@ -351,4 +351,47 @@ some_id 1 2 drop table t1; +CREATE TABLE t1 (a int, b int, PRIMARY KEY (a)); +INSERT INTO t1 VALUES (1,1),(2,1),(3,1),(4,1),(5,1),(6,1); +CREATE TABLE t2 (a int, b int, PRIMARY KEY (a)); +INSERT INTO t2 VALUES (3,2),(4,2); +CREATE TABLE t3 (a int PRIMARY KEY); +INSERT INTO t3 VALUES (1),(2),(3),(4); +CREATE TABLE t4 (a int PRIMARY KEY); +INSERT INTO t4 VALUES (1),(2); +EXPLAIN SELECT STRAIGHT_JOIN * FROM t3 +JOIN t1 ON t3.a=t1.a +JOIN t2 ON t3.a=t2.a +JOIN t4 WHERE t4.a IN (t1.b, t2.b); +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t3 index PRIMARY PRIMARY 4 NULL 4 Using index +1 SIMPLE t1 eq_ref PRIMARY PRIMARY 4 test.t3.a 1 +1 SIMPLE t2 eq_ref PRIMARY PRIMARY 4 test.t3.a 1 +1 SIMPLE t4 ALL PRIMARY NULL NULL NULL 2 Range checked for each record (index map: 0x1) +SELECT STRAIGHT_JOIN * FROM t3 +JOIN t1 ON t3.a=t1.a +JOIN t2 ON t3.a=t2.a +JOIN t4 WHERE t4.a IN (t1.b, t2.b); +a a b a b a +3 3 1 3 2 1 +3 3 1 3 2 2 +4 4 1 4 2 1 +4 4 1 4 2 2 +EXPLAIN SELECT STRAIGHT_JOIN +(SELECT SUM(t4.a) FROM t4 WHERE t4.a IN (t1.b, t2.b)) +FROM t3, t1, t2 +WHERE t3.a=t1.a AND t3.a=t2.a; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t3 index PRIMARY PRIMARY 4 NULL 4 Using index +1 PRIMARY t1 eq_ref PRIMARY PRIMARY 4 test.t3.a 1 +1 PRIMARY t2 eq_ref PRIMARY PRIMARY 4 test.t3.a 1 +2 DEPENDENT SUBQUERY t4 index NULL PRIMARY 4 NULL 2 Using where; Using index +SELECT STRAIGHT_JOIN +(SELECT SUM(t4.a) FROM t4 WHERE t4.a IN (t1.b, t2.b)) +FROM t3, t1, t2 +WHERE t3.a=t1.a AND t3.a=t2.a; +(SELECT SUM(t4.a) FROM t4 WHERE t4.a IN (t1.b, t2.b)) +3 +3 +DROP TABLE t1,t2,t3,t4; End of 5.0 tests diff --git a/mysql-test/t/func_in.test b/mysql-test/t/func_in.test index d48606ac6e6..8c89aa1e729 100644 --- a/mysql-test/t/func_in.test +++ b/mysql-test/t/func_in.test @@ -254,5 +254,41 @@ select some_id from t1 where some_id not in(-4,-1,-4); select some_id from t1 where some_id not in(-4,-1,3423534,2342342); drop table t1; +# +# BUG#20420: optimizer reports wrong keys on left join with IN +# +CREATE TABLE t1 (a int, b int, PRIMARY KEY (a)); +INSERT INTO t1 VALUES (1,1),(2,1),(3,1),(4,1),(5,1),(6,1); + +CREATE TABLE t2 (a int, b int, PRIMARY KEY (a)); +INSERT INTO t2 VALUES (3,2),(4,2); + +CREATE TABLE t3 (a int PRIMARY KEY); +INSERT INTO t3 VALUES (1),(2),(3),(4); + +CREATE TABLE t4 (a int PRIMARY KEY); +INSERT INTO t4 VALUES (1),(2); + +EXPLAIN SELECT STRAIGHT_JOIN * FROM t3 + JOIN t1 ON t3.a=t1.a + JOIN t2 ON t3.a=t2.a + JOIN t4 WHERE t4.a IN (t1.b, t2.b); + +SELECT STRAIGHT_JOIN * FROM t3 + JOIN t1 ON t3.a=t1.a + JOIN t2 ON t3.a=t2.a + JOIN t4 WHERE t4.a IN (t1.b, t2.b); + +EXPLAIN SELECT STRAIGHT_JOIN + (SELECT SUM(t4.a) FROM t4 WHERE t4.a IN (t1.b, t2.b)) + FROM t3, t1, t2 + WHERE t3.a=t1.a AND t3.a=t2.a; + +SELECT STRAIGHT_JOIN + (SELECT SUM(t4.a) FROM t4 WHERE t4.a IN (t1.b, t2.b)) + FROM t3, t1, t2 + WHERE t3.a=t1.a AND t3.a=t2.a; + +DROP TABLE t1,t2,t3,t4; --echo End of 5.0 tests diff --git a/sql/item_cmpfunc.h b/sql/item_cmpfunc.h index 454aed01aff..5149ab4cfbe 100644 --- a/sql/item_cmpfunc.h +++ b/sql/item_cmpfunc.h @@ -965,6 +965,10 @@ class Item_func_in :public Item_func_opt_neg { public: Item_result cmp_type; + /* + an array of values when the right hand arguments of IN + are all SQL constant and there are no nulls + */ in_vector *array; cmp_item *in_item; bool have_null; @@ -990,7 +994,7 @@ public: DBUG_VOID_RETURN; } optimize_type select_optimize() const - { return array ? OPTIMIZE_KEY : OPTIMIZE_NONE; } + { return OPTIMIZE_KEY; } void print(String *str); enum Functype functype() const { return IN_FUNC; } const char *func_name() const { return " IN "; } From 53a4949d3bb899390845621fee94eb273e139904 Mon Sep 17 00:00:00 2001 From: "evgen@moonbone.local" <> Date: Mon, 15 Jan 2007 22:40:39 +0300 Subject: [PATCH 10/22] sql_select.cc: Fix for crashes on 64bit platforms after fixing bug#23417. --- sql/sql_select.cc | 8 +++++--- 1 file changed, 5 insertions(+), 3 deletions(-) diff --git a/sql/sql_select.cc b/sql/sql_select.cc index fb4e2c3ab30..93b29c05fd5 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -13416,10 +13416,12 @@ count_field_types(TMP_TABLE_PARAM *param, List &fields, param->quick_group=1; while ((field=li++)) { - Item::Type type=field->real_item()->type(); - if (type == Item::FIELD_ITEM) + Item::Type type=field->type(); + Item::Type real_type= field->real_item()->type(); + if (type == Item::FIELD_ITEM || (real_type == Item::FIELD_ITEM && + (type != Item::REF_ITEM || !((Item_ref *) field)->depended_from))) param->field_count++; - else if (type == Item::SUM_FUNC_ITEM) + else if (real_type == Item::SUM_FUNC_ITEM) { if (! field->const_item()) { From f3b3f1ef73d32d75926266989702dcacdc5a8f73 Mon Sep 17 00:00:00 2001 From: "igor@olga.mysql.com" <> Date: Mon, 15 Jan 2007 14:01:36 -0800 Subject: [PATCH 11/22] Adjusted results after merge 4.1 -> 5.0 for the patch fixing bug 24776. --- mysql-test/r/range.result | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/mysql-test/r/range.result b/mysql-test/r/range.result index 6037824ea16..f84bb2788e1 100644 --- a/mysql-test/r/range.result +++ b/mysql-test/r/range.result @@ -704,7 +704,7 @@ WHERE s.oxrootid = 'd8c4177d09f8b11f5.52725521' AND v.oxrootid ='d8c4177d09f8b11f5.52725521' AND s.oxleft > v.oxleft AND s.oxleft < v.oxright; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE v ref OXLEFT,OXRIGHT,OXROOTID OXROOTID 32 const 5 Using where +1 SIMPLE v ref OXLEFT,OXRIGHT,OXROOTID OXROOTID 34 const 5 Using where 1 SIMPLE s ALL OXLEFT NULL NULL NULL 5 Range checked for each record (index map: 0x4) SELECT s.oxid FROM t1 v, t1 s WHERE s.oxrootid = 'd8c4177d09f8b11f5.52725521' AND From c1927e9a70f38a92a3164f71f4f7ff4449befcea Mon Sep 17 00:00:00 2001 From: "igor@olga.mysql.com" <> Date: Wed, 17 Jan 2007 20:13:45 -0800 Subject: [PATCH 12/22] Fixed bug #25580: incorrect stored representations of views in cases when they contain the '!' operator. Added an implementation for the method Item_func_not::print. The method encloses any NOT expression into extra parentheses to avoid incorrect stored representations of views that use the '!' operators. Without this change when a view was created that contained the expression !0*5 its stored representation contained not this expression but rather the expression not(0)*5 . The operator '!' is of a higher precedence than '*', while NOT is of a lower precedence than '*'. That's why the expression !0*5 is interpreted as not(0)*5, while the expression not(0)*5 is interpreted as not((0)*5) unless sql_mode is set to HIGH_NOT_PRECEDENCE. Now we translate !0*5 into (not(0))*5. --- mysql-test/r/sp-code.result | 2 +- mysql-test/r/subselect.result | 10 +++++----- mysql-test/r/view.result | 11 +++++++++++ mysql-test/t/view.test | 11 +++++++++++ sql/item_cmpfunc.cc | 16 ++++++++++++++++ sql/item_cmpfunc.h | 1 + 6 files changed, 45 insertions(+), 6 deletions(-) diff --git a/mysql-test/r/sp-code.result b/mysql-test/r/sp-code.result index 4ae38861d29..8fea85b7cd7 100644 --- a/mysql-test/r/sp-code.result +++ b/mysql-test/r/sp-code.result @@ -187,7 +187,7 @@ Pos Instruction 32 set v_dig@4 (v_dig@4 + 1) 33 stmt 4 "update sudoku_work set dig = v_dig wh..." 34 set v_tcounter@6 (v_tcounter@6 + 1) -35 jump_if_not 37(37) not(`test`.`sudoku_digit_ok`(v_row@7,v_col@8,v_dig@4)) +35 jump_if_not 37(37) (not(`test`.`sudoku_digit_ok`(v_row@7,v_col@8,v_dig@4))) 36 jump 15 37 set v_i@3 (v_i@3 + 1) 38 jump 15 diff --git a/mysql-test/r/subselect.result b/mysql-test/r/subselect.result index 1bf6d6c7716..7d72a9cb038 100644 --- a/mysql-test/r/subselect.result +++ b/mysql-test/r/subselect.result @@ -1464,7 +1464,7 @@ id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t1 index NULL s1 6 NULL 3 Using index 2 DEPENDENT SUBQUERY t2 index_subquery s1 s1 6 func 2 Using index Warnings: -Note 1003 select `test`.`t1`.`s1` AS `s1`,not((`test`.`t1`.`s1`,(((`test`.`t1`.`s1`) in t2 on s1 checking NULL)))) AS `s1 NOT IN (SELECT s1 FROM t2)` from `test`.`t1` +Note 1003 select `test`.`t1`.`s1` AS `s1`,(not((`test`.`t1`.`s1`,(((`test`.`t1`.`s1`) in t2 on s1 checking NULL))))) AS `s1 NOT IN (SELECT s1 FROM t2)` from `test`.`t1` explain extended select s1, s1 = ANY (SELECT s1 FROM t2) from t1; id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t1 index NULL s1 6 NULL 3 Using index @@ -1476,13 +1476,13 @@ id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t1 index NULL s1 6 NULL 3 Using index 2 DEPENDENT SUBQUERY t2 index_subquery s1 s1 6 func 2 Using index Warnings: -Note 1003 select `test`.`t1`.`s1` AS `s1`,not((`test`.`t1`.`s1`,(((`test`.`t1`.`s1`) in t2 on s1 checking NULL)))) AS `s1 <> ALL (SELECT s1 FROM t2)` from `test`.`t1` +Note 1003 select `test`.`t1`.`s1` AS `s1`,(not((`test`.`t1`.`s1`,(((`test`.`t1`.`s1`) in t2 on s1 checking NULL))))) AS `s1 <> ALL (SELECT s1 FROM t2)` from `test`.`t1` explain extended select s1, s1 NOT IN (SELECT s1 FROM t2 WHERE s1 < 'a2') from t1; id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t1 index NULL s1 6 NULL 3 Using index 2 DEPENDENT SUBQUERY t2 index_subquery s1 s1 6 func 2 Using index; Using where Warnings: -Note 1003 select `test`.`t1`.`s1` AS `s1`,not((`test`.`t1`.`s1`,(((`test`.`t1`.`s1`) in t2 on s1 checking NULL where (`test`.`t2`.`s1` < _latin1'a2'))))) AS `s1 NOT IN (SELECT s1 FROM t2 WHERE s1 < 'a2')` from `test`.`t1` +Note 1003 select `test`.`t1`.`s1` AS `s1`,(not((`test`.`t1`.`s1`,(((`test`.`t1`.`s1`) in t2 on s1 checking NULL where (`test`.`t2`.`s1` < _latin1'a2')))))) AS `s1 NOT IN (SELECT s1 FROM t2 WHERE s1 < 'a2')` from `test`.`t1` drop table t1,t2; create table t2 (a int, b int); create table t3 (a int); @@ -1737,14 +1737,14 @@ id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t1 ALL NULL NULL NULL NULL 12 Using where 2 DEPENDENT SUBQUERY t1 unique_subquery PRIMARY PRIMARY 4 func 1 Using index; Using where Warnings: -Note 1003 select `test`.`t1`.`id` AS `id`,`test`.`t1`.`text` AS `text` from `test`.`t1` where not((`test`.`t1`.`id`,(((`test`.`t1`.`id`) in t1 on PRIMARY where (`test`.`t1`.`id` < 8))))) +Note 1003 select `test`.`t1`.`id` AS `id`,`test`.`t1`.`text` AS `text` from `test`.`t1` where (not((`test`.`t1`.`id`,(((`test`.`t1`.`id`) in t1 on PRIMARY where (`test`.`t1`.`id` < 8)))))) explain extended select * from t1 as tt where not exists (select id from t1 where id < 8 and (id = tt.id or id is null) having id is not null); id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY tt ALL NULL NULL NULL NULL 12 Using where 2 DEPENDENT SUBQUERY t1 eq_ref PRIMARY PRIMARY 4 test.tt.id 1 Using where; Using index Warnings: Note 1276 Field or reference 'tt.id' of SELECT #2 was resolved in SELECT #1 -Note 1003 select `test`.`tt`.`id` AS `id`,`test`.`tt`.`text` AS `text` from `test`.`t1` `tt` where not(exists(select `test`.`t1`.`id` AS `id` from `test`.`t1` where ((`test`.`t1`.`id` < 8) and (`test`.`t1`.`id` = `test`.`tt`.`id`)) having (`test`.`t1`.`id` is not null))) +Note 1003 select `test`.`tt`.`id` AS `id`,`test`.`tt`.`text` AS `text` from `test`.`t1` `tt` where (not(exists(select `test`.`t1`.`id` AS `id` from `test`.`t1` where ((`test`.`t1`.`id` < 8) and (`test`.`t1`.`id` = `test`.`tt`.`id`)) having (`test`.`t1`.`id` is not null)))) insert into t1 (id, text) values (1000, 'text1000'), (1001, 'text1001'); create table t2 (id int not null, text varchar(20) not null default '', primary key (id)); insert into t2 (id, text) values (1, 'text1'), (2, 'text2'), (3, 'text3'), (4, 'text4'), (5, 'text5'), (6, 'text6'), (7, 'text7'), (8, 'text8'), (9, 'text9'), (10, 'text10'), (11, 'text1'), (12, 'text2'), (13, 'text3'), (14, 'text4'), (15, 'text5'), (16, 'text6'), (17, 'text7'), (18, 'text8'), (19, 'text9'), (20, 'text10'),(21, 'text1'), (22, 'text2'), (23, 'text3'), (24, 'text4'), (25, 'text5'), (26, 'text6'), (27, 'text7'), (28, 'text8'), (29, 'text9'), (30, 'text10'), (31, 'text1'), (32, 'text2'), (33, 'text3'), (34, 'text4'), (35, 'text5'), (36, 'text6'), (37, 'text7'), (38, 'text8'), (39, 'text9'), (40, 'text10'), (41, 'text1'), (42, 'text2'), (43, 'text3'), (44, 'text4'), (45, 'text5'), (46, 'text6'), (47, 'text7'), (48, 'text8'), (49, 'text9'), (50, 'text10'); diff --git a/mysql-test/r/view.result b/mysql-test/r/view.result index 4d076db5c22..7f3106e5972 100644 --- a/mysql-test/r/view.result +++ b/mysql-test/r/view.result @@ -3014,4 +3014,15 @@ i j 6 3 DROP VIEW v1, v2; DROP TABLE t1; +CREATE VIEW v AS SELECT !0 * 5 AS x FROM DUAL; +SHOW CREATE VIEW v; +View Create View +v CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v` AS select ((not(0)) * 5) AS `x` +SELECT !0 * 5 AS x FROM DUAL; +x +5 +SELECT * FROM v; +x +5 +DROP VIEW v; End of 5.0 tests. diff --git a/mysql-test/t/view.test b/mysql-test/t/view.test index 8473458ae15..123759ec82e 100644 --- a/mysql-test/t/view.test +++ b/mysql-test/t/view.test @@ -2959,5 +2959,16 @@ SELECT * FROM t1; DROP VIEW v1, v2; DROP TABLE t1; +# +# Bug #25580: !0 as an operand in a select expression of a view +# + +CREATE VIEW v AS SELECT !0 * 5 AS x FROM DUAL; +SHOW CREATE VIEW v; + +SELECT !0 * 5 AS x FROM DUAL; +SELECT * FROM v; + +DROP VIEW v; --echo End of 5.0 tests. diff --git a/sql/item_cmpfunc.cc b/sql/item_cmpfunc.cc index 936ae04e93d..846aa0c9150 100644 --- a/sql/item_cmpfunc.cc +++ b/sql/item_cmpfunc.cc @@ -146,6 +146,22 @@ longlong Item_func_not::val_int() return ((!null_value && value == 0) ? 1 : 0); } +/* + We put any NOT expression into parenthesis to avoid + possible problems with internal view representations where + any '!' is converted to NOT. It may cause a problem if + '!' is used in an expression together with other operators + whose precedence is lower than the precedence of '!' yet + higher than the precedence of NOT. +*/ + +void Item_func_not::print(String *str) +{ + str->append('('); + Item_func::print(str); + str->append(')'); +} + /* special NOT for ALL subquery */ diff --git a/sql/item_cmpfunc.h b/sql/item_cmpfunc.h index 1d85d08c434..54457d37d18 100644 --- a/sql/item_cmpfunc.h +++ b/sql/item_cmpfunc.h @@ -269,6 +269,7 @@ public: enum Functype functype() const { return NOT_FUNC; } const char *func_name() const { return "not"; } Item *neg_transformer(THD *thd); + void print(String *str); }; class Item_maxmin_subselect; From 20d94f1105e02dc61e93af8ffe6e744b9c7803d8 Mon Sep 17 00:00:00 2001 From: "gkodinov/kgeorge@macbook.gmz" <> Date: Thu, 18 Jan 2007 17:33:38 +0200 Subject: [PATCH 13/22] Bug #25382: Passing NULL to an UDF called from stored procedures crashes server Check for null value is reliable only after calling some of the val_xxx() methods. If the val_xxx() method is not called the null_value flag will be set only for certain types of NULL values (like SQL constant NULLs for example). This caused a crash while trying to dereference a NULL pointer that is returned by val_str() for NULL values. Fixed by swapping the order of val_xxx() and null_value check. --- mysql-test/r/udf.result | 34 +++++++++++++++++++++++++++++ mysql-test/t/udf.test | 47 +++++++++++++++++++++++++++++++++++++++++ sql/item_func.cc | 9 +++++--- 3 files changed, 87 insertions(+), 3 deletions(-) diff --git a/mysql-test/r/udf.result b/mysql-test/r/udf.result index 64b7111bbc8..d5f59247084 100644 --- a/mysql-test/r/udf.result +++ b/mysql-test/r/udf.result @@ -240,3 +240,37 @@ drop table bug18761; select is_const((1,2,3)); ERROR 21000: Operand should contain 1 column(s) drop function if exists is_const; +CREATE FUNCTION metaphon RETURNS STRING SONAME "UDF_EXAMPLE_LIB"; +CREATE FUNCTION myfunc_double RETURNS REAL SONAME "UDF_EXAMPLE_LIB"; +CREATE FUNCTION myfunc_int RETURNS INTEGER SONAME "UDF_EXAMPLE_LIB"; +create function f1(p1 varchar(255)) +returns varchar(255) +begin +return metaphon(p1); +end// +create function f2(p1 varchar(255)) +returns double +begin +return myfunc_double(p1); +end// +create function f3(p1 varchar(255)) +returns double +begin +return myfunc_int(p1); +end// +select f3(NULL); +f3(NULL) +0 +select f2(NULL); +f2(NULL) +NULL +select f1(NULL); +f1(NULL) +NULL +drop function f1; +drop function f2; +drop function f3; +drop function metaphon; +drop function myfunc_double; +drop function myfunc_int; +End of 5.0 tests. diff --git a/mysql-test/t/udf.test b/mysql-test/t/udf.test index 65cbc7ae3ae..0b582dc61b6 100644 --- a/mysql-test/t/udf.test +++ b/mysql-test/t/udf.test @@ -242,3 +242,50 @@ drop table bug18761; select is_const((1,2,3)); drop function if exists is_const; + +# +# Bug #25382: Passing NULL to an UDF called from stored procedures +# crashes server +# +--replace_result $UDF_EXAMPLE_LIB UDF_EXAMPLE_LIB +eval CREATE FUNCTION metaphon RETURNS STRING SONAME "$UDF_EXAMPLE_LIB"; + +--replace_result $UDF_EXAMPLE_LIB UDF_EXAMPLE_LIB +eval CREATE FUNCTION myfunc_double RETURNS REAL SONAME "$UDF_EXAMPLE_LIB"; + +--replace_result $UDF_EXAMPLE_LIB UDF_EXAMPLE_LIB +eval CREATE FUNCTION myfunc_int RETURNS INTEGER SONAME "$UDF_EXAMPLE_LIB"; + +delimiter //; +create function f1(p1 varchar(255)) +returns varchar(255) +begin + return metaphon(p1); +end// + +create function f2(p1 varchar(255)) +returns double +begin + return myfunc_double(p1); +end// + +create function f3(p1 varchar(255)) +returns double +begin + return myfunc_int(p1); +end// + +delimiter ;// + +select f3(NULL); +select f2(NULL); +select f1(NULL); + +drop function f1; +drop function f2; +drop function f3; +drop function metaphon; +drop function myfunc_double; +drop function myfunc_int; + +--echo End of 5.0 tests. diff --git a/sql/item_func.cc b/sql/item_func.cc index 4138573785e..02aad2cfdc7 100644 --- a/sql/item_func.cc +++ b/sql/item_func.cc @@ -2729,25 +2729,28 @@ udf_handler::fix_fields(THD *thd, Item_result_field *func, if (arguments[i]->const_item()) { - if (arguments[i]->null_value) - continue; - switch (arguments[i]->result_type()) { case STRING_RESULT: case DECIMAL_RESULT: { String *res= arguments[i]->val_str(&buffers[i]); + if (arguments[i]->null_value) + continue; f_args.args[i]= (char*) res->ptr(); break; } case INT_RESULT: *((longlong*) to)= arguments[i]->val_int(); + if (arguments[i]->null_value) + continue; f_args.args[i]= to; to+= ALIGN_SIZE(sizeof(longlong)); break; case REAL_RESULT: *((double*) to)= arguments[i]->val_real(); + if (arguments[i]->null_value) + continue; f_args.args[i]= to; to+= ALIGN_SIZE(sizeof(double)); break; From 3c814f224356e361a4a1c576949adcea72256ac8 Mon Sep 17 00:00:00 2001 From: "igor@olga.mysql.com" <> Date: Fri, 19 Jan 2007 00:17:28 -0800 Subject: [PATCH 14/22] Fixed bug #25219: crash for a query that contains an EXIST subquery with UNION over correlated and uncorrelated SELECTS. In such subqueries each uncorrelated SELECT should be considered as uncacheable. Otherwise join_free is called for it and in many cases it causes some problems. --- mysql-test/r/subselect.result | 33 +++++++++++++++++++++++++++++++++ mysql-test/t/subselect.test | 34 ++++++++++++++++++++++++++++++++++ sql/mysql_priv.h | 5 ++++- sql/sql_lex.cc | 12 ++++++++++-- 4 files changed, 81 insertions(+), 3 deletions(-) diff --git a/mysql-test/r/subselect.result b/mysql-test/r/subselect.result index 1bf6d6c7716..5cf3cd110c0 100644 --- a/mysql-test/r/subselect.result +++ b/mysql-test/r/subselect.result @@ -3605,3 +3605,36 @@ FROM t1) t; COUNT(*) 3000 DROP TABLE t1,t2; +CREATE TABLE t1 (id char(4) PRIMARY KEY, c int); +CREATE TABLE t2 (c int); +INSERT INTO t1 VALUES ('aa', 1); +INSERT INTO t2 VALUES (1); +SELECT * FROM t1 +WHERE EXISTS (SELECT c FROM t2 WHERE c=1 +UNION +SELECT c from t2 WHERE c=t1.c); +id c +aa 1 +INSERT INTO t1 VALUES ('bb', 2), ('cc', 3), ('dd',1); +SELECT * FROM t1 +WHERE EXISTS (SELECT c FROM t2 WHERE c=1 +UNION +SELECT c from t2 WHERE c=t1.c); +id c +aa 1 +bb 2 +cc 3 +dd 1 +INSERT INTO t2 VALUES (2); +CREATE TABLE t3 (c int); +INSERT INTO t3 VALUES (1); +SELECT * FROM t1 +WHERE EXISTS (SELECT t2.c FROM t2 JOIN t3 ON t2.c=t3.c WHERE t2.c=1 +UNION +SELECT c from t2 WHERE c=t1.c); +id c +aa 1 +bb 2 +cc 3 +dd 1 +DROP TABLE t1,t2,t3; diff --git a/mysql-test/t/subselect.test b/mysql-test/t/subselect.test index 0b658f746a4..c6dd34b5172 100644 --- a/mysql-test/t/subselect.test +++ b/mysql-test/t/subselect.test @@ -2508,3 +2508,37 @@ SELECT SQL_NO_CACHE COUNT(*) FROM t1) t; DROP TABLE t1,t2; + +# +# Bug #25219: EXIST subquery with UNION over a mix of +# correlated and uncorrelated selects +# + +CREATE TABLE t1 (id char(4) PRIMARY KEY, c int); +CREATE TABLE t2 (c int); + +INSERT INTO t1 VALUES ('aa', 1); +INSERT INTO t2 VALUES (1); + +SELECT * FROM t1 + WHERE EXISTS (SELECT c FROM t2 WHERE c=1 + UNION + SELECT c from t2 WHERE c=t1.c); + +INSERT INTO t1 VALUES ('bb', 2), ('cc', 3), ('dd',1); + +SELECT * FROM t1 + WHERE EXISTS (SELECT c FROM t2 WHERE c=1 + UNION + SELECT c from t2 WHERE c=t1.c); + +INSERT INTO t2 VALUES (2); +CREATE TABLE t3 (c int); +INSERT INTO t3 VALUES (1); + +SELECT * FROM t1 + WHERE EXISTS (SELECT t2.c FROM t2 JOIN t3 ON t2.c=t3.c WHERE t2.c=1 + UNION + SELECT c from t2 WHERE c=t1.c); + +DROP TABLE t1,t2,t3; diff --git a/sql/mysql_priv.h b/sql/mysql_priv.h index caf3e6479f9..3033c7f360c 100644 --- a/sql/mysql_priv.h +++ b/sql/mysql_priv.h @@ -410,7 +410,10 @@ MY_LOCALE *my_locale_by_name(const char *name); #define UNCACHEABLE_EXPLAIN 8 /* Don't evaluate subqueries in prepare even if they're not correlated */ #define UNCACHEABLE_PREPARE 16 -/* Used to chack GROUP BY list in the MODE_ONLY_FULL_GROUP_BY mode */ +/* For uncorrelated SELECT in an UNION with some correlated SELECTs */ +#define UNCACHEABLE_UNITED 32 + +/* Used to check GROUP BY list in the MODE_ONLY_FULL_GROUP_BY mode */ #define UNDEF_POS (-1) #ifdef EXTRA_DEBUG /* diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index 3ae95ef9036..87793849094 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -1371,9 +1371,17 @@ void st_select_lex::mark_as_dependent(SELECT_LEX *last) if (!(s->uncacheable & UNCACHEABLE_DEPENDENT)) { // Select is dependent of outer select - s->uncacheable|= UNCACHEABLE_DEPENDENT; + s->uncacheable= (s->uncacheable & ~UNCACHEABLE_UNITED) | + UNCACHEABLE_DEPENDENT; SELECT_LEX_UNIT *munit= s->master_unit(); - munit->uncacheable|= UNCACHEABLE_DEPENDENT; + munit->uncacheable= (munit->uncacheable & ~UNCACHEABLE_UNITED) | + UNCACHEABLE_DEPENDENT; + for (SELECT_LEX *sl= munit->first_select(); sl ; sl= sl->next_select()) + { + if (sl != s && + !(sl->uncacheable & (UNCACHEABLE_DEPENDENT | UNCACHEABLE_UNITED))) + sl->uncacheable|= UNCACHEABLE_UNITED; + } } is_correlated= TRUE; this->master_unit()->item->is_correlated= TRUE; From d7d5db64ec83dc83728803bc9756dc53668da3c0 Mon Sep 17 00:00:00 2001 From: "evgen@moonbone.local" <> Date: Fri, 19 Jan 2007 18:34:09 +0300 Subject: [PATCH 15/22] Bug#25172: Not checked buffer size leads to a server crash. After fix for bug#21798 JOIN stores the pointer to the buffer for sorting fields. It is used while sorting for grouping and for ordering. If ORDER BY clause has more elements then the GROUP BY clause then a memory overrun occurs. Now the length of the ORDER BY list is always passed to the make_unireg_sortorder() function and it allocates buffer big enough to be used for bigger list. --- mysql-test/r/select.result | 8 ++++++++ mysql-test/t/select.test | 11 +++++++++++ sql/sql_delete.cc | 2 +- sql/sql_select.cc | 12 ++++++++---- sql/sql_table.cc | 2 +- sql/sql_update.cc | 2 +- 6 files changed, 30 insertions(+), 7 deletions(-) diff --git a/mysql-test/r/select.result b/mysql-test/r/select.result index 44063c1e890..d890510ee67 100644 --- a/mysql-test/r/select.result +++ b/mysql-test/r/select.result @@ -3611,3 +3611,11 @@ id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t2 range si,ai si 5 NULL 2 Using where 1 SIMPLE t3 eq_ref PRIMARY,ci PRIMARY 4 test.t2.a 1 Using where DROP TABLE t1,t2,t3; +CREATE TABLE t1 ( f1 int primary key, f2 int, f3 int, f4 int, f5 int, f6 int, checked_out int); +CREATE TABLE t2 ( f11 int PRIMARY KEY ); +INSERT INTO t1 VALUES (1,1,1,0,0,0,0),(2,1,1,3,8,1,0),(3,1,1,4,12,1,0); +INSERT INTO t2 VALUES (62); +SELECT * FROM t1 LEFT JOIN t2 ON f11 = t1.checked_out GROUP BY f1 ORDER BY f2, f3, f4, f5 LIMIT 0, 1; +f1 f2 f3 f4 f5 f6 checked_out f11 +1 1 1 0 0 0 0 NULL +DROP TABLE t1, t2; diff --git a/mysql-test/t/select.test b/mysql-test/t/select.test index 0c82cef867f..5288151f330 100644 --- a/mysql-test/t/select.test +++ b/mysql-test/t/select.test @@ -3092,3 +3092,14 @@ SELECT t3.a FROM t1,t2,t3 t3.c IN ('bb','ee'); DROP TABLE t1,t2,t3; + +# +# Bug#25172: Not checked buffer size leads to a server crash +# +CREATE TABLE t1 ( f1 int primary key, f2 int, f3 int, f4 int, f5 int, f6 int, checked_out int); +CREATE TABLE t2 ( f11 int PRIMARY KEY ); +INSERT INTO t1 VALUES (1,1,1,0,0,0,0),(2,1,1,3,8,1,0),(3,1,1,4,12,1,0); +INSERT INTO t2 VALUES (62); +SELECT * FROM t1 LEFT JOIN t2 ON f11 = t1.checked_out GROUP BY f1 ORDER BY f2, f3, f4, f5 LIMIT 0, 1; +DROP TABLE t1, t2; + diff --git a/sql/sql_delete.cc b/sql/sql_delete.cc index 7752ac80adb..e8291edda5d 100644 --- a/sql/sql_delete.cc +++ b/sql/sql_delete.cc @@ -142,7 +142,7 @@ bool mysql_delete(THD *thd, TABLE_LIST *table_list, COND *conds, if (order && order->elements) { - uint length; + uint length= 0; SORT_FIELD *sortorder; TABLE_LIST tables; List fields; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 93b29c05fd5..b03c4556279 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -12262,7 +12262,7 @@ static int create_sort_index(THD *thd, JOIN *join, ORDER *order, ha_rows filesort_limit, ha_rows select_limit) { - uint length; + uint length= 0; ha_rows examined_rows; TABLE *table; SQL_SELECT *select; @@ -12283,8 +12283,10 @@ create_sort_index(THD *thd, JOIN *join, ORDER *order, !(join->select_options & SELECT_BIG_RESULT)) && test_if_skip_sort_order(tab,order,select_limit,0)) DBUG_RETURN(0); + for (ORDER *ord= join->order; ord; ord= ord->next) + length++; if (!(join->sortorder= - make_unireg_sortorder(order,&length,join->sortorder))) + make_unireg_sortorder(order, &length, join->sortorder))) goto err; /* purecov: inspected */ table->sort.io_cache=(IO_CACHE*) my_malloc(sizeof(IO_CACHE), @@ -12690,8 +12692,10 @@ SORT_FIELD *make_unireg_sortorder(ORDER *order, uint *length, for (ORDER *tmp = order; tmp; tmp=tmp->next) count++; if (!sortorder) - sortorder= (SORT_FIELD*) sql_alloc(sizeof(SORT_FIELD)*(count+1)); - pos=sort=sortorder; + sortorder= (SORT_FIELD*) sql_alloc(sizeof(SORT_FIELD) * + (max(count, *length) + 1)); + pos= sort= sortorder; + if (!pos) return 0; diff --git a/sql/sql_table.cc b/sql/sql_table.cc index b3bd3182a59..fd52b9becf6 100644 --- a/sql/sql_table.cc +++ b/sql/sql_table.cc @@ -3883,7 +3883,7 @@ copy_data_between_tables(TABLE *from,TABLE *to, Copy_field *copy,*copy_end; ulong found_count,delete_count; THD *thd= current_thd; - uint length; + uint length= 0; SORT_FIELD *sortorder; READ_RECORD info; TABLE_LIST tables; diff --git a/sql/sql_update.cc b/sql/sql_update.cc index abffd704188..76d4847f923 100644 --- a/sql/sql_update.cc +++ b/sql/sql_update.cc @@ -304,7 +304,7 @@ int mysql_update(THD *thd, Doing an ORDER BY; Let filesort find and sort the rows we are going to update */ - uint length; + uint length= 0; SORT_FIELD *sortorder; ha_rows examined_rows; From 9ea140d13ebb5c32b28bec568aebceede53da36e Mon Sep 17 00:00:00 2001 From: "gkodinov/kgeorge@macbook.gmz" <> Date: Mon, 22 Jan 2007 12:51:21 +0200 Subject: [PATCH 16/22] BUG#16590: Optimized does not do right "const" table pre-read st_table::const_key_parts member is used in determining if certain key has a prefix that is compared to constant(s) in the query predicates. If there's such prefix the index can be used to get the data from the remaining suffix columns in sorted order. However if a field is compared to another field from a "const" table the const_key_parts is not amended. This makes the optimizer unable to detect that the key can be used for sorting and adds an extra filesort. Fixed by updating const_key_parts after reading in the "const" table. --- mysql-test/r/order_by.result | 9 +++++++++ mysql-test/t/order_by.test | 13 +++++++++++++ sql/sql_select.cc | 16 ++++++++++++++++ 3 files changed, 38 insertions(+) diff --git a/mysql-test/r/order_by.result b/mysql-test/r/order_by.result index e5cc47fd9d2..646390317d0 100644 --- a/mysql-test/r/order_by.result +++ b/mysql-test/r/order_by.result @@ -918,3 +918,12 @@ NULL 2 3 DROP TABLE t1,t2,t3,t4; +CREATE TABLE t1 (a INT, b INT, PRIMARY KEY (a), UNIQUE KEY b (b)); +INSERT INTO t1 VALUES (1,1),(2,2); +CREATE TABLE t2 (a INT, b INT, KEY a (a,b)); +INSERT INTO t2 VALUES (1,1),(1,2),(2,1),(2,2); +EXPLAIN SELECT 1 FROM t1,t2 WHERE t1.b=2 AND t1.a=t2.a ORDER BY t2.b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const PRIMARY,b b 5 const 1 +1 SIMPLE t2 ref a a 5 const 2 Using where; Using index +DROP TABLE t1,t2; diff --git a/mysql-test/t/order_by.test b/mysql-test/t/order_by.test index d7cf0e2a375..40d2d745cc7 100644 --- a/mysql-test/t/order_by.test +++ b/mysql-test/t/order_by.test @@ -625,3 +625,16 @@ SELECT t2.b FROM t1 LEFT JOIN (t2, t3 LEFT JOIN t4 ON t3.a=t4.a) ON (t1.a=t2.a AND t1.b=t3.b) order by t2.b; DROP TABLE t1,t2,t3,t4; + +# +# BUG#16590: Optimized does not do right "const" table pre-read +# +CREATE TABLE t1 (a INT, b INT, PRIMARY KEY (a), UNIQUE KEY b (b)); +INSERT INTO t1 VALUES (1,1),(2,2); + +CREATE TABLE t2 (a INT, b INT, KEY a (a,b)); +INSERT INTO t2 VALUES (1,1),(1,2),(2,1),(2,2); + +EXPLAIN SELECT 1 FROM t1,t2 WHERE t1.b=2 AND t1.a=t2.a ORDER BY t2.b; + +DROP TABLE t1,t2; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 3c1c2fe4778..83a665a8d24 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -7712,6 +7712,22 @@ static void update_const_equal_items(COND *cond, JOIN_TAB *tab) key_map possible_keys= field->key_start; possible_keys.intersect(field->table->keys_in_use_for_query); stat[0].const_keys.merge(possible_keys); + + /* + For each field in the multiple equality (for which we know that it + is a constant) we have to find its corresponding key part, and set + that key part in const_key_parts. + */ + if (!possible_keys.is_clear_all()) + { + TABLE *tab= field->table; + KEYUSE *use; + for (use= stat->keyuse; use && use->table == tab; use++) + if (possible_keys.is_set(use->key) && + tab->key_info[use->key].key_part[use->keypart].field == + field) + tab->const_key_parts[use->key]|= use->keypart_map; + } } } } From e921ac7afcb98fbedf34890fc17a56bfc70a8b2b Mon Sep 17 00:00:00 2001 From: "evgen@moonbone.local" <> Date: Mon, 22 Jan 2007 15:14:38 +0300 Subject: [PATCH 17/22] Bug#25123: ON DUPLICATE KEY clause allows fields not from the insert table. When inserting into a join-based view the update fields from the ON DUPLICATE KEY UPDATE wasn't checked to be from the table being inserted into and were silently ignored. The new check_view_single_update() function is added to check that insert/update fields are being from the same single table of the view. --- mysql-test/r/insert.result | 21 +++++++++ mysql-test/t/insert.test | 18 ++++++++ sql/sql_insert.cc | 93 ++++++++++++++++++++++++++++++-------- 3 files changed, 112 insertions(+), 20 deletions(-) diff --git a/mysql-test/r/insert.result b/mysql-test/r/insert.result index 78ef6fbccba..7900e0b7695 100644 --- a/mysql-test/r/insert.result +++ b/mysql-test/r/insert.result @@ -325,3 +325,24 @@ select row_count(); row_count() 1 drop table t1; +create table t1 (f1 int unique, f2 int); +create table t2 (f3 int, f4 int); +create view v1 as select * from t1, t2 where f1= f3; +insert into t1 values (1,11), (2,22); +insert into t2 values (1,12), (2,24); +insert into v1 (f1) values (3) on duplicate key update f3= f3 + 10; +ERROR HY000: Can not modify more than one base table through a join view 'test.v1' +insert into v1 (f1) values (3) on duplicate key update f1= f3 + 10; +select * from t1; +f1 f2 +1 11 +2 22 +3 NULL +insert into v1 (f1) values (3) on duplicate key update f1= f3 + 10; +select * from t1; +f1 f2 +1 11 +2 22 +12 NULL +drop view v1; +drop table t1,t2; diff --git a/mysql-test/t/insert.test b/mysql-test/t/insert.test index 029c4d19e63..0a8e184ea5c 100644 --- a/mysql-test/t/insert.test +++ b/mysql-test/t/insert.test @@ -198,3 +198,21 @@ select row_count(); insert into t1 values (5, 5) on duplicate key update data= data + 10; select row_count(); drop table t1; + +# +# Bug#25123: ON DUPLICATE KEY clause allows fields not from the insert table +# +create table t1 (f1 int unique, f2 int); +create table t2 (f3 int, f4 int); +create view v1 as select * from t1, t2 where f1= f3; +insert into t1 values (1,11), (2,22); +insert into t2 values (1,12), (2,24); +--error 1393 +insert into v1 (f1) values (3) on duplicate key update f3= f3 + 10; +insert into v1 (f1) values (3) on duplicate key update f1= f3 + 10; +select * from t1; +insert into v1 (f1) values (3) on duplicate key update f1= f3 + 10; +select * from t1; +drop view v1; +drop table t1,t2; + diff --git a/sql/sql_insert.cc b/sql/sql_insert.cc index be6707c80a9..0e81730e772 100644 --- a/sql/sql_insert.cc +++ b/sql/sql_insert.cc @@ -80,6 +80,65 @@ static bool check_view_insertability(THD *thd, TABLE_LIST *view); #define my_safe_afree(ptr, size, min_length) if (size > min_length) my_free(ptr,MYF(0)) #endif +/* + Check that insert/update fields are from the same single table of a view. + + SYNOPSIS + check_view_single_update() + fields The insert/update fields to be checked. + view The view for insert. + map [in/out] The insert table map. + + DESCRIPTION + This function is called in 2 cases: + 1. to check insert fields. In this case *map will be set to 0. + Insert fields are checked to be all from the same single underlying + table of the given view. Otherwise the error is thrown. Found table + map is returned in the map parameter. + 2. to check update fields of the ON DUPLICATE KEY UPDATE clause. + In this case *map contains table_map found on the previous call of + the function to check insert fields. Update fields are checked to be + from the same table as the insert fields. + + RETURN + 0 OK + 1 Error +*/ + +bool check_view_single_update(List &fields, TABLE_LIST *view, + table_map *map) +{ + /* it is join view => we need to find the table for update */ + List_iterator_fast it(fields); + Item *item; + TABLE_LIST *tbl= 0; // reset for call to check_single_table() + table_map tables= 0; + + while ((item= it++)) + tables|= item->used_tables(); + + /* Check found map against provided map */ + if (*map) + { + if (tables != *map) + goto error; + return FALSE; + } + + if (view->check_single_table(&tbl, tables, view) || tbl == 0) + goto error; + + view->table= tbl->table; + *map= tables; + + return FALSE; + +error: + my_error(ER_VIEW_MULTIUPDATE, MYF(0), + view->view_db.str, view->view_name.str); + return TRUE; +} + /* Check if insert fields are correct. @@ -104,7 +163,7 @@ static bool check_view_insertability(THD *thd, TABLE_LIST *view); static int check_insert_fields(THD *thd, TABLE_LIST *table_list, List &fields, List &values, - bool check_unique) + bool check_unique, table_map *map) { TABLE *table= table_list->table; @@ -177,21 +236,9 @@ static int check_insert_fields(THD *thd, TABLE_LIST *table_list, if (table_list->effective_algorithm == VIEW_ALGORITHM_MERGE) { - /* it is join view => we need to find table for update */ - List_iterator_fast it(fields); - Item *item; - TABLE_LIST *tbl= 0; // reset for call to check_single_table() - table_map map= 0; - - while ((item= it++)) - map|= item->used_tables(); - if (table_list->check_single_table(&tbl, map, table_list) || tbl == 0) - { - my_error(ER_VIEW_MULTIUPDATE, MYF(0), - table_list->view_db.str, table_list->view_name.str); + if (check_view_single_update(fields, table_list, map)) return -1; - } - table_list->table= table= tbl->table; + table= table_list->table; } if (check_unique && thd->dupp_field) @@ -241,7 +288,7 @@ static int check_insert_fields(THD *thd, TABLE_LIST *table_list, */ static int check_update_fields(THD *thd, TABLE_LIST *insert_table_list, - List &update_fields) + List &update_fields, table_map *map) { TABLE *table= insert_table_list->table; query_id_t timestamp_query_id; @@ -264,6 +311,10 @@ static int check_update_fields(THD *thd, TABLE_LIST *insert_table_list, if (setup_fields(thd, 0, update_fields, 1, 0, 0)) return -1; + if (insert_table_list->effective_algorithm == VIEW_ALGORITHM_MERGE && + check_view_single_update(update_fields, insert_table_list, map)) + return -1; + if (table->timestamp_field) { /* Don't set timestamp column if this is modified. */ @@ -910,6 +961,7 @@ bool mysql_prepare_insert(THD *thd, TABLE_LIST *table_list, Name_resolution_context_state ctx_state; bool insert_into_view= (table_list->view != 0); bool res= 0; + table_map map= 0; DBUG_ENTER("mysql_prepare_insert"); DBUG_PRINT("enter", ("table_list 0x%lx, table 0x%lx, view %d", (ulong)table_list, (ulong)table, @@ -959,12 +1011,12 @@ bool mysql_prepare_insert(THD *thd, TABLE_LIST *table_list, /* Prepare the fields in the statement. */ if (values && !(res= check_insert_fields(thd, context->table_list, fields, *values, - !insert_into_view) || + !insert_into_view, &map) || setup_fields(thd, 0, *values, 0, 0, 0)) && duplic == DUP_UPDATE) { select_lex->no_wrap_view_item= TRUE; - res= check_update_fields(thd, context->table_list, update_fields); + res= check_update_fields(thd, context->table_list, update_fields, &map); select_lex->no_wrap_view_item= FALSE; /* When we are not using GROUP BY we can refer to other tables in the @@ -2286,6 +2338,7 @@ select_insert::prepare(List &values, SELECT_LEX_UNIT *u) { LEX *lex= thd->lex; int res; + table_map map= 0; SELECT_LEX *lex_current_select_save= lex->current_select; DBUG_ENTER("select_insert::prepare"); @@ -2297,7 +2350,7 @@ select_insert::prepare(List &values, SELECT_LEX_UNIT *u) */ lex->current_select= &lex->select_lex; res= check_insert_fields(thd, table_list, *fields, values, - !insert_into_view) || + !insert_into_view, &map) || setup_fields(thd, 0, values, 0, 0, 0); if (info.handle_duplicates == DUP_UPDATE) @@ -2315,7 +2368,7 @@ select_insert::prepare(List &values, SELECT_LEX_UNIT *u) lex->select_lex.no_wrap_view_item= TRUE; res= res || check_update_fields(thd, context->table_list, - *info.update_fields); + *info.update_fields, &map); lex->select_lex.no_wrap_view_item= FALSE; /* When we are not using GROUP BY we can refer to other tables in the From 4e0760067a0dc994f3d3d4e2c6c6bd3e72a62324 Mon Sep 17 00:00:00 2001 From: "evgen@moonbone.local" <> Date: Mon, 22 Jan 2007 22:08:51 +0300 Subject: [PATCH 18/22] sql_prepare.cc: Post fix for bug#25123. --- sql/sql_prepare.cc | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/sql/sql_prepare.cc b/sql/sql_prepare.cc index e9f33a172c4..90442ef4c68 100644 --- a/sql/sql_prepare.cc +++ b/sql/sql_prepare.cc @@ -1676,7 +1676,7 @@ static bool check_prepared_statement(Prepared_statement *stmt, case SQLCOM_INSERT: res= mysql_test_insert(stmt, tables, lex->field_list, lex->many_values, - select_lex->item_list, lex->value_list, + lex->update_list, lex->value_list, lex->duplicates); break; From 884713fb08418ae819ba39a5429a3dd18586c423 Mon Sep 17 00:00:00 2001 From: "evgen@moonbone.local" <> Date: Mon, 22 Jan 2007 23:04:14 +0300 Subject: [PATCH 19/22] sql_select.cc: Code cleanup after fix for bug#23417. --- sql/sql_select.cc | 5 ++--- 1 file changed, 2 insertions(+), 3 deletions(-) diff --git a/sql/sql_select.cc b/sql/sql_select.cc index b03c4556279..7bced1719eb 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -8766,8 +8766,7 @@ Field *create_tmp_field(THD *thd, TABLE *table,Item *item, Item::Type type, if (type != Item::FIELD_ITEM && item->real_item()->type() == Item::FIELD_ITEM && - (item->type() != Item::REF_ITEM || - !((Item_ref *) item)->depended_from)) + !((Item_ref *) item)->depended_from) { orig_item= item; item= item->real_item(); @@ -13423,7 +13422,7 @@ count_field_types(TMP_TABLE_PARAM *param, List &fields, Item::Type type=field->type(); Item::Type real_type= field->real_item()->type(); if (type == Item::FIELD_ITEM || (real_type == Item::FIELD_ITEM && - (type != Item::REF_ITEM || !((Item_ref *) field)->depended_from))) + !((Item_ref *) field)->depended_from)) param->field_count++; else if (real_type == Item::SUM_FUNC_ITEM) { From 450e9b6b30a043ca7acaabc0d0447d326aa46362 Mon Sep 17 00:00:00 2001 From: "gkodinov/kgeorge@macbook.gmz" <> Date: Tue, 23 Jan 2007 19:45:58 +0200 Subject: [PATCH 20/22] Bug #6172: RAND(a) should only accept constant values as arguments RAND() must accept scalar expressions regardless of their kind. That includes both constant expressions and expressions that depend on column values. When the expression is constant the random seed can be initialized at compile time. However when the expression is not constant the random seed must be initialized at each invocation (while it still can be allocated at compile time). Implemented the above rules by extending Item_func_rand::val_real() to initialize the random seed at the correct place. --- mysql-test/r/func_math.result | 45 +++++++++++++++++++++++++++++++---- mysql-test/t/func_math.test | 24 +++++++++++++++---- sql/item_func.cc | 36 +++++++++++++--------------- sql/item_func.h | 2 ++ 4 files changed, 78 insertions(+), 29 deletions(-) diff --git a/mysql-test/r/func_math.result b/mysql-test/r/func_math.result index 9a2c55b802d..565c283ee83 100644 --- a/mysql-test/r/func_math.result +++ b/mysql-test/r/func_math.result @@ -177,11 +177,46 @@ drop table t1; select abs(-2) * -2; abs(-2) * -2 -4 -create table t1 (i int); -insert into t1 values (1); -select rand(i) from t1; -ERROR HY000: Incorrect arguments to RAND -drop table t1; +CREATE TABLE t1 (a INT); +INSERT INTO t1 VALUES (1),(1),(1),(2); +SELECT CAST(RAND(2) * 1000 AS UNSIGNED), CAST(RAND(a) * 1000 AS UNSIGNED) +FROM t1; +CAST(RAND(2) * 1000 AS UNSIGNED) CAST(RAND(a) * 1000 AS UNSIGNED) +656 405 +122 405 +645 405 +858 656 +SELECT CAST(RAND(2) * 1000 AS UNSIGNED), CAST(RAND(a) * 1000 AS UNSIGNED) +FROM t1 WHERE a = 1; +CAST(RAND(2) * 1000 AS UNSIGNED) CAST(RAND(a) * 1000 AS UNSIGNED) +656 405 +122 405 +645 405 +INSERT INTO t1 VALUES (3); +SELECT CAST(RAND(2) * 1000 AS UNSIGNED), CAST(RAND(a) * 1000 AS UNSIGNED) +FROM t1; +CAST(RAND(2) * 1000 AS UNSIGNED) CAST(RAND(a) * 1000 AS UNSIGNED) +656 405 +122 405 +645 405 +858 656 +354 906 +SELECT CAST(RAND(2) * 1000 AS UNSIGNED), CAST(RAND(a) * 1000 AS UNSIGNED) +FROM t1 WHERE a = 1; +CAST(RAND(2) * 1000 AS UNSIGNED) CAST(RAND(a) * 1000 AS UNSIGNED) +656 405 +122 405 +645 405 +PREPARE stmt FROM +"SELECT CAST(RAND(2) * 1000 AS UNSIGNED), CAST(RAND(?) * 1000 AS UNSIGNED) + FROM t1 WHERE a = 1"; +set @var=2; +EXECUTE stmt USING @var; +CAST(RAND(2) * 1000 AS UNSIGNED) CAST(RAND(?) * 1000 AS UNSIGNED) +656 656 +122 122 +645 645 +DROP TABLE t1; create table t1 (a varchar(90), ts datetime not null, index (a)) engine=innodb default charset=utf8; insert into t1 values ('http://www.foo.com/', now()); select a from t1 where a='http://www.foo.com/' order by abs(timediff(ts, 0)); diff --git a/mysql-test/t/func_math.test b/mysql-test/t/func_math.test index 09aa5751301..639ced6a1c0 100644 --- a/mysql-test/t/func_math.test +++ b/mysql-test/t/func_math.test @@ -115,11 +115,25 @@ select abs(-2) * -2; # # Bug #6172 RAND(a) should only accept constant values as arguments # -create table t1 (i int); -insert into t1 values (1); ---error 1210 -select rand(i) from t1; -drop table t1; +CREATE TABLE t1 (a INT); + +INSERT INTO t1 VALUES (1),(1),(1),(2); +SELECT CAST(RAND(2) * 1000 AS UNSIGNED), CAST(RAND(a) * 1000 AS UNSIGNED) + FROM t1; +SELECT CAST(RAND(2) * 1000 AS UNSIGNED), CAST(RAND(a) * 1000 AS UNSIGNED) + FROM t1 WHERE a = 1; +INSERT INTO t1 VALUES (3); +SELECT CAST(RAND(2) * 1000 AS UNSIGNED), CAST(RAND(a) * 1000 AS UNSIGNED) + FROM t1; +SELECT CAST(RAND(2) * 1000 AS UNSIGNED), CAST(RAND(a) * 1000 AS UNSIGNED) + FROM t1 WHERE a = 1; +PREPARE stmt FROM + "SELECT CAST(RAND(2) * 1000 AS UNSIGNED), CAST(RAND(?) * 1000 AS UNSIGNED) + FROM t1 WHERE a = 1"; +set @var=2; +EXECUTE stmt USING @var; + +DROP TABLE t1; # # Bug #14009: use of abs() on null value causes problems with filesort diff --git a/sql/item_func.cc b/sql/item_func.cc index 37778acd962..7dfd02c9887 100644 --- a/sql/item_func.cc +++ b/sql/item_func.cc @@ -2042,6 +2042,18 @@ my_decimal *Item_func_round::decimal_op(my_decimal *decimal_value) } +void Item_func_rand::seed_random(Item *arg) +{ + /* + TODO: do not do reinit 'rand' for every execute of PS/SP if + args[0] is a constant. + */ + uint32 tmp= (uint32) arg->val_int(); + randominit(rand, (uint32) (tmp*0x10001L+55555555L), + (uint32) (tmp*0x10000001L)); +} + + bool Item_func_rand::fix_fields(THD *thd,Item **ref) { if (Item_real_func::fix_fields(thd, ref)) @@ -2049,11 +2061,6 @@ bool Item_func_rand::fix_fields(THD *thd,Item **ref) used_tables_cache|= RAND_TABLE_BIT; if (arg_count) { // Only use argument once in query - if (!args[0]->const_during_execution()) - { - my_error(ER_WRONG_ARGUMENTS, MYF(0), "RAND"); - return TRUE; - } /* Allocate rand structure once: we must use thd->stmt_arena to create rand in proper mem_root if it's a prepared statement or @@ -2065,20 +2072,9 @@ bool Item_func_rand::fix_fields(THD *thd,Item **ref) if (!rand && !(rand= (struct rand_struct*) thd->stmt_arena->alloc(sizeof(*rand)))) return TRUE; - /* - PARAM_ITEM is returned if we're in statement prepare and consequently - no placeholder value is set yet. - */ - if (args[0]->type() != PARAM_ITEM) - { - /* - TODO: do not do reinit 'rand' for every execute of PS/SP if - args[0] is a constant. - */ - uint32 tmp= (uint32) args[0]->val_int(); - randominit(rand, (uint32) (tmp*0x10001L+55555555L), - (uint32) (tmp*0x10000001L)); - } + + if (args[0]->const_item()) + seed_random (args[0]); } else { @@ -2108,6 +2104,8 @@ void Item_func_rand::update_used_tables() double Item_func_rand::val_real() { DBUG_ASSERT(fixed == 1); + if (arg_count && !args[0]->const_item()) + seed_random (args[0]); return my_rnd(rand); } diff --git a/sql/item_func.h b/sql/item_func.h index 7810c0ce9a9..3306b059097 100644 --- a/sql/item_func.h +++ b/sql/item_func.h @@ -679,6 +679,8 @@ public: bool const_item() const { return 0; } void update_used_tables(); bool fix_fields(THD *thd, Item **ref); +private: + void seed_random (Item * val); }; From 8190cfca8512dbbf281a0ea90f5550133563f925 Mon Sep 17 00:00:00 2001 From: "holyfoot/hf@mysql.com/hfmain.(none)" <> Date: Wed, 24 Jan 2007 14:49:36 +0400 Subject: [PATCH 21/22] bug #22682 Test fails --without-geometry geometry dependent parts moved to proper .test files --- .bzrignore | 1 + mysql-test/r/gis.result | 11 +++++++++++ mysql-test/r/innodb.result | 2 -- mysql-test/r/innodb_gis.result | 2 ++ mysql-test/r/view.result | 11 ----------- mysql-test/t/gis.test | 10 ++++++++++ mysql-test/t/innodb.test | 6 ------ mysql-test/t/innodb_gis.test | 6 ++++++ mysql-test/t/view.test | 9 --------- 9 files changed, 30 insertions(+), 28 deletions(-) diff --git a/.bzrignore b/.bzrignore index 73cb4341beb..b1b337580dd 100644 --- a/.bzrignore +++ b/.bzrignore @@ -2933,3 +2933,4 @@ win/vs71cache.txt win/vs8cache.txt zlib/*.ds? zlib/*.vcproj +libmysqld/sql_servers.cc diff --git a/mysql-test/r/gis.result b/mysql-test/r/gis.result index b7f0e4b6b80..8cbc344f062 100644 --- a/mysql-test/r/gis.result +++ b/mysql-test/r/gis.result @@ -718,3 +718,14 @@ desc t1; Field Type Null Key Default Extra GeomFromText('point(1 1)') geometry NO drop table t1; +create table t1 (f1 tinyint(1), f2 char(1), f3 varchar(1), f4 geometry, f5 datetime); +create view v1 as select * from t1; +desc v1; +Field Type Null Key Default Extra +f1 tinyint(1) YES NULL +f2 char(1) YES NULL +f3 varchar(1) YES NULL +f4 geometry YES NULL +f5 datetime YES NULL +drop view v1; +drop table t1; diff --git a/mysql-test/r/innodb.result b/mysql-test/r/innodb.result index e7fa950a131..9032ea00e11 100644 --- a/mysql-test/r/innodb.result +++ b/mysql-test/r/innodb.result @@ -3447,8 +3447,6 @@ SELECT p0.a FROM t2 p0 WHERE BINARY p0.b = 'customer_over'; a 1 drop table t2, t1; -create table t1 (g geometry not null, spatial gk(g)) engine=innodb; -ERROR HY000: The used table type doesn't support SPATIAL indexes CREATE TABLE t1 ( a int ) ENGINE=innodb; BEGIN; INSERT INTO t1 VALUES (1); diff --git a/mysql-test/r/innodb_gis.result b/mysql-test/r/innodb_gis.result index 09f0aebaefa..e714dbeffc0 100644 --- a/mysql-test/r/innodb_gis.result +++ b/mysql-test/r/innodb_gis.result @@ -460,3 +460,5 @@ ERROR 22003: Cannot get geometry object from data you send to the GEOMETRY field insert into t1 (fl) values (pointfromtext('point(1,1)')); ERROR 22003: Cannot get geometry object from data you send to the GEOMETRY field drop table t1; +create table t1 (g geometry not null, spatial gk(g)) engine=innodb; +ERROR HY000: The used table type doesn't support SPATIAL indexes diff --git a/mysql-test/r/view.result b/mysql-test/r/view.result index 4fbe0176c57..838df85594b 100644 --- a/mysql-test/r/view.result +++ b/mysql-test/r/view.result @@ -2060,17 +2060,6 @@ CALL p1(); DROP PROCEDURE p1; DROP VIEW v1; DROP TABLE t1; -create table t1 (f1 tinyint(1), f2 char(1), f3 varchar(1), f4 geometry, f5 datetime); -create view v1 as select * from t1; -desc v1; -Field Type Null Key Default Extra -f1 tinyint(1) YES NULL -f2 char(1) YES NULL -f3 varchar(1) YES NULL -f4 geometry YES NULL -f5 datetime YES NULL -drop view v1; -drop table t1; create table t1(f1 datetime); insert into t1 values('2005.01.01 12:0:0'); create view v1 as select f1, subtime(f1, '1:1:1') as sb from t1; diff --git a/mysql-test/t/gis.test b/mysql-test/t/gis.test index 196ff5b8ff0..d1ea8dbe18f 100644 --- a/mysql-test/t/gis.test +++ b/mysql-test/t/gis.test @@ -428,3 +428,13 @@ drop table t1; create table t1 select GeomFromText('point(1 1)'); desc t1; drop table t1; + +# +# Bug #11335 View redefines column types +# +create table t1 (f1 tinyint(1), f2 char(1), f3 varchar(1), f4 geometry, f5 datetime); +create view v1 as select * from t1; +desc v1; +drop view v1; +drop table t1; + diff --git a/mysql-test/t/innodb.test b/mysql-test/t/innodb.test index e1e74ac8a11..bbecd787324 100644 --- a/mysql-test/t/innodb.test +++ b/mysql-test/t/innodb.test @@ -2488,12 +2488,6 @@ SELECT p0.a FROM t2 p0 WHERE BINARY p0.b = 'customer_over'; drop table t2, t1; -# -# Bug #15680 (SPATIAL key in innodb) -# ---error ER_TABLE_CANT_HANDLE_SPKEYS -create table t1 (g geometry not null, spatial gk(g)) engine=innodb; - # # Test optimize on table with open transaction # diff --git a/mysql-test/t/innodb_gis.test b/mysql-test/t/innodb_gis.test index 142b526af92..9675b6b69dc 100644 --- a/mysql-test/t/innodb_gis.test +++ b/mysql-test/t/innodb_gis.test @@ -1,3 +1,9 @@ --source include/have_innodb.inc SET storage_engine=innodb; --source include/gis_generic.inc + +# +# Bug #15680 (SPATIAL key in innodb) +# +--error ER_TABLE_CANT_HANDLE_SPKEYS +create table t1 (g geometry not null, spatial gk(g)) engine=innodb; diff --git a/mysql-test/t/view.test b/mysql-test/t/view.test index 7175db1db4e..ad73a39dc54 100644 --- a/mysql-test/t/view.test +++ b/mysql-test/t/view.test @@ -1878,15 +1878,6 @@ DROP PROCEDURE p1; DROP VIEW v1; DROP TABLE t1; -# -# Bug #11335 View redefines column types -# -create table t1 (f1 tinyint(1), f2 char(1), f3 varchar(1), f4 geometry, f5 datetime); -create view v1 as select * from t1; -desc v1; -drop view v1; -drop table t1; - # # Bug #11760 Typo in Item_func_add_time::print() results in NULLs returned # subtime() in view From 13238b0e3d2c8c1362c3f8a18c62e8913e7926e6 Mon Sep 17 00:00:00 2001 From: "gkodinov/kgeorge@macbook.gmz" <> Date: Wed, 24 Jan 2007 15:55:16 +0200 Subject: [PATCH 22/22] merge of 5.0-opt -> 5.1-opt --- mysql-test/r/func_in.result | 49 ++----------------------- mysql-test/r/func_str.result | 12 +++---- mysql-test/r/range.result | 2 +- mysql-test/r/view.result | 54 ++++++++++++++++++++++------ mysql-test/t/func_in.test | 70 ++++++++++++++++++------------------ sql/item_strfunc.cc | 13 ------- sql/item_strfunc.h | 4 --- 7 files changed, 90 insertions(+), 114 deletions(-) diff --git a/mysql-test/r/func_in.result b/mysql-test/r/func_in.result index 0069146bfe3..9b09cc0a43c 100644 --- a/mysql-test/r/func_in.result +++ b/mysql-test/r/func_in.result @@ -351,49 +351,6 @@ some_id 1 2 drop table t1; -CREATE TABLE t1 (a int, b int, PRIMARY KEY (a)); -INSERT INTO t1 VALUES (1,1),(2,1),(3,1),(4,1),(5,1),(6,1); -CREATE TABLE t2 (a int, b int, PRIMARY KEY (a)); -INSERT INTO t2 VALUES (3,2),(4,2); -CREATE TABLE t3 (a int PRIMARY KEY); -INSERT INTO t3 VALUES (1),(2),(3),(4); -CREATE TABLE t4 (a int PRIMARY KEY); -INSERT INTO t4 VALUES (1),(2); -EXPLAIN SELECT STRAIGHT_JOIN * FROM t3 -JOIN t1 ON t3.a=t1.a -JOIN t2 ON t3.a=t2.a -JOIN t4 WHERE t4.a IN (t1.b, t2.b); -id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t3 index PRIMARY PRIMARY 4 NULL 4 Using index -1 SIMPLE t1 eq_ref PRIMARY PRIMARY 4 test.t3.a 1 -1 SIMPLE t2 eq_ref PRIMARY PRIMARY 4 test.t3.a 1 -1 SIMPLE t4 ALL PRIMARY NULL NULL NULL 2 Range checked for each record (index map: 0x1) -SELECT STRAIGHT_JOIN * FROM t3 -JOIN t1 ON t3.a=t1.a -JOIN t2 ON t3.a=t2.a -JOIN t4 WHERE t4.a IN (t1.b, t2.b); -a a b a b a -3 3 1 3 2 1 -3 3 1 3 2 2 -4 4 1 4 2 1 -4 4 1 4 2 2 -EXPLAIN SELECT STRAIGHT_JOIN -(SELECT SUM(t4.a) FROM t4 WHERE t4.a IN (t1.b, t2.b)) -FROM t3, t1, t2 -WHERE t3.a=t1.a AND t3.a=t2.a; -id select_type table type possible_keys key key_len ref rows Extra -1 PRIMARY t3 index PRIMARY PRIMARY 4 NULL 4 Using index -1 PRIMARY t1 eq_ref PRIMARY PRIMARY 4 test.t3.a 1 -1 PRIMARY t2 eq_ref PRIMARY PRIMARY 4 test.t3.a 1 -2 DEPENDENT SUBQUERY t4 index NULL PRIMARY 4 NULL 2 Using where; Using index -SELECT STRAIGHT_JOIN -(SELECT SUM(t4.a) FROM t4 WHERE t4.a IN (t1.b, t2.b)) -FROM t3, t1, t2 -WHERE t3.a=t1.a AND t3.a=t2.a; -(SELECT SUM(t4.a) FROM t4 WHERE t4.a IN (t1.b, t2.b)) -3 -3 -DROP TABLE t1,t2,t3,t4; End of 5.0 tests create table t1(f1 char(1)); insert into t1 values ('a'),('b'),('1'); @@ -419,7 +376,7 @@ Warnings: Warning 1292 Truncated incorrect DOUBLE value: 'b' explain select f1 from t1 where f1 in ('a',1); id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 index NULL t1f1_idx 2 NULL 3 Using where; Using index +1 SIMPLE t1 index t1f1_idx t1f1_idx 2 NULL 3 Using where; Using index select f1 from t1 where f1 in ('a','b'); f1 a @@ -448,7 +405,7 @@ Warning 1292 Truncated incorrect DOUBLE value: 'a' Warning 1292 Truncated incorrect DOUBLE value: 'a' explain select f2 from t2 where f2 in ('a',2); id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t2 index NULL t2f2 5 NULL 3 Using where; Using index +1 SIMPLE t2 index t2f2 t2f2 5 NULL 3 Using where; Using index select f2 from t2 where f2 in ('a','b'); f2 0 @@ -470,6 +427,6 @@ Warning 1292 Truncated incorrect DOUBLE value: 'b' Warning 1292 Truncated incorrect DOUBLE value: 'b' explain select f2 from t2 where f2 in (1,'b'); id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t2 index NULL t2f2 5 NULL 3 Using where; Using index +1 SIMPLE t2 index t2f2 t2f2 5 NULL 3 Using where; Using index drop table t1, t2; End of 5.1 tests diff --git a/mysql-test/r/func_str.result b/mysql-test/r/func_str.result index fea7464f854..e6c323276ea 100644 --- a/mysql-test/r/func_str.result +++ b/mysql-test/r/func_str.result @@ -1306,15 +1306,15 @@ Note 1003 select `test`.`t1`.`s` AS `s` from `test`.`t1` where (trim(both _latin DROP TABLE t1; create table t1(f1 varchar(4)); explain extended select encode(f1,'zxcv') as 'enc' from t1; -id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 system NULL NULL NULL NULL 0 const row not found +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 system NULL NULL NULL NULL 0 0.00 const row not found Warnings: -Note 1003 select encode(`test`.`t1`.`f1`,'zxcv') AS `enc` from `test`.`t1` +Note 1003 select encode(`test`.`t1`.`f1`,_latin1'zxcv') AS `enc` from `test`.`t1` explain extended select decode(f1,'zxcv') as 'enc' from t1; -id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 system NULL NULL NULL NULL 0 const row not found +id select_type table type possible_keys key key_len ref rows filtered Extra +1 SIMPLE t1 system NULL NULL NULL NULL 0 0.00 const row not found Warnings: -Note 1003 select decode(`test`.`t1`.`f1`,'zxcv') AS `enc` from `test`.`t1` +Note 1003 select decode(`test`.`t1`.`f1`,_latin1'zxcv') AS `enc` from `test`.`t1` drop table t1; End of 4.1 tests create table t1 (d decimal default null); diff --git a/mysql-test/r/range.result b/mysql-test/r/range.result index c94efb50bfe..1023287572d 100644 --- a/mysql-test/r/range.result +++ b/mysql-test/r/range.result @@ -705,7 +705,7 @@ v.oxrootid ='d8c4177d09f8b11f5.52725521' AND s.oxleft > v.oxleft AND s.oxleft < v.oxright; id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE v ref OXLEFT,OXRIGHT,OXROOTID OXROOTID 34 const 5 Using where -1 SIMPLE s ALL OXLEFT NULL NULL NULL 5 Range checked for each record (index map: 0x4) +1 SIMPLE s ALL OXLEFT NULL NULL NULL 6 Range checked for each record (index map: 0x4) SELECT s.oxid FROM t1 v, t1 s WHERE s.oxrootid = 'd8c4177d09f8b11f5.52725521' AND v.oxrootid ='d8c4177d09f8b11f5.52725521' AND diff --git a/mysql-test/r/view.result b/mysql-test/r/view.result index 77d9d8c8973..86765efc42f 100644 --- a/mysql-test/r/view.result +++ b/mysql-test/r/view.result @@ -2970,16 +2970,6 @@ UPDATE t1 SET i= f1(); DROP FUNCTION f1; DROP VIEW v1; DROP TABLE t1; -CREATE TABLE t1(id INT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, val INT UNSIGNED NOT NULL); -CREATE VIEW v1 AS SELECT id, val FROM t1 WHERE val >= 1 AND val <= 5 WITH CHECK OPTION; -INSERT INTO v1 (val) VALUES (2); -INSERT INTO v1 (val) VALUES (4); -INSERT INTO v1 (val) VALUES (6); -ERROR HY000: CHECK OPTION failed 'test.v1' -UPDATE v1 SET val=6 WHERE id=2; -ERROR HY000: CHECK OPTION failed 'test.v1' -DROP VIEW v1; -DROP TABLE t1; DROP VIEW IF EXISTS v1, v2; DROP TABLE IF EXISTS t1; CREATE TABLE t1 (i INT AUTO_INCREMENT PRIMARY KEY, j INT); @@ -3026,6 +3016,50 @@ x 5 DROP VIEW v; End of 5.0 tests. +CREATE TABLE t1(id INT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY, val INT UNSIGNED NOT NULL); +CREATE VIEW v1 AS SELECT id, val FROM t1 WHERE val >= 1 AND val <= 5 WITH CHECK OPTION; +INSERT INTO v1 (val) VALUES (2); +INSERT INTO v1 (val) VALUES (4); +INSERT INTO v1 (val) VALUES (6); +ERROR HY000: CHECK OPTION failed 'test.v1' +UPDATE v1 SET val=6 WHERE id=2; +ERROR HY000: CHECK OPTION failed 'test.v1' +DROP VIEW v1; +DROP TABLE t1; +DROP VIEW IF EXISTS v1, v2; +DROP TABLE IF EXISTS t1; +CREATE TABLE t1 (i INT AUTO_INCREMENT PRIMARY KEY, j INT); +CREATE VIEW v1 AS SELECT j FROM t1; +CREATE VIEW v2 AS SELECT * FROM t1; +INSERT INTO t1 (j) VALUES (1); +SELECT LAST_INSERT_ID(); +LAST_INSERT_ID() +1 +INSERT INTO v1 (j) VALUES (2); +# LAST_INSERT_ID() should not change. +SELECT LAST_INSERT_ID(); +LAST_INSERT_ID() +1 +INSERT INTO v2 (j) VALUES (3); +# LAST_INSERT_ID() should be updated. +SELECT LAST_INSERT_ID(); +LAST_INSERT_ID() +3 +INSERT INTO v1 (j) SELECT j FROM t1; +# LAST_INSERT_ID() should not change. +SELECT LAST_INSERT_ID(); +LAST_INSERT_ID() +3 +SELECT * FROM t1; +i j +1 1 +2 2 +3 3 +4 1 +5 2 +6 3 +DROP VIEW v1, v2; +DROP TABLE t1; DROP DATABASE IF EXISTS `d-1`; CREATE DATABASE `d-1`; USE `d-1`; diff --git a/mysql-test/t/func_in.test b/mysql-test/t/func_in.test index db730cf1828..2a2d5535915 100644 --- a/mysql-test/t/func_in.test +++ b/mysql-test/t/func_in.test @@ -254,42 +254,44 @@ select some_id from t1 where some_id not in(-4,-1,-4); select some_id from t1 where some_id not in(-4,-1,3423534,2342342); drop table t1; +# TODO:Disabled until re-resolution of bug #20420 for 5.1. +# Results must be the same as in 5.0 +## +## BUG#20420: optimizer reports wrong keys on left join with IN +## +#CREATE TABLE t1 (a int, b int, PRIMARY KEY (a)); +#INSERT INTO t1 VALUES (1,1),(2,1),(3,1),(4,1),(5,1),(6,1); # -# BUG#20420: optimizer reports wrong keys on left join with IN +#CREATE TABLE t2 (a int, b int, PRIMARY KEY (a)); +#INSERT INTO t2 VALUES (3,2),(4,2),(100,100),(101,201),(102,102); # -CREATE TABLE t1 (a int, b int, PRIMARY KEY (a)); -INSERT INTO t1 VALUES (1,1),(2,1),(3,1),(4,1),(5,1),(6,1); - -CREATE TABLE t2 (a int, b int, PRIMARY KEY (a)); -INSERT INTO t2 VALUES (3,2),(4,2); - -CREATE TABLE t3 (a int PRIMARY KEY); -INSERT INTO t3 VALUES (1),(2),(3),(4); - -CREATE TABLE t4 (a int PRIMARY KEY); -INSERT INTO t4 VALUES (1),(2); - -EXPLAIN SELECT STRAIGHT_JOIN * FROM t3 - JOIN t1 ON t3.a=t1.a - JOIN t2 ON t3.a=t2.a - JOIN t4 WHERE t4.a IN (t1.b, t2.b); - -SELECT STRAIGHT_JOIN * FROM t3 - JOIN t1 ON t3.a=t1.a - JOIN t2 ON t3.a=t2.a - JOIN t4 WHERE t4.a IN (t1.b, t2.b); - -EXPLAIN SELECT STRAIGHT_JOIN - (SELECT SUM(t4.a) FROM t4 WHERE t4.a IN (t1.b, t2.b)) - FROM t3, t1, t2 - WHERE t3.a=t1.a AND t3.a=t2.a; - -SELECT STRAIGHT_JOIN - (SELECT SUM(t4.a) FROM t4 WHERE t4.a IN (t1.b, t2.b)) - FROM t3, t1, t2 - WHERE t3.a=t1.a AND t3.a=t2.a; - -DROP TABLE t1,t2,t3,t4; +#CREATE TABLE t3 (a int PRIMARY KEY); +#INSERT INTO t3 VALUES (1),(2),(3),(4); +# +#CREATE TABLE t4 (a int PRIMARY KEY,b int); +#INSERT INTO t4 VALUES (1,1),(2,2),(1000,1000),(1001,1001),(1002,1002),(1003,1003),(1004,1004); +# +#EXPLAIN SELECT STRAIGHT_JOIN * FROM t3 +# JOIN t1 ON t3.a=t1.a +# JOIN t2 ON t3.a=t2.a +# JOIN t4 WHERE t4.a IN (t1.b, t2.b); +# +#SELECT STRAIGHT_JOIN * FROM t3 +# JOIN t1 ON t3.a=t1.a +# JOIN t2 ON t3.a=t2.a +# JOIN t4 WHERE t4.a IN (t1.b, t2.b); +# +#EXPLAIN SELECT STRAIGHT_JOIN +# (SELECT SUM(t4.a) FROM t4 WHERE t4.a IN (t1.b, t2.b)) +# FROM t3, t1, t2 +# WHERE t3.a=t1.a AND t3.a=t2.a; +# +#SELECT STRAIGHT_JOIN +# (SELECT SUM(t4.a) FROM t4 WHERE t4.a IN (t1.b, t2.b)) +# FROM t3, t1, t2 +# WHERE t3.a=t1.a AND t3.a=t2.a; +# +#DROP TABLE t1,t2,t3,t4; --echo End of 5.0 tests diff --git a/sql/item_strfunc.cc b/sql/item_strfunc.cc index 76c3c1da11e..89a85a19f56 100644 --- a/sql/item_strfunc.cc +++ b/sql/item_strfunc.cc @@ -1706,19 +1706,6 @@ String *Item_func_encode::val_str(String *str) return res; } -void Item_func_encode::print(String *str) -{ - str->append(func_name()); - str->append('('); - args[0]->print(str); - str->append(','); - str->append('\''); - str->append(seed); - str->append('\''); - str->append(')'); -} - - String *Item_func_decode::val_str(String *str) { String *res; diff --git a/sql/item_strfunc.h b/sql/item_strfunc.h index 1d4020a0fc8..ae11e001551 100644 --- a/sql/item_strfunc.h +++ b/sql/item_strfunc.h @@ -360,16 +360,12 @@ public: class Item_func_encode :public Item_str_func { - protected: - SQL_CRYPT sql_crypt; - String seed; public: Item_func_encode(Item *a, Item *seed): Item_str_func(a, seed) {} String *val_str(String *); void fix_length_and_dec(); const char *func_name() const { return "encode"; } - void print(String *str); };