From 1a0cf6db7ca901547c667ac3d2d3c11db28a8eec Mon Sep 17 00:00:00 2001 From: "igor@olga.mysql.com" <> Date: Tue, 1 May 2007 23:34:14 -0700 Subject: [PATCH 1/7] Fixed bug #28188: performance degradation for outer join queries to which 'not exists' optimization is applied. In fact 'not exists' optimization did not work anymore after the patch introducing the evaluate_join_record function had been applied. Corrected the evaluate_join_record function to respect the 'not_exists' optimization. --- mysql-test/r/join_outer.result | 25 +++++++++++++++++++++++++ mysql-test/t/join_outer.test | 20 ++++++++++++++++++++ sql/sql_select.cc | 5 ++--- 3 files changed, 47 insertions(+), 3 deletions(-) diff --git a/mysql-test/r/join_outer.result b/mysql-test/r/join_outer.result index df66336bd81..c62601946c2 100644 --- a/mysql-test/r/join_outer.result +++ b/mysql-test/r/join_outer.result @@ -1214,3 +1214,28 @@ SELECT * FROM t1 LEFT JOIN t2 USING(f1) WHERE f1='Bla'; f1 f2 f3 bla blah sheep DROP TABLE t1,t2; +CREATE TABLE t1 (id int PRIMARY KEY, a varchar(8)); +CREATE TABLE t2 (id int NOT NULL, b int NOT NULL, INDEX idx(id)); +INSERT INTO t1 VALUES +(1,'aaaaaaa'), (5,'eeeeeee'), (4,'ddddddd'), (2,'bbbbbbb'), (3,'ccccccc'); +INSERT INTO t2 VALUES +(3,10), (2,20), (5,30), (3,20), (5,10), (3,40), (3,30), (2,10), (2,40); +EXPLAIN +SELECT t1.id, a FROM t1 LEFT JOIN t2 ON t1.id=t2.id WHERE t2.b IS NULL; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 5 +1 SIMPLE t2 ref idx idx 4 test.t1.id 2 Using where; Not exists +flush status; +SELECT t1.id, a FROM t1 LEFT JOIN t2 ON t1.id=t2.id WHERE t2.b IS NULL; +id a +1 aaaaaaa +4 ddddddd +show status like 'Handler_read%'; +Variable_name Value +Handler_read_first 0 +Handler_read_key 5 +Handler_read_next 0 +Handler_read_prev 0 +Handler_read_rnd 0 +Handler_read_rnd_next 6 +DROP TABLE t1,t2; diff --git a/mysql-test/t/join_outer.test b/mysql-test/t/join_outer.test index a0620e144c2..51e79a20d65 100644 --- a/mysql-test/t/join_outer.test +++ b/mysql-test/t/join_outer.test @@ -825,3 +825,23 @@ SELECT * FROM t1 LEFT JOIN t2 USING(f1) WHERE f1='bla'; SELECT * FROM t1 LEFT JOIN t2 USING(f1) WHERE f1='Bla'; DROP TABLE t1,t2; + +# +# Bug 28188: 'not exists' optimization for outer joins +# + +CREATE TABLE t1 (id int PRIMARY KEY, a varchar(8)); +CREATE TABLE t2 (id int NOT NULL, b int NOT NULL, INDEX idx(id)); +INSERT INTO t1 VALUES + (1,'aaaaaaa'), (5,'eeeeeee'), (4,'ddddddd'), (2,'bbbbbbb'), (3,'ccccccc'); +INSERT INTO t2 VALUES + (3,10), (2,20), (5,30), (3,20), (5,10), (3,40), (3,30), (2,10), (2,40); + +EXPLAIN +SELECT t1.id, a FROM t1 LEFT JOIN t2 ON t1.id=t2.id WHERE t2.b IS NULL; + +flush status; +SELECT t1.id, a FROM t1 LEFT JOIN t2 ON t1.id=t2.id WHERE t2.b IS NULL; +show status like 'Handler_read%'; + +DROP TABLE t1,t2; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index b7ac2130784..acef5a5ff48 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -10526,7 +10526,6 @@ static enum_nested_loop_state evaluate_join_record(JOIN *join, JOIN_TAB *join_tab, int error, my_bool *report_error) { - bool not_exists_optimize= join_tab->table->reginfo.not_exists_optimize; bool not_used_in_distinct=join_tab->not_used_in_distinct; ha_rows found_records=join->found_records; COND *select_cond= join_tab->select_cond; @@ -10563,6 +10562,8 @@ evaluate_join_record(JOIN *join, JOIN_TAB *join_tab, first_unmatched->found= 1; for (JOIN_TAB *tab= first_unmatched; tab <= join_tab; tab++) { + if (tab->table->reginfo.not_exists_optimize) + return NESTED_LOOP_NO_MORE_ROWS; /* Check all predicates that has just been activated. */ /* Actually all predicates non-guarded by first_unmatched->found @@ -10608,8 +10609,6 @@ evaluate_join_record(JOIN *join, JOIN_TAB *join_tab, if (found) { enum enum_nested_loop_state rc; - if (not_exists_optimize) - return NESTED_LOOP_NO_MORE_ROWS; /* A match from join_tab is found for the current partial join. */ rc= (*join_tab->next_select)(join, join_tab+1, 0); if (rc != NESTED_LOOP_OK && rc != NESTED_LOOP_NO_MORE_ROWS) From 7f9411c156610819d470cb2786ef69850b4369fb Mon Sep 17 00:00:00 2001 From: "evgen@moonbone.local" <> Date: Fri, 4 May 2007 00:53:37 +0400 Subject: [PATCH 2/7] Bug#23656: Wrong conversion result of a DATETIME to integer using CAST function. The generic string to int conversion was used by the Item_func_signed and the Item_func_unsigned classes to convert DATE/DATETIME values to the SIGNED/UNSIGNED type. But this conversion produces wrong results for such values. Now if the item which result has to be converted can return its result as longlong then the item->val_int() method is used to allow the item to carry out the conversion itself and return the correct result. This condition is checked in the Item_func_signed::val_int() and the Item_func_unsigned::val_int() functions. --- mysql-test/r/cast.result | 6 ++++++ mysql-test/t/cast.test | 6 ++++++ sql/item_func.cc | 6 ++++-- 3 files changed, 16 insertions(+), 2 deletions(-) diff --git a/mysql-test/r/cast.result b/mysql-test/r/cast.result index 23c38bb792c..f6f46bd4079 100644 --- a/mysql-test/r/cast.result +++ b/mysql-test/r/cast.result @@ -281,4 +281,10 @@ DROP TABLE t1; select isnull(date(NULL)), isnull(cast(NULL as DATE)); isnull(date(NULL)) isnull(cast(NULL as DATE)) 1 1 +SELECT CAST(cast('01-01-01' as date) AS UNSIGNED); +CAST(cast('01-01-01' as date) AS UNSIGNED) +20010101 +SELECT CAST(cast('01-01-01' as date) AS SIGNED); +CAST(cast('01-01-01' as date) AS SIGNED) +20010101 End of 4.1 tests diff --git a/mysql-test/t/cast.test b/mysql-test/t/cast.test index 7e8ef031e6b..8eef66f9e1b 100644 --- a/mysql-test/t/cast.test +++ b/mysql-test/t/cast.test @@ -173,4 +173,10 @@ DROP TABLE t1; select isnull(date(NULL)), isnull(cast(NULL as DATE)); +# +# Bug#23656: Wrong result of CAST from DATE to int +# +SELECT CAST(cast('01-01-01' as date) AS UNSIGNED); +SELECT CAST(cast('01-01-01' as date) AS SIGNED); + --echo End of 4.1 tests diff --git a/sql/item_func.cc b/sql/item_func.cc index c6b2fa5cc3e..12bb6571369 100644 --- a/sql/item_func.cc +++ b/sql/item_func.cc @@ -477,7 +477,8 @@ longlong Item_func_signed::val_int() longlong value; int error; - if (args[0]->cast_to_int_type() != STRING_RESULT) + if (args[0]->cast_to_int_type() != STRING_RESULT || + args[0]->result_as_longlong()) { value= args[0]->val_int(); null_value= args[0]->null_value; @@ -529,7 +530,8 @@ longlong Item_func_unsigned::val_int() return (longlong) (dvalue + (dvalue > 0 ? 0.5 : -0.5)); } - if (args[0]->cast_to_int_type() != STRING_RESULT) + if (args[0]->cast_to_int_type() != STRING_RESULT || + args[0]->result_as_longlong()) { value= args[0]->val_int(); null_value= args[0]->null_value; From 6badb08ce30c7b96714e7df91b8d7cf008a7bbb9 Mon Sep 17 00:00:00 2001 From: "gkodinov/kgeorge@magare.gmz" <> Date: Fri, 4 May 2007 10:48:51 +0300 Subject: [PATCH 3/7] Bug #27807. Non-correlated scalar subqueries may get executed in EXPLAIN at the optimization phase if they are part of a right hand sargable expression. If the scalar subquery uses a temp table to materialize its results it will replace the subquery structure from the parser with a simple select from the materialization table. As a result the EXPLAIN will crash as the temporary materialization table is not to be shown in EXPLAIN at all. Fixed by preserving the original query structure right after calling optimize() for scalar subqueries with temp tables executed during EXPLAIN. --- mysql-test/r/subselect.result | 8 ++++++++ mysql-test/t/subselect.test | 10 ++++++++++ sql/item_subselect.cc | 15 +++++++++++++++ sql/sql_select.cc | 36 +++++++++++++++++++++++++++-------- sql/sql_select.h | 1 + 5 files changed, 62 insertions(+), 8 deletions(-) diff --git a/mysql-test/r/subselect.result b/mysql-test/r/subselect.result index 94075df57b4..2b16242fac2 100644 --- a/mysql-test/r/subselect.result +++ b/mysql-test/r/subselect.result @@ -4012,3 +4012,11 @@ WHERE (SELECT COUNT(t0.b) FROM t1 t WHERE t.b>20) GROUP BY a; ERROR HY000: Invalid use of group function SET @@sql_mode=default; DROP TABLE t1; +CREATE TABLE t1 (a int, b int, KEY (a)); +INSERT INTO t1 VALUES (1,1),(2,1); +EXPLAIN SELECT 1 FROM t1 WHERE a = (SELECT COUNT(*) FROM t1 GROUP BY b); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ref a a 5 const 1 Using where; Using index +2 SUBQUERY t1 ALL NULL NULL NULL NULL 2 Using temporary; Using filesort +DROP TABLE t1; +End of 5.0 tests. diff --git a/mysql-test/t/subselect.test b/mysql-test/t/subselect.test index 482b3e883e6..123a1ef3282 100644 --- a/mysql-test/t/subselect.test +++ b/mysql-test/t/subselect.test @@ -2845,3 +2845,13 @@ SELECT a FROM t1 t0 SET @@sql_mode=default; DROP TABLE t1; + +# +# Bug #27807: Server crash when executing subquery with EXPLAIN +# +CREATE TABLE t1 (a int, b int, KEY (a)); +INSERT INTO t1 VALUES (1,1),(2,1); +EXPLAIN SELECT 1 FROM t1 WHERE a = (SELECT COUNT(*) FROM t1 GROUP BY b); +DROP TABLE t1; + +--echo End of 5.0 tests. diff --git a/sql/item_subselect.cc b/sql/item_subselect.cc index b3744d6eb96..a4d07e08473 100644 --- a/sql/item_subselect.cc +++ b/sql/item_subselect.cc @@ -1774,6 +1774,21 @@ int subselect_single_select_engine::exec() thd->lex->current_select= save_select; DBUG_RETURN(join->error ? join->error : 1); } + if (!select_lex->uncacheable && thd->lex->describe && + !(join->select_options & SELECT_DESCRIBE) && + join->need_tmp && item->const_item()) + { + /* + Force join->join_tmp creation, because this subquery will be replaced + by a simple select from the materialization temp table by optimize() + called by EXPLAIN and we need to preserve the initial query structure + so we can display it. + */ + select_lex->uncacheable|= UNCACHEABLE_EXPLAIN; + select_lex->master_unit()->uncacheable|= UNCACHEABLE_EXPLAIN; + if (join->init_save_join_tab()) + DBUG_RETURN(1); + } if (item->engine_changed) { DBUG_RETURN(1); diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 9b27daabc0e..499fed58c4b 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -1426,14 +1426,13 @@ JOIN::optimize() } } - if (select_lex->uncacheable && !is_top_level_join()) - { - /* If this join belongs to an uncacheable subquery */ - if (!(tmp_join= (JOIN*)thd->alloc(sizeof(JOIN)))) - DBUG_RETURN(-1); - error= 0; // Ensure that tmp_join.error= 0 - restore_tmp(); - } + /* + If this join belongs to an uncacheable subquery save + the original join + */ + if (select_lex->uncacheable && !is_top_level_join() && + init_save_join_tab()) + DBUG_RETURN(-1); } error= 0; @@ -1495,6 +1494,27 @@ JOIN::reinit() DBUG_RETURN(0); } +/** + @brief Save the original join layout + + @details Saves the original join layout so it can be reused in + re-execution and for EXPLAIN. + + @return Operation status + @retval 0 success. + @retval 1 error occurred. +*/ + +bool +JOIN::init_save_join_tab() +{ + if (!(tmp_join= (JOIN*)thd->alloc(sizeof(JOIN)))) + return 1; + error= 0; // Ensure that tmp_join.error= 0 + restore_tmp(); + return 0; +} + bool JOIN::save_join_tab() diff --git a/sql/sql_select.h b/sql/sql_select.h index 9aa6fc1cfcd..5081366c10b 100644 --- a/sql/sql_select.h +++ b/sql/sql_select.h @@ -434,6 +434,7 @@ public: void cleanup(bool full); void clear(); bool save_join_tab(); + bool init_save_join_tab(); bool send_row_on_empty_set() { return (do_send_rows && tmp_table_param.sum_func_count != 0 && From 16d6bdfd751565f75c1d977032aab32e8b02d9fb Mon Sep 17 00:00:00 2001 From: "gluh@mysql.com/eagle.(none)" <> Date: Fri, 4 May 2007 14:41:58 +0500 Subject: [PATCH 4/7] Bug#28181 Access denied to 'information_schema when select into out file (regression) allow select into out file from I_S if user has FILE privilege otherwise issue an error --- mysql-test/r/outfile.result | Bin 1382 -> 2135 bytes mysql-test/t/outfile.test | 35 +++++++++++++++++++++++++++++++++++ sql/sql_parse.cc | 3 ++- 3 files changed, 37 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/outfile.result b/mysql-test/r/outfile.result index 023c4ea205f4c5a038bf841e341968343f71ad5e..8503df545d2d0bfc67d5c8aa9e6e8a51ca23d5ca 100644 GIT binary patch delta 766 zcmb`_y-ve05C`yy#S@Qk%3`U4G@wpoDFZW7XQaw?F0F+>g6$S%$}90UyaCU_If(*N zVTjZvQFQ+J=XdwTKCeIOt4?|p5up-M>_k8?ZFtiWLoC@?ItKKR9^1RMc2ekrOVzy> zHiFO^oc-CAFCe-I_wpJPcFPE2J(Mu Kllaual6?b_NfAN- delta 7 OcmcaE@QiCi8Y=(|&jRxR diff --git a/mysql-test/t/outfile.test b/mysql-test/t/outfile.test index 7c90fd32909..f285407efd4 100644 --- a/mysql-test/t/outfile.test +++ b/mysql-test/t/outfile.test @@ -96,3 +96,38 @@ create table t1(a int); eval select * into outfile "$MYSQL_TEST_DIR/outfile-test1" from t1; drop table t1; +# +# Bug#28181 Access denied to 'information_schema when +# select into out file (regression) +# +create database mysqltest; +create user user_1@localhost; +grant all on mysqltest.* to user_1@localhost; +connect (con28181_1,localhost,user_1,,mysqltest); + +--error 1044 +eval select schema_name +into outfile "../tmp/outfile-test.4" +fields terminated by ',' optionally enclosed by '"' + lines terminated by '\n' +from information_schema.schemata +where schema_name like 'mysqltest'; + +connection default; +grant file on *.* to user_1@localhost; + +connect (con28181_2,localhost,user_1,,mysqltest); +eval select schema_name +into outfile "../tmp/outfile-test.4" +fields terminated by ',' optionally enclosed by '"' + lines terminated by '\n' +from information_schema.schemata +where schema_name like 'mysqltest'; + +connection default; +--exec rm $MYSQLTEST_VARDIR/tmp/outfile-test.4 +use test; +revoke all privileges on *.* from user_1@localhost; +drop user user_1@localhost; +drop database mysqltest; + diff --git a/sql/sql_parse.cc b/sql/sql_parse.cc index 35089bbb251..3ca0c78d96a 100644 --- a/sql/sql_parse.cc +++ b/sql/sql_parse.cc @@ -5261,7 +5261,8 @@ check_access(THD *thd, ulong want_access, const char *db, ulong *save_priv, if (schema_db) { - if (want_access & ~(SELECT_ACL | EXTRA_ACL)) + if (!(sctx->master_access & FILE_ACL) && (want_access & FILE_ACL) || + (want_access & ~(SELECT_ACL | EXTRA_ACL | FILE_ACL))) { if (!no_errors) { From d11e1f248bbf6fef285ba068e640b07139b23753 Mon Sep 17 00:00:00 2001 From: "gkodinov/kgeorge@magare.gmz" <> Date: Fri, 4 May 2007 16:43:29 +0300 Subject: [PATCH 5/7] Bug #27531: the 4.1 fix. When checking for applicability of join cache we must disable its usage only if there is no temp table in use. When a temp table is used we can use join cache (and it will not make the result-set unordered) to fill the temp table. The filesort() operation is then applied to the data in the temp table and hence is not affected by join cache usage. Fixed by narrowing the condition for disabling join cache to exclude the case where temp table is used. --- mysql-test/r/join.result | 50 ++++++++++++++++++++++++++++++++++++++++ mysql-test/t/join.test | 24 +++++++++++++++++++ sql/sql_select.cc | 9 +++++--- 3 files changed, 80 insertions(+), 3 deletions(-) diff --git a/mysql-test/r/join.result b/mysql-test/r/join.result index dc763472b0e..9ac8825fcb8 100644 --- a/mysql-test/r/join.result +++ b/mysql-test/r/join.result @@ -376,3 +376,53 @@ i i i 2 NULL 4 2 2 2 drop table t1,t2,t3; +CREATE TABLE t1 (a int, b int default 0, c int default 1); +INSERT INTO t1 (a) VALUES (1),(2),(3),(4),(5),(6),(7),(8); +INSERT INTO t1 (a) SELECT a + 8 FROM t1; +INSERT INTO t1 (a) SELECT a + 16 FROM t1; +CREATE TABLE t2 (a int, d int, e int default 0); +INSERT INTO t2 (a, d) VALUES (1,1),(2,2),(3,3),(4,4); +INSERT INTO t2 (a, d) SELECT a+4, a+4 FROM t2; +INSERT INTO t2 (a, d) SELECT a+8, a+8 FROM t2; +EXPLAIN +SELECT STRAIGHT_JOIN t2.e FROM t1,t2 WHERE t2.d=1 AND t1.b=t2.e +ORDER BY t1.b, t1.c; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 32 Using temporary; Using filesort +1 SIMPLE t2 ALL NULL NULL NULL NULL 16 Using where +SELECT STRAIGHT_JOIN t2.e FROM t1,t2 WHERE t2.d=1 AND t1.b=t2.e +ORDER BY t1.b, t1.c; +e +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +0 +DROP TABLE t1,t2; diff --git a/mysql-test/t/join.test b/mysql-test/t/join.test index 2715f30b6cf..0fe5de8c9b7 100644 --- a/mysql-test/t/join.test +++ b/mysql-test/t/join.test @@ -326,4 +326,28 @@ select t1.i,t2.i,t3.i from t2 natural right join t3,t1 order by t1.i,t2.i,t3.i; select t1.i,t2.i,t3.i from t2 right join t3 on (t2.i=t3.i),t1 order by t1.i,t2.i,t3.i; drop table t1,t2,t3; +# +# Bug #27531: Query performance degredation in 4.1.22 and greater +# +CREATE TABLE t1 (a int, b int default 0, c int default 1); + +INSERT INTO t1 (a) VALUES (1),(2),(3),(4),(5),(6),(7),(8); +INSERT INTO t1 (a) SELECT a + 8 FROM t1; +INSERT INTO t1 (a) SELECT a + 16 FROM t1; + +CREATE TABLE t2 (a int, d int, e int default 0); + +INSERT INTO t2 (a, d) VALUES (1,1),(2,2),(3,3),(4,4); +INSERT INTO t2 (a, d) SELECT a+4, a+4 FROM t2; +INSERT INTO t2 (a, d) SELECT a+8, a+8 FROM t2; + +# should use join cache +EXPLAIN +SELECT STRAIGHT_JOIN t2.e FROM t1,t2 WHERE t2.d=1 AND t1.b=t2.e + ORDER BY t1.b, t1.c; +SELECT STRAIGHT_JOIN t2.e FROM t1,t2 WHERE t2.d=1 AND t1.b=t2.e + ORDER BY t1.b, t1.c; + +DROP TABLE t1,t2; + # End of 4.1 tests diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 36a15841065..656d1b5639a 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -3939,14 +3939,17 @@ make_join_readinfo(JOIN *join, uint options) disable join cache because it will change the ordering of the results. Code handles sort table that is at any location (not only first after the const tables) despite the fact that it's currently prohibited. + We must disable join cache if the first non-const table alone is + ordered. If there is a temp table the ordering is done as a last + operation and doesn't prevent join cache usage. */ - if (!ordered_set && - (table == join->sort_by_table && + if (!ordered_set && !join->need_tmp && + ((table == join->sort_by_table && (!join->order || join->skip_sort_order || test_if_skip_sort_order(tab, join->order, join->select_limit, 1)) ) || - (join->sort_by_table == (TABLE *) 1 && i != join->const_tables)) + (join->sort_by_table == (TABLE *) 1 && i != join->const_tables))) ordered_set= 1; switch (tab->type) { From 239f727b7e58dd4dd7d89906baf6858605185c15 Mon Sep 17 00:00:00 2001 From: "evgen@moonbone.local" <> Date: Fri, 4 May 2007 18:57:10 +0400 Subject: [PATCH 6/7] Bug#27759: Wrong DATE/DATETIME comparison in LEAST()/GREATEST() functions. The LEAST/GREATEST functions compared DATE/DATETIME values as strings which in some cases could lead to a wrong result. A new member function called cmp_datetimes() is added to the Item_func_min_max class. It compares arguments in DATETIME context and returns index of the least/greatest argument. The Item_func_min_max::fix_length_and_dec() function now detects when arguments should be compared in DATETIME context and sets the newly added flag compare_as_dates. It indicates that the cmp_datetimes() function should be called to get a correct result. Item_func_min_max::val_xxx() methods are corrected to call the cmp_datetimes() function when needed. Objects of the Item_splocal class now stores and reports correct original field type. --- mysql-test/r/sp-vars.result | 4 +- mysql-test/r/type_datetime.result | 30 +++++++++++ mysql-test/t/type_datetime.test | 26 +++++++++ sql/item.cc | 1 + sql/item.h | 3 +- sql/item_cmpfunc.cc | 4 +- sql/item_func.cc | 90 +++++++++++++++++++++++++++++++ sql/item_func.h | 10 +++- sql/mysql_priv.h | 2 + 9 files changed, 164 insertions(+), 6 deletions(-) diff --git a/mysql-test/r/sp-vars.result b/mysql-test/r/sp-vars.result index 6090dfdf737..b112c6bece6 100644 --- a/mysql-test/r/sp-vars.result +++ b/mysql-test/r/sp-vars.result @@ -690,12 +690,12 @@ END| CALL p1(NOW()); Table Create Table t1 CREATE TABLE "t1" ( - "x" varbinary(19) default NULL + "x" datetime default NULL ) CALL p1('test'); Table Create Table t1 CREATE TABLE "t1" ( - "x" varbinary(19) default NULL + "x" datetime default NULL ) Warnings: Warning 1264 Out of range value adjusted for column 'x' at row 1 diff --git a/mysql-test/r/type_datetime.result b/mysql-test/r/type_datetime.result index 3a28410b7dc..3a7313f48eb 100644 --- a/mysql-test/r/type_datetime.result +++ b/mysql-test/r/type_datetime.result @@ -264,3 +264,33 @@ f2 SELECT 1 from dual where NOW() BETWEEN CURRENT_DATE() - INTERVAL 1 DAY AND CURRENT_DATE(); 1 drop table t1; +select least(cast('01-01-01' as date), '01-01-02'); +least(cast('01-01-01' as date), '01-01-02') +2001-01-01 +select greatest(cast('01-01-01' as date), '01-01-02'); +greatest(cast('01-01-01' as date), '01-01-02') +01-01-02 +select least(cast('01-01-01' as date), '01-01-02') + 0; +least(cast('01-01-01' as date), '01-01-02') + 0 +20010101 +select greatest(cast('01-01-01' as date), '01-01-02') + 0; +greatest(cast('01-01-01' as date), '01-01-02') + 0 +20010102 +select least(cast('01-01-01' as datetime), '01-01-02') + 0; +least(cast('01-01-01' as datetime), '01-01-02') + 0 +20010101000000 +DROP PROCEDURE IF EXISTS test27759 ; +CREATE PROCEDURE test27759() +BEGIN +declare v_a date default '2007-4-10'; +declare v_b date default '2007-4-11'; +declare v_c datetime default '2004-4-9 0:0:0'; +select v_a as a,v_b as b, +least( v_a, v_b ) as a_then_b, +least( v_b, v_a ) as b_then_a, +least( v_c, v_a ) as c_then_a; +END;| +call test27759(); +a b a_then_b b_then_a c_then_a +2007-04-10 2007-04-11 2007-04-10 2007-04-10 2004-04-09 00:00:00 +drop procedure test27759; diff --git a/mysql-test/t/type_datetime.test b/mysql-test/t/type_datetime.test index fc7b20d77a4..c82dee168d2 100644 --- a/mysql-test/t/type_datetime.test +++ b/mysql-test/t/type_datetime.test @@ -178,3 +178,29 @@ select f2, f3 from t1 where '01-03-10' between f2 and f3; select f2 from t1 where DATE(f2) between "2001-4-15" AND "01-4-15"; SELECT 1 from dual where NOW() BETWEEN CURRENT_DATE() - INTERVAL 1 DAY AND CURRENT_DATE(); drop table t1; + +# +# Bug#27759: Wrong DATE/DATETIME comparison in LEAST()/GREATEST() functions. +# +select least(cast('01-01-01' as date), '01-01-02'); +select greatest(cast('01-01-01' as date), '01-01-02'); +select least(cast('01-01-01' as date), '01-01-02') + 0; +select greatest(cast('01-01-01' as date), '01-01-02') + 0; +select least(cast('01-01-01' as datetime), '01-01-02') + 0; +--disable_warnings +DROP PROCEDURE IF EXISTS test27759 ; +--enable_warnings +DELIMITER |; +CREATE PROCEDURE test27759() +BEGIN +declare v_a date default '2007-4-10'; +declare v_b date default '2007-4-11'; +declare v_c datetime default '2004-4-9 0:0:0'; +select v_a as a,v_b as b, + least( v_a, v_b ) as a_then_b, + least( v_b, v_a ) as b_then_a, + least( v_c, v_a ) as c_then_a; +END;| +DELIMITER ;| +call test27759(); +drop procedure test27759; diff --git a/sql/item.cc b/sql/item.cc index 28729e9936f..30486e7559a 100644 --- a/sql/item.cc +++ b/sql/item.cc @@ -1011,6 +1011,7 @@ Item_splocal::Item_splocal(const LEX_STRING &sp_var_name, maybe_null= TRUE; m_type= sp_map_item_type(sp_var_type); + m_field_type= sp_var_type; m_result_type= sp_map_result_type(sp_var_type); } diff --git a/sql/item.h b/sql/item.h index 43afbd30d47..18a05b0b4ad 100644 --- a/sql/item.h +++ b/sql/item.h @@ -946,7 +946,7 @@ class Item_splocal :public Item_sp_variable, Type m_type; Item_result m_result_type; - + enum_field_types m_field_type; public: /* Position of this reference to SP variable in the statement (the @@ -978,6 +978,7 @@ public: inline enum Type type() const; inline Item_result result_type() const; + inline enum_field_types field_type() const { return m_field_type; } private: bool set_value(THD *thd, sp_rcontext *ctx, Item **it); diff --git a/sql/item_cmpfunc.cc b/sql/item_cmpfunc.cc index 66c73dd910e..5d614e7cd04 100644 --- a/sql/item_cmpfunc.cc +++ b/sql/item_cmpfunc.cc @@ -745,7 +745,7 @@ void Arg_comparator::set_datetime_cmp_func(Item **a1, Item **b1) obtained value */ -static ulonglong +ulonglong get_datetime_value(THD *thd, Item ***item_arg, Item **cache_arg, Item *warn_item, bool *is_null) { @@ -781,7 +781,7 @@ get_datetime_value(THD *thd, Item ***item_arg, Item **cache_arg, MYSQL_TYPE_DATE ? MYSQL_TIMESTAMP_DATE : MYSQL_TIMESTAMP_DATETIME; value= get_date_from_str(thd, str, t_type, warn_item->name, &error); } - if (item->const_item()) + if (item->const_item() && cache_arg) { Item_cache_int *cache= new Item_cache_int(); /* Mark the cache as non-const to prevent re-caching. */ diff --git a/sql/item_func.cc b/sql/item_func.cc index 503b4362e7a..4ee6af37dad 100644 --- a/sql/item_func.cc +++ b/sql/item_func.cc @@ -2120,6 +2120,7 @@ double Item_func_units::val_real() void Item_func_min_max::fix_length_and_dec() { int max_int_part=0; + bool datetime_found= FALSE; decimals=0; max_length=0; maybe_null=0; @@ -2133,18 +2134,88 @@ void Item_func_min_max::fix_length_and_dec() if (args[i]->maybe_null) maybe_null=1; cmp_type=item_cmp_type(cmp_type,args[i]->result_type()); + if (args[i]->result_type() != ROW_RESULT && args[i]->is_datetime()) + { + datetime_found= TRUE; + if (!datetime_item || args[i]->field_type() == MYSQL_TYPE_DATETIME) + datetime_item= args[i]; + } } if (cmp_type == STRING_RESULT) + { agg_arg_charsets(collation, args, arg_count, MY_COLL_CMP_CONV, 1); + if (datetime_found) + { + thd= current_thd; + compare_as_dates= TRUE; + } + } else if ((cmp_type == DECIMAL_RESULT) || (cmp_type == INT_RESULT)) max_length= my_decimal_precision_to_length(max_int_part+decimals, decimals, unsigned_flag); } +/* + Compare item arguments in the DATETIME context. + + SYNOPSIS + cmp_datetimes() + value [out] found least/greatest DATE/DATETIME value + + DESCRIPTION + Compare item arguments as DATETIME values and return the index of the + least/greatest argument in the arguments array. + The correct integer DATE/DATETIME value of the found argument is + stored to the value pointer, if latter is provided. + + RETURN + 0 If one of arguments is NULL + # index of the least/greatest argument +*/ + +uint Item_func_min_max::cmp_datetimes(ulonglong *value) +{ + ulonglong min_max; + uint min_max_idx= 0; + LINT_INIT(min_max); + + for (uint i=0; i < arg_count ; i++) + { + Item **arg= args + i; + bool is_null; + ulonglong res= get_datetime_value(thd, &arg, 0, datetime_item, &is_null); + if ((null_value= args[i]->null_value)) + return 0; + if (i == 0 || (res < min_max ? cmp_sign : -cmp_sign) > 0) + { + min_max= res; + min_max_idx= i; + } + } + if (value) + { + *value= min_max; + if (datetime_item->field_type() == MYSQL_TYPE_DATE) + *value/= 1000000L; + } + return min_max_idx; +} + + String *Item_func_min_max::val_str(String *str) { DBUG_ASSERT(fixed == 1); + if (compare_as_dates) + { + String *str_res; + uint min_max_idx= cmp_datetimes(NULL); + if (null_value) + return 0; + str_res= args[min_max_idx]->val_str(str); + str_res->set_charset(collation.collation); + return str_res; + } switch (cmp_type) { case INT_RESULT: { @@ -2212,6 +2283,12 @@ double Item_func_min_max::val_real() { DBUG_ASSERT(fixed == 1); double value=0.0; + if (compare_as_dates) + { + ulonglong result; + (void)cmp_datetimes(&result); + return (double)result; + } for (uint i=0; i < arg_count ; i++) { if (i == 0) @@ -2233,6 +2310,12 @@ longlong Item_func_min_max::val_int() { DBUG_ASSERT(fixed == 1); longlong value=0; + if (compare_as_dates) + { + ulonglong result; + (void)cmp_datetimes(&result); + return (longlong)result; + } for (uint i=0; i < arg_count ; i++) { if (i == 0) @@ -2256,6 +2339,13 @@ my_decimal *Item_func_min_max::val_decimal(my_decimal *dec) my_decimal tmp_buf, *tmp, *res; LINT_INIT(res); + if (compare_as_dates) + { + ulonglong value; + (void)cmp_datetimes(&value); + ulonglong2decimal(value, dec); + return dec; + } for (uint i=0; i < arg_count ; i++) { if (i == 0) diff --git a/sql/item_func.h b/sql/item_func.h index ec5d6bcda02..99e5328c39c 100644 --- a/sql/item_func.h +++ b/sql/item_func.h @@ -693,15 +693,23 @@ class Item_func_min_max :public Item_func Item_result cmp_type; String tmp_value; int cmp_sign; + /* TRUE <=> arguments should be compared in the DATETIME context. */ + bool compare_as_dates; + /* An item used for issuing warnings while string to DATETIME conversion. */ + Item *datetime_item; + THD *thd; + public: Item_func_min_max(List &list,int cmp_sign_arg) :Item_func(list), - cmp_type(INT_RESULT), cmp_sign(cmp_sign_arg) {} + cmp_type(INT_RESULT), cmp_sign(cmp_sign_arg), compare_as_dates(FALSE), + datetime_item(0) {} double val_real(); longlong val_int(); String *val_str(String *); my_decimal *val_decimal(my_decimal *); void fix_length_and_dec(); enum Item_result result_type () const { return cmp_type; } + uint cmp_datetimes(ulonglong *value); }; class Item_func_min :public Item_func_min_max diff --git a/sql/mysql_priv.h b/sql/mysql_priv.h index 7e873dd7cc6..9995afb8287 100644 --- a/sql/mysql_priv.h +++ b/sql/mysql_priv.h @@ -1525,6 +1525,8 @@ void make_date(const DATE_TIME_FORMAT *format, const TIME *l_time, String *str); void make_time(const DATE_TIME_FORMAT *format, const TIME *l_time, String *str); +ulonglong get_datetime_value(THD *thd, Item ***item_arg, Item **cache_arg, + Item *warn_item, bool *is_null); int test_if_number(char *str,int *res,bool allow_wildcards); void change_byte(byte *,uint,char,char); From 13e55b8a21014e5a4e026e1f07c4fd1951553bee Mon Sep 17 00:00:00 2001 From: "gkodinov/kgeorge@magare.gmz" <> Date: Fri, 4 May 2007 18:55:01 +0300 Subject: [PATCH 7/7] bug #27531: fixed coverage of out-of-mem errors --- sql/item_subselect.cc | 2 +- sql/sql_select.cc | 4 ++-- 2 files changed, 3 insertions(+), 3 deletions(-) diff --git a/sql/item_subselect.cc b/sql/item_subselect.cc index a4d07e08473..ccd361dba99 100644 --- a/sql/item_subselect.cc +++ b/sql/item_subselect.cc @@ -1787,7 +1787,7 @@ int subselect_single_select_engine::exec() select_lex->uncacheable|= UNCACHEABLE_EXPLAIN; select_lex->master_unit()->uncacheable|= UNCACHEABLE_EXPLAIN; if (join->init_save_join_tab()) - DBUG_RETURN(1); + DBUG_RETURN(1); /* purecov: inspected */ } if (item->engine_changed) { diff --git a/sql/sql_select.cc b/sql/sql_select.cc index efdc834f04a..3a480c01ac1 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -1432,7 +1432,7 @@ JOIN::optimize() */ if (select_lex->uncacheable && !is_top_level_join() && init_save_join_tab()) - DBUG_RETURN(-1); + DBUG_RETURN(-1); /* purecov: inspected */ } error= 0; @@ -1509,7 +1509,7 @@ bool JOIN::init_save_join_tab() { if (!(tmp_join= (JOIN*)thd->alloc(sizeof(JOIN)))) - return 1; + return 1; /* purecov: inspected */ error= 0; // Ensure that tmp_join.error= 0 restore_tmp(); return 0;