From 8e8ece72eb0530bee9b200d92ba14a143cd1dec9 Mon Sep 17 00:00:00 2001 From: unknown Date: Tue, 1 May 2007 23:34:14 -0700 Subject: [PATCH 1/4] 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: Added a test case for bug #28188. mysql-test/t/join_outer.test: Added a test case for bug #28188. sql/sql_select.cc: Fixed bug #28188: performance degradation for outer join queries to which 'not exists' optimization is 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 1a0e3a285818f0a71cdc7f387a63f7cc72c72972 Mon Sep 17 00:00:00 2001 From: unknown Date: Fri, 4 May 2007 00:53:37 +0400 Subject: [PATCH 2/4] 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/t/cast.test: Added a test case for the bug#23656: Wrong conversion result of a DATETIME to integer using CAST function. mysql-test/r/cast.result: Added a test case for the bug#23656: Wrong conversion result of a DATETIME to integer using CAST function. sql/item_func.cc: Bug#23656: Wrong conversion result of a DATETIME to integer using CAST function. 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 0ad4e1b2a6f4919afbfc43a7cd71e828e3aeb74a Mon Sep 17 00:00:00 2001 From: unknown Date: Fri, 4 May 2007 10:48:51 +0300 Subject: [PATCH 3/4] 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: Bug #27807: test case mysql-test/t/subselect.test: Bug #27807: test case sql/item_subselect.cc: Bug #27807: preserve the join structure sql/sql_select.cc: Bug #27807: introduce initialization function for tmp_join sql/sql_select.h: Bug #27807: introduce initialization function for tmp_join --- 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 13cfc4775c4e310ad8a8c44efa512944b4c7a11d Mon Sep 17 00:00:00 2001 From: unknown Date: Fri, 4 May 2007 14:41:58 +0500 Subject: [PATCH 4/4] 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: test result mysql-test/t/outfile.test: test case sql/sql_parse.cc: 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) {