From d280a06e36b04d245ad26126c5f0466d21726146 Mon Sep 17 00:00:00 2001 From: unknown Date: Fri, 17 Aug 2007 18:30:41 +0400 Subject: [PATCH 01/20] Bug#30245: A wrong type of a BIT field is reported when grouped by it. HEAP tables can't index BIT fields. Due to this when grouping by such fields is needed they are converted to a fields of the LONG type when temporary table is being created. But a side effect of this is that a wrong type of BIT fields is returned to a client. Now the JOIN::prepare and the create_distinct_group functions are create additional hidden copy of BIT fields to preserve original fields untouched. New hidden fields are used for grouping instead. mysql-test/t/type_bit.test: Added a test case for the bug#30245: A wrong type of a BIT field is reported when grouped by it. mysql-test/r/type_bit.result: Added a test case for the bug#30245: A wrong type of a BIT field is reported when grouped by it. sql/sql_select.cc: Bug#30245: A wrong type of a BIT field is reported when grouped by it. Now the JOIN::prepare and the create_distinct_group functions are create additional hidden copy of BIT fields to preserve original fields untouched. New hidden fields are used for grouping instead. --- mysql-test/r/type_bit.result | 15 +++++++++ mysql-test/t/type_bit.test | 13 ++++++++ sql/sql_select.cc | 62 ++++++++++++++++++++++++++++++------ 3 files changed, 81 insertions(+), 9 deletions(-) diff --git a/mysql-test/r/type_bit.result b/mysql-test/r/type_bit.result index 7c765d6d50b..5356f7e0712 100644 --- a/mysql-test/r/type_bit.result +++ b/mysql-test/r/type_bit.result @@ -642,4 +642,19 @@ b+0 COUNT(DISTINCT a) 1 1 3 2 DROP TABLE t1; +CREATE TABLE t1 (b BIT); +INSERT INTO t1 (b) VALUES (1), (0); +SELECT DISTINCT b FROM t1; +Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr +def test t1 t1 b b 16 1 1 Y 32 0 63 +b +# +# +SELECT b FROM t1 GROUP BY b; +Catalog Database Table Table_alias Column Column_alias Type Length Max length Is_null Flags Decimals Charsetnr +def test t1 t1 b b 16 1 1 Y 32 0 63 +b +# +# +DROP TABLE t1; End of 5.0 tests diff --git a/mysql-test/t/type_bit.test b/mysql-test/t/type_bit.test index 6423d017afb..66538f59c6f 100644 --- a/mysql-test/t/type_bit.test +++ b/mysql-test/t/type_bit.test @@ -291,4 +291,17 @@ INSERT INTO t1 (b, a) VALUES (1, 1), (3, 2), (0, 3), (3, 4); SELECT b+0, COUNT(DISTINCT a) FROM t1 GROUP BY b; DROP TABLE t1; +# +# Bug#30245: A wrong type of a BIT field is reported when grouped by it. +# +CREATE TABLE t1 (b BIT); +INSERT INTO t1 (b) VALUES (1), (0); +--enable_metadata +--replace_column 1 # +SELECT DISTINCT b FROM t1; +--replace_column 1 # +SELECT b FROM t1 GROUP BY b; +--disable_metadata +DROP TABLE t1; + --echo End of 5.0 tests diff --git a/sql/sql_select.cc b/sql/sql_select.cc index ac8dc84f118..84c09707fb6 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -189,6 +189,7 @@ static bool setup_new_fields(THD *thd, List &fields, List &all_fields, ORDER *new_order); static ORDER *create_distinct_group(THD *thd, Item **ref_pointer_array, ORDER *order, List &fields, + List &all_fields, bool *all_order_by_fields_used); static bool test_if_subpart(ORDER *a,ORDER *b); static TABLE *get_sort_by_table(ORDER *a,ORDER *b,TABLE_LIST *tables); @@ -537,6 +538,28 @@ JOIN::prepare(Item ***rref_pointer_array, fix_inner_refs(thd, all_fields, select_lex, ref_pointer_array)) DBUG_RETURN(-1); + if (group) + { + /* + Because HEAP tables can't index BIT fields we need to use an + additional hidden field for grouping because later it will be + converted to a LONG field. Original field will remain of the + BIT type and will be returned to a client. + */ + for (ORDER *ord= group_list; ord; ord= ord->next) + { + if ((*ord->item)->type() == Item::FIELD_ITEM && + (*ord->item)->field_type() == MYSQL_TYPE_BIT) + { + Item_field *field= new Item_field(thd, *(Item_field**)ord->item); + int el= all_fields.elements; + ref_pointer_array[el]= field; + all_fields.push_front(field); + ord->item= ref_pointer_array + el; + } + } + } + if (setup_ftfuncs(select_lex)) /* should be after having->fix_fields */ DBUG_RETURN(-1); @@ -1068,12 +1091,13 @@ JOIN::optimize() if (order) skip_sort_order= test_if_skip_sort_order(tab, order, select_limit, 1); if ((group_list=create_distinct_group(thd, select_lex->ref_pointer_array, - order, fields_list, + order, fields_list, all_fields, &all_order_fields_used))) { bool skip_group= (skip_sort_order && test_if_skip_sort_order(tab, group_list, select_limit, 1) != 0); + count_field_types(select_lex, &tmp_table_param, all_fields, 0); if ((skip_group && all_order_fields_used) || select_limit == HA_POS_ERROR || (order && !skip_sort_order)) @@ -13646,11 +13670,12 @@ setup_new_fields(THD *thd, List &fields, static ORDER * create_distinct_group(THD *thd, Item **ref_pointer_array, - ORDER *order_list, List &fields, + ORDER *order_list, List &fields, + List &all_fields, bool *all_order_by_fields_used) { List_iterator li(fields); - Item *item; + Item *item, **orig_ref_pointer_array= ref_pointer_array; ORDER *order,*group,**prev; *all_order_by_fields_used= 1; @@ -13690,12 +13715,31 @@ create_distinct_group(THD *thd, Item **ref_pointer_array, ORDER *ord=(ORDER*) thd->calloc(sizeof(ORDER)); if (!ord) return 0; - /* - We have here only field_list (not all_field_list), so we can use - simple indexing of ref_pointer_array (order in the array and in the - list are same) - */ - ord->item= ref_pointer_array; + + if (item->type() == Item::FIELD_ITEM && + item->field_type() == MYSQL_TYPE_BIT) + { + /* + Because HEAP tables can't index BIT fields we need to use an + additional hidden field for grouping because later it will be + converted to a LONG field. Original field will remain of the + BIT type and will be returned to a client. + */ + Item_field *new_item= new Item_field(thd, (Item_field*)item); + int el= all_fields.elements; + orig_ref_pointer_array[el]= new_item; + all_fields.push_front(new_item); + ord->item= orig_ref_pointer_array + el; + } + else + { + /* + We have here only field_list (not all_field_list), so we can use + simple indexing of ref_pointer_array (order in the array and in the + list are same) + */ + ord->item= ref_pointer_array; + } ord->asc=1; *prev=ord; prev= &ord->next; From 06d80f111958ff9bebc9ccb4c58b9ba362484c00 Mon Sep 17 00:00:00 2001 From: unknown Date: Fri, 24 Aug 2007 18:06:44 +0300 Subject: [PATCH 02/20] Bug #28284: Test "mysqlslap" reports "out of memory" When locking a "fast" mutex a static variable cpu_count was used as a flag to initialize itself on the first usage by calling sysconf() and setting non-zero value. This is not thread and optimization safe on some platforms. That's why the global initialization needs to be done once in a designated function. This will also speed up the usage (by a small bit) because it won't have to check if it's initialized on every call. Fixed by moving the fast mutexes initialization out of my_pthread_fastmutex_lock() to fastmutex_global_init() and call it from my_init() include/my_pthread.h: Bug #28284: move the fast mutexes initialization out of my_pthread_fastmutex_lock() to fastmutex_global_init() and call it from my_init() mysys/my_init.c: Bug #28284: move the fast mutexes initialization out of my_pthread_fastmutex_lock() to fastmutex_global_init() and call it from my_init() mysys/thr_mutex.c: Bug #28284: move the fast mutexes initialization out of my_pthread_fastmutex_lock() to fastmutex_global_init() and call it from my_init() --- include/my_pthread.h | 1 + mysys/my_init.c | 3 +++ mysys/thr_mutex.c | 17 +++++++++++------ 3 files changed, 15 insertions(+), 6 deletions(-) diff --git a/include/my_pthread.h b/include/my_pthread.h index 27b621de925..fad324cb9a7 100644 --- a/include/my_pthread.h +++ b/include/my_pthread.h @@ -538,6 +538,7 @@ typedef struct st_my_pthread_fastmutex_t pthread_mutex_t mutex; uint spins; } my_pthread_fastmutex_t; +void fastmutex_global_init(void); int my_pthread_fastmutex_init(my_pthread_fastmutex_t *mp, const pthread_mutexattr_t *attr); diff --git a/mysys/my_init.c b/mysys/my_init.c index 257edb351b4..b2eefe97ee8 100644 --- a/mysys/my_init.c +++ b/mysys/my_init.c @@ -78,6 +78,9 @@ my_bool my_init(void) my_umask_dir= 0700; /* Default umask for new directories */ #if defined(THREAD) && defined(SAFE_MUTEX) safe_mutex_global_init(); /* Must be called early */ +#endif +#if defined(THREAD) && defined(MY_PTHREAD_FASTMUTEX) && !defined(SAFE_MUTEX) + fastmutex_global_init(); /* Must be called early */ #endif netware_init(); #ifdef THREAD diff --git a/mysys/thr_mutex.c b/mysys/thr_mutex.c index 007bae2accf..e7a927e562a 100644 --- a/mysys/thr_mutex.c +++ b/mysys/thr_mutex.c @@ -394,15 +394,11 @@ ulong mutex_delay(ulong delayloops) #define MY_PTHREAD_FASTMUTEX_SPINS 8 #define MY_PTHREAD_FASTMUTEX_DELAY 4 +static int cpu_count= 0; + int my_pthread_fastmutex_init(my_pthread_fastmutex_t *mp, const pthread_mutexattr_t *attr) { - static int cpu_count= 0; -#ifdef _SC_NPROCESSORS_CONF - if (!cpu_count && (attr == MY_MUTEX_INIT_FAST)) - cpu_count= sysconf(_SC_NPROCESSORS_CONF); -#endif - if ((cpu_count > 1) && (attr == MY_MUTEX_INIT_FAST)) mp->spins= MY_PTHREAD_FASTMUTEX_SPINS; else @@ -432,4 +428,13 @@ int my_pthread_fastmutex_lock(my_pthread_fastmutex_t *mp) } return pthread_mutex_lock(&mp->mutex); } + + +void fastmutex_global_init(void) +{ +#ifdef _SC_NPROCESSORS_CONF + cpu_count= sysconf(_SC_NPROCESSORS_CONF); +#endif +} + #endif /* defined(THREAD) && defined(MY_PTHREAD_FASTMUTEX) && !defined(SAFE_MUTEX) */ From 5b03876f2e5d0a456170874d660374762f7fc99e Mon Sep 17 00:00:00 2001 From: unknown Date: Sat, 25 Aug 2007 17:32:17 +0000 Subject: [PATCH 03/20] sql_select.cc: Additional fix for the bug#30245. sql/sql_select.cc: Additional fix for the bug#30245. --- sql/sql_select.cc | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 9db0a2ee490..f685d3093d6 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -538,7 +538,7 @@ JOIN::prepare(Item ***rref_pointer_array, fix_inner_refs(thd, all_fields, select_lex, ref_pointer_array)) DBUG_RETURN(-1); - if (group) + if (group_list) { /* Because HEAP tables can't index BIT fields we need to use an From 236866468123d5f61713c627ba77aae73c916d28 Mon Sep 17 00:00:00 2001 From: unknown Date: Mon, 27 Aug 2007 17:33:41 +0200 Subject: [PATCH 04/20] Bug #30596 GROUP BY optimization gives wrong result order The optimization that uses a unique index to remove GROUP BY, did not ensure that the index was actually used, thus violating the ORDER BY that is impled by GROUP BY. Fixed by replacing GROUP BY with ORDER BY if the GROUP BY clause contains a unique index. In case GROUP BY ... ORDER BY null is used, GROUP BY is simply removed. BitKeeper/etc/ignore: Added support-files/mysqld_multi.server tests/bug25714 cscope.in.out cscope.out cscope.po.out to the ignore list mysql-test/r/distinct.result: Bug#30596: Changed test case. Prior to Bug#16458, These queries use temp table and filesort. The bug was that they used a temp table. However, that patch removed filesort also, in which case we can no longer gurantee correct ordering. mysql-test/r/group_by.result: Bug#30596: Correct result mysql-test/r/innodb_mysql.result: Bug#30596: Test case for innodb. Here, as opposed to for MyISAM, row lookup is done using index whenever the index covers the group list. mysql-test/t/group_by.test: Bug#30596: Test case mysql-test/t/innodb_mysql.test: Bug#30596: Test case sql/sql_select.cc: Bug#30596: The fix, replacing GROUP BY with ORDER BY unless ORDER BY [NULL|] --- .bzrignore | 5 ++++ mysql-test/r/distinct.result | 6 ++-- mysql-test/r/group_by.result | 49 ++++++++++++++++++++++++++++++++ mysql-test/r/innodb_mysql.result | 49 ++++++++++++++++++++++++++++++++ mysql-test/t/group_by.test | 27 ++++++++++++++++++ mysql-test/t/innodb_mysql.test | 27 ++++++++++++++++++ sql/sql_select.cc | 8 ++++++ 7 files changed, 168 insertions(+), 3 deletions(-) diff --git a/.bzrignore b/.bzrignore index 759ca4a20bf..35f5199be3c 100644 --- a/.bzrignore +++ b/.bzrignore @@ -1345,3 +1345,8 @@ zlib/*.vcproj debian/control debian/defs.mk include/abi_check +support-files/mysqld_multi.server +tests/bug25714 +cscope.in.out +cscope.out +cscope.po.out diff --git a/mysql-test/r/distinct.result b/mysql-test/r/distinct.result index 8525e0f19e4..8cfe5aa78b5 100644 --- a/mysql-test/r/distinct.result +++ b/mysql-test/r/distinct.result @@ -526,10 +526,10 @@ id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t1 index NULL PRIMARY 4 NULL 3 Using index EXPLAIN SELECT a,b FROM t1 GROUP BY a,b; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 ALL NULL NULL NULL NULL 3 +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort EXPLAIN SELECT DISTINCT a,b FROM t1 GROUP BY a,b; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 ALL NULL NULL NULL NULL 3 +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort CREATE TABLE t2(a INT, b INT NOT NULL, c INT NOT NULL, d INT, PRIMARY KEY (a,b)); INSERT INTO t2 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4); @@ -554,7 +554,7 @@ id select_type table type possible_keys key key_len ref rows Extra CREATE UNIQUE INDEX c_b_unq ON t2 (c,b); EXPLAIN SELECT DISTINCT a,b,d FROM t2 GROUP BY c,b,d; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t2 ALL NULL NULL NULL NULL 3 +1 SIMPLE t2 ALL NULL NULL NULL NULL 3 Using filesort DROP TABLE t1,t2; create table t1 (id int, dsc varchar(50)); insert into t1 values (1, "line number one"), (2, "line number two"), (3, "line number three"); diff --git a/mysql-test/r/group_by.result b/mysql-test/r/group_by.result index d4ffbe43a91..053c2901509 100644 --- a/mysql-test/r/group_by.result +++ b/mysql-test/r/group_by.result @@ -1064,3 +1064,52 @@ select t1.f1,t.* from t1, t1 t group by 1; ERROR 42000: 'test.t.f1' isn't in GROUP BY drop table t1; SET SQL_MODE = ''; +CREATE TABLE t1( +a INT, +b INT NOT NULL, +c INT NOT NULL, +d INT, +UNIQUE KEY (c,b) +); +INSERT INTO t1 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4); +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort +SELECT c,b,d FROM t1 GROUP BY c,b,d; +c b d +1 1 50 +3 1 4 +3 2 40 +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 +SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL; +c b d +1 1 50 +3 2 40 +3 1 4 +EXPLAIN SELECT c,b,d FROM t1 ORDER BY c,b,d; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort +SELECT c,b,d FROM t1 ORDER BY c,b,d; +c b d +1 1 50 +3 1 4 +3 2 40 +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort +SELECT c,b,d FROM t1 GROUP BY c,b; +c b d +1 1 50 +3 1 4 +3 2 40 +EXPLAIN SELECT c,b FROM t1 GROUP BY c,b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 index NULL c 8 NULL 3 Using index +SELECT c,b FROM t1 GROUP BY c,b; +c b +1 1 +3 1 +3 2 +DROP TABLE t1; diff --git a/mysql-test/r/innodb_mysql.result b/mysql-test/r/innodb_mysql.result index 63e25b7aa1e..82955af4c8a 100644 --- a/mysql-test/r/innodb_mysql.result +++ b/mysql-test/r/innodb_mysql.result @@ -1047,4 +1047,53 @@ t1 CREATE TABLE `t1` ( KEY `a` (`a`(255)) ) ENGINE=InnoDB DEFAULT CHARSET=utf8 drop table t1; +CREATE TABLE t1( +a INT, +b INT NOT NULL, +c INT NOT NULL, +d INT, +UNIQUE KEY (c,b) +) engine=innodb; +INSERT INTO t1 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4); +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort +SELECT c,b,d FROM t1 GROUP BY c,b,d; +c b d +1 1 50 +3 1 4 +3 2 40 +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 +SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL; +c b d +1 1 50 +3 1 4 +3 2 40 +EXPLAIN SELECT c,b,d FROM t1 ORDER BY c,b,d; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort +SELECT c,b,d FROM t1 ORDER BY c,b,d; +c b d +1 1 50 +3 1 4 +3 2 40 +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 index NULL c 8 NULL 3 +SELECT c,b,d FROM t1 GROUP BY c,b; +c b d +1 1 50 +3 1 4 +3 2 40 +EXPLAIN SELECT c,b FROM t1 GROUP BY c,b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 index NULL c 8 NULL 3 Using index +SELECT c,b FROM t1 GROUP BY c,b; +c b +1 1 +3 1 +3 2 +DROP TABLE t1; End of 5.0 tests diff --git a/mysql-test/t/group_by.test b/mysql-test/t/group_by.test index 91e69f9db34..b7c28cada46 100644 --- a/mysql-test/t/group_by.test +++ b/mysql-test/t/group_by.test @@ -788,3 +788,30 @@ select * from t1 group by f1, f2; select t1.f1,t.* from t1, t1 t group by 1; drop table t1; SET SQL_MODE = ''; + +# +# Bug#30596: GROUP BY optimization gives wrong result order +# +CREATE TABLE t1( + a INT, + b INT NOT NULL, + c INT NOT NULL, + d INT, + UNIQUE KEY (c,b) +); + +INSERT INTO t1 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4); + +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d; +SELECT c,b,d FROM t1 GROUP BY c,b,d; +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL; +SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL; +EXPLAIN SELECT c,b,d FROM t1 ORDER BY c,b,d; +SELECT c,b,d FROM t1 ORDER BY c,b,d; + +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b; +SELECT c,b,d FROM t1 GROUP BY c,b; +EXPLAIN SELECT c,b FROM t1 GROUP BY c,b; +SELECT c,b FROM t1 GROUP BY c,b; + +DROP TABLE t1; diff --git a/mysql-test/t/innodb_mysql.test b/mysql-test/t/innodb_mysql.test index adcfec68d3e..949e602a299 100644 --- a/mysql-test/t/innodb_mysql.test +++ b/mysql-test/t/innodb_mysql.test @@ -882,4 +882,31 @@ alter table t1 add index(a(1024)); show create table t1; drop table t1; +# +# Bug#30596: GROUP BY optimization gives wrong result order +# +CREATE TABLE t1( + a INT, + b INT NOT NULL, + c INT NOT NULL, + d INT, + UNIQUE KEY (c,b) +) engine=innodb; + +INSERT INTO t1 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4); + +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d; +SELECT c,b,d FROM t1 GROUP BY c,b,d; +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL; +SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL; +EXPLAIN SELECT c,b,d FROM t1 ORDER BY c,b,d; +SELECT c,b,d FROM t1 ORDER BY c,b,d; + +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b; +SELECT c,b,d FROM t1 GROUP BY c,b; +EXPLAIN SELECT c,b FROM t1 GROUP BY c,b; +SELECT c,b FROM t1 GROUP BY c,b; + +DROP TABLE t1; + --echo End of 5.0 tests diff --git a/sql/sql_select.cc b/sql/sql_select.cc index ac8dc84f118..4be542975b5 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -1030,6 +1030,14 @@ JOIN::optimize() find_field_in_order_list, (void *) group_list)) { + /* + We have found that grouping can be removed since groups correspond to + only one row anyway, but we still have to guarantee correct result + order. The line below effectively rewrites the query from GROUP BY + to ORDER BY . One exception is if skip_sort_order is + set (see above), then we can simply skip GROUP BY. + */ + order= skip_sort_order ? 0 : group_list; group_list= 0; group= 0; } From 310afbd4a96baeedc7202a3b2cac7860c76d83e2 Mon Sep 17 00:00:00 2001 From: unknown Date: Tue, 28 Aug 2007 18:51:03 +0300 Subject: [PATCH 05/20] Bug #30377: EXPLAIN loses last_query_cost when used with UNION Currently the Last_query_cost session status variable shows only the cost of a single flat subselect. For complex queries (with subselects or unions etc) Last_query_cost is not valid as it was showing the cost for the last optimized subselect. Fixed by reseting to zero Last_query_cost when the complete cost of the query cannot be determined. Last_query_cost will be non-zero only for single flat queries. mysql-test/r/status.result: Bug #30377: test case mysql-test/t/status.test: Bug #30377: test case sql/sql_lex.h: Bug #30377: helper function sql/sql_select.cc: Bug #30377: don't assign cost if not on single level statement --- mysql-test/r/status.result | 48 ++++++++++++++++++++++++++++++++++++++ mysql-test/t/status.test | 32 +++++++++++++++++++++++++ sql/sql_lex.h | 22 +++++++++++++++++ sql/sql_select.cc | 8 +++++-- 4 files changed, 108 insertions(+), 2 deletions(-) diff --git a/mysql-test/r/status.result b/mysql-test/r/status.result index ca21b333a6a..36857e22aaf 100644 --- a/mysql-test/r/status.result +++ b/mysql-test/r/status.result @@ -43,3 +43,51 @@ SHOW STATUS LIKE 'max_used_connections'; Variable_name Value Max_used_connections 4 SET GLOBAL thread_cache_size=@save_thread_cache_size; +CREATE TABLE t1 ( a INT ); +INSERT INTO t1 VALUES (1), (2); +SELECT a FROM t1 LIMIT 1; +a +1 +SHOW SESSION STATUS LIKE 'Last_query_cost'; +Variable_name Value +Last_query_cost 2.402418 +EXPLAIN SELECT a FROM t1; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 2 +SHOW SESSION STATUS LIKE 'Last_query_cost'; +Variable_name Value +Last_query_cost 2.402418 +SELECT a FROM t1 UNION SELECT a FROM t1 ORDER BY a; +a +1 +2 +SHOW SESSION STATUS LIKE 'Last_query_cost'; +Variable_name Value +Last_query_cost 0.000000 +EXPLAIN SELECT a FROM t1 UNION SELECT a FROM t1 ORDER BY a; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 2 +2 UNION t1 ALL NULL NULL NULL NULL 2 +NULL UNION RESULT ALL NULL NULL NULL NULL NULL Using filesort +SHOW SESSION STATUS LIKE 'Last_query_cost'; +Variable_name Value +Last_query_cost 0.000000 +SELECT a IN (SELECT a FROM t1) FROM t1 LIMIT 1; +a IN (SELECT a FROM t1) +1 +SHOW SESSION STATUS LIKE 'Last_query_cost'; +Variable_name Value +Last_query_cost 0.000000 +SELECT (SELECT a FROM t1 LIMIT 1) x FROM t1 LIMIT 1; +x +1 +SHOW SESSION STATUS LIKE 'Last_query_cost'; +Variable_name Value +Last_query_cost 0.000000 +SELECT * FROM t1 a, t1 b LIMIT 1; +a a +1 1 +SHOW SESSION STATUS LIKE 'Last_query_cost'; +Variable_name Value +Last_query_cost 4.805836 +DROP TABLE t1; diff --git a/mysql-test/t/status.test b/mysql-test/t/status.test index 6fcb82e160d..33bba3a626a 100644 --- a/mysql-test/t/status.test +++ b/mysql-test/t/status.test @@ -139,4 +139,36 @@ disconnect con3; disconnect con2; disconnect con1; + +# +# Bug #30377: EXPLAIN loses last_query_cost when used with UNION +# + +CREATE TABLE t1 ( a INT ); +INSERT INTO t1 VALUES (1), (2); + +SELECT a FROM t1 LIMIT 1; +SHOW SESSION STATUS LIKE 'Last_query_cost'; + +EXPLAIN SELECT a FROM t1; +SHOW SESSION STATUS LIKE 'Last_query_cost'; + +SELECT a FROM t1 UNION SELECT a FROM t1 ORDER BY a; +SHOW SESSION STATUS LIKE 'Last_query_cost'; + +EXPLAIN SELECT a FROM t1 UNION SELECT a FROM t1 ORDER BY a; +SHOW SESSION STATUS LIKE 'Last_query_cost'; + +SELECT a IN (SELECT a FROM t1) FROM t1 LIMIT 1; +SHOW SESSION STATUS LIKE 'Last_query_cost'; + +SELECT (SELECT a FROM t1 LIMIT 1) x FROM t1 LIMIT 1; +SHOW SESSION STATUS LIKE 'Last_query_cost'; + +SELECT * FROM t1 a, t1 b LIMIT 1; +SHOW SESSION STATUS LIKE 'Last_query_cost'; + +DROP TABLE t1; + + # End of 5.0 tests diff --git a/sql/sql_lex.h b/sql/sql_lex.h index 94015a9fe07..ce56be79744 100644 --- a/sql/sql_lex.h +++ b/sql/sql_lex.h @@ -1257,6 +1257,28 @@ typedef struct st_lex : public Query_tables_list void reset_n_backup_query_tables_list(Query_tables_list *backup); void restore_backup_query_tables_list(Query_tables_list *backup); + + /** + @brief check if the statement is a single-level join + @return result of the check + @retval TRUE The statement doesn't contain subqueries, unions and + stored procedure calls. + @retval FALSE There are subqueries, UNIONs or stored procedure calls. + */ + bool is_single_level_stmt() + { + /* + This check exploits the fact that the last added to all_select_list is + on its top. So select_lex (as the first added) will be at the tail + of the list. + */ + if (&select_lex == all_selects_list && !sroutines.records) + { + DBUG_ASSERT(!all_selects_list->next_select_in_list()); + return TRUE; + } + return FALSE; + } } LEX; struct st_lex_local: public st_lex diff --git a/sql/sql_select.cc b/sql/sql_select.cc index b7846a7433d..7e9cb4cfbec 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -4369,9 +4369,13 @@ choose_plan(JOIN *join, table_map join_tables) /* Store the cost of this query into a user variable - Don't update last_query_cost for 'show status' command + Don't update last_query_cost for 'show status' command. + Don't update last_query_cost for statements that are not "flat joins" : + i.e. they have subqueries, unions or call stored procedures. + TODO: calculate a correct cost for a query with subqueries and UNIONs. */ - if (join->thd->lex->orig_sql_command != SQLCOM_SHOW_STATUS) + if (join->thd->lex->orig_sql_command != SQLCOM_SHOW_STATUS && + join->thd->lex->is_single_level_stmt()) join->thd->status_var.last_query_cost= join->best_read; DBUG_RETURN(FALSE); } From 22440b53877385c4c46a34e64421d9771a841bad Mon Sep 17 00:00:00 2001 From: unknown Date: Tue, 28 Aug 2007 18:01:29 +0200 Subject: [PATCH 06/20] Bug #30596 GROUP BY optimization gives wrong result order The optimization that uses a unique index to remove GROUP BY did not ensure that the index was actually used, thus violating the ORDER BY that is implied by GROUP BY. Fixed by replacing GROUP BY with ORDER BY if the GROUP BY clause contains a unique index over non-nullable field(s). In case GROUP BY ... ORDER BY null is used, GROUP BY is simply removed. mysql-test/include/mix1.inc: Bug#30596: Test case for InnoDB Here, as opposed to for MyISAM, row lookup is done using index whenever the index covers the group list. mysql-test/r/distinct.result: Bug#30596: Changed test case. Prior to Bug#16458, These queries use temp table and filesort. The bug was that they used a temp table. However, that patch removed filesort also, in which case we can no longer gurantee correct ordering. mysql-test/r/group_by.result: Bug#30596: Correct result The test case for IGNORE INDEX FOR GROUP BY gets degraded performance (unneccesary filesort). This is due to Bug#30665, which will be fixed separately. mysql-test/r/innodb_mysql.result: Bug#30596: Test result mysql-test/t/group_by.test: Bug#30596: Test case sql/sql_select.cc: Bug#30596: The fix: - replace GROUP BY with ORDER BY unless ORDER BY [NULL|] - make sure to use the keys for GROUP BY in this ORDER BY. --- mysql-test/include/mix1.inc | 27 ++++++++++ mysql-test/r/distinct.result | 6 +-- mysql-test/r/group_by.result | 93 +++++++++++++++++++++++++++++++- mysql-test/r/innodb_mysql.result | 49 +++++++++++++++++ mysql-test/t/group_by.test | 44 +++++++++++++++ sql/sql_select.cc | 14 +++++ 6 files changed, 229 insertions(+), 4 deletions(-) diff --git a/mysql-test/include/mix1.inc b/mysql-test/include/mix1.inc index 5e6a535fce5..a55e0f22a7c 100644 --- a/mysql-test/include/mix1.inc +++ b/mysql-test/include/mix1.inc @@ -969,6 +969,33 @@ ROLLBACK; ROLLBACK; DROP TABLE t1; +# +# Bug#30596: GROUP BY optimization gives wrong result order +# +CREATE TABLE t1( + a INT, + b INT NOT NULL, + c INT NOT NULL, + d INT, + UNIQUE KEY (c,b) +) engine=innodb; + +INSERT INTO t1 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4); + +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d; +SELECT c,b,d FROM t1 GROUP BY c,b,d; +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL; +SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL; +EXPLAIN SELECT c,b,d FROM t1 ORDER BY c,b,d; +SELECT c,b,d FROM t1 ORDER BY c,b,d; + +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b; +SELECT c,b,d FROM t1 GROUP BY c,b; +EXPLAIN SELECT c,b FROM t1 GROUP BY c,b; +SELECT c,b FROM t1 GROUP BY c,b; + +DROP TABLE t1; + --echo End of 5.0 tests # Fix for BUG#19243 "wrong LAST_INSERT_ID() after ON DUPLICATE KEY diff --git a/mysql-test/r/distinct.result b/mysql-test/r/distinct.result index 795d8956a08..b2a9eb04c04 100644 --- a/mysql-test/r/distinct.result +++ b/mysql-test/r/distinct.result @@ -526,10 +526,10 @@ id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t1 index NULL PRIMARY 4 NULL 3 Using index EXPLAIN SELECT a,b FROM t1 GROUP BY a,b; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 ALL NULL NULL NULL NULL 3 +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort EXPLAIN SELECT DISTINCT a,b FROM t1 GROUP BY a,b; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 ALL NULL NULL NULL NULL 3 +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort CREATE TABLE t2(a INT, b INT NOT NULL, c INT NOT NULL, d INT, PRIMARY KEY (a,b)); INSERT INTO t2 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4); @@ -554,7 +554,7 @@ id select_type table type possible_keys key key_len ref rows Extra CREATE UNIQUE INDEX c_b_unq ON t2 (c,b); EXPLAIN SELECT DISTINCT a,b,d FROM t2 GROUP BY c,b,d; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t2 ALL NULL NULL NULL NULL 3 +1 SIMPLE t2 ALL NULL NULL NULL NULL 3 Using filesort DROP TABLE t1,t2; create table t1 (id int, dsc varchar(50)); insert into t1 values (1, "line number one"), (2, "line number two"), (3, "line number three"); diff --git a/mysql-test/r/group_by.result b/mysql-test/r/group_by.result index 13ddccaee92..1839cb709a2 100644 --- a/mysql-test/r/group_by.result +++ b/mysql-test/r/group_by.result @@ -1093,7 +1093,7 @@ id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t1 ALL NULL NULL NULL NULL 144 EXPLAIN SELECT a FROM t1 IGNORE INDEX FOR GROUP BY (PRIMARY,i2) GROUP BY a; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 index NULL PRIMARY 4 NULL 144 Using index +1 SIMPLE t1 index NULL PRIMARY 4 NULL 144 Using index; Using filesort EXPLAIN SELECT a FROM t1 IGNORE INDEX FOR ORDER BY (PRIMARY,i2) ORDER BY a; id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t1 index NULL PRIMARY 4 NULL 144 Using index; Using filesort @@ -1176,3 +1176,94 @@ old OFF SET @@old = off; ERROR HY000: Variable 'old' is a read only variable DROP TABLE t1, t2; +CREATE TABLE t1( +a INT, +b INT NOT NULL, +c INT NOT NULL, +d INT, +UNIQUE KEY (c,b) +); +INSERT INTO t1 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4); +CREATE TABLE t2( +a INT, +b INT, +UNIQUE KEY(a,b) +); +INSERT INTO t2 VALUES (NULL, NULL), (NULL, NULL), (NULL, 1), (1, NULL), (1, 1), (1,2); +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort +SELECT c,b,d FROM t1 GROUP BY c,b,d; +c b d +1 1 50 +3 1 4 +3 2 40 +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 +SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL; +c b d +1 1 50 +3 2 40 +3 1 4 +EXPLAIN SELECT c,b,d FROM t1 ORDER BY c,b,d; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort +SELECT c,b,d FROM t1 ORDER BY c,b,d; +c b d +1 1 50 +3 1 4 +3 2 40 +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort +SELECT c,b,d FROM t1 GROUP BY c,b; +c b d +1 1 50 +3 1 4 +3 2 40 +EXPLAIN SELECT c,b FROM t1 GROUP BY c,b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 index NULL c 8 NULL 3 Using index +SELECT c,b FROM t1 GROUP BY c,b; +c b +1 1 +3 1 +3 2 +EXPLAIN SELECT a,b from t2 ORDER BY a,b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t2 index NULL a 10 NULL 6 Using index +SELECT a,b from t2 ORDER BY a,b; +a b +NULL NULL +NULL NULL +NULL 1 +1 NULL +1 1 +1 2 +EXPLAIN SELECT a,b from t2 GROUP BY a,b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t2 index NULL a 10 NULL 6 Using index +SELECT a,b from t2 GROUP BY a,b; +a b +NULL NULL +NULL 1 +1 NULL +1 1 +1 2 +EXPLAIN SELECT a from t2 GROUP BY a; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t2 index NULL a 10 NULL 6 Using index +SELECT a from t2 GROUP BY a; +a +NULL +1 +EXPLAIN SELECT b from t2 GROUP BY b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t2 index NULL a 10 NULL 6 Using index; Using temporary; Using filesort +SELECT b from t2 GROUP BY b; +b +NULL +1 +2 +DROP TABLE t1; diff --git a/mysql-test/r/innodb_mysql.result b/mysql-test/r/innodb_mysql.result index 32c692501ad..3293f05a1f9 100644 --- a/mysql-test/r/innodb_mysql.result +++ b/mysql-test/r/innodb_mysql.result @@ -1141,6 +1141,55 @@ a b ROLLBACK; ROLLBACK; DROP TABLE t1; +CREATE TABLE t1( +a INT, +b INT NOT NULL, +c INT NOT NULL, +d INT, +UNIQUE KEY (c,b) +) engine=innodb; +INSERT INTO t1 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4); +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort +SELECT c,b,d FROM t1 GROUP BY c,b,d; +c b d +1 1 50 +3 1 4 +3 2 40 +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 +SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL; +c b d +1 1 50 +3 1 4 +3 2 40 +EXPLAIN SELECT c,b,d FROM t1 ORDER BY c,b,d; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort +SELECT c,b,d FROM t1 ORDER BY c,b,d; +c b d +1 1 50 +3 1 4 +3 2 40 +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 index NULL c 8 NULL 3 +SELECT c,b,d FROM t1 GROUP BY c,b; +c b d +1 1 50 +3 1 4 +3 2 40 +EXPLAIN SELECT c,b FROM t1 GROUP BY c,b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 index NULL c 8 NULL 3 Using index +SELECT c,b FROM t1 GROUP BY c,b; +c b +1 1 +3 1 +3 2 +DROP TABLE t1; End of 5.0 tests CREATE TABLE `t2` ( `k` int(11) NOT NULL auto_increment, diff --git a/mysql-test/t/group_by.test b/mysql-test/t/group_by.test index 5db110e8d36..f6296c17f9c 100644 --- a/mysql-test/t/group_by.test +++ b/mysql-test/t/group_by.test @@ -861,3 +861,47 @@ SHOW VARIABLES LIKE 'old'; SET @@old = off; DROP TABLE t1, t2; + +# +# Bug#30596: GROUP BY optimization gives wrong result order +# +CREATE TABLE t1( + a INT, + b INT NOT NULL, + c INT NOT NULL, + d INT, + UNIQUE KEY (c,b) +); + +INSERT INTO t1 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4); + +CREATE TABLE t2( + a INT, + b INT, + UNIQUE KEY(a,b) +); + +INSERT INTO t2 VALUES (NULL, NULL), (NULL, NULL), (NULL, 1), (1, NULL), (1, 1), (1,2); + +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d; +SELECT c,b,d FROM t1 GROUP BY c,b,d; +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL; +SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL; +EXPLAIN SELECT c,b,d FROM t1 ORDER BY c,b,d; +SELECT c,b,d FROM t1 ORDER BY c,b,d; + +EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b; +SELECT c,b,d FROM t1 GROUP BY c,b; +EXPLAIN SELECT c,b FROM t1 GROUP BY c,b; +SELECT c,b FROM t1 GROUP BY c,b; + +EXPLAIN SELECT a,b from t2 ORDER BY a,b; +SELECT a,b from t2 ORDER BY a,b; +EXPLAIN SELECT a,b from t2 GROUP BY a,b; +SELECT a,b from t2 GROUP BY a,b; +EXPLAIN SELECT a from t2 GROUP BY a; +SELECT a from t2 GROUP BY a; +EXPLAIN SELECT b from t2 GROUP BY b; +SELECT b from t2 GROUP BY b; + +DROP TABLE t1; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index f694e224bd4..03ef8979b86 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -1042,6 +1042,20 @@ JOIN::optimize() find_field_in_order_list, (void *) group_list)) { + /* + We have found that grouping can be removed since groups correspond to + only one row anyway, but we still have to guarantee correct result + order. The line below effectively rewrites the query from GROUP BY + to ORDER BY . One exception is if skip_sort_order is + set (see above), then we can simply skip GROUP BY. + */ + order= skip_sort_order ? 0 : group_list; + /* + If we have an IGNORE INDEX FOR GROUP BY(fields) clause, this must be + rewritten to IGNORE INDEX FOR ORDER BY(fields). + */ + join_tab->table->keys_in_use_for_order_by= + join_tab->table->keys_in_use_for_group_by; group_list= 0; group= 0; } From d2bd51c55f76e3f0fc6ad13f1dce091019eb7555 Mon Sep 17 00:00:00 2001 From: unknown Date: Wed, 29 Aug 2007 12:39:42 +0300 Subject: [PATCH 07/20] Addendum to the 5.1 merge of the fix for bug 30377: use the function instead of the complex condition. --- sql/sql_parse.cc | 3 +-- 1 file changed, 1 insertion(+), 2 deletions(-) diff --git a/sql/sql_parse.cc b/sql/sql_parse.cc index 2e4ce65f1c4..39f4998daf0 100644 --- a/sql/sql_parse.cc +++ b/sql/sql_parse.cc @@ -1732,8 +1732,7 @@ mysql_execute_command(THD *thd) variables, but for now this is probably good enough. Don't reset warnings when executing a stored routine. */ - if ((all_tables || &lex->select_lex != lex->all_selects_list || - lex->sroutines.records) && !thd->spcont) + if ((all_tables || !lex->is_single_level_stmt()) && !thd->spcont) mysql_reset_errors(thd, 0); #ifdef HAVE_REPLICATION From 1bae3c20a8cd8b6abfe8066f17b7d3c82b01ba25 Mon Sep 17 00:00:00 2001 From: unknown Date: Wed, 29 Aug 2007 14:46:49 +0300 Subject: [PATCH 08/20] Bug #30393: Test "group_by" fails with a difference in "row count" and strategy (explain) The fix for WL3527 adds tests that test if the index usage hints combinations don't cause syntax errors. The EXPLAIN for one of these tests can be affected by the size of the rowid on the disk (affected by the presence of large file support). Fixed to avoid the platform dependent test result by removing the irrelevant columns from the EXPLAIN result. mysql-test/r/group_by.result: Bug #30393: ignore columns irrelevant to the test mysql-test/t/group_by.test: Bug #30393: ignore columns irrelevant to the test --- mysql-test/r/group_by.result | 2 +- mysql-test/t/group_by.test | 5 +++++ 2 files changed, 6 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/group_by.result b/mysql-test/r/group_by.result index 1839cb709a2..2faf7832aca 100644 --- a/mysql-test/r/group_by.result +++ b/mysql-test/r/group_by.result @@ -1129,7 +1129,7 @@ ERROR 42000: You have an error in your SQL syntax; check the manual that corresp EXPLAIN SELECT a FROM t1 USE INDEX FOR JOIN (i2) USE INDEX FOR GROUP BY (i2) GROUP BY a; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 index NULL i2 9 NULL 144 Using index +1 SIMPLE t1 # NULL i2 # NULL # # EXPLAIN SELECT a FROM t1 FORCE INDEX FOR JOIN (i2) FORCE INDEX FOR GROUP BY (i2) GROUP BY a; id select_type table type possible_keys key key_len ref rows Extra diff --git a/mysql-test/t/group_by.test b/mysql-test/t/group_by.test index f6296c17f9c..ae616df0dfd 100644 --- a/mysql-test/t/group_by.test +++ b/mysql-test/t/group_by.test @@ -828,6 +828,11 @@ EXPLAIN SELECT a FROM t1 USE INDEX (i2) USE INDEX (); EXPLAIN SELECT a FROM t1 FORCE INDEX (); --error ER_PARSE_ERROR EXPLAIN SELECT a FROM t1 IGNORE INDEX (); +# disable the columns irrelevant to this test here. On some systems +# without support for large files the rowid is shorter and its size affects +# the cost calculations. This causes the optimizer to choose loose index +# scan over normal index access. +--replace_column 4 # 7 # 9 # 10 # EXPLAIN SELECT a FROM t1 USE INDEX FOR JOIN (i2) USE INDEX FOR GROUP BY (i2) GROUP BY a; EXPLAIN SELECT a FROM t1 FORCE INDEX FOR JOIN (i2) From 385ef618e8a7e45b6087eadd30426d60b529e354 Mon Sep 17 00:00:00 2001 From: unknown Date: Wed, 29 Aug 2007 14:54:32 +0300 Subject: [PATCH 09/20] Bug #30244: row_count/found_rows does not replicate well The functions ROW_COUNT/FOUND_ROWS are indeed not safe to be used in statement based replication. Added code to declare them as such and switch the statement they're in to row based logging for mixed mode. sql/item_create.cc: Bug #30244: row_count/found_rows does not replicate well - add the functions to the set of "unsafe functions" for statement based replication mysql-test/suite/rpl/r/rpl_row_unsafe_funcs.result: BitKeeper file /home/kgeorge/mysql/work/B30244-5.1-opt/mysql-test/suite/rpl/r/rpl_row_unsafe_funcs.result mysql-test/suite/rpl/t/rpl_row_unsafe_funcs.test: BitKeeper file /home/kgeorge/mysql/work/B30244-5.1-opt/mysql-test/suite/rpl/t/rpl_row_unsafe_funcs.test --- .../suite/rpl/r/rpl_row_unsafe_funcs.result | 22 ++++++++++++ .../suite/rpl/t/rpl_row_unsafe_funcs.test | 35 +++++++++++++++++++ sql/item_create.cc | 2 ++ 3 files changed, 59 insertions(+) create mode 100644 mysql-test/suite/rpl/r/rpl_row_unsafe_funcs.result create mode 100644 mysql-test/suite/rpl/t/rpl_row_unsafe_funcs.test diff --git a/mysql-test/suite/rpl/r/rpl_row_unsafe_funcs.result b/mysql-test/suite/rpl/r/rpl_row_unsafe_funcs.result new file mode 100644 index 00000000000..800670b78ae --- /dev/null +++ b/mysql-test/suite/rpl/r/rpl_row_unsafe_funcs.result @@ -0,0 +1,22 @@ +stop slave; +drop table if exists t1,t2,t3,t4,t5,t6,t7,t8,t9; +reset master; +reset slave; +drop table if exists t1,t2,t3,t4,t5,t6,t7,t8,t9; +start slave; +CREATE TABLE t1 (a INT); +CREATE TABLE t2 (a INT, b INT); +INSERT INTO t1 SELECT 1; +INSERT INTO t1 VALUES (2),(3),(4),(5),(6); +INSERT INTO t2 SELECT 1, ROW_COUNT(); +INSERT INTO t1 VALUES (2),(3),(4); +INSERT INTO t2 SELECT 2, ROW_COUNT(); +SELECT b FROM t2 ORDER BY a; +b +1 +3 +SELECT b FROM t2 ORDER BY a; +b +1 +3 +DROP TABLE t1, t2; diff --git a/mysql-test/suite/rpl/t/rpl_row_unsafe_funcs.test b/mysql-test/suite/rpl/t/rpl_row_unsafe_funcs.test new file mode 100644 index 00000000000..069700546ce --- /dev/null +++ b/mysql-test/suite/rpl/t/rpl_row_unsafe_funcs.test @@ -0,0 +1,35 @@ +source include/master-slave.inc; +source include/have_binlog_format_mixed.inc; + +# +# Bug #30244: row_count/found_rows does not replicate well +# + +connection master; + +CREATE TABLE t1 (a INT); +CREATE TABLE t2 (a INT, b INT); + +INSERT INTO t1 SELECT 1; + +connection master1; +INSERT INTO t1 VALUES (2),(3),(4),(5),(6); + +connection master; +INSERT INTO t2 SELECT 1, ROW_COUNT(); + +INSERT INTO t1 VALUES (2),(3),(4); +INSERT INTO t2 SELECT 2, ROW_COUNT(); + +#must return 1 and 3 +SELECT b FROM t2 ORDER BY a; + +sync_slave_with_master; + +#must return 1 and 3 +SELECT b FROM t2 ORDER BY a; + +connection master; +DROP TABLE t1, t2; +sync_slave_with_master; +connection master; diff --git a/sql/item_create.cc b/sql/item_create.cc index fa15b992e5c..4c8dbd267b4 100644 --- a/sql/item_create.cc +++ b/sql/item_create.cc @@ -3339,6 +3339,7 @@ Create_func_found_rows Create_func_found_rows::s_singleton; Item* Create_func_found_rows::create(THD *thd) { + thd->lex->set_stmt_unsafe(); thd->lex->safe_to_cache_query= 0; return new (thd->mem_root) Item_func_found_rows(); } @@ -4234,6 +4235,7 @@ Create_func_row_count Create_func_row_count::s_singleton; Item* Create_func_row_count::create(THD *thd) { + thd->lex->set_stmt_unsafe(); thd->lex->safe_to_cache_query= 0; return new (thd->mem_root) Item_func_row_count(); } From ff149b713cc8fef67a6b25945efa8e4f4f65bcdb Mon Sep 17 00:00:00 2001 From: unknown Date: Fri, 31 Aug 2007 16:59:07 +0500 Subject: [PATCH 10/20] Fixed bug #30126. When dumping database from a 4.x server, the mysqldump client inserted a delimiter sign inside special commentaries of the form: /*!... CREATE DATABASE IF NOT EXISTS ... ;*/ During restoration that dump file was splitten by delimiter signs on the client side, and the rest of some commentary strings was prepended to following statements. The 4x_server_emul test case option has been added for use with the DBUG_EXECUTE_IF debugging macro. This option affects debug server builds only to emulate particular behavior of a 4.x server for the mysqldump client testing. Non-debugging builds are not affected. mysql-test/r/mysqldump-compat.result: Added test case for bug #30126. mysql-test/t/mysqldump-compat.opt: Added test case for bug #30126. mysql-test/t/mysqldump-compat.test: Added test case for bug #30126. sql/sql_parse.cc: Fixed bug #30126. The mysqldump client uses the "SHOW CREATE DATABASE" query to obtain the "CREATE DATABASE" statement from that database. The 4.x server doesn't recognise that query, and mysqldump forms the "CREATE DATABASE" statement from scratch. That statement was formed incorrectly. To enforce the mysqldump client to create that statement from scratch, debugging code has been added to the mysql_execute_command function: in tcase of the --loose-debug=d,4x_server_emul option, the server returns parse error to client to emulate old behaviour. The 4x_server_emul test case option has been added for use with the DBUG_EXECUTE_IF debugging macro. This option affects debug server builds only to emulate particular behavior of a 4.x server for the mysqldump client testing. Non-debugging builds are not affected. client/mysqldump.c: Fixed bug #30126. The init_dumping_tables function has been modified to output semicolon outside of commentaries. --- client/mysqldump.c | 2 +- mysql-test/r/mysqldump-compat.result | 4 ++++ mysql-test/t/mysqldump-compat.opt | 1 + mysql-test/t/mysqldump-compat.test | 13 +++++++++++++ sql/sql_parse.cc | 2 ++ 5 files changed, 21 insertions(+), 1 deletion(-) create mode 100644 mysql-test/r/mysqldump-compat.result create mode 100644 mysql-test/t/mysqldump-compat.opt create mode 100644 mysql-test/t/mysqldump-compat.test diff --git a/client/mysqldump.c b/client/mysqldump.c index 577e439d6a7..cc8458c7a8e 100644 --- a/client/mysqldump.c +++ b/client/mysqldump.c @@ -2898,7 +2898,7 @@ int init_dumping_tables(char *qdatabase) /* Old server version, dump generic CREATE DATABASE */ if (opt_drop_database) fprintf(md_result_file, - "\n/*!40000 DROP DATABASE IF EXISTS %s;*/\n", + "\n/*!40000 DROP DATABASE IF EXISTS %s*/;\n", qdatabase); fprintf(md_result_file, "\nCREATE DATABASE /*!32312 IF NOT EXISTS*/ %s;\n", diff --git a/mysql-test/r/mysqldump-compat.result b/mysql-test/r/mysqldump-compat.result new file mode 100644 index 00000000000..f15cc7a1d7a --- /dev/null +++ b/mysql-test/r/mysqldump-compat.result @@ -0,0 +1,4 @@ +CREATE DATABASE mysqldump_30126; +USE mysqldump_30126; +CREATE TABLE t1 (c1 int); +DROP DATABASE mysqldump_30126; diff --git a/mysql-test/t/mysqldump-compat.opt b/mysql-test/t/mysqldump-compat.opt new file mode 100644 index 00000000000..40d4ac738a6 --- /dev/null +++ b/mysql-test/t/mysqldump-compat.opt @@ -0,0 +1 @@ +--loose-debug=d,4x_server_emul diff --git a/mysql-test/t/mysqldump-compat.test b/mysql-test/t/mysqldump-compat.test new file mode 100644 index 00000000000..848d66cc728 --- /dev/null +++ b/mysql-test/t/mysqldump-compat.test @@ -0,0 +1,13 @@ +# Embedded server doesn't support external clients +--source include/not_embedded.inc + +# +# Bug #30126: semicolon before closing */ in /*!... CREATE DATABASE ;*/ +# + +CREATE DATABASE mysqldump_30126; +USE mysqldump_30126; +CREATE TABLE t1 (c1 int); +--exec $MYSQL_DUMP --add-drop-database mysqldump_30126 > $MYSQLTEST_VARDIR/tmp/bug30126.sql +--exec $MYSQL mysqldump_30126 < $MYSQLTEST_VARDIR/tmp/bug30126.sql +DROP DATABASE mysqldump_30126; diff --git a/sql/sql_parse.cc b/sql/sql_parse.cc index 58f5ffc5235..bb3ab9a67fe 100644 --- a/sql/sql_parse.cc +++ b/sql/sql_parse.cc @@ -3990,6 +3990,8 @@ end_with_restore_list: } case SQLCOM_SHOW_CREATE_DB: { + DBUG_EXECUTE_IF("4x_server_emul", + my_error(ER_UNKNOWN_ERROR, MYF(0)); goto error;); if (!strip_sp(lex->name) || check_db_name(lex->name)) { my_error(ER_WRONG_DB_NAME, MYF(0), lex->name); From ee0b7d895d42b0e3c93bdbffa7c4d3f51c1f60c2 Mon Sep 17 00:00:00 2001 From: unknown Date: Mon, 3 Sep 2007 12:22:56 +0500 Subject: [PATCH 11/20] Bug#29408 Cannot find view in columns table if the selection contains a function Use view db name as thread default database, in order to ensure that the view is parsed and prepared correctly. mysql-test/r/sp.result: test result mysql-test/t/sp.test: test case sql/sql_parse.cc: copy thd->db_length to table_list->db_length sql/sql_view.cc: Use view db name as thread default database, in order to ensure that the view is parsed and prepared correctly. --- mysql-test/r/sp.result | 22 ++++++++++++++++++++++ mysql-test/t/sp.test | 33 +++++++++++++++++++++++++++++++++ sql/sql_parse.cc | 2 +- sql/sql_view.cc | 14 ++++++++++++++ 4 files changed, 70 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/sp.result b/mysql-test/r/sp.result index 4a278cd4aec..917ade02e0a 100644 --- a/mysql-test/r/sp.result +++ b/mysql-test/r/sp.result @@ -6314,4 +6314,26 @@ CALL p1(); NULL SET NAMES default; DROP PROCEDURE p1; +create function f1() +returns int(11) +not deterministic +contains sql +sql security definer +comment '' +begin +declare x int(11); +set x=-1; +return x; +end| +create view v1 as select 1 as one, f1() as days; +show create view test.v1; +View Create View +v1 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `test`.`v1` AS select 1 AS `one`,`f1`() AS `days` +select column_name from information_schema.columns +where table_name='v1' and table_schema='test'; +column_name +one +days +drop view v1; +drop function f1; End of 5.0 tests diff --git a/mysql-test/t/sp.test b/mysql-test/t/sp.test index 46a1b1dc740..f1c7c6969db 100644 --- a/mysql-test/t/sp.test +++ b/mysql-test/t/sp.test @@ -7299,4 +7299,37 @@ CALL p1(); SET NAMES default; DROP PROCEDURE p1; +# +# Bug#29408 Cannot find view in columns table if the selection contains a function +# +delimiter |; + +create function f1() + returns int(11) +not deterministic +contains sql +sql security definer +comment '' +begin + declare x int(11); + set x=-1; + return x; +end| + +delimiter ;| + +create view v1 as select 1 as one, f1() as days; + +connect (bug29408, localhost, root,,*NO-ONE*); +connection bug29408; + +show create view test.v1; +select column_name from information_schema.columns +where table_name='v1' and table_schema='test'; + +connection default; +disconnect bug29408; +drop view v1; +drop function f1; + --echo End of 5.0 tests diff --git a/sql/sql_parse.cc b/sql/sql_parse.cc index bb3ab9a67fe..084bcfc3c76 100644 --- a/sql/sql_parse.cc +++ b/sql/sql_parse.cc @@ -1864,7 +1864,7 @@ bool dispatch_command(enum enum_server_command command, THD *thd, statistic_increment(thd->status_var.com_stat[SQLCOM_SHOW_FIELDS], &LOCK_status); bzero((char*) &table_list,sizeof(table_list)); - if (thd->copy_db_to(&table_list.db, 0)) + if (thd->copy_db_to(&table_list.db, &table_list.db_length)) break; pend= strend(packet); thd->convert_string(&conv_name, system_charset_info, diff --git a/sql/sql_view.cc b/sql/sql_view.cc index 56d7a3f8a9d..35a97411511 100644 --- a/sql/sql_view.cc +++ b/sql/sql_view.cc @@ -1008,8 +1008,19 @@ bool mysql_make_view(THD *thd, File_parser *parser, TABLE_LIST *table, table->view= lex= thd->lex= (LEX*) new(thd->mem_root) st_lex_local; { + char old_db_buf[NAME_LEN+1]; + LEX_STRING old_db= { old_db_buf, sizeof(old_db_buf) }; + bool dbchanged; Lex_input_stream lip(thd, table->query.str, table->query.length); thd->m_lip= &lip; + + /* + Use view db name as thread default database, in order to ensure + that the view is parsed and prepared correctly. + */ + if ((result= sp_use_new_db(thd, table->view_db, &old_db, 1, &dbchanged))) + goto end; + lex_start(thd); view_select= &lex->select_lex; view_select->select_number= ++thd->select_number; @@ -1051,6 +1062,9 @@ bool mysql_make_view(THD *thd, File_parser *parser, TABLE_LIST *table, thd->variables.character_set_client= save_cs; thd->variables.sql_mode= save_mode; + + if (dbchanged && mysql_change_db(thd, &old_db, TRUE)) + goto err; } if (!res && !thd->is_fatal_error) { From f0d4beee7925035658a9ed4e48b826f699c31b7a Mon Sep 17 00:00:00 2001 From: unknown Date: Mon, 3 Sep 2007 11:55:35 +0200 Subject: [PATCH 12/20] Bug #30234: Unexpected behavior using DELETE with AS and USING DELETE FROM ... USING ... statements with the following type of ambiguous aliasing gave unexpected results: DELETE FROM t1 AS alias USING t1, t2 AS alias WHERE t1.a = alias.a; This query would leave table t1 intact but delete rows from t2. Fixed by changing DELETE FROM ... USING syntax so that only alias references (as opposed to alias declarations) may be used in FROM. mysql-test/r/delete.result: Bug#30234: Test Result mysql-test/t/delete.test: Bug#30234: Test Case sql/sql_yacc.yy: Bug#30234: - Added parser rule table_alias_ref_list that contains a list of table aliases only. - Added parser rule table_alias_ref that sets the TL_OPTION_ALIAS in order to turn off semantic checking that applies only for table names. --- mysql-test/r/delete.result | 37 ++++++++++++++++++++++++++++++++ mysql-test/t/delete.test | 44 ++++++++++++++++++++++++++++++++++++++ sql/sql_yacc.yy | 19 ++++++++++++++-- 3 files changed, 98 insertions(+), 2 deletions(-) diff --git a/mysql-test/r/delete.result b/mysql-test/r/delete.result index 4bdf1c770d3..d333425f23a 100644 --- a/mysql-test/r/delete.result +++ b/mysql-test/r/delete.result @@ -223,3 +223,40 @@ ERROR 42S22: Unknown column 't2.x' in 'order clause' DELETE FROM t1 ORDER BY (SELECT x); ERROR 42S22: Unknown column 'x' in 'field list' DROP TABLE t1; +CREATE TABLE t1 ( +a INT +); +CREATE TABLE t2 ( +a INT +); +CREATE DATABASE db1; +CREATE TABLE db1.t1 ( +a INT +); +INSERT INTO db1.t1 (a) SELECT * FROM t1; +CREATE DATABASE db2; +CREATE TABLE db2.t1 ( +a INT +); +INSERT INTO db2.t1 (a) SELECT * FROM t2; +DELETE FROM t1 alias USING t1, t2 alias WHERE t1.a = alias.a; +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'alias USING t1, t2 alias WHERE t1.a = alias.a' at line 1 +DELETE FROM alias USING t1, t2 alias WHERE t1.a = alias.a; +DELETE FROM t1, alias USING t1, t2 alias WHERE t1.a = alias.a; +DELETE FROM t1, t2 USING t1, t2 alias WHERE t1.a = alias.a; +ERROR 42S02: Unknown table 't2' in MULTI DELETE +DELETE FROM db1.t1 alias USING db1.t1, db2.t1 alias WHERE db1.t1.a = alias.a; +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'alias USING db1.t1, db2.t1 alias WHERE db1.t1.a = alias.a' at line 1 +DELETE FROM alias USING db1.t1, db2.t1 alias WHERE db1.t1.a = alias.a; +ERROR 42S02: Unknown table 'alias' in MULTI DELETE +DELETE FROM db2.alias USING db1.t1, db2.t1 alias WHERE db1.t1.a = alias.a; +DELETE FROM t1 USING t1 WHERE a = 1; +SELECT * FROM t1; +a +DELETE FROM t1 alias USING t1 alias WHERE a = 2; +ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'alias USING t1 alias WHERE a = 2' at line 1 +SELECT * FROM t1; +a +DROP TABLE t1, t2; +DROP DATABASE db1; +DROP DATABASE db2; diff --git a/mysql-test/t/delete.test b/mysql-test/t/delete.test index 36d627209db..e3713d248c4 100644 --- a/mysql-test/t/delete.test +++ b/mysql-test/t/delete.test @@ -221,3 +221,47 @@ DELETE FROM t1 ORDER BY t2.x; DELETE FROM t1 ORDER BY (SELECT x); DROP TABLE t1; + +# +# Bug #30234: Unexpected behavior using DELETE with AS and USING +# ' +CREATE TABLE t1 ( + a INT +); + +CREATE TABLE t2 ( + a INT +); + +CREATE DATABASE db1; +CREATE TABLE db1.t1 ( + a INT +); +INSERT INTO db1.t1 (a) SELECT * FROM t1; + +CREATE DATABASE db2; +CREATE TABLE db2.t1 ( + a INT +); +INSERT INTO db2.t1 (a) SELECT * FROM t2; + +--error ER_PARSE_ERROR +DELETE FROM t1 alias USING t1, t2 alias WHERE t1.a = alias.a; +DELETE FROM alias USING t1, t2 alias WHERE t1.a = alias.a; +DELETE FROM t1, alias USING t1, t2 alias WHERE t1.a = alias.a; +--error ER_UNKNOWN_TABLE +DELETE FROM t1, t2 USING t1, t2 alias WHERE t1.a = alias.a; +--error ER_PARSE_ERROR +DELETE FROM db1.t1 alias USING db1.t1, db2.t1 alias WHERE db1.t1.a = alias.a; +--error ER_UNKNOWN_TABLE +DELETE FROM alias USING db1.t1, db2.t1 alias WHERE db1.t1.a = alias.a; +DELETE FROM db2.alias USING db1.t1, db2.t1 alias WHERE db1.t1.a = alias.a; +DELETE FROM t1 USING t1 WHERE a = 1; +SELECT * FROM t1; +--error ER_PARSE_ERROR +DELETE FROM t1 alias USING t1 alias WHERE a = 2; +SELECT * FROM t1; + +DROP TABLE t1, t2; +DROP DATABASE db1; +DROP DATABASE db2; diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index 6fbd521e302..de64e7664b1 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -1159,7 +1159,8 @@ bool my_yyoverflow(short **a, YYSTYPE **b, ulong *yystacksize); field_opt_list opt_binary table_lock_list table_lock ref_list opt_on_delete opt_on_delete_list opt_on_delete_item use opt_delete_options opt_delete_option varchar nchar nvarchar - opt_outer table_list table_name opt_option opt_place + opt_outer table_list table_name table_alias_ref_list table_alias_ref + opt_option opt_place opt_attribute opt_attribute_list attribute column_list column_list_id opt_column_list grant_privileges grant_ident grant_list grant_option object_privilege object_privilege_list user_list rename_list @@ -6504,6 +6505,20 @@ table_name: } ; +table_alias_ref_list: + table_alias_ref + | table_alias_ref_list ',' table_alias_ref; + +table_alias_ref: + table_ident + { + if (!Select->add_table_to_list(YYTHD, $1, NULL, + TL_OPTION_UPDATING | TL_OPTION_ALIAS, + Lex->lock_option )) + MYSQL_YYABORT; + } + ; + if_exists: /* empty */ { $$= 0; } | IF EXISTS { $$= 1; } @@ -6774,7 +6789,7 @@ single_multi: if (multi_delete_set_locks_and_link_aux_tables(Lex)) MYSQL_YYABORT; } - | FROM table_wild_list + | FROM table_alias_ref_list { mysql_init_multi_delete(Lex); } USING join_table_list where_clause { From 6a71b067b03c43d90012718cce2b040892c7ac86 Mon Sep 17 00:00:00 2001 From: unknown Date: Wed, 5 Sep 2007 11:35:29 +0500 Subject: [PATCH 13/20] Fixed bug #29938. mysqldump --skip-events --all-databases dumped data of the mysqld.event table, and during the restoration from this dump events were created in spite of the --skip-events option. The mysqldump client has been modified to ignore mysql.event table data in case of --skip-events options. client/mysqldump.c: Fixed bug #29938. The dump_table function has been modified to skip dumping of the mysql.event table data in case of the --skip-event mysqldump client option. mysql-test/t/mysqldump.test: Updated test case for bug #29938. mysql-test/r/mysqldump.result: Updated test case for bug #29938. --- client/mysqldump.c | 12 ++++++++++++ mysql-test/r/mysqldump.result | 13 +++++++++++++ mysql-test/t/mysqldump.test | 16 ++++++++++++++++ 3 files changed, 41 insertions(+) diff --git a/client/mysqldump.c b/client/mysqldump.c index 3d2aec92dea..e6b707f9811 100644 --- a/client/mysqldump.c +++ b/client/mysqldump.c @@ -3039,6 +3039,18 @@ static void dump_table(char *table, char *db) DBUG_VOID_RETURN; } + /* + Check --skip-events flag: it is not enough to skip creation of events + discarding SHOW CREATE EVENT statements generation. The myslq.event + table data should be skipped too. + */ + if (!opt_events && !my_strcasecmp(&my_charset_latin1, db, "mysql") && + !my_strcasecmp(&my_charset_latin1, table, "event")) + { + verbose_msg("-- Skipping data table mysql.event, --skip-events was used\n"); + DBUG_VOID_RETURN; + } + result_table= quote_name(table,table_buff, 1); opt_quoted_table= quote_name(table, table_buff2, 0); diff --git a/mysql-test/r/mysqldump.result b/mysql-test/r/mysqldump.result index 58bcac42f9c..d8688ea5509 100644 --- a/mysql-test/r/mysqldump.result +++ b/mysql-test/r/mysqldump.result @@ -4177,5 +4177,18 @@ set names latin1; # Cleanup. DROP DATABASE mysqldump_test_db; # +# BUG#29938: wrong behavior of mysqldump --skip-events +# with --all-databases +# +TRUNCATE mysql.event; +USE test; +CREATE event e29938 ON SCHEDULE AT '2035-12-31 20:01:23' DO SET @bug29938=29938; +SHOW EVENTS; +Db Name Definer Time zone Type Execute at Interval value Interval field Starts Ends Status Originator character_set_client collation_connection Database Collation +test e29938 root@localhost SYSTEM ONE TIME 2035-12-31 20:01:23 NULL NULL NULL NULL ENABLED 1 latin1 latin1_swedish_ci latin1_swedish_ci +TRUNCATE mysql.event; +SHOW EVENTS; +Db Name Definer Time zone Type Execute at Interval value Interval field Starts Ends Status Originator character_set_client collation_connection Database Collation +# # End of 5.1 tests # diff --git a/mysql-test/t/mysqldump.test b/mysql-test/t/mysqldump.test index 171434f9dfd..0440b0fb63a 100644 --- a/mysql-test/t/mysqldump.test +++ b/mysql-test/t/mysqldump.test @@ -1755,6 +1755,22 @@ DROP DATABASE mysqldump_test_db; ########################################################################### +--echo # +--echo # BUG#29938: wrong behavior of mysqldump --skip-events +--echo # with --all-databases +--echo # + +TRUNCATE mysql.event; + +USE test; +CREATE event e29938 ON SCHEDULE AT '2035-12-31 20:01:23' DO SET @bug29938=29938; +SHOW EVENTS; +--exec $MYSQL_DUMP --skip-events --all-databases > $MYSQLTEST_VARDIR/tmp/bug29938.sql + +TRUNCATE mysql.event; +--exec $MYSQL < $MYSQLTEST_VARDIR/tmp/bug29938.sql +SHOW EVENTS; + --echo # --echo # End of 5.1 tests --echo # From d9a7fd12ffc1953712175b6b2293510782ebf1dd Mon Sep 17 00:00:00 2001 From: unknown Date: Thu, 6 Sep 2007 20:42:36 +0500 Subject: [PATCH 14/20] sp.result: Post-merge fix. mysql-test/r/sp.result: Post-merge fix. --- mysql-test/r/sp.result | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/mysql-test/r/sp.result b/mysql-test/r/sp.result index e1279c783e1..3be5aa374b4 100644 --- a/mysql-test/r/sp.result +++ b/mysql-test/r/sp.result @@ -6559,8 +6559,8 @@ return x; end| create view v1 as select 1 as one, f1() as days; show create view test.v1; -View Create View -v1 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `test`.`v1` AS select 1 AS `one`,`f1`() AS `days` +View Create View character_set_client collation_connection +v1 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `test`.`v1` AS select 1 AS `one`,`f1`() AS `days` latin1 latin1_swedish_ci select column_name from information_schema.columns where table_name='v1' and table_schema='test'; column_name From d7262773e13978f123a1407f12ab675aefc0aa76 Mon Sep 17 00:00:00 2001 From: unknown Date: Thu, 6 Sep 2007 21:56:46 +0500 Subject: [PATCH 15/20] sql_parse.cc: Post-merge fix. sql/sql_parse.cc: Post-merge fix. --- sql/sql_parse.cc | 1 - 1 file changed, 1 deletion(-) diff --git a/sql/sql_parse.cc b/sql/sql_parse.cc index a3703dc78df..1b6e179aa09 100644 --- a/sql/sql_parse.cc +++ b/sql/sql_parse.cc @@ -1003,7 +1003,6 @@ bool dispatch_command(enum enum_server_command command, THD *thd, /* Locked closure of all tables */ TABLE_LIST table_list; LEX_STRING conv_name; - size_t dummy; /* used as fields initializator */ lex_start(thd); From afd34c69be22a45a85799297894d5725637d1dd5 Mon Sep 17 00:00:00 2001 From: unknown Date: Fri, 7 Sep 2007 18:41:49 +0500 Subject: [PATCH 16/20] Bug #28430 Failure in replication of innodb partitioned tables on row/mixed format. In the ha_partition::position() we don't calculate the number of the partition of the record, but use m_last_part value instead, relying on that it's previously set by some other call like ::write_row(). Delete_rows_log_event::do_exec_row() calls find_and_fetch_row(), where we used position() + rnd_pos() call for the InnoDB-based PARTITION-ed table as there HA_PRIMARY_KEY_REQUIRED_FOR_POSITION enabled. fixed by introducing new handler::rnd_pos_by_record() method to be used for random record-based positioning sql/ha_partition.cc: Bug #28430 Failure in replication of innodb partitioned tables on row/mixed format. ha_partition::rnd_pos_by_record() implemented sql/ha_partition.h: Bug #28430 Failure in replication of innodb partitioned tables on row/mixed format. ha_partition::rnd_pos_by_record() declared sql/handler.h: Bug #28430 Failure in replication of innodb partitioned tables on row/mixed format. handler::rnd_pos_by_record() introduced sql/log_event.cc: Bug #28430 Failure in replication of innodb partitioned tables on row/mixed format. handler::rnd_pos_by_record used instead of position() + rnd_pos() call --- sql/ha_partition.cc | 38 ++++++++++++++++++++++++++++++++------ sql/ha_partition.h | 1 + sql/handler.h | 11 +++++++++++ sql/log_event.cc | 3 +-- 4 files changed, 45 insertions(+), 8 deletions(-) diff --git a/sql/ha_partition.cc b/sql/ha_partition.cc index bff94da63bb..88e5eecc94f 100644 --- a/sql/ha_partition.cc +++ b/sql/ha_partition.cc @@ -3235,14 +3235,9 @@ end_dont_reset_start_part: void ha_partition::position(const uchar *record) { - handler *file; + handler *file= m_file[m_last_part]; DBUG_ENTER("ha_partition::position"); - if (unlikely(get_part_for_delete(record, m_rec0, m_part_info, &m_last_part))) - m_last_part= 0; - - file= m_file[m_last_part]; - file->position(record); int2store(ref, m_last_part); memcpy((ref + PARTITION_BYTES_IN_POS), file->ref, @@ -3257,6 +3252,7 @@ void ha_partition::position(const uchar *record) DBUG_VOID_RETURN; } + /* Read row using position @@ -3292,6 +3288,36 @@ int ha_partition::rnd_pos(uchar * buf, uchar *pos) } +/* + Read row using position using given record to find + + SYNOPSIS + rnd_pos_by_record() + record Current record in MySQL Row Format + + RETURN VALUE + >0 Error code + 0 Success + + DESCRIPTION + this works as position()+rnd_pos() functions, but does some extra work, + calculating m_last_part - the partition to where the 'record' + should go. + + called from replication (log_event.cc) +*/ + +int ha_partition::rnd_pos_by_record(uchar *record) +{ + DBUG_ENTER("ha_partition::rnd_pos_by_record"); + + if (unlikely(get_part_for_delete(record, m_rec0, m_part_info, &m_last_part))) + DBUG_RETURN(1); + + DBUG_RETURN(handler::rnd_pos_by_record(record)); +} + + /**************************************************************************** MODULE index scan ****************************************************************************/ diff --git a/sql/ha_partition.h b/sql/ha_partition.h index 434d90a4487..8fe512fadb3 100644 --- a/sql/ha_partition.h +++ b/sql/ha_partition.h @@ -353,6 +353,7 @@ public: virtual int rnd_end(); virtual int rnd_next(uchar * buf); virtual int rnd_pos(uchar * buf, uchar * pos); + virtual int rnd_pos_by_record(uchar *record); virtual void position(const uchar * record); /* diff --git a/sql/handler.h b/sql/handler.h index 557b9fd7887..b91d8a39b88 100644 --- a/sql/handler.h +++ b/sql/handler.h @@ -1343,6 +1343,17 @@ public: virtual int ft_read(uchar *buf) { return HA_ERR_WRONG_COMMAND; } virtual int rnd_next(uchar *buf)=0; virtual int rnd_pos(uchar * buf, uchar *pos)=0; + /* + one has to use this method when to find + random position by record as the plain + position() call doesn't work for some + handlers for random position + */ + virtual int rnd_pos_by_record(uchar *record) + { + position(record); + return rnd_pos(record, ref); + } virtual int read_first_row(uchar *buf, uint primary_key); /* The following function is only needed for tables that may be temporary diff --git a/sql/log_event.cc b/sql/log_event.cc index 7d9c7c69574..14936495c2b 100644 --- a/sql/log_event.cc +++ b/sql/log_event.cc @@ -7509,8 +7509,7 @@ static int find_and_fetch_row(TABLE *table, uchar *key) table->s->reclength) == 0); */ - table->file->position(table->record[0]); - int error= table->file->rnd_pos(table->record[0], table->file->ref); + int error= table->file->rnd_pos_by_record(table->record[0]); /* rnd_pos() returns the record in table->record[0], so we have to move it to table->record[1]. From 732f05a642279a569c6ed2b67fafff05b9de76c3 Mon Sep 17 00:00:00 2001 From: unknown Date: Mon, 10 Sep 2007 16:26:51 +0400 Subject: [PATCH 17/20] BUG#30385: Server crash when deleting with ORDER BY and LIMIT in get_index_for_order(), don't walk over the end of the index key parts when matching index description and needed ordering. mysql-test/r/delete.result: BUG#30385: Testcase mysql-test/t/delete.test: BUG#30385: Testcase --- mysql-test/r/delete.result | 11 +++++++++++ mysql-test/t/delete.test | 13 +++++++++++++ sql/opt_range.cc | 3 ++- 3 files changed, 26 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/delete.result b/mysql-test/r/delete.result index a5c22e66569..5dd37e6b98d 100644 --- a/mysql-test/r/delete.result +++ b/mysql-test/r/delete.result @@ -193,4 +193,15 @@ select @a; @a 1 drop table t1; +CREATE TABLE t1 ( +`date` date , +`time` time , +`seq` int(10) unsigned NOT NULL auto_increment, +PRIMARY KEY (`seq`), +KEY `seq` (`seq`), +KEY `time` (`time`), +KEY `date` (`date`) +); +DELETE FROM t1 ORDER BY date ASC, time ASC LIMIT 1; +drop table t1; End of 4.1 tests diff --git a/mysql-test/t/delete.test b/mysql-test/t/delete.test index 301b2cdbb99..fdbb96e0c2f 100644 --- a/mysql-test/t/delete.test +++ b/mysql-test/t/delete.test @@ -184,4 +184,17 @@ delete from t1 where (@a:= f1) order by f1 limit 1; select @a; drop table t1; +# BUG#30385 "Server crash when deleting with order by and limit" +CREATE TABLE t1 ( + `date` date , + `time` time , + `seq` int(10) unsigned NOT NULL auto_increment, + PRIMARY KEY (`seq`), + KEY `seq` (`seq`), + KEY `time` (`time`), + KEY `date` (`date`) +); +DELETE FROM t1 ORDER BY date ASC, time ASC LIMIT 1; +drop table t1; + --echo End of 4.1 tests diff --git a/sql/opt_range.cc b/sql/opt_range.cc index 01b366077b0..a8ba609f9dc 100644 --- a/sql/opt_range.cc +++ b/sql/opt_range.cc @@ -825,6 +825,7 @@ uint get_index_for_order(TABLE *table, ORDER *order, ha_rows limit) if (!(table->keys_in_use_for_query.is_set(idx))) continue; KEY_PART_INFO *keyinfo= table->key_info[idx].key_part; + uint n_parts= table->key_info[idx].key_parts; uint partno= 0; /* @@ -834,7 +835,7 @@ uint get_index_for_order(TABLE *table, ORDER *order, ha_rows limit) */ if (!(table->file->index_flags(idx, 0, 1) & HA_READ_ORDER)) continue; - for (ord= order; ord; ord= ord->next, partno++) + for (ord= order; ord && partno < n_parts; ord= ord->next, partno++) { Item *item= order->item[0]; if (!(item->type() == Item::FIELD_ITEM && From 4e5c03961a60eb056e0dd43427cdec2f57de1144 Mon Sep 17 00:00:00 2001 From: unknown Date: Tue, 11 Sep 2007 02:41:42 +0400 Subject: [PATCH 18/20] Post-merge fixes --- mysql-test/t/delete.test | 1 - 1 file changed, 1 deletion(-) diff --git a/mysql-test/t/delete.test b/mysql-test/t/delete.test index df8c529407e..8a03cb6c715 100644 --- a/mysql-test/t/delete.test +++ b/mysql-test/t/delete.test @@ -187,7 +187,6 @@ DELETE FROM t1 ORDER BY date ASC, time ASC LIMIT 1; drop table t1; --echo End of 4.1 tests -# End of 4.1 tests # # Test of multi-delete where we are not scanning the first table From 4c2d50e426a9c93445a6759d5761e551c9da7ec7 Mon Sep 17 00:00:00 2001 From: unknown Date: Tue, 11 Sep 2007 20:47:17 +0500 Subject: [PATCH 19/20] merging --- mysql-test/r/partition_pruning.result | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/mysql-test/r/partition_pruning.result b/mysql-test/r/partition_pruning.result index 776e6f3a15a..9595676016c 100644 --- a/mysql-test/r/partition_pruning.result +++ b/mysql-test/r/partition_pruning.result @@ -631,7 +631,7 @@ flush status; delete from t2 where b > 5; show status like 'Handler_read_rnd_next'; Variable_name Value -Handler_read_rnd_next 1115 +Handler_read_rnd_next 1215 show status like 'Handler_read_key'; Variable_name Value Handler_read_key 0 @@ -645,7 +645,7 @@ flush status; delete from t2 where b < 5 or b > 3; show status like 'Handler_read_rnd_next'; Variable_name Value -Handler_read_rnd_next 1115 +Handler_read_rnd_next 1215 show status like 'Handler_read_key'; Variable_name Value Handler_read_key 0 From ba39449e01c88f84a3a1b0cbc55fadb77ef20e82 Mon Sep 17 00:00:00 2001 From: unknown Date: Wed, 12 Sep 2007 01:52:27 +0400 Subject: [PATCH 20/20] Post-merge fixes --- mysql-test/r/delete.result | 1 - 1 file changed, 1 deletion(-) diff --git a/mysql-test/r/delete.result b/mysql-test/r/delete.result index a3ba61c9046..5084498c01c 100644 --- a/mysql-test/r/delete.result +++ b/mysql-test/r/delete.result @@ -195,7 +195,6 @@ KEY `date` (`date`) DELETE FROM t1 ORDER BY date ASC, time ASC LIMIT 1; drop table t1; End of 4.1 tests -End of 4.1 tests CREATE TABLE t1 (a int not null,b int not null); CREATE TABLE t2 (a int not null, b int not null, primary key (a,b)); CREATE TABLE t3 (a int not null, b int not null, primary key (a,b));