From 174dcb07abc4d91eabd185ee896ec29416fad83a Mon Sep 17 00:00:00 2001 From: "gkodinov/kgeorge@magare.gmz" <> Date: Fri, 20 Jul 2007 14:17:15 +0300 Subject: [PATCH 1/6] Bug #29644: alter table hangs if records locked in share mode by long running transaction On Windows opened files can't be deleted. There was a special upgraded lock mode (TL_WRITE instead of TL_WRITE_ALLOW_READ) in ALTER TABLE to make sure nobody has the table opened when deleting the old table in ALTER TABLE. This special mode was causing ALTER TABLE to hang waiting on a lock inside InnoDB. This special lock is no longer necessary as the server is closing the tables it needs to delete in ALTER TABLE. Fixed by removing the special lock. Note that this also reverses the fix for bug 17264 that deals with another consequence of this special lock mode being used. --- mysql-test/r/innodb_mysql.result | 23 ++++++++++++++ mysql-test/t/innodb_mysql.test | 51 ++++++++++++++++++++++++++++++++ sql/ha_innodb.cc | 11 ------- sql/sql_base.cc | 7 ----- 4 files changed, 74 insertions(+), 18 deletions(-) diff --git a/mysql-test/r/innodb_mysql.result b/mysql-test/r/innodb_mysql.result index 4535710c905..1cb9563216b 100644 --- a/mysql-test/r/innodb_mysql.result +++ b/mysql-test/r/innodb_mysql.result @@ -735,4 +735,27 @@ COUNT(*) 3072 set @@sort_buffer_size=default; DROP TABLE t1,t2; +CREATE TABLE t1 (a INT, PRIMARY KEY (a)) ENGINE=InnoDB; +INSERT INTO t1 VALUES (1),(2),(3),(4),(5),(6),(7),(8); +INSERT INTO t1 SELECT a + 8 FROM t1; +INSERT INTO t1 SELECT a + 16 FROM t1; +CREATE PROCEDURE p1 () +BEGIN +DECLARE i INT DEFAULT 50; +DECLARE cnt INT; +START TRANSACTION; +ALTER TABLE t1 ENGINE=InnoDB; +COMMIT; +START TRANSACTION; +WHILE (i > 0) DO +SET i = i - 1; +SELECT COUNT(*) INTO cnt FROM t1 LOCK IN SHARE MODE; +END WHILE; +COMMIT; +END;| +CALL p1(); +CALL p1(); +CALL p1(); +DROP PROCEDURE p1; +DROP TABLE t1; End of 5.0 tests diff --git a/mysql-test/t/innodb_mysql.test b/mysql-test/t/innodb_mysql.test index d4ce997ddb1..a8724d2e7d5 100644 --- a/mysql-test/t/innodb_mysql.test +++ b/mysql-test/t/innodb_mysql.test @@ -741,4 +741,55 @@ set @@sort_buffer_size=default; DROP TABLE t1,t2; +# +# Bug #29644: alter table hangs if records locked in share mode by long +# running transaction +# + +CREATE TABLE t1 (a INT, PRIMARY KEY (a)) ENGINE=InnoDB; + +INSERT INTO t1 VALUES (1),(2),(3),(4),(5),(6),(7),(8); +INSERT INTO t1 SELECT a + 8 FROM t1; +INSERT INTO t1 SELECT a + 16 FROM t1; + +DELIMITER |; +CREATE PROCEDURE p1 () +BEGIN + DECLARE i INT DEFAULT 50; + DECLARE cnt INT; + START TRANSACTION; + ALTER TABLE t1 ENGINE=InnoDB; + COMMIT; + START TRANSACTION; + WHILE (i > 0) DO + SET i = i - 1; + SELECT COUNT(*) INTO cnt FROM t1 LOCK IN SHARE MODE; + END WHILE; + COMMIT; +END;| + +DELIMITER ;| + +CONNECT (con1,localhost,root,,); +CONNECT (con2,localhost,root,,); + +CONNECTION con1; +SEND CALL p1(); +CONNECTION con2; +SEND CALL p1(); +CONNECTION default; +CALL p1(); + +CONNECTION con1; +REAP; +CONNECTION con2; +REAP; +CONNECTION default; +DISCONNECT con1; +DISCONNECT con2; + +DROP PROCEDURE p1; +DROP TABLE t1; + + --echo End of 5.0 tests diff --git a/sql/ha_innodb.cc b/sql/ha_innodb.cc index a3676bd7e1b..0177829614d 100644 --- a/sql/ha_innodb.cc +++ b/sql/ha_innodb.cc @@ -6702,17 +6702,6 @@ ha_innobase::store_lock( && !thd->tablespace_op && thd->lex->sql_command != SQLCOM_TRUNCATE && thd->lex->sql_command != SQLCOM_OPTIMIZE - -#ifdef __WIN__ - /* For alter table on win32 for succesful operation - completion it is used TL_WRITE(=10) lock instead of - TL_WRITE_ALLOW_READ(=6), however here in innodb handler - TL_WRITE is lifted to TL_WRITE_ALLOW_WRITE, which causes - race condition when several clients do alter table - simultaneously (bug #17264). This fix avoids the problem. */ - && thd->lex->sql_command != SQLCOM_ALTER_TABLE -#endif - && thd->lex->sql_command != SQLCOM_CREATE_TABLE) { lock_type = TL_WRITE_ALLOW_WRITE; diff --git a/sql/sql_base.cc b/sql/sql_base.cc index ed006714143..e633b548a08 100644 --- a/sql/sql_base.cc +++ b/sql/sql_base.cc @@ -2938,13 +2938,6 @@ TABLE *open_ltable(THD *thd, TABLE_LIST *table_list, thr_lock_type lock_type) if (table) { -#if defined( __WIN__) || defined(OS2) - /* Win32 can't drop a file that is open */ - if (lock_type == TL_WRITE_ALLOW_READ) - { - lock_type= TL_WRITE; - } -#endif /* __WIN__ || OS2 */ table_list->lock_type= lock_type; table_list->table= table; table->grant= table_list->grant; From 8fc401e21fc3560a1c50fe24504d713e49e72e2d Mon Sep 17 00:00:00 2001 From: "gkodinov/kgeorge@magare.gmz" <> Date: Fri, 20 Jul 2007 21:05:29 +0300 Subject: [PATCH 2/6] Bug #28591: MySQL need not sort the records in case of ORDER BY primary_key on InnoDB table Queries that use an InnoDB secondary index to retrieve data don't need to sort in case of ORDER BY primary key if the secondary index is compared to constant(s). They can also skip sorting if ORDER BY contains both the the secondary key parts and the primary key parts (in that order). This is because InnoDB returns the rows in order of the primary key for rows with the same values of the secondary key columns. Fixed by preventing temp table sort for the qualifying queries. --- mysql-test/r/innodb_mysql.result | 245 +++++++++++++++++++++++++++++++ mysql-test/t/innodb_mysql.test | 33 +++++ sql/sql_select.cc | 29 +++- sql/table.cc | 4 + 4 files changed, 309 insertions(+), 2 deletions(-) diff --git a/mysql-test/r/innodb_mysql.result b/mysql-test/r/innodb_mysql.result index 4535710c905..28f53a628ee 100644 --- a/mysql-test/r/innodb_mysql.result +++ b/mysql-test/r/innodb_mysql.result @@ -735,4 +735,249 @@ COUNT(*) 3072 set @@sort_buffer_size=default; DROP TABLE t1,t2; +CREATE TABLE t1 (a int, b int, PRIMARY KEY (a), KEY bkey (b)) ENGINE=InnoDB; +INSERT INTO t1 VALUES (1,2),(3,2),(2,2),(4,2),(5,2),(6,2),(7,2),(8,2); +INSERT INTO t1 SELECT a + 8, 2 FROM t1; +INSERT INTO t1 SELECT a + 16, 1 FROM t1; +EXPLAIN SELECT * FROM t1 WHERE b=2 ORDER BY a; +id 1 +select_type SIMPLE +table t1 +type ref +possible_keys bkey +key bkey +key_len 5 +ref const +rows 16 +Extra Using where; Using index +SELECT * FROM t1 WHERE b=2 ORDER BY a; +a b +1 2 +2 2 +3 2 +4 2 +5 2 +6 2 +7 2 +8 2 +9 2 +10 2 +11 2 +12 2 +13 2 +14 2 +15 2 +16 2 +EXPLAIN SELECT * FROM t1 WHERE b BETWEEN 1 AND 2 ORDER BY a; +id 1 +select_type SIMPLE +table t1 +type range +possible_keys bkey +key bkey +key_len 5 +ref NULL +rows 16 +Extra Using where; Using index; Using filesort +SELECT * FROM t1 WHERE b BETWEEN 1 AND 2 ORDER BY a; +a b +1 2 +2 2 +3 2 +4 2 +5 2 +6 2 +7 2 +8 2 +9 2 +10 2 +11 2 +12 2 +13 2 +14 2 +15 2 +16 2 +17 1 +18 1 +19 1 +20 1 +21 1 +22 1 +23 1 +24 1 +25 1 +26 1 +27 1 +28 1 +29 1 +30 1 +31 1 +32 1 +EXPLAIN SELECT * FROM t1 WHERE b BETWEEN 1 AND 2 ORDER BY b,a; +id 1 +select_type SIMPLE +table t1 +type range +possible_keys bkey +key bkey +key_len 5 +ref NULL +rows 16 +Extra Using where; Using index +SELECT * FROM t1 WHERE b BETWEEN 1 AND 2 ORDER BY b,a; +a b +17 1 +18 1 +19 1 +20 1 +21 1 +22 1 +23 1 +24 1 +25 1 +26 1 +27 1 +28 1 +29 1 +30 1 +31 1 +32 1 +1 2 +2 2 +3 2 +4 2 +5 2 +6 2 +7 2 +8 2 +9 2 +10 2 +11 2 +12 2 +13 2 +14 2 +15 2 +16 2 +CREATE TABLE t2 (a int, b int, c int, PRIMARY KEY (a), KEY bkey (b,c)) +ENGINE=InnoDB; +INSERT INTO t2 VALUES (1,1,1),(3,1,1),(2,1,1),(4,1,1); +INSERT INTO t2 SELECT a + 4, 1, 1 FROM t2; +INSERT INTO t2 SELECT a + 8, 1, 1 FROM t2; +EXPLAIN SELECT * FROM t2 WHERE b=1 ORDER BY a; +id 1 +select_type SIMPLE +table t2 +type ref +possible_keys bkey +key bkey +key_len 5 +ref const +rows 8 +Extra Using where; Using index; Using filesort +SELECT * FROM t2 WHERE b=1 ORDER BY a; +a b c +1 1 1 +2 1 1 +3 1 1 +4 1 1 +5 1 1 +6 1 1 +7 1 1 +8 1 1 +9 1 1 +10 1 1 +11 1 1 +12 1 1 +13 1 1 +14 1 1 +15 1 1 +16 1 1 +EXPLAIN SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY a; +id 1 +select_type SIMPLE +table t2 +type ref +possible_keys bkey +key bkey +key_len 10 +ref const,const +rows 8 +Extra Using where; Using index +SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY a; +a b c +1 1 1 +2 1 1 +3 1 1 +4 1 1 +5 1 1 +6 1 1 +7 1 1 +8 1 1 +9 1 1 +10 1 1 +11 1 1 +12 1 1 +13 1 1 +14 1 1 +15 1 1 +16 1 1 +EXPLAIN SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY b,c,a; +id 1 +select_type SIMPLE +table t2 +type ref +possible_keys bkey +key bkey +key_len 10 +ref const,const +rows 8 +Extra Using where; Using index +SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY b,c,a; +a b c +1 1 1 +2 1 1 +3 1 1 +4 1 1 +5 1 1 +6 1 1 +7 1 1 +8 1 1 +9 1 1 +10 1 1 +11 1 1 +12 1 1 +13 1 1 +14 1 1 +15 1 1 +16 1 1 +EXPLAIN SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY c,a; +id 1 +select_type SIMPLE +table t2 +type ref +possible_keys bkey +key bkey +key_len 10 +ref const,const +rows 8 +Extra Using where; Using index +SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY c,a; +a b c +1 1 1 +2 1 1 +3 1 1 +4 1 1 +5 1 1 +6 1 1 +7 1 1 +8 1 1 +9 1 1 +10 1 1 +11 1 1 +12 1 1 +13 1 1 +14 1 1 +15 1 1 +16 1 1 +DROP TABLE t1,t2; End of 5.0 tests diff --git a/mysql-test/t/innodb_mysql.test b/mysql-test/t/innodb_mysql.test index d4ce997ddb1..9a44c673548 100644 --- a/mysql-test/t/innodb_mysql.test +++ b/mysql-test/t/innodb_mysql.test @@ -741,4 +741,37 @@ set @@sort_buffer_size=default; DROP TABLE t1,t2; +# +# Bug #28591: MySQL need not sort the records in case of ORDER BY +# primary_key on InnoDB table +# + +CREATE TABLE t1 (a int, b int, PRIMARY KEY (a), KEY bkey (b)) ENGINE=InnoDB; +INSERT INTO t1 VALUES (1,2),(3,2),(2,2),(4,2),(5,2),(6,2),(7,2),(8,2); +INSERT INTO t1 SELECT a + 8, 2 FROM t1; +INSERT INTO t1 SELECT a + 16, 1 FROM t1; +query_vertical EXPLAIN SELECT * FROM t1 WHERE b=2 ORDER BY a; +SELECT * FROM t1 WHERE b=2 ORDER BY a; +query_vertical EXPLAIN SELECT * FROM t1 WHERE b BETWEEN 1 AND 2 ORDER BY a; +SELECT * FROM t1 WHERE b BETWEEN 1 AND 2 ORDER BY a; +query_vertical EXPLAIN SELECT * FROM t1 WHERE b BETWEEN 1 AND 2 ORDER BY b,a; +SELECT * FROM t1 WHERE b BETWEEN 1 AND 2 ORDER BY b,a; + +CREATE TABLE t2 (a int, b int, c int, PRIMARY KEY (a), KEY bkey (b,c)) + ENGINE=InnoDB; +INSERT INTO t2 VALUES (1,1,1),(3,1,1),(2,1,1),(4,1,1); +INSERT INTO t2 SELECT a + 4, 1, 1 FROM t2; +INSERT INTO t2 SELECT a + 8, 1, 1 FROM t2; + +query_vertical EXPLAIN SELECT * FROM t2 WHERE b=1 ORDER BY a; +SELECT * FROM t2 WHERE b=1 ORDER BY a; +query_vertical EXPLAIN SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY a; +SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY a; +query_vertical EXPLAIN SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY b,c,a; +SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY b,c,a; +query_vertical EXPLAIN SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY c,a; +SELECT * FROM t2 WHERE b=1 AND c=1 ORDER BY c,a; + +DROP TABLE t1,t2; + --echo End of 5.0 tests diff --git a/sql/sql_select.cc b/sql/sql_select.cc index c62a19b2752..c77fb341232 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -12009,6 +12009,7 @@ static int test_if_order_by_key(ORDER *order, TABLE *table, uint idx, key_part_end=key_part+table->key_info[idx].key_parts; key_part_map const_key_parts=table->const_key_parts[idx]; int reverse=0; + my_bool on_primary_key= FALSE; DBUG_ENTER("test_if_order_by_key"); for (; order ; order=order->next, const_key_parts>>=1) @@ -12023,7 +12024,30 @@ static int test_if_order_by_key(ORDER *order, TABLE *table, uint idx, for (; const_key_parts & 1 ; const_key_parts>>= 1) key_part++; - if (key_part == key_part_end || key_part->field != field) + if (key_part == key_part_end) + { + /* + We are at the end of the key. Check if the engine has the primary + key as a suffix to the secondary keys. If it has continue to check + the primary key as a suffix. + */ + if (!on_primary_key && + (table->file->table_flags() & HA_PRIMARY_KEY_IN_READ_INDEX) && + table->s->primary_key != MAX_KEY) + { + on_primary_key= TRUE; + key_part= table->key_info[table->s->primary_key].key_part; + key_part_end=key_part+table->key_info[table->s->primary_key].key_parts; + const_key_parts=table->const_key_parts[table->s->primary_key]; + + for (; const_key_parts & 1 ; const_key_parts>>= 1) + key_part++; + } + else + DBUG_RETURN(0); + } + + if (key_part->field != field) DBUG_RETURN(0); /* set flag to 1 if we can use read-next on key, else to -1 */ @@ -12034,7 +12058,8 @@ static int test_if_order_by_key(ORDER *order, TABLE *table, uint idx, reverse=flag; // Remember if reverse key_part++; } - *used_key_parts= (uint) (key_part - table->key_info[idx].key_part); + *used_key_parts= on_primary_key ? table->key_info[idx].key_parts : + (uint) (key_part - table->key_info[idx].key_part); if (reverse == -1 && !(table->file->index_flags(idx, *used_key_parts-1, 1) & HA_READ_PREV)) reverse= 0; // Index can't be used diff --git a/sql/table.cc b/sql/table.cc index 4e0f2b5d287..8cfd206a74f 100644 --- a/sql/table.cc +++ b/sql/table.cc @@ -780,7 +780,11 @@ int openfrm(THD *thd, const char *name, const char *alias, uint db_stat, the primary key, then we can use any key to find this column */ if (ha_option & HA_PRIMARY_KEY_IN_READ_INDEX) + { field->part_of_key= share->keys_in_use; + if (field->part_of_sortkey.is_set(key)) + field->part_of_sortkey= share->keys_in_use; + } } if (field->key_length() != key_part->length) { From 07e0cd2f4ecada460bae12e1b1031f893eb7eb78 Mon Sep 17 00:00:00 2001 From: "igor@olga.mysql.com" <> Date: Fri, 20 Jul 2007 22:56:19 -0700 Subject: [PATCH 3/6] Fixed bug #29911. This bug manifested itself for join queries with GROUP BY and HAVING clauses whose SELECT lists contained DISTINCT. It occurred when the optimizer could deduce that the result set would have not more than one row. The bug could lead to wrong result sets for queries of this type because HAVING conditions were erroneously ignored in some cases in the function remove_duplicates. --- mysql-test/r/having.result | 19 +++++++++++++++++++ mysql-test/t/having.test | 26 ++++++++++++++++++++++++++ sql/sql_select.cc | 2 +- 3 files changed, 46 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/having.result b/mysql-test/r/having.result index ccd1f0e61e7..7b4340a133b 100644 --- a/mysql-test/r/having.result +++ b/mysql-test/r/having.result @@ -158,3 +158,22 @@ EXPLAIN SELECT 0 AS x, a FROM t1 GROUP BY x,a HAVING x=1 AND a > 1; id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE NULL NULL NULL NULL NULL NULL NULL Impossible HAVING DROP table t1; +CREATE TABLE t1 (a int PRIMARY KEY); +CREATE TABLE t2 (b int PRIMARY KEY, a int); +CREATE TABLE t3 (b int, flag int); +INSERT INTO t1 VALUES (1); +INSERT INTO t2 VALUES (1,1), (2,1), (3,1); +INSERT INTO t3(b,flag) VALUES (2, 1); +SELECT t1.a +FROM t1 INNER JOIN t2 ON t1.a=t2.a LEFT JOIN t3 ON t2.b=t3.b +GROUP BY t1.a, t2.b HAVING MAX(t3.flag)=0; +a +SELECT DISTINCT t1.a, MAX(t3.flag) +FROM t1 INNER JOIN t2 ON t1.a=t2.a LEFT JOIN t3 ON t2.b=t3.b +GROUP BY t1.a, t2.b HAVING MAX(t3.flag)=0; +a MAX(t3.flag) +SELECT DISTINCT t1.a +FROM t1 INNER JOIN t2 ON t1.a=t2.a LEFT JOIN t3 ON t2.b=t3.b +GROUP BY t1.a, t2.b HAVING MAX(t3.flag)=0; +a +DROP TABLE t1,t2,t3; diff --git a/mysql-test/t/having.test b/mysql-test/t/having.test index 8b39e3bd454..c0ce3cbace7 100644 --- a/mysql-test/t/having.test +++ b/mysql-test/t/having.test @@ -151,4 +151,30 @@ EXPLAIN SELECT 0 AS x, a FROM t1 GROUP BY x,a HAVING x=1 AND a > 1; DROP table t1; +# +# Bug #29911: HAVING clause depending on constant table and evaluated to false +# + +CREATE TABLE t1 (a int PRIMARY KEY); +CREATE TABLE t2 (b int PRIMARY KEY, a int); +CREATE TABLE t3 (b int, flag int); + +INSERT INTO t1 VALUES (1); +INSERT INTO t2 VALUES (1,1), (2,1), (3,1); +INSERT INTO t3(b,flag) VALUES (2, 1); + +SELECT t1.a + FROM t1 INNER JOIN t2 ON t1.a=t2.a LEFT JOIN t3 ON t2.b=t3.b + GROUP BY t1.a, t2.b HAVING MAX(t3.flag)=0; + +SELECT DISTINCT t1.a, MAX(t3.flag) + FROM t1 INNER JOIN t2 ON t1.a=t2.a LEFT JOIN t3 ON t2.b=t3.b + GROUP BY t1.a, t2.b HAVING MAX(t3.flag)=0; + +SELECT DISTINCT t1.a + FROM t1 INNER JOIN t2 ON t1.a=t2.a LEFT JOIN t3 ON t2.b=t3.b + GROUP BY t1.a, t2.b HAVING MAX(t3.flag)=0; + +DROP TABLE t1,t2,t3; + # End of 4.1 tests diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 8b5664a7f96..afbffc499ad 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -8118,7 +8118,7 @@ remove_duplicates(JOIN *join, TABLE *entry,List &fields, Item *having) field_count++; } - if (!field_count && !(join->select_options & OPTION_FOUND_ROWS)) + if (!field_count && !(join->select_options & OPTION_FOUND_ROWS) && !having) { // only const items with no OPTION_FOUND_ROWS join->unit->select_limit_cnt= 1; // Only send first row DBUG_RETURN(0); From 54f3949a27940b68886fead2dfcec0efdc97dd18 Mon Sep 17 00:00:00 2001 From: "igor@olga.mysql.com" <> Date: Sun, 22 Jul 2007 18:26:16 -0700 Subject: [PATCH 4/6] Fixed bug #29611. If a primary key is defined over column c of enum type then the EXPLAIN command for a look-up query of the form SELECT * FROM t WHERE c=0 said that the query was with an impossible where condition though the query correctly returned non-empty result set when the table indeed contained rows with error empty strings for column c. This kind of misbehavior was due to a bug in the function Field_enum::store(longlong,bool) that erroneously returned 1 if the the value to be stored was equal to 0. Note that the method Field_enum::store(const char *from,uint length,CHARSET_INFO *cs) correctly returned 0 if a value of the error empty string was stored. --- mysql-test/r/type_enum.result | 24 ++++++++++++++++++++++++ mysql-test/t/type_enum.test | 24 ++++++++++++++++++++++++ sql/field.cc | 7 +++++-- 3 files changed, 53 insertions(+), 2 deletions(-) diff --git a/mysql-test/r/type_enum.result b/mysql-test/r/type_enum.result index ca516f027ba..994001d94e5 100644 --- a/mysql-test/r/type_enum.result +++ b/mysql-test/r/type_enum.result @@ -1829,3 +1829,27 @@ c1 + 0 0 2 DROP TABLE t1,t2; +CREATE TABLE t1(a enum('a','b','c','d')); +INSERT INTO t1 VALUES (4),(1),(0),(3); +Warnings: +Warning 1265 Data truncated for column 'a' at row 3 +SELECT a FROM t1; +a +d +a + +c +EXPLAIN SELECT a FROM t1 WHERE a=0; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 4 Using where +SELECT a FROM t1 WHERE a=0; +a + +ALTER TABLE t1 ADD PRIMARY KEY (a); +EXPLAIN SELECT a FROM t1 WHERE a=0; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const PRIMARY PRIMARY 1 const 1 Using index +SELECT a FROM t1 WHERE a=0; +a + +DROP TABLE t1; diff --git a/mysql-test/t/type_enum.test b/mysql-test/t/type_enum.test index fbba38f926d..3dedb0018b1 100644 --- a/mysql-test/t/type_enum.test +++ b/mysql-test/t/type_enum.test @@ -200,3 +200,27 @@ CREATE TABLE t2 SELECT * FROM t1; SELECT c1 + 0 FROM t2; DROP TABLE t1,t2; + +# +# Bug#29661: Lookup by 0 for a primary index over a enum type +# + +CREATE TABLE t1(a enum('a','b','c','d')); +INSERT INTO t1 VALUES (4),(1),(0),(3); + +SELECT a FROM t1; + +EXPLAIN SELECT a FROM t1 WHERE a=0; +SELECT a FROM t1 WHERE a=0; + +ALTER TABLE t1 ADD PRIMARY KEY (a); + +EXPLAIN SELECT a FROM t1 WHERE a=0; +SELECT a FROM t1 WHERE a=0; + +DROP TABLE t1; + + + + + diff --git a/sql/field.cc b/sql/field.cc index 993c1fb3c4f..4a1320af48c 100644 --- a/sql/field.cc +++ b/sql/field.cc @@ -7640,8 +7640,11 @@ int Field_enum::store(longlong nr, bool unsigned_val) if ((ulonglong) nr > typelib->count || nr == 0) { set_warning(MYSQL_ERROR::WARN_LEVEL_WARN, WARN_DATA_TRUNCATED, 1); - nr=0; - error=1; + if (nr != 0 || table->in_use->count_cuted_fields) + { + nr= 0; + error= 1; + } } store_type((ulonglong) (uint) nr); return error; From bc1a6ba954d395bf39b1e59f90dcd62410fb7ba2 Mon Sep 17 00:00:00 2001 From: "gkodinov/kgeorge@magare.gmz" <> Date: Mon, 23 Jul 2007 06:26:57 +0300 Subject: [PATCH 5/6] table.cc, sql_select.cc: Limit the fix for bug 28591 to InnoDB only --- sql/sql_select.cc | 1 + sql/table.cc | 3 ++- 2 files changed, 3 insertions(+), 1 deletion(-) diff --git a/sql/sql_select.cc b/sql/sql_select.cc index d82a0fdcf41..2d9d261bb31 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -12033,6 +12033,7 @@ static int test_if_order_by_key(ORDER *order, TABLE *table, uint idx, */ if (!on_primary_key && (table->file->table_flags() & HA_PRIMARY_KEY_IN_READ_INDEX) && + table->s->db_type == DB_TYPE_INNODB && table->s->primary_key != MAX_KEY) { on_primary_key= TRUE; diff --git a/sql/table.cc b/sql/table.cc index b231033d4f2..7b826bcdf2d 100644 --- a/sql/table.cc +++ b/sql/table.cc @@ -782,7 +782,8 @@ int openfrm(THD *thd, const char *name, const char *alias, uint db_stat, if (ha_option & HA_PRIMARY_KEY_IN_READ_INDEX) { field->part_of_key= share->keys_in_use; - if (field->part_of_sortkey.is_set(key)) + if (share->db_type == DB_TYPE_INNODB && + field->part_of_sortkey.is_set(key)) field->part_of_sortkey= share->keys_in_use; } } From fd1a43b0805b3040b7515c37fc3b615d9e8a1370 Mon Sep 17 00:00:00 2001 From: "evgen@moonbone.local" <> Date: Tue, 24 Jul 2007 18:15:44 +0400 Subject: [PATCH 6/6] Bug#15130: CREATE .. SELECT was denied to use advantages of the SQL_BIG_RESULT. When the SQL_BIG_RESULT flag is specified SELECT should store items from the select list in the filesort data and use them when sending to a client. The get_addon_fields function is responsible for creating necessary structures for that. But this function was allowed to do so only for SELECT and INSERT .. SELECT queries. This makes the SQL_BIG_RESULT useless for the CREATE .. SELECT queries. Now the get_addon_fields allows storing select list items in the filesort data for the CREATE .. SELECT queries. --- mysql-test/r/create.result | 13 +++++++++++++ mysql-test/t/create.test | 10 ++++++++++ sql/filesort.cc | 3 ++- 3 files changed, 25 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/create.result b/mysql-test/r/create.result index e692dbf3938..dedd01be340 100644 --- a/mysql-test/r/create.result +++ b/mysql-test/r/create.result @@ -1503,4 +1503,17 @@ t1 CREATE TABLE `t1` ( `c17` int(11) default NULL ) ENGINE=MyISAM DEFAULT CHARSET=latin1 drop table t1; +create table t1(f1 int,f2 int); +insert into t1 value(1,1),(1,2),(1,3),(2,1),(2,2),(2,3); +flush status; +create table t2 select sql_big_result f1,count(f2) from t1 group by f1; +show status like 'handler_read%'; +Variable_name Value +Handler_read_first 0 +Handler_read_key 0 +Handler_read_next 0 +Handler_read_prev 0 +Handler_read_rnd 0 +Handler_read_rnd_next 7 +drop table t1,t2; End of 5.0 tests diff --git a/mysql-test/t/create.test b/mysql-test/t/create.test index 99f3fea416a..822620aa552 100644 --- a/mysql-test/t/create.test +++ b/mysql-test/t/create.test @@ -1119,4 +1119,14 @@ show create table t1; drop table t1; +# +# Bug#15130:CREATE .. SELECT was denied to use advantages of the SQL_BIG_RESULT. +# +create table t1(f1 int,f2 int); +insert into t1 value(1,1),(1,2),(1,3),(2,1),(2,2),(2,3); +flush status; +create table t2 select sql_big_result f1,count(f2) from t1 group by f1; +show status like 'handler_read%'; +drop table t1,t2; + --echo End of 5.0 tests diff --git a/sql/filesort.cc b/sql/filesort.cc index f8868ed6927..db73ede99b0 100644 --- a/sql/filesort.cc +++ b/sql/filesort.cc @@ -1430,7 +1430,8 @@ get_addon_fields(THD *thd, Field **ptabfield, uint sortlength, uint *plength) doesn't work for alter table */ if (thd->lex->sql_command != SQLCOM_SELECT && - thd->lex->sql_command != SQLCOM_INSERT_SELECT) + thd->lex->sql_command != SQLCOM_INSERT_SELECT && + thd->lex->sql_command != SQLCOM_CREATE_TABLE) return 0; for (pfield= ptabfield; (field= *pfield) ; pfield++) {