From 4fd71723915fa9859599d6e8b71c29d5f0a6c38d Mon Sep 17 00:00:00 2001 From: unknown Date: Fri, 29 Sep 2006 00:50:00 +0400 Subject: [PATCH 01/16] Fixed bug#20503: Server crash due to the ORDER clause not taken into account while space allocation Under some circumstances DISTINCT clause can be converted to grouping. In such cases grouping is performed by all items in the select list. If an ORDER clause is present then items from it is prepended to group list. But the case with ORDER wasn't taken into account when allocating the array for sum functions. This leads to memory corruption and crash. The JOIN::alloc_func_list() function now allocates additional space if there is an ORDER by clause is specified and DISTINCT -> GROUP BY optimization is possible. mysql-test/t/select.test: Added the test case for bug#20503: Server crash due to the ORDER clause not taken into account while space allocation mysql-test/r/select.result: Added the test case for bug#20503: Server crash due to the ORDER clause not taken into account while space allocation sql/sql_select.cc: Fixed bug#20503: Server crash due to the ORDER clause not taken into account while space allocation The JOIN::alloc_func_list() function now allocates additional space if there is an ORDER by clause is specified and DISTINCT -> GROUP BY optimization is possible. --- mysql-test/r/select.result | 6 ++++++ mysql-test/t/select.test | 11 ++++++++++- sql/sql_select.cc | 12 ++++++++++++ 3 files changed, 28 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/select.result b/mysql-test/r/select.result index 0c62d3f570f..350a05a13c8 100644 --- a/mysql-test/r/select.result +++ b/mysql-test/r/select.result @@ -3517,3 +3517,9 @@ id a b c d e 2 NULL NULL NULL 2 40 2 NULL NULL NULL 2 50 DROP TABLE t1,t2,t3; +create table t1 (c1 varchar(1), c2 int, c3 int, c4 int, c5 int, c6 int, +c7 int, c8 int, c9 int, fulltext key (`c1`)); +select distinct match (`c1`) against ('z') , c2, c3, c4,c5, c6,c7, c8 +from t1 where c9=1 order by c2, c2; +match (`c1`) against ('z') c2 c3 c4 c5 c6 c7 c8 +drop table t1; diff --git a/mysql-test/t/select.test b/mysql-test/t/select.test index 36b3749b4d7..0686f670edf 100644 --- a/mysql-test/t/select.test +++ b/mysql-test/t/select.test @@ -2996,5 +2996,14 @@ SELECT * FROM t1 LEFT JOIN t2 ON t2.b=t1.a INNER JOIN t3 ON t3.d=t1.id SELECT * FROM t1 LEFT JOIN t2 ON t2.b=t1.a INNER JOIN t3 ON t3.d=t1.id WHERE t1.id=2; - DROP TABLE t1,t2,t3; + +# +# Bug#20503: Server crash due to the ORDER clause isn't taken into account +# while space allocation +# +create table t1 (c1 varchar(1), c2 int, c3 int, c4 int, c5 int, c6 int, +c7 int, c8 int, c9 int, fulltext key (`c1`)); +select distinct match (`c1`) against ('z') , c2, c3, c4,c5, c6,c7, c8 + from t1 where c9=1 order by c2, c2; +drop table t1; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index ac4b404ce8e..a412df8cdeb 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -13515,7 +13515,19 @@ bool JOIN::alloc_func_list() disctinct->group_by optimization */ if (select_distinct) + { group_parts+= fields_list.elements; + /* + If the ORDER clause is specified then it's possible that + it also will be optimized, so reserve space for it too + */ + if (order) + { + ORDER *ord; + for (ord= order; ord; ord= ord->next) + group_parts++; + } + } /* This must use calloc() as rollup_make_fields depends on this */ sum_funcs= (Item_sum**) thd->calloc(sizeof(Item_sum**) * (func_count+1) + From af2ba777c3abeb5721fbc14e9d094ffa620c75a5 Mon Sep 17 00:00:00 2001 From: unknown Date: Fri, 29 Sep 2006 07:43:25 -0700 Subject: [PATCH 02/16] Fixed bug #22753. After the patch for big 21698 equality propagation stopped working for BETWEEN and IN predicates with STRING arguments. This changeset completes the solution of the above patch. mysql-test/r/select.result: Added a test case for bug #22735. mysql-test/t/select.test: Added a test case for bug #22735. sql/item_cmpfunc.h: Fixed bug #22753. After the patch for big 21698 equality propagation stopped working for BETWEEN and IN predicates with STRING arguments. This changeset completes the solution of the above patch. Added an implementation of the subst_argument_checker method for Item_func_opt_neg (the direct ancestor of Item_func_between and Item_func_in) which allows equality propagation for BETWEEN and IN predicates. --- mysql-test/r/select.result | 29 +++++++++++++++++++++++++++++ mysql-test/t/select.test | 29 ++++++++++++++++++++++++++++- sql/item_cmpfunc.h | 1 + 3 files changed, 58 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/select.result b/mysql-test/r/select.result index 0c62d3f570f..34b2a93e39b 100644 --- a/mysql-test/r/select.result +++ b/mysql-test/r/select.result @@ -3517,3 +3517,32 @@ id a b c d e 2 NULL NULL NULL 2 40 2 NULL NULL NULL 2 50 DROP TABLE t1,t2,t3; +CREATE TABLE t1 (pk varchar(10) PRIMARY KEY, fk varchar(16)); +CREATE TABLE t2 (pk varchar(16) PRIMARY KEY, fk varchar(10)); +INSERT INTO t1 VALUES +('d','dddd'), ('i','iii'), ('a','aa'), ('b','bb'), ('g','gg'), +('e','eee'), ('c','cccc'), ('h','hhh'), ('j','jjj'), ('f','fff'); +INSERT INTO t2 VALUES +('jjj', 'j'), ('cc','c'), ('ccc','c'), ('aaa', 'a'), ('jjjj','j'), +('hhh','h'), ('gg','g'), ('fff','f'), ('ee','e'), ('ffff','f'), +('bbb','b'), ('ff','f'), ('cccc','c'), ('dddd','d'), ('jj','j'), +('aaaa','a'), ('bb','b'), ('eeee','e'), ('aa','a'), ('hh','h'); +EXPLAIN SELECT t2.* +FROM t1 JOIN t2 ON t2.fk=t1.pk +WHERE t2.fk < 'c' AND t2.pk=t1.fk; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 range PRIMARY PRIMARY 12 NULL 3 Using where +1 SIMPLE t2 ref PRIMARY PRIMARY 18 test.t1.fk 1 Using where +EXPLAIN SELECT t2.* +FROM t1 JOIN t2 ON t2.fk=t1.pk +WHERE t2.fk BETWEEN 'a' AND 'b' AND t2.pk=t1.fk; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 range PRIMARY PRIMARY 12 NULL 2 Using where +1 SIMPLE t2 ref PRIMARY PRIMARY 18 test.t1.fk 1 Using where +EXPLAIN SELECT t2.* +FROM t1 JOIN t2 ON t2.fk=t1.pk +WHERE t2.fk IN ('a','b') AND t2.pk=t1.fk; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 range PRIMARY PRIMARY 12 NULL 2 Using where +1 SIMPLE t2 ref PRIMARY PRIMARY 18 test.t1.fk 1 Using where +DROP TABLE t1,t2; diff --git a/mysql-test/t/select.test b/mysql-test/t/select.test index 36b3749b4d7..861b9160644 100644 --- a/mysql-test/t/select.test +++ b/mysql-test/t/select.test @@ -2996,5 +2996,32 @@ SELECT * FROM t1 LEFT JOIN t2 ON t2.b=t1.a INNER JOIN t3 ON t3.d=t1.id SELECT * FROM t1 LEFT JOIN t2 ON t2.b=t1.a INNER JOIN t3 ON t3.d=t1.id WHERE t1.id=2; - DROP TABLE t1,t2,t3; + +# +# Bug #22735: no equality propagation for BETWEEN and IN with STRING arguments +# + +CREATE TABLE t1 (pk varchar(10) PRIMARY KEY, fk varchar(16)); +CREATE TABLE t2 (pk varchar(16) PRIMARY KEY, fk varchar(10)); + +INSERT INTO t1 VALUES + ('d','dddd'), ('i','iii'), ('a','aa'), ('b','bb'), ('g','gg'), + ('e','eee'), ('c','cccc'), ('h','hhh'), ('j','jjj'), ('f','fff'); +INSERT INTO t2 VALUES + ('jjj', 'j'), ('cc','c'), ('ccc','c'), ('aaa', 'a'), ('jjjj','j'), + ('hhh','h'), ('gg','g'), ('fff','f'), ('ee','e'), ('ffff','f'), + ('bbb','b'), ('ff','f'), ('cccc','c'), ('dddd','d'), ('jj','j'), + ('aaaa','a'), ('bb','b'), ('eeee','e'), ('aa','a'), ('hh','h'); + +EXPLAIN SELECT t2.* + FROM t1 JOIN t2 ON t2.fk=t1.pk + WHERE t2.fk < 'c' AND t2.pk=t1.fk; +EXPLAIN SELECT t2.* + FROM t1 JOIN t2 ON t2.fk=t1.pk + WHERE t2.fk BETWEEN 'a' AND 'b' AND t2.pk=t1.fk; +EXPLAIN SELECT t2.* + FROM t1 JOIN t2 ON t2.fk=t1.pk + WHERE t2.fk IN ('a','b') AND t2.pk=t1.fk; + +DROP TABLE t1,t2; diff --git a/sql/item_cmpfunc.h b/sql/item_cmpfunc.h index f2c43833bd9..c8439cba303 100644 --- a/sql/item_cmpfunc.h +++ b/sql/item_cmpfunc.h @@ -446,6 +446,7 @@ public: negated= !negated; return this; } + bool subst_argument_checker(byte **arg) { return TRUE; } }; From da9f990b5480645014f982fe5c2b1880ce54b314 Mon Sep 17 00:00:00 2001 From: unknown Date: Fri, 29 Sep 2006 20:02:53 +0400 Subject: [PATCH 03/16] Fixed bug#20825: rollup puts non-equal values together Fix for bug 7894 replaces a field(s) in a non-aggregate function with a item reference if such a field was specified in the GROUP BY clause in order to get a correct result. When ROLLUP is involved this lead to a wrong result due to value of a such field is got through a copy function and copying happens after the function evaluation. Such replacement isn't needed if grouping is also done by such a function. The change_group_ref() function now isn't called for a function present in the group list. mysql-test/t/olap.test: Added the test case for the bug#20825: rollup puts non-equal values together mysql-test/r/olap.result: Added the test case for the bug#20825: rollup puts non-equal values together sql/sql_select.cc: Fixed bug#20825: rollup puts non-equal values together The change_group_ref() function now isn't called for a function present in the group list. --- mysql-test/r/olap.result | 15 +++++++++++++++ mysql-test/t/olap.test | 9 +++++++++ sql/sql_select.cc | 7 ++++++- 3 files changed, 30 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/olap.result b/mysql-test/r/olap.result index fef990297d9..74b7570ea2a 100644 --- a/mysql-test/r/olap.result +++ b/mysql-test/r/olap.result @@ -541,3 +541,18 @@ a max(b) NULL 2 a 1 drop table t1; +create table t1 (a varchar(22) not null , b int); +insert into t1 values ("2006-07-01 21:30", 1), ("2006-07-01 23:30", 10); +select left(a,10), a, sum(b) from t1 group by 1,2 with rollup; +left(a,10) a sum(b) +2006-07-01 2006-07-01 21:30 1 +2006-07-01 2006-07-01 23:30 10 +2006-07-01 NULL 11 +NULL NULL 11 +select left(a,10) x, a, sum(b) from t1 group by x,a with rollup; +x a sum(b) +2006-07-01 2006-07-01 21:30 1 +2006-07-01 2006-07-01 23:30 10 +2006-07-01 NULL 11 +NULL NULL 11 +drop table t1; diff --git a/mysql-test/t/olap.test b/mysql-test/t/olap.test index 4f9790b0de6..683e1402678 100644 --- a/mysql-test/t/olap.test +++ b/mysql-test/t/olap.test @@ -272,4 +272,13 @@ select a, max(b) from t1 group by a with rollup; select distinct a, max(b) from t1 group by a with rollup; drop table t1; +# +# Bug #20825: rollup puts non-equal values together +# +create table t1 (a varchar(22) not null , b int); +insert into t1 values ("2006-07-01 21:30", 1), ("2006-07-01 23:30", 10); +select left(a,10), a, sum(b) from t1 group by 1,2 with rollup; +select left(a,10) x, a, sum(b) from t1 group by x,a with rollup; +drop table t1; + # End of 4.1 tests diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 74a9fc573c4..57b7fcceebe 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -9706,12 +9706,17 @@ bool JOIN::rollup_init() while ((item= it++)) { ORDER *group_tmp; + bool found_in_group= 0; + for (group_tmp= group_list; group_tmp; group_tmp= group_tmp->next) { if (*group_tmp->item == item) + { item->maybe_null= 1; + found_in_group= 1; + } } - if (item->type() == Item::FUNC_ITEM) + if (item->type() == Item::FUNC_ITEM && !found_in_group) { bool changed= FALSE; if (change_group_ref(thd, (Item_func *) item, group_list, &changed)) From 45cad70ff4b9e191e9ac553298e25fe500a747c5 Mon Sep 17 00:00:00 2001 From: unknown Date: Mon, 9 Oct 2006 19:51:41 +0400 Subject: [PATCH 04/16] Bug #22781: SQL_BIG_RESULT fails to influence sort plan Currently SQL_BIG_RESULT is checked only at compile time. However, additional optimizations may take place after this check that change the sort method from 'filesort' to sorting via index. As a result the actual plan executed is not the one specified by the SQL_BIG_RESULT hint. Similarly, there is no such test when executing EXPLAIN, resulting in incorrect output. The patch corrects the problem by testing for SQL_BIG_RESULT both during the explain and execution phases. mysql-test/r/bdb.result: Bug #22781: SQL_BIG_RESULT fails to influence sort plan - updated sql_big_result testcase mysql-test/r/group_by.result: Bug #22781: SQL_BIG_RESULT fails to influence sort plan - test case with MyISAM mysql-test/r/innodb.result: Bug #22781: SQL_BIG_RESULT fails to influence sort plan - updated sql_big_result testcase mysql-test/r/innodb_mysql.result: Bug #22781: SQL_BIG_RESULT fails to influence sort plan - test case with InnoDB mysql-test/r/myisam.result: Bug #22781: SQL_BIG_RESULT fails to influence sort plan - updated sql_big_result testcase mysql-test/t/group_by.test: Bug #22781: SQL_BIG_RESULT fails to influence sort plan - test case with MyISAM mysql-test/t/innodb_mysql.test: Bug #22781: SQL_BIG_RESULT fails to influence sort plan - test case with InnoDB sql/sql_select.cc: Bug #22781: SQL_BIG_RESULT fails to influence sort plan - When SQL_BIG_RESULT is specified, disable the optimization performed at execution/explain time that decides to use an index instead of filesort. --- mysql-test/r/bdb.result | 72 ++++++++++++++++---------------- mysql-test/r/group_by.result | 67 ++++++++++++++++++++++++++++- mysql-test/r/innodb.result | 16 +++---- mysql-test/r/innodb_mysql.result | 16 +++++++ mysql-test/r/myisam.result | 16 +++---- mysql-test/t/group_by.test | 22 ++++++++++ mysql-test/t/innodb_mysql.test | 18 ++++++++ sql/sql_select.cc | 13 ++++-- 8 files changed, 183 insertions(+), 57 deletions(-) diff --git a/mysql-test/r/bdb.result b/mysql-test/r/bdb.result index ee7cdceefda..c5b3b1f86e7 100644 --- a/mysql-test/r/bdb.result +++ b/mysql-test/r/bdb.result @@ -1509,27 +1509,27 @@ i 10 select sql_big_result v,count(t) from t1 group by v limit 10; v count(t) a 1 -a 10 -b 10 -c 10 -d 10 -e 10 -f 10 -g 10 -h 10 -i 10 +a 10 +b 10 +c 10 +d 10 +e 10 +f 10 +g 10 +h 10 +i 10 select sql_big_result v,count(c) from t1 group by v limit 10; v count(c) a 1 -a 10 -b 10 -c 10 -d 10 -e 10 -f 10 -g 10 -h 10 -i 10 +a 10 +b 10 +c 10 +d 10 +e 10 +f 10 +g 10 +h 10 +i 10 select c,count(*) from t1 group by c limit 10; c count(*) a 1 @@ -1673,15 +1673,15 @@ i 10 select sql_big_result v,count(t) from t1 group by v limit 10; v count(t) a 1 -a 10 -b 10 -c 10 -d 10 -e 10 -f 10 -g 10 -h 10 -i 10 +a 10 +b 10 +c 10 +d 10 +e 10 +f 10 +g 10 +h 10 +i 10 alter table t1 drop key v, add key v (v(30)); show create table t1; Table Create Table @@ -1800,15 +1800,15 @@ i 10 select sql_big_result v,count(t) from t1 group by v limit 10; v count(t) a 1 -a 10 -b 10 -c 10 -d 10 -e 10 -f 10 -g 10 -h 10 -i 10 +a 10 +b 10 +c 10 +d 10 +e 10 +f 10 +g 10 +h 10 +i 10 drop table t1; create table t1 (a char(10), unique (a)); insert into t1 values ('a '); diff --git a/mysql-test/r/group_by.result b/mysql-test/r/group_by.result index 5eb2e5744c1..5a55abbc923 100644 --- a/mysql-test/r/group_by.result +++ b/mysql-test/r/group_by.result @@ -303,10 +303,10 @@ spid sum(userid) 1 1 explain select sql_big_result score,count(*) from t1 group by score desc; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 index NULL score 3 NULL 8 Using index +1 SIMPLE t1 index NULL score 3 NULL 8 Using index; Using filesort explain select sql_big_result score,count(*) from t1 group by score desc order by null; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 index NULL score 3 NULL 8 Using index +1 SIMPLE t1 index NULL score 3 NULL 8 Using index; Using filesort select sql_big_result score,count(*) from t1 group by score desc; score count(*) 3 5 @@ -821,3 +821,66 @@ a b real_b 68 France France DROP VIEW v1; DROP TABLE t1,t2; +CREATE TABLE t1 (a INT PRIMARY KEY, b INT, key (b)); +INSERT INTO t1 VALUES (1, 1); +INSERT INTO t1 SELECT a + 1 , MOD(a + 1 , 20) FROM t1; +INSERT INTO t1 SELECT a + 2 , MOD(a + 2 , 20) FROM t1; +INSERT INTO t1 SELECT a + 4 , MOD(a + 4 , 20) FROM t1; +INSERT INTO t1 SELECT a + 8 , MOD(a + 8 , 20) FROM t1; +INSERT INTO t1 SELECT a + 16, MOD(a + 16, 20) FROM t1; +INSERT INTO t1 SELECT a + 32, MOD(a + 32, 20) FROM t1; +INSERT INTO t1 SELECT a + 64, MOD(a + 64, 20) FROM t1; +SELECT MIN(b), MAX(b) from t1; +MIN(b) MAX(b) +0 19 +EXPLAIN SELECT b, sum(1) FROM t1 GROUP BY b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 index NULL b 5 NULL 128 Using index +EXPLAIN SELECT SQL_BIG_RESULT b, sum(1) FROM t1 GROUP BY b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 index NULL b 5 NULL 128 Using index; Using filesort +SELECT b, sum(1) FROM t1 GROUP BY b; +b sum(1) +0 6 +1 7 +2 7 +3 7 +4 7 +5 7 +6 7 +7 7 +8 7 +9 6 +10 6 +11 6 +12 6 +13 6 +14 6 +15 6 +16 6 +17 6 +18 6 +19 6 +SELECT SQL_BIG_RESULT b, sum(1) FROM t1 GROUP BY b; +b sum(1) +0 6 +1 7 +2 7 +3 7 +4 7 +5 7 +6 7 +7 7 +8 7 +9 6 +10 6 +11 6 +12 6 +13 6 +14 6 +15 6 +16 6 +17 6 +18 6 +19 6 +DROP TABLE t1; diff --git a/mysql-test/r/innodb.result b/mysql-test/r/innodb.result index 1d1f26e4b01..38d71ac7a42 100644 --- a/mysql-test/r/innodb.result +++ b/mysql-test/r/innodb.result @@ -2070,15 +2070,15 @@ i 10 select sql_big_result v,count(c) from t1 group by v limit 10; v count(c) a 1 -a 10 -b 10 -c 10 -d 10 -e 10 -f 10 -g 10 +a 10 +b 10 +c 10 +d 10 +e 10 +f 10 +g 10 h 10 -i 10 +i 10 select c,count(*) from t1 group by c limit 10; c count(*) a 1 diff --git a/mysql-test/r/innodb_mysql.result b/mysql-test/r/innodb_mysql.result index b4101e037f2..c4564251a35 100644 --- a/mysql-test/r/innodb_mysql.result +++ b/mysql-test/r/innodb_mysql.result @@ -337,3 +337,19 @@ id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t2 index NULL fkey 5 NULL 5 Using index 1 SIMPLE t1 eq_ref PRIMARY PRIMARY 4 test.t2.fkey 1 Using where DROP TABLE t1,t2; +CREATE TABLE t1 (a INT PRIMARY KEY, b INT, c FLOAT, KEY b(b)) ENGINE = INNODB; +INSERT INTO t1 VALUES ( 1 , 1 , 1); +INSERT INTO t1 SELECT a + 1 , MOD(a + 1 , 20), 1 FROM t1; +INSERT INTO t1 SELECT a + 2 , MOD(a + 2 , 20), 1 FROM t1; +INSERT INTO t1 SELECT a + 4 , MOD(a + 4 , 20), 1 FROM t1; +INSERT INTO t1 SELECT a + 8 , MOD(a + 8 , 20), 1 FROM t1; +INSERT INTO t1 SELECT a + 16, MOD(a + 16, 20), 1 FROM t1; +INSERT INTO t1 SELECT a + 32, MOD(a + 32, 20), 1 FROM t1; +INSERT INTO t1 SELECT a + 64, MOD(a + 64, 20), 1 FROM t1; +EXPLAIN SELECT b, SUM(c) FROM t1 GROUP BY b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 index NULL b 5 NULL 128 +EXPLAIN SELECT SQL_BIG_RESULT b, SUM(c) FROM t1 GROUP BY b; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 128 Using filesort +DROP TABLE t1; diff --git a/mysql-test/r/myisam.result b/mysql-test/r/myisam.result index 0021e6717ee..b1d5765a304 100644 --- a/mysql-test/r/myisam.result +++ b/mysql-test/r/myisam.result @@ -1002,15 +1002,15 @@ i 10 select sql_big_result v,count(c) from t1 group by v limit 10; v count(c) a 1 -a 10 -b 10 -c 10 -d 10 -e 10 -f 10 -g 10 +a 10 +b 10 +c 10 +d 10 +e 10 +f 10 +g 10 h 10 -i 10 +i 10 select c,count(*) from t1 group by c limit 10; c count(*) a 1 diff --git a/mysql-test/t/group_by.test b/mysql-test/t/group_by.test index ce1e4e59600..5d47f64f3d1 100644 --- a/mysql-test/t/group_by.test +++ b/mysql-test/t/group_by.test @@ -655,3 +655,25 @@ where t2.b=v1.a GROUP BY t2.b; DROP VIEW v1; DROP TABLE t1,t2; + +# +# Bug#22781: SQL_BIG_RESULT fails to influence sort plan +# +CREATE TABLE t1 (a INT PRIMARY KEY, b INT, key (b)); + +INSERT INTO t1 VALUES (1, 1); +INSERT INTO t1 SELECT a + 1 , MOD(a + 1 , 20) FROM t1; +INSERT INTO t1 SELECT a + 2 , MOD(a + 2 , 20) FROM t1; +INSERT INTO t1 SELECT a + 4 , MOD(a + 4 , 20) FROM t1; +INSERT INTO t1 SELECT a + 8 , MOD(a + 8 , 20) FROM t1; +INSERT INTO t1 SELECT a + 16, MOD(a + 16, 20) FROM t1; +INSERT INTO t1 SELECT a + 32, MOD(a + 32, 20) FROM t1; +INSERT INTO t1 SELECT a + 64, MOD(a + 64, 20) FROM t1; + +SELECT MIN(b), MAX(b) from t1; + +EXPLAIN SELECT b, sum(1) FROM t1 GROUP BY b; +EXPLAIN SELECT SQL_BIG_RESULT b, sum(1) FROM t1 GROUP BY b; +SELECT b, sum(1) FROM t1 GROUP BY b; +SELECT SQL_BIG_RESULT b, sum(1) FROM t1 GROUP BY b; +DROP TABLE t1; diff --git a/mysql-test/t/innodb_mysql.test b/mysql-test/t/innodb_mysql.test index 59dbe5e96d4..4d87e9dfb02 100644 --- a/mysql-test/t/innodb_mysql.test +++ b/mysql-test/t/innodb_mysql.test @@ -302,3 +302,21 @@ SELECT COUNT(*) FROM t2 LEFT JOIN t1 ON t2.fkey = t1.id WHERE t1.name LIKE 'A%' OR FALSE; DROP TABLE t1,t2; + +# +# Bug#22781: SQL_BIG_RESULT fails to influence sort plan +# +CREATE TABLE t1 (a INT PRIMARY KEY, b INT, c FLOAT, KEY b(b)) ENGINE = INNODB; + +INSERT INTO t1 VALUES ( 1 , 1 , 1); +INSERT INTO t1 SELECT a + 1 , MOD(a + 1 , 20), 1 FROM t1; +INSERT INTO t1 SELECT a + 2 , MOD(a + 2 , 20), 1 FROM t1; +INSERT INTO t1 SELECT a + 4 , MOD(a + 4 , 20), 1 FROM t1; +INSERT INTO t1 SELECT a + 8 , MOD(a + 8 , 20), 1 FROM t1; +INSERT INTO t1 SELECT a + 16, MOD(a + 16, 20), 1 FROM t1; +INSERT INTO t1 SELECT a + 32, MOD(a + 32, 20), 1 FROM t1; +INSERT INTO t1 SELECT a + 64, MOD(a + 64, 20), 1 FROM t1; + +EXPLAIN SELECT b, SUM(c) FROM t1 GROUP BY b; +EXPLAIN SELECT SQL_BIG_RESULT b, SUM(c) FROM t1 GROUP BY b; +DROP TABLE t1; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index b328d9162d5..e9c282c1d24 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -1399,7 +1399,8 @@ JOIN::exec() simple_order= simple_group; skip_sort_order= 0; } - if (order && + if (order && + (order != group_list || !(select_options & SELECT_BIG_RESULT)) && (const_tables == tables || ((simple_order || skip_sort_order) && test_if_skip_sort_order(&join_tab[const_tables], order, @@ -11995,11 +11996,17 @@ create_sort_index(THD *thd, JOIN *join, ORDER *order, table= tab->table; select= tab->select; - if (test_if_skip_sort_order(tab,order,select_limit,0)) + /* + When there is SQL_BIG_RESULT do not sort using index for GROUP BY, + and thus force sorting on disk. + */ + if ((order != join->group_list || + !(join->select_options & SELECT_BIG_RESULT)) && + test_if_skip_sort_order(tab,order,select_limit,0)) DBUG_RETURN(0); if (!(sortorder=make_unireg_sortorder(order,&length))) goto err; /* purecov: inspected */ - /* It's not fatal if the following alloc fails */ + table->sort.io_cache=(IO_CACHE*) my_malloc(sizeof(IO_CACHE), MYF(MY_WME | MY_ZEROFILL)); table->status=0; // May be wrong if quick_select From b6248f76ed201d524ccc9b33cae2d961a0724c5e Mon Sep 17 00:00:00 2001 From: unknown Date: Wed, 11 Oct 2006 19:44:12 +0400 Subject: [PATCH 05/16] Bug#22138: Unhandled NULL caused server crash The Cached_item_decimal::cmp() method wasn't checking for null pointer returned from the val_decimal() of the item being cached. This leads to server crash. The Cached_item_decimal::cmp() method now check for null values. sql/item_buff.cc: Bug#22138: Unhandled NULL caused server crash The Cached_item_decimal::cmp() method now check for null values. mysql-test/r/type_decimal.result: Added the test case for bug#22138: Unhandled NULL caused server crash mysql-test/t/type_decimal.test: Added the test case for bug#22138: Unhandled NULL caused server crash --- mysql-test/r/type_decimal.result | 11 +++++++++++ mysql-test/t/type_decimal.test | 9 +++++++++ sql/item_buff.cc | 12 +++++++++--- 3 files changed, 29 insertions(+), 3 deletions(-) diff --git a/mysql-test/r/type_decimal.result b/mysql-test/r/type_decimal.result index 8b2c08065e0..c9c42d18d68 100644 --- a/mysql-test/r/type_decimal.result +++ b/mysql-test/r/type_decimal.result @@ -779,3 +779,14 @@ select f1 from t1 where f1 in (select f1 from t1); f1 40 drop table t1; +create table t1 as +select from_days(s) as date,t +from (select 1 as s,'t' as t union select null, null ) as sub1; +select group_concat(t) from t1 group by week(date)/10; +group_concat(t) +t +Warnings: +Warning 1292 Truncated incorrect datetime value: '0000-00-00' +Warning 1292 Truncated incorrect datetime value: '0000-00-00' +Warning 1292 Truncated incorrect datetime value: '0000-00-00' +drop table t1; diff --git a/mysql-test/t/type_decimal.test b/mysql-test/t/type_decimal.test index 441d750004e..4fdb0c8458f 100644 --- a/mysql-test/t/type_decimal.test +++ b/mysql-test/t/type_decimal.test @@ -385,3 +385,12 @@ insert into t1 values (40); flush tables; select f1 from t1 where f1 in (select f1 from t1); drop table t1; + +# +# Bug#22183: Unhandled NULL caused server crash +# +create table t1 as + select from_days(s) as date,t + from (select 1 as s,'t' as t union select null, null ) as sub1; +select group_concat(t) from t1 group by week(date)/10; +drop table t1; diff --git a/sql/item_buff.cc b/sql/item_buff.cc index 1661f04a4ae..37f9ca7ce6c 100644 --- a/sql/item_buff.cc +++ b/sql/item_buff.cc @@ -132,11 +132,17 @@ bool Cached_item_decimal::cmp() { my_decimal tmp; my_decimal *ptmp= item->val_decimal(&tmp); - if (null_value != item->null_value || my_decimal_cmp(&value, ptmp)) + if (null_value != item->null_value || + (!item->null_value && my_decimal_cmp(&value, ptmp))) { null_value= item->null_value; - my_decimal2decimal(ptmp, &value); - return TRUE; + /* Save only not null values */ + if (!null_value) + { + my_decimal2decimal(ptmp, &value); + return TRUE; + } + return FALSE; } return FALSE; } From 67770b7671652ee4fe89c82ffbe77a3a1c08ed78 Mon Sep 17 00:00:00 2001 From: unknown Date: Fri, 13 Oct 2006 21:59:52 +0400 Subject: [PATCH 06/16] Bug#14959: ALTER TABLE isn't able to rename a view The mysql_alter_table() was able to rename only a table. The view/table renaming code is moved from the function rename_tables to the new function called do_rename(). The mysql_alter_table() function calls it when it needs to rename a view. mysql-test/t/rename.test: Added a test case for bug#14959: ALTER TABLE isn't able to rename a view mysql-test/r/rename.result: Added a test case for bug#14959: ALTER TABLE isn't able to rename a view sql/mysql_priv.h: Bug#14959: ALTER TABLE isn't able to rename a view Added the prototype of the do_rename() function. sql/sql_rename.cc: Bug#14959: ALTER TABLE isn't able to rename a view The view/table renaming code is moved from the function rename_tables to the new function called do_rename(). sql/sql_table.cc: Bug#14959: ALTER TABLE isn't able to rename a view Added handling of a view rename to the mysql_alter_table() function. --- mysql-test/r/rename.result | 10 ++ mysql-test/t/rename.test | 13 +++ sql/mysql_priv.h | 3 + sql/sql_rename.cc | 202 +++++++++++++++++++++++-------------- sql/sql_table.cc | 48 ++++++++- 5 files changed, 200 insertions(+), 76 deletions(-) diff --git a/mysql-test/r/rename.result b/mysql-test/r/rename.result index 76c0f4422fe..345270231ef 100644 --- a/mysql-test/r/rename.result +++ b/mysql-test/r/rename.result @@ -54,3 +54,13 @@ Tables_in_test t2 t4 drop table t2, t4; +create table t1(f1 int); +create view v1 as select * from t1; +alter table v1 rename to v2; +alter table v1 rename to v2; +ERROR 42S02: Table 'test.v1' doesn't exist +rename table v2 to v1; +rename table v2 to v1; +ERROR 42S01: Table 'v1' already exists +drop view v1; +drop table t1; diff --git a/mysql-test/t/rename.test b/mysql-test/t/rename.test index 86e4b6eed0a..054b1bd3403 100644 --- a/mysql-test/t/rename.test +++ b/mysql-test/t/rename.test @@ -72,4 +72,17 @@ disconnect con2; disconnect con1; connection default; +# +# Bug#14959: ALTER TABLE isn't able to rename a view +# +create table t1(f1 int); +create view v1 as select * from t1; +alter table v1 rename to v2; +--error 1146 +alter table v1 rename to v2; +rename table v2 to v1; +--error 1050 +rename table v2 to v1; +drop view v1; +drop table t1; # End of 4.1 tests diff --git a/sql/mysql_priv.h b/sql/mysql_priv.h index ff04022b110..1cee013852e 100644 --- a/sql/mysql_priv.h +++ b/sql/mysql_priv.h @@ -648,6 +648,9 @@ int quick_rm_table(enum db_type base,const char *db, const char *table_name); void close_cached_table(THD *thd, TABLE *table); bool mysql_rename_tables(THD *thd, TABLE_LIST *table_list); +bool do_rename(THD *thd, TABLE_LIST *ren_table, char *new_db, + char *new_table_name, char *new_table_alias, + bool skip_error); bool mysql_change_db(THD *thd,const char *name,bool no_access_check); void mysql_parse(THD *thd,char *inBuf,uint length); bool mysql_test_parse_for_slave(THD *thd,char *inBuf,uint length); diff --git a/sql/sql_rename.cc b/sql/sql_rename.cc index 74951029de9..1a4f1d82cb5 100644 --- a/sql/sql_rename.cc +++ b/sql/sql_rename.cc @@ -125,95 +125,147 @@ static TABLE_LIST *reverse_table_list(TABLE_LIST *table_list) } +/* + Rename a single table or a view + + SYNPOSIS + do_rename() + thd Thread handle + ren_table A table/view to be renamed + new_db The database to which the table to be moved to + new_table_name The new table/view name + new_table_alias The new table/view alias + skip_error Whether to skip error + + DESCRIPTION + Rename a single table or a view. + + RETURN + false Ok + true rename failed +*/ + +bool +do_rename(THD *thd, TABLE_LIST *ren_table, char *new_db, char *new_table_name, + char *new_table_alias, bool skip_error) +{ + int rc= 1; + char name[FN_REFLEN]; + const char *new_alias, *old_alias; + frm_type_enum frm_type; + db_type table_type; + + DBUG_ENTER("do_rename"); + + if (lower_case_table_names == 2) + { + old_alias= ren_table->alias; + new_alias= new_table_alias; + } + else + { + old_alias= ren_table->table_name; + new_alias= new_table_name; + } + sprintf(name,"%s/%s/%s%s",mysql_data_home, + new_db, new_alias, reg_ext); + unpack_filename(name, name); + if (!access(name,F_OK)) + { + my_error(ER_TABLE_EXISTS_ERROR, MYF(0), new_alias); + DBUG_RETURN(ren_table); // This can't be skipped + } + sprintf(name,"%s/%s/%s%s",mysql_data_home, + ren_table->db, old_alias, + reg_ext); + unpack_filename(name, name); + + frm_type= mysql_frm_type(thd, name, &table_type); + switch (frm_type) + { + case FRMTYPE_TABLE: + { + if (table_type == DB_TYPE_UNKNOWN) + my_error(ER_FILE_NOT_FOUND, MYF(0), name, my_errno); + else + { + if (!(rc= mysql_rename_table(table_type, ren_table->db, old_alias, + new_db, new_alias))) + { + if ((rc= Table_triggers_list::change_table_name(thd, ren_table->db, + old_alias, + new_db, + new_alias))) + { + /* + We've succeeded in renaming table's .frm and in updating + corresponding handler data, but have failed to update table's + triggers appropriately. So let us revert operations on .frm + and handler's data and report about failure to rename table. + */ + (void) mysql_rename_table(table_type, new_db, new_alias, + ren_table->db, old_alias); + } + } + } + break; + } + case FRMTYPE_VIEW: + /* change of schema is not allowed */ + if (strcmp(ren_table->db, new_db)) + my_error(ER_FORBID_SCHEMA_CHANGE, MYF(0), ren_table->db, + new_db); + else + rc= mysql_rename_view(thd, new_alias, ren_table); + break; + default: + DBUG_ASSERT(0); // should never happen + case FRMTYPE_ERROR: + my_error(ER_FILE_NOT_FOUND, MYF(0), name, my_errno); + break; + } + if (rc && !skip_error) + DBUG_RETURN(1); + + DBUG_RETURN(0); + +} /* Rename all tables in list; Return pointer to wrong entry if something goes wrong. Note that the table_list may be empty! */ +/* + Rename tables/views in the list + + SYNPOSIS + rename_tables() + thd Thread handle + table_list List of tables to rename + skip_error Whether to skip errors + + DESCRIPTION + Take a table/view name from and odd list element and rename it to a + the name taken from list element+1. Note that the table_list may be + empty. + + RETURN + false Ok + true rename failed +*/ + static TABLE_LIST * rename_tables(THD *thd, TABLE_LIST *table_list, bool skip_error) { - TABLE_LIST *ren_table,*new_table; - frm_type_enum frm_type; - db_type table_type; + TABLE_LIST *ren_table,*new_table, *tmp_table; DBUG_ENTER("rename_tables"); for (ren_table= table_list; ren_table; ren_table= new_table->next_local) { - int rc= 1; - char name[FN_REFLEN]; - const char *new_alias, *old_alias; - new_table= ren_table->next_local; - if (lower_case_table_names == 2) - { - old_alias= ren_table->alias; - new_alias= new_table->alias; - } - else - { - old_alias= ren_table->table_name; - new_alias= new_table->table_name; - } - sprintf(name,"%s/%s/%s%s",mysql_data_home, - new_table->db, new_alias, reg_ext); - unpack_filename(name, name); - if (!access(name,F_OK)) - { - my_error(ER_TABLE_EXISTS_ERROR, MYF(0), new_alias); - DBUG_RETURN(ren_table); // This can't be skipped - } - sprintf(name,"%s/%s/%s%s",mysql_data_home, - ren_table->db, old_alias, - reg_ext); - unpack_filename(name, name); - - frm_type= mysql_frm_type(thd, name, &table_type); - switch (frm_type) - { - case FRMTYPE_TABLE: - { - if (table_type == DB_TYPE_UNKNOWN) - my_error(ER_FILE_NOT_FOUND, MYF(0), name, my_errno); - else - { - if (!(rc= mysql_rename_table(table_type, ren_table->db, old_alias, - new_table->db, new_alias))) - { - if ((rc= Table_triggers_list::change_table_name(thd, ren_table->db, - old_alias, - new_table->db, - new_alias))) - { - /* - We've succeeded in renaming table's .frm and in updating - corresponding handler data, but have failed to update table's - triggers appropriately. So let us revert operations on .frm - and handler's data and report about failure to rename table. - */ - (void) mysql_rename_table(table_type, new_table->db, new_alias, - ren_table->db, old_alias); - } - } - } - break; - } - case FRMTYPE_VIEW: - /* change of schema is not allowed */ - if (strcmp(ren_table->db, new_table->db)) - my_error(ER_FORBID_SCHEMA_CHANGE, MYF(0), ren_table->db, - new_table->db); - else - rc= mysql_rename_view(thd, new_alias, ren_table); - break; - default: - DBUG_ASSERT(0); // should never happen - case FRMTYPE_ERROR: - my_error(ER_FILE_NOT_FOUND, MYF(0), name, my_errno); - break; - } - if (rc && !skip_error) + if (do_rename(thd, ren_table, new_table->db, new_table->table_name, + new_table->alias, skip_error)) DBUG_RETURN(ren_table); } DBUG_RETURN(0); diff --git a/sql/sql_table.cc b/sql/sql_table.cc index a340c5ffc98..9ce5084c34f 100644 --- a/sql/sql_table.cc +++ b/sql/sql_table.cc @@ -3154,9 +3154,10 @@ bool mysql_alter_table(THD *thd,char *new_db, char *new_name, ha_rows copied,deleted; ulonglong next_insert_id; uint db_create_options, used_fields; - enum db_type old_db_type,new_db_type; + enum db_type old_db_type, new_db_type, table_type; bool need_copy_table; bool no_table_reopen= FALSE, varchar= FALSE; + frm_type_enum frm_type; DBUG_ENTER("mysql_alter_table"); thd->proc_info="init"; @@ -3174,6 +3175,51 @@ bool mysql_alter_table(THD *thd,char *new_db, char *new_name, if (alter_info->tablespace_op != NO_TABLESPACE_OP) DBUG_RETURN(mysql_discard_or_import_tablespace(thd,table_list, alter_info->tablespace_op)); + sprintf(new_name_buff,"%s/%s/%s%s",mysql_data_home, db, table_name, reg_ext); + unpack_filename(new_name_buff, new_name_buff); + if (lower_case_table_names != 2) + my_casedn_str(files_charset_info, new_name_buff); + frm_type= mysql_frm_type(thd, new_name_buff, &table_type); + /* Rename a view */ + if (frm_type == FRMTYPE_VIEW && !(alter_info->flags & ~ALTER_RENAME)) + { + /* + Avoid problems with a rename on a table that we have locked or + if the user is trying to to do this in a transcation context + */ + + if (thd->locked_tables || thd->active_transaction()) + { + my_message(ER_LOCK_OR_ACTIVE_TRANSACTION, + ER(ER_LOCK_OR_ACTIVE_TRANSACTION), MYF(0)); + DBUG_RETURN(1); + } + + if (wait_if_global_read_lock(thd,0,1)) + DBUG_RETURN(1); + VOID(pthread_mutex_lock(&LOCK_open)); + if (lock_table_names(thd, table_list)) + goto view_err; + + error=0; + if (!do_rename(thd, table_list, new_db, new_name, new_name, 1)) + { + if (mysql_bin_log.is_open()) + { + thd->clear_error(); + Query_log_event qinfo(thd, thd->query, thd->query_length, 0, FALSE); + mysql_bin_log.write(&qinfo); + } + send_ok(thd); + } + + unlock_table_names(thd, table_list, (TABLE_LIST*) 0); + +view_err: + pthread_mutex_unlock(&LOCK_open); + start_waiting_global_read_lock(thd); + DBUG_RETURN(error); + } if (!(table=open_ltable(thd,table_list,TL_WRITE_ALLOW_READ))) DBUG_RETURN(TRUE); From 750a2a0b862ba6a02c341a6120a96a081a83ac4f Mon Sep 17 00:00:00 2001 From: unknown Date: Mon, 16 Oct 2006 13:10:25 +0300 Subject: [PATCH 07/16] BUG#14019 : group by converts literal string to column name When resolving unqualified name references MySQL was not checking what is the item type for the reference. Thus e.g a string literal item that has by convention a name equal to its string value will also work as a reference to a SELECT list item or a table field. Fixed by allowing only Item_ref or Item_field to referenced by (unqualified) name. mysql-test/r/func_gconcat.result: Bug #14019: group by converts literal string to column name - removed undeterministic testcase : order by a constant means no order. mysql-test/r/group_by.result: Bug #14019: group by converts literal string to column name - test case mysql-test/t/func_gconcat.test: Bug #14019: group by converts literal string to column name - removed undeterministic testcase : order by a constant means no order. mysql-test/t/group_by.test: Bug #14019: group by converts literal string to column name - test case sql/sql_base.cc: Bug #14019: group by converts literal string to column name - resolve unqualified by name refs only for real references --- mysql-test/r/func_gconcat.result | 5 ---- mysql-test/r/group_by.result | 45 ++++++++++++++++++++++++++++++++ mysql-test/t/func_gconcat.test | 1 - mysql-test/t/group_by.test | 23 ++++++++++++++++ sql/sql_base.cc | 11 ++++++-- 5 files changed, 77 insertions(+), 8 deletions(-) diff --git a/mysql-test/r/func_gconcat.result b/mysql-test/r/func_gconcat.result index db0125b7d4f..d4a46bfd79f 100644 --- a/mysql-test/r/func_gconcat.result +++ b/mysql-test/r/func_gconcat.result @@ -74,11 +74,6 @@ grp group_concat(c order by 1) 1 a 2 b,c 3 C,D,d,d,D,E -select grp,group_concat(c order by "c") from t1 group by grp; -grp group_concat(c order by "c") -1 a -2 b,c -3 C,D,d,d,D,E select grp,group_concat(distinct c order by c) from t1 group by grp; grp group_concat(distinct c order by c) 1 a diff --git a/mysql-test/r/group_by.result b/mysql-test/r/group_by.result index 4ad28091164..61b73dc7005 100644 --- a/mysql-test/r/group_by.result +++ b/mysql-test/r/group_by.result @@ -773,3 +773,48 @@ select sql_buffer_result max(f1)+1 from t1; max(f1)+1 3 drop table t1; +CREATE TABLE t1(a INT); +INSERT INTO t1 VALUES (1),(2); +SELECT a FROM t1 GROUP BY 'a'; +a +1 +SELECT a FROM t1 GROUP BY "a"; +a +1 +SELECT a FROM t1 GROUP BY `a`; +a +1 +2 +set sql_mode=ANSI_QUOTES; +SELECT a FROM t1 GROUP BY "a"; +a +1 +2 +SELECT a FROM t1 GROUP BY 'a'; +a +1 +SELECT a FROM t1 GROUP BY `a`; +a +1 +2 +set sql_mode=''; +SELECT a FROM t1 HAVING 'a' > 1; +a +SELECT a FROM t1 HAVING "a" > 1; +a +SELECT a FROM t1 HAVING `a` > 1; +a +2 +SELECT a FROM t1 ORDER BY 'a' DESC; +a +1 +2 +SELECT a FROM t1 ORDER BY "a" DESC; +a +1 +2 +SELECT a FROM t1 ORDER BY `a` DESC; +a +2 +1 +DROP TABLE t1; diff --git a/mysql-test/t/func_gconcat.test b/mysql-test/t/func_gconcat.test index 8f50690dd8b..d51d88d50ef 100644 --- a/mysql-test/t/func_gconcat.test +++ b/mysql-test/t/func_gconcat.test @@ -32,7 +32,6 @@ select grp,group_concat(d order by a desc) from t1 group by grp; select grp,group_concat(a order by a,d+c-ascii(c)-a) from t1 group by grp; select grp,group_concat(a order by d+c-ascii(c),a) from t1 group by grp; select grp,group_concat(c order by 1) from t1 group by grp; -select grp,group_concat(c order by "c") from t1 group by grp; select grp,group_concat(distinct c order by c) from t1 group by grp; select grp,group_concat(distinct c order by c desc) from t1 group by grp; explain extended select grp,group_concat(distinct c order by c desc) from t1 group by grp; diff --git a/mysql-test/t/group_by.test b/mysql-test/t/group_by.test index f14fab2d30e..064d46aa0c0 100644 --- a/mysql-test/t/group_by.test +++ b/mysql-test/t/group_by.test @@ -610,4 +610,27 @@ select sql_buffer_result max(f1) is null from t1; select sql_buffer_result max(f1)+1 from t1; drop table t1; +# +# BUG#14019-4.1-opt +# +CREATE TABLE t1(a INT); INSERT INTO t1 VALUES (1),(2); + +SELECT a FROM t1 GROUP BY 'a'; +SELECT a FROM t1 GROUP BY "a"; +SELECT a FROM t1 GROUP BY `a`; + +set sql_mode=ANSI_QUOTES; +SELECT a FROM t1 GROUP BY "a"; +SELECT a FROM t1 GROUP BY 'a'; +SELECT a FROM t1 GROUP BY `a`; +set sql_mode=''; + +SELECT a FROM t1 HAVING 'a' > 1; +SELECT a FROM t1 HAVING "a" > 1; +SELECT a FROM t1 HAVING `a` > 1; + +SELECT a FROM t1 ORDER BY 'a' DESC; +SELECT a FROM t1 ORDER BY "a" DESC; +SELECT a FROM t1 ORDER BY `a` DESC; +DROP TABLE t1; # End of 4.1 tests diff --git a/sql/sql_base.cc b/sql/sql_base.cc index 0a9529d6067..40adf5e1f15 100644 --- a/sql/sql_base.cc +++ b/sql/sql_base.cc @@ -2284,12 +2284,19 @@ find_item_in_list(Item *find, List &items, uint *counter, const char *field_name=0; const char *table_name=0; bool found_unaliased_non_uniq= 0; + /* + true if the item that we search for is a valid name reference + (and not an item that happens to have a name). + */ + bool is_ref_by_name= 0; uint unaliased_counter; LINT_INIT(unaliased_counter); *unaliased= FALSE; - if (find->type() == Item::FIELD_ITEM || find->type() == Item::REF_ITEM) + is_ref_by_name= (find->type() == Item::FIELD_ITEM || + find->type() == Item::REF_ITEM); + if (is_ref_by_name) { field_name= ((Item_ident*) find)->field_name; table_name= ((Item_ident*) find)->table_name; @@ -2401,7 +2408,7 @@ find_item_in_list(Item *find, List &items, uint *counter, } } else if (!table_name && (item->eq(find,0) || - find->name && item->name && + is_ref_by_name && find->name && item->name && !my_strcasecmp(system_charset_info, item->name,find->name))) { From a42e0830a78fbc6effee9f0e7dee6c49ebfe2bdb Mon Sep 17 00:00:00 2001 From: unknown Date: Mon, 16 Oct 2006 16:27:06 +0300 Subject: [PATCH 08/16] Merge update of the fix for bug 14019 in 5.0 --- mysql-test/r/group_by.result | 4 ++++ 1 file changed, 4 insertions(+) diff --git a/mysql-test/r/group_by.result b/mysql-test/r/group_by.result index 679106bd71b..7d1e8832069 100644 --- a/mysql-test/r/group_by.result +++ b/mysql-test/r/group_by.result @@ -802,8 +802,12 @@ a set sql_mode=''; SELECT a FROM t1 HAVING 'a' > 1; a +Warnings: +Warning 1292 Truncated incorrect DOUBLE value: 'a' SELECT a FROM t1 HAVING "a" > 1; a +Warnings: +Warning 1292 Truncated incorrect DOUBLE value: 'a' SELECT a FROM t1 HAVING `a` > 1; a 2 From ffc1facce894359d5339ca7513a5518c2d829f29 Mon Sep 17 00:00:00 2001 From: unknown Date: Mon, 16 Oct 2006 18:09:58 +0300 Subject: [PATCH 09/16] Bug #22367: Optimizer uses ref join type instead of eq_ref for simple join on strings MySQL is setting the flag HA_END_SPACE_KEYS for all the keys that reference text or varchar columns with collation different than binary. This was done to handle correctly the situation where a lookup on such a key may return more than 1 row because of the presence of many rows that differ only by the amount of trailing space in the table's string column. Inserting such values however appears to violate the unique checks on INSERT/UPDATE. Thus that flag must not be set as it will prevent the optimizer from choosing a faster access method. This fix removes the setting of the HA_END_SPACE_KEYS flag. include/my_base.h: Bug #22367: Optimizer uses ref join type instead of eq_ref for simple join on strings - disabled HA_END_SPACE_KEY as it's no longer needed mysql-test/r/func_str.result: Bug #22367: Optimizer uses ref join type instead of eq_ref for simple join on strings - fixed explain in an existing case mysql-test/r/merge.result: Bug #22367: Optimizer uses ref join type instead of eq_ref for simple join on strings - fixed explain in an existing case mysql-test/r/select.result: Bug #22367: Optimizer uses ref join type instead of eq_ref for simple join on strings - test case mysql-test/r/subselect.result: Bug #22367: Optimizer uses ref join type instead of eq_ref for simple join on strings - fixed explain in an existing case mysql-test/t/select.test: Bug #22367: Optimizer uses ref join type instead of eq_ref for simple join on strings - test case --- include/my_base.h | 7 ++++++- mysql-test/r/func_str.result | 4 ++-- mysql-test/r/merge.result | 2 +- mysql-test/r/select.result | 10 ++++++++++ mysql-test/r/subselect.result | 10 +++++----- mysql-test/t/select.test | 14 ++++++++++++++ 6 files changed, 38 insertions(+), 9 deletions(-) diff --git a/include/my_base.h b/include/my_base.h index d8a0e15ccbe..985a27a0c54 100644 --- a/include/my_base.h +++ b/include/my_base.h @@ -224,12 +224,17 @@ enum ha_base_keytype { /* poor old NISAM has 8-bit flags :-( */ #define HA_SORT_ALLOWS_SAME 128 /* Intern bit when sorting records */ #endif +#if MYSQL_VERSION_ID < 0x50200 /* Key has a part that can have end space. If this is an unique key we have to handle it differently from other unique keys as we can find many matching rows for one key (because end space are not compared) */ -#define HA_END_SPACE_KEY 4096 +#define HA_END_SPACE_KEY 0 /* was: 4096 */ +#else +#error HA_END_SPACE_KEY is obsolete, please remove it +#endif + /* These flags can be added to key-seg-flag */ diff --git a/mysql-test/r/func_str.result b/mysql-test/r/func_str.result index 00642e1a570..c2c12f8d291 100644 --- a/mysql-test/r/func_str.result +++ b/mysql-test/r/func_str.result @@ -1143,9 +1143,9 @@ EXPLAIN EXTENDED SELECT * FROM t1 INNER JOIN t2 ON code=id WHERE id='a12' AND (LENGTH(code)=5 OR code < 'a00'); id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t2 const PRIMARY PRIMARY 12 const 1 Using index 1 SIMPLE t1 ref code code 13 const 3 Using where; Using index -1 SIMPLE t2 ref PRIMARY PRIMARY 12 const 1 Using where; Using index Warnings: -Note 1003 select `test`.`t1`.`code` AS `code`,`test`.`t2`.`id` AS `id` from `test`.`t1` join `test`.`t2` where ((`test`.`t1`.`code` = _latin1'a12') and (`test`.`t2`.`id` = _latin1'a12') and (length(`test`.`t1`.`code`) = 5)) +Note 1003 select `test`.`t1`.`code` AS `code`,`test`.`t2`.`id` AS `id` from `test`.`t1` join `test`.`t2` where ((`test`.`t1`.`code` = _latin1'a12') and (length(`test`.`t1`.`code`) = 5)) DROP TABLE t1,t2; End of 5.0 tests diff --git a/mysql-test/r/merge.result b/mysql-test/r/merge.result index b8fdd24be74..5196462e97e 100644 --- a/mysql-test/r/merge.result +++ b/mysql-test/r/merge.result @@ -626,7 +626,7 @@ id select_type table type possible_keys key key_len ref rows Extra EXPLAIN SELECT * FROM t2 WHERE fileset_id = 2 AND file_code = '0000000115' LIMIT 1; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t2 ref PRIMARY,files PRIMARY 35 const,const 1 Using where +1 SIMPLE t2 const PRIMARY,files PRIMARY 35 const,const 1 DROP TABLE t2, t1; create table t1 (x int, y int, index xy(x, y)); create table t2 (x int, y int, index xy(x, y)); diff --git a/mysql-test/r/select.result b/mysql-test/r/select.result index 0c62d3f570f..5f059260b95 100644 --- a/mysql-test/r/select.result +++ b/mysql-test/r/select.result @@ -3517,3 +3517,13 @@ id a b c d e 2 NULL NULL NULL 2 40 2 NULL NULL NULL 2 50 DROP TABLE t1,t2,t3; +CREATE TABLE t1 (a int, b varchar(20) NOT NULL, PRIMARY KEY(a)); +CREATE TABLE t2 (a int, b varchar(20) NOT NULL, +PRIMARY KEY (a), UNIQUE KEY (b)); +INSERT INTO t1 VALUES (1,'a'),(2,'b'),(3,'c'); +INSERT INTO t2 VALUES (1,'a'),(2,'b'),(3,'c'); +EXPLAIN SELECT t1.a FROM t1 LEFT JOIN t2 ON t2.b=t1.b WHERE t1.a=3; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const PRIMARY PRIMARY 4 const 1 +1 SIMPLE t2 const b b 22 const 1 Using index +DROP TABLE t1,t2; diff --git a/mysql-test/r/subselect.result b/mysql-test/r/subselect.result index 6bf85979002..abe840e96d9 100644 --- a/mysql-test/r/subselect.result +++ b/mysql-test/r/subselect.result @@ -363,12 +363,12 @@ INSERT INTO t8 (pseudo,email) VALUES ('joce1','test1'); INSERT INTO t8 (pseudo,email) VALUES ('2joce1','2test1'); EXPLAIN EXTENDED SELECT pseudo,(SELECT email FROM t8 WHERE pseudo=(SELECT pseudo FROM t8 WHERE pseudo='joce')) FROM t8 WHERE pseudo=(SELECT pseudo FROM t8 WHERE pseudo='joce'); id select_type table type possible_keys key key_len ref rows Extra -1 PRIMARY t8 ref PRIMARY PRIMARY 37 const 1 Using where; Using index -4 SUBQUERY t8 ref PRIMARY PRIMARY 37 1 Using where; Using index -2 SUBQUERY t8 ref PRIMARY PRIMARY 37 const 1 Using where -3 SUBQUERY t8 ref PRIMARY PRIMARY 37 1 Using where; Using index +1 PRIMARY t8 const PRIMARY PRIMARY 37 const 1 Using index +4 SUBQUERY t8 const PRIMARY PRIMARY 37 1 Using index +2 SUBQUERY t8 const PRIMARY PRIMARY 37 const 1 +3 SUBQUERY t8 const PRIMARY PRIMARY 37 1 Using index Warnings: -Note 1003 select `test`.`t8`.`pseudo` AS `pseudo`,(select `test`.`t8`.`email` AS `email` from `test`.`t8` where (`test`.`t8`.`pseudo` = (select `test`.`t8`.`pseudo` AS `pseudo` from `test`.`t8` where (`test`.`t8`.`pseudo` = _latin1'joce')))) AS `(SELECT email FROM t8 WHERE pseudo=(SELECT pseudo FROM t8 WHERE pseudo='joce'))` from `test`.`t8` where (`test`.`t8`.`pseudo` = (select `test`.`t8`.`pseudo` AS `pseudo` from `test`.`t8` where (`test`.`t8`.`pseudo` = _latin1'joce'))) +Note 1003 select `test`.`t8`.`pseudo` AS `pseudo`,(select `test`.`t8`.`email` AS `email` from `test`.`t8` where 1) AS `(SELECT email FROM t8 WHERE pseudo=(SELECT pseudo FROM t8 WHERE pseudo='joce'))` from `test`.`t8` where 1 SELECT pseudo FROM t8 WHERE pseudo=(SELECT pseudo,email FROM t8 WHERE pseudo='joce'); ERROR 21000: Operand should contain 1 column(s) diff --git a/mysql-test/t/select.test b/mysql-test/t/select.test index 36b3749b4d7..1a5a3d2b254 100644 --- a/mysql-test/t/select.test +++ b/mysql-test/t/select.test @@ -2998,3 +2998,17 @@ SELECT * FROM t1 LEFT JOIN t2 ON t2.b=t1.a INNER JOIN t3 ON t3.d=t1.id DROP TABLE t1,t2,t3; + +# +# Bug #22367: Optimizer uses ref join type instead of eq_ref for simple +# join on strings +# +CREATE TABLE t1 (a int, b varchar(20) NOT NULL, PRIMARY KEY(a)); +CREATE TABLE t2 (a int, b varchar(20) NOT NULL, + PRIMARY KEY (a), UNIQUE KEY (b)); +INSERT INTO t1 VALUES (1,'a'),(2,'b'),(3,'c'); +INSERT INTO t2 VALUES (1,'a'),(2,'b'),(3,'c'); + +EXPLAIN SELECT t1.a FROM t1 LEFT JOIN t2 ON t2.b=t1.b WHERE t1.a=3; + +DROP TABLE t1,t2; From decf9082fbc170e34d896598217b8113b06634cb Mon Sep 17 00:00:00 2001 From: unknown Date: Mon, 16 Oct 2006 19:30:19 +0300 Subject: [PATCH 10/16] Bug #22342: No results returned for query using max and group by When using index for group by and range access the server isolates a set of ranges based on the conditions over the key parts of the index used. Then it uses only the ranges over the GROUP BY fields to jump from one group to another. Since the GROUP BY fields may form a prefix over the index, we may use only a prefix of the ranges produced by the range optimizer. Each range contains a notion on whether it includes its border values. The problem is that when using a range prefix, the last range is open because it assumes that there is a range on the next keypart. Thus when we use a prefix range as it is, it excludes all border values. The solution is when ignoring the suffix of the range conditions (to jump over the GROUP BY prefix only) the server must change the remaining intervals so they always contain their borders, e.g. if the whole range was : (1,-inf) <= (,) < (1, 3) we must make (1) <= () <= (1) because (a,b) < (c1,c2) means : a < c1 OR (a = c1 AND b < c2). mysql-test/r/group_min_max.result: Bug #22342: No results returned for query using max and group by - test case mysql-test/t/group_min_max.test: Bug #22342: No results returned for query using max and group by - test case sql/opt_range.cc: Bug #22342: No results returned for query using max and group by - open the intervals for prefix select when there are more conditions than used for the prefix search. sql/opt_range.h: Bug #22342: No results returned for query using max and group by - open the intervals for prefix select when there are more conditions than used for the prefix search. --- mysql-test/r/group_min_max.result | 20 +++++++++++++++++ mysql-test/t/group_min_max.test | 16 +++++++++++++ sql/opt_range.cc | 37 +++++++++++++++++++++++++++++++ sql/opt_range.h | 2 ++ 4 files changed, 75 insertions(+) diff --git a/mysql-test/r/group_min_max.result b/mysql-test/r/group_min_max.result index fe6f7c4ca55..826e642ce88 100644 --- a/mysql-test/r/group_min_max.result +++ b/mysql-test/r/group_min_max.result @@ -2142,3 +2142,23 @@ t1; id2 id3 id5 id4 id3 id6 id5 id1 1 1 1 1 1 1 1 1 DROP TABLE t1,t2,t3,t4,t5,t6; +CREATE TABLE t1 (a int, b int, PRIMARY KEY (a,b), KEY b (b)); +INSERT INTO t1 VALUES (1,1),(1,2); +explain SELECT MAX(b), a FROM t1 WHERE b < 2 AND a = 1 GROUP BY a; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 range PRIMARY,b PRIMARY 8 NULL 2 Using where; Using index for group-by +SELECT MAX(b), a FROM t1 WHERE b < 2 AND a = 1 GROUP BY a; +MAX(b) a +1 1 +SELECT MIN(b), a FROM t1 WHERE b > 1 AND a = 1 GROUP BY a; +MIN(b) a +2 1 +CREATE TABLE t2 (a int, b int, c int, PRIMARY KEY (a,b,c)); +INSERT INTO t2 SELECT a,b,b FROM t1; +explain SELECT MIN(c) FROM t2 WHERE b = 2 and a = 1 and c > 1 GROUP BY a; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t2 range PRIMARY PRIMARY 12 NULL 2 Using where; Using index for group-by +SELECT MIN(c) FROM t2 WHERE b = 2 and a = 1 and c > 1 GROUP BY a; +MIN(c) +2 +DROP TABLE t1,t2; diff --git a/mysql-test/t/group_min_max.test b/mysql-test/t/group_min_max.test index 5427727a8f4..9f3fb5ea51e 100644 --- a/mysql-test/t/group_min_max.test +++ b/mysql-test/t/group_min_max.test @@ -794,3 +794,19 @@ SELECT * FROM t1; DROP TABLE t1,t2,t3,t4,t5,t6; + +# +# Bug#22342: No results returned for query using max and group by +# +CREATE TABLE t1 (a int, b int, PRIMARY KEY (a,b), KEY b (b)); +INSERT INTO t1 VALUES (1,1),(1,2); + +explain SELECT MAX(b), a FROM t1 WHERE b < 2 AND a = 1 GROUP BY a; +SELECT MAX(b), a FROM t1 WHERE b < 2 AND a = 1 GROUP BY a; +SELECT MIN(b), a FROM t1 WHERE b > 1 AND a = 1 GROUP BY a; +CREATE TABLE t2 (a int, b int, c int, PRIMARY KEY (a,b,c)); +INSERT INTO t2 SELECT a,b,b FROM t1; +explain SELECT MIN(c) FROM t2 WHERE b = 2 and a = 1 and c > 1 GROUP BY a; +SELECT MIN(c) FROM t2 WHERE b = 2 and a = 1 and c > 1 GROUP BY a; + +DROP TABLE t1,t2; diff --git a/sql/opt_range.cc b/sql/opt_range.cc index 93566dbc281..ad0abb798d1 100644 --- a/sql/opt_range.cc +++ b/sql/opt_range.cc @@ -8374,6 +8374,7 @@ TRP_GROUP_MIN_MAX::make_quick(PARAM *param, bool retrieve_full_rows, quick->quick_prefix_select= NULL; quick->update_key_stat(); + quick->adjust_prefix_ranges(); DBUG_RETURN(quick); } @@ -8603,6 +8604,42 @@ bool QUICK_GROUP_MIN_MAX_SELECT::add_range(SEL_ARG *sel_range) } +/* + Opens the ranges if there are more conditions in quick_prefix_select than + the ones used for jumping through the prefixes. + + SYNOPSIS + QUICK_GROUP_MIN_MAX_SELECT::adjust_prefix_ranges() + + NOTES + quick_prefix_select is made over the conditions on the whole key. + It defines a number of ranges of length x. + However when jumping through the prefixes we use only the the first + few most significant keyparts in the range key. However if there + are more keyparts to follow the ones we are using we must make the + condition on the key inclusive (because x < "ab" means + x[0] < 'a' OR (x[0] == 'a' AND x[1] < 'b'). + To achive the above we must turn off the NEAR_MIN/NEAR_MAX +*/ +void QUICK_GROUP_MIN_MAX_SELECT::adjust_prefix_ranges () +{ + if (quick_prefix_select && + group_prefix_len < quick_prefix_select->max_used_key_length) + { + DYNAMIC_ARRAY *arr; + uint inx; + + for (inx= 0, arr= &quick_prefix_select->ranges; inx < arr->elements; inx++) + { + QUICK_RANGE *range; + + get_dynamic(arr, (gptr)&range, inx); + range->flag &= ~(NEAR_MIN | NEAR_MAX); + } + } +} + + /* Determine the total number and length of the keys that will be used for index lookup. diff --git a/sql/opt_range.h b/sql/opt_range.h index 9474f2d469f..784dd648ad2 100644 --- a/sql/opt_range.h +++ b/sql/opt_range.h @@ -294,6 +294,7 @@ protected: friend class QUICK_SELECT_DESC; friend class QUICK_INDEX_MERGE_SELECT; friend class QUICK_ROR_INTERSECT_SELECT; + friend class QUICK_GROUP_MIN_MAX_SELECT; DYNAMIC_ARRAY ranges; /* ordered array of range ptrs */ QUICK_RANGE **cur_range; /* current element in ranges */ @@ -642,6 +643,7 @@ public: ~QUICK_GROUP_MIN_MAX_SELECT(); bool add_range(SEL_ARG *sel_range); void update_key_stat(); + void adjust_prefix_ranges(); bool alloc_buffers(); int init(); int reset(); From 6101fd25d0cafcdd785ca701ed9988cb3db61249 Mon Sep 17 00:00:00 2001 From: unknown Date: Mon, 16 Oct 2006 14:25:28 -0700 Subject: [PATCH 11/16] Fixed bug #19579: at range analysis optimizer did not take into account predicates that become sargable after reading const tables. In some cases this resulted in choosing non-optimal execution plans. Now info of such potentially saragable predicates is saved in an array and after reading const tables we check whether this predicates has become saragable. mysql-test/r/select.result: Added a test case for bug #19579. mysql-test/t/select.test: Added a test case for bug #19579. sql/item_cmpfunc.cc: Fixed bug #19579: at range analysis optimizer did not take into account predicates that become sargable after reading const tables. Added a counter of between predicates. sql/sql_base.cc: Fixed bug #19579: at range analysis optimizer did not take into account predicates that become sargable after reading const tables. Added a counter of between predicates. sql/sql_lex.cc: Fixed bug #19579: at range analysis optimizer did not take into account predicates that become sargable after reading const tables. Added a counter of between predicates. sql/sql_lex.h: Fixed bug #19579: at range analysis optimizer did not take into account predicates that become sargable after reading const tables. Added a counter of between predicates. sql/sql_select.cc: Fixed bug #19579: at range analysis optimizer did not take into account predicates that become sargable after reading const tables. Now info of such potentially saragable predicates is saved in an array and after reading const tables we check whether this predicates has become saragable. --- mysql-test/r/select.result | 49 +++++++++++ mysql-test/t/select.test | 45 ++++++++++ sql/item_cmpfunc.cc | 2 + sql/sql_base.cc | 1 + sql/sql_lex.cc | 2 +- sql/sql_lex.h | 3 +- sql/sql_select.cc | 171 ++++++++++++++++++++++++++++++------- 7 files changed, 238 insertions(+), 35 deletions(-) diff --git a/mysql-test/r/select.result b/mysql-test/r/select.result index 9c35e1963e6..19492d418ff 100644 --- a/mysql-test/r/select.result +++ b/mysql-test/r/select.result @@ -3552,3 +3552,52 @@ id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t1 range PRIMARY PRIMARY 12 NULL 2 Using where 1 SIMPLE t2 ref PRIMARY PRIMARY 18 test.t1.fk 1 Using where DROP TABLE t1,t2; +CREATE TABLE t1(id int PRIMARY KEY, b int, e int); +CREATE TABLE t2(i int, a int, INDEX si(i), INDEX ai(a)); +CREATE TABLE t3(a int PRIMARY KEY, c char(4), INDEX ci(c)); +INSERT INTO t1 VALUES +(1,10,19), (2,20,22), (4,41,42), (9,93,95), (7, 77,79), +(6,63,67), (5,55,58), (3,38,39), (8,81,89); +INSERT INTO t2 VALUES +(21,210), (41,410), (82,820), (83,830), (84,840), +(65,650), (51,510), (37,370), (94,940), (76,760), +(22,220), (33,330), (40,400), (95,950), (38,380), +(67,670), (88,880), (57,570), (96,960), (97,970); +INSERT INTO t3 VALUES +(210,'bb'), (950,'ii'), (400,'ab'), (500,'ee'), (220,'gg'), +(440,'gg'), (310,'eg'), (380,'ee'), (840,'bb'), (830,'ff'), +(230,'aa'), (960,'ii'), (410,'aa'), (510,'ee'), (290,'bb'), +(450,'gg'), (320,'dd'), (390,'hh'), (850,'jj'), (860,'ff'); +EXPLAIN +SELECT t3.a FROM t1,t2 FORCE INDEX (si),t3 +WHERE t1.id = 8 AND t2.i BETWEEN t1.b AND t1.e AND +t3.a=t2.a AND t3.c IN ('bb','ee'); +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const PRIMARY PRIMARY 4 const 1 +1 SIMPLE t2 range si si 5 NULL 4 Using where +1 SIMPLE t3 eq_ref PRIMARY,ci PRIMARY 4 test.t2.a 1 Using where +EXPLAIN +SELECT t3.a FROM t1,t2,t3 +WHERE t1.id = 8 AND t2.i BETWEEN t1.b AND t1.e AND +t3.a=t2.a AND t3.c IN ('bb','ee') ; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const PRIMARY PRIMARY 4 const 1 +1 SIMPLE t2 range si,ai si 5 NULL 4 Using where +1 SIMPLE t3 eq_ref PRIMARY,ci PRIMARY 4 test.t2.a 1 Using where +EXPLAIN +SELECT t3.a FROM t1,t2 FORCE INDEX (si),t3 +WHERE t1.id = 8 AND (t2.i=t1.b OR t2.i=t1.e) AND t3.a=t2.a AND +t3.c IN ('bb','ee'); +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const PRIMARY PRIMARY 4 const 1 +1 SIMPLE t2 range si si 5 NULL 2 Using where +1 SIMPLE t3 eq_ref PRIMARY,ci PRIMARY 4 test.t2.a 1 Using where +EXPLAIN +SELECT t3.a FROM t1,t2,t3 +WHERE t1.id = 8 AND (t2.i=t1.b OR t2.i=t1.e) AND t3.a=t2.a AND +t3.c IN ('bb','ee'); +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 const PRIMARY PRIMARY 4 const 1 +1 SIMPLE t2 range si,ai si 5 NULL 2 Using where +1 SIMPLE t3 eq_ref PRIMARY,ci PRIMARY 4 test.t2.a 1 Using where +DROP TABLE t1,t2,t3; diff --git a/mysql-test/t/select.test b/mysql-test/t/select.test index 166b709f9b6..a49872654b3 100644 --- a/mysql-test/t/select.test +++ b/mysql-test/t/select.test @@ -3007,6 +3007,8 @@ c7 int, c8 int, c9 int, fulltext key (`c1`)); select distinct match (`c1`) against ('z') , c2, c3, c4,c5, c6,c7, c8 from t1 where c9=1 order by c2, c2; drop table t1; + +# # Bug #22735: no equality propagation for BETWEEN and IN with STRING arguments # @@ -3033,3 +3035,46 @@ EXPLAIN SELECT t2.* WHERE t2.fk IN ('a','b') AND t2.pk=t1.fk; DROP TABLE t1,t2; + +# +# Bug #19579: predicates that become sargable after reading const tables +# are not taken into account by optimizer +# + +CREATE TABLE t1(id int PRIMARY KEY, b int, e int); +CREATE TABLE t2(i int, a int, INDEX si(i), INDEX ai(a)); +CREATE TABLE t3(a int PRIMARY KEY, c char(4), INDEX ci(c)); + +INSERT INTO t1 VALUES + (1,10,19), (2,20,22), (4,41,42), (9,93,95), (7, 77,79), + (6,63,67), (5,55,58), (3,38,39), (8,81,89); +INSERT INTO t2 VALUES + (21,210), (41,410), (82,820), (83,830), (84,840), + (65,650), (51,510), (37,370), (94,940), (76,760), + (22,220), (33,330), (40,400), (95,950), (38,380), + (67,670), (88,880), (57,570), (96,960), (97,970); +INSERT INTO t3 VALUES + (210,'bb'), (950,'ii'), (400,'ab'), (500,'ee'), (220,'gg'), + (440,'gg'), (310,'eg'), (380,'ee'), (840,'bb'), (830,'ff'), + (230,'aa'), (960,'ii'), (410,'aa'), (510,'ee'), (290,'bb'), + (450,'gg'), (320,'dd'), (390,'hh'), (850,'jj'), (860,'ff'); + +EXPLAIN +SELECT t3.a FROM t1,t2 FORCE INDEX (si),t3 + WHERE t1.id = 8 AND t2.i BETWEEN t1.b AND t1.e AND + t3.a=t2.a AND t3.c IN ('bb','ee'); +EXPLAIN +SELECT t3.a FROM t1,t2,t3 + WHERE t1.id = 8 AND t2.i BETWEEN t1.b AND t1.e AND + t3.a=t2.a AND t3.c IN ('bb','ee') ; + +EXPLAIN +SELECT t3.a FROM t1,t2 FORCE INDEX (si),t3 + WHERE t1.id = 8 AND (t2.i=t1.b OR t2.i=t1.e) AND t3.a=t2.a AND + t3.c IN ('bb','ee'); +EXPLAIN +SELECT t3.a FROM t1,t2,t3 + WHERE t1.id = 8 AND (t2.i=t1.b OR t2.i=t1.e) AND t3.a=t2.a AND + t3.c IN ('bb','ee'); + +DROP TABLE t1,t2,t3; diff --git a/sql/item_cmpfunc.cc b/sql/item_cmpfunc.cc index 780d70d51dc..9a400d60ae6 100644 --- a/sql/item_cmpfunc.cc +++ b/sql/item_cmpfunc.cc @@ -1078,6 +1078,8 @@ bool Item_func_between::fix_fields(THD *thd, Item **ref) if (Item_func_opt_neg::fix_fields(thd, ref)) return 1; + thd->lex->current_select->between_count++; + /* not_null_tables_cache == union(T1(e),T1(e1),T1(e2)) */ if (pred_level && !negated) return 0; diff --git a/sql/sql_base.cc b/sql/sql_base.cc index 047fb8f3cff..0939fb3a47e 100644 --- a/sql/sql_base.cc +++ b/sql/sql_base.cc @@ -4906,6 +4906,7 @@ int setup_conds(THD *thd, TABLE_LIST *tables, TABLE_LIST *leaves, thd->set_query_id=1; select_lex->cond_count= 0; + select_lex->between_count= 0; for (table= tables; table; table= table->next_local) { diff --git a/sql/sql_lex.cc b/sql/sql_lex.cc index 788276ac654..af81960f9ef 100644 --- a/sql/sql_lex.cc +++ b/sql/sql_lex.cc @@ -1138,7 +1138,7 @@ void st_select_lex::init_query() initialization is checked for failure. */ parent_lex->push_context(&context); - cond_count= with_wild= 0; + cond_count= between_count= with_wild= 0; conds_processed_with_permanent_arena= 0; ref_pointer_array= 0; select_n_having_items= 0; diff --git a/sql/sql_lex.h b/sql/sql_lex.h index fdf14c691e9..a3173b73d6d 100644 --- a/sql/sql_lex.h +++ b/sql/sql_lex.h @@ -530,7 +530,8 @@ public: list during split_sum_func */ uint select_n_having_items; - uint cond_count; /* number of arguments of and/or/xor in where/having */ + uint cond_count; /* number of arguments of and/or/xor in where/having/on */ + uint between_count; /* number of between predicates in where/having/on */ enum_parsing_place parsing_place; /* where we are parsing expression */ bool with_sum_func; /* sum function indicator */ /* diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 3935029190b..d233e2824ea 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -35,14 +35,17 @@ const char *join_type_str[]={ "UNKNOWN","system","const","eq_ref","ref", "index_merge" }; +struct st_sargable_param; + static void optimize_keyuse(JOIN *join, DYNAMIC_ARRAY *keyuse_array); static bool make_join_statistics(JOIN *join, TABLE_LIST *leaves, COND *conds, DYNAMIC_ARRAY *keyuse); static bool update_ref_and_keys(THD *thd, DYNAMIC_ARRAY *keyuse, - JOIN_TAB *join_tab, + JOIN_TAB *join_tab, uint tables, COND *conds, COND_EQUAL *cond_equal, - table_map table_map, SELECT_LEX *select_lex); + table_map table_map, SELECT_LEX *select_lex, + st_sargable_param **sargables); static int sort_keyuse(KEYUSE *a,KEYUSE *b); static void set_position(JOIN *join,uint index,JOIN_TAB *table,KEYUSE *key); static bool create_ref_for_key(JOIN *join, JOIN_TAB *j, KEYUSE *org_keyuse, @@ -2042,6 +2045,19 @@ static ha_rows get_quick_record_count(THD *thd, SQL_SELECT *select, DBUG_RETURN(HA_POS_ERROR); /* This shouldn't happend */ } +/* + This structure is used to collect info on potentially sargable + predicates in order to check whether they become sargable after + reading const tables. + We form a bitmap of indexes that can be used for sargable predicates. + Only such indexes are involved in range analysis. +*/ +typedef struct st_sargable_param +{ + Field *field; /* field against which to check sargability */ + Item **arg_value; /* values of potential keys for lookups */ + uint num_values; /* number of values in the above array */ +} SARGABLE_PARAM; /* Calculate the best possible join and initialize the join structure @@ -2064,6 +2080,7 @@ make_join_statistics(JOIN *join, TABLE_LIST *tables, COND *conds, JOIN_TAB *stat,*stat_end,*s,**stat_ref; KEYUSE *keyuse,*start_keyuse; table_map outer_join=0; + SARGABLE_PARAM *sargables= 0; JOIN_TAB *stat_vector[MAX_TABLES+1]; DBUG_ENTER("make_join_statistics"); @@ -2185,7 +2202,7 @@ make_join_statistics(JOIN *join, TABLE_LIST *tables, COND *conds, if (conds || outer_join) if (update_ref_and_keys(join->thd, keyuse_array, stat, join->tables, conds, join->cond_equal, - ~outer_join, join->select_lex)) + ~outer_join, join->select_lex, &sargables)) DBUG_RETURN(1); /* Read tables with 0 or 1 rows (system tables) */ @@ -2335,6 +2352,26 @@ make_join_statistics(JOIN *join, TABLE_LIST *tables, COND *conds, } } while (join->const_table_map & found_ref && ref_changed); + /* + Update info on indexes that can be used for search lookups as + reading const tables may has added new sargable predicates. + */ + if (const_count && sargables) + { + for( ; sargables->field ; sargables++) + { + Field *field= sargables->field; + JOIN_TAB *stat= field->table->reginfo.join_tab; + key_map possible_keys= field->key_start; + possible_keys.intersect(field->table->keys_in_use_for_query); + bool is_const= 1; + for (uint i=0; i< sargables->num_values; i++) + is_const&= sargables->arg_value[i]->const_item(); + if (is_const) + stat[0].const_keys.merge(possible_keys); + } + } + /* Calc how many (possible) matched records in each table */ for (s=stat ; s < stat_end ; s++) @@ -2594,6 +2631,7 @@ merge_key_fields(KEY_FIELD *start,KEY_FIELD *new_fields,KEY_FIELD *end, eq_func True if we used =, <=> or IS NULL value Value used for comparison with field usable_tables Tables which can be used for key optimization + sargables IN/OUT Array of found sargable candidates NOTES If we are doing a NOT NULL comparison on a NOT NULL field in a outer join @@ -2605,8 +2643,8 @@ merge_key_fields(KEY_FIELD *start,KEY_FIELD *new_fields,KEY_FIELD *end, static void add_key_field(KEY_FIELD **key_fields,uint and_level, Item_func *cond, - Field *field, bool eq_func, Item **value, uint num_values, - table_map usable_tables) + Field *field, bool eq_func, Item **value, uint num_values, + table_map usable_tables, SARGABLE_PARAM **sargables) { uint exists_optimize= 0; if (!(field->flags & PART_KEY_FLAG)) @@ -2662,6 +2700,19 @@ add_key_field(KEY_FIELD **key_fields,uint and_level, Item_func *cond, is_const&= value[i]->const_item(); if (is_const) stat[0].const_keys.merge(possible_keys); + else if (!eq_func) + { + /* + Save info to be able check whether this predicate can be + considered as sargable for range analisis after reading const tables. + We do not save info about equalities as update_const_equal_items + will take care of updating info on keys from sargable equalities. + */ + (*sargables)--; + (*sargables)->field= field; + (*sargables)->arg_value= value; + (*sargables)->num_values= num_values; + } /* We can't always use indexes when comparing a string index to a number. cmp_type() is checked to allow compare of dates to numbers. @@ -2752,6 +2803,7 @@ add_key_field(KEY_FIELD **key_fields,uint and_level, Item_func *cond, value Value used for comparison with field Is NULL for BETWEEN and IN usable_tables Tables which can be used for key optimization + sargables IN/OUT Array of found sargable candidates NOTES If field items f1 and f2 belong to the same multiple equality and @@ -2765,11 +2817,12 @@ static void add_key_equal_fields(KEY_FIELD **key_fields, uint and_level, Item_func *cond, Item_field *field_item, bool eq_func, Item **val, - uint num_values, table_map usable_tables) + uint num_values, table_map usable_tables, + SARGABLE_PARAM **sargables) { Field *field= field_item->field; add_key_field(key_fields, and_level, cond, field, - eq_func, val, num_values, usable_tables); + eq_func, val, num_values, usable_tables, sargables); Item_equal *item_equal= field_item->item_equal; if (item_equal) { @@ -2784,7 +2837,8 @@ add_key_equal_fields(KEY_FIELD **key_fields, uint and_level, if (!field->eq(item->field)) { add_key_field(key_fields, and_level, cond, item->field, - eq_func, val, num_values, usable_tables); + eq_func, val, num_values, usable_tables, + sargables); } } } @@ -2792,7 +2846,8 @@ add_key_equal_fields(KEY_FIELD **key_fields, uint and_level, static void add_key_fields(KEY_FIELD **key_fields,uint *and_level, - COND *cond, table_map usable_tables) + COND *cond, table_map usable_tables, + SARGABLE_PARAM **sargables) { if (cond->type() == Item_func::COND_ITEM) { @@ -2803,20 +2858,20 @@ add_key_fields(KEY_FIELD **key_fields,uint *and_level, { Item *item; while ((item=li++)) - add_key_fields(key_fields,and_level,item,usable_tables); + add_key_fields(key_fields,and_level,item,usable_tables,sargables); for (; org_key_fields != *key_fields ; org_key_fields++) org_key_fields->level= *and_level; } else { (*and_level)++; - add_key_fields(key_fields,and_level,li++,usable_tables); + add_key_fields(key_fields,and_level,li++,usable_tables,sargables); Item *item; while ((item=li++)) { KEY_FIELD *start_key_fields= *key_fields; (*and_level)++; - add_key_fields(key_fields,and_level,item,usable_tables); + add_key_fields(key_fields,and_level,item,usable_tables,sargables); *key_fields=merge_key_fields(org_key_fields,start_key_fields, *key_fields,++(*and_level)); } @@ -2847,9 +2902,9 @@ add_key_fields(KEY_FIELD **key_fields,uint *and_level, cond_func->argument_count() != 2); add_key_equal_fields(key_fields, *and_level, cond_func, (Item_field*) (cond_func->key_item()->real_item()), - 0, values, + 0, values, cond_func->argument_count()-1, - usable_tables); + usable_tables, sargables); } if (cond_func->functype() == Item_func::BETWEEN) { @@ -2863,7 +2918,8 @@ add_key_fields(KEY_FIELD **key_fields,uint *and_level, { field_item= (Item_field *) (cond_func->arguments()[i]->real_item()); add_key_equal_fields(key_fields, *and_level, cond_func, - field_item, 0, values, 1, usable_tables); + field_item, 0, values, 1, usable_tables, + sargables); } } } @@ -2880,7 +2936,8 @@ add_key_fields(KEY_FIELD **key_fields,uint *and_level, add_key_equal_fields(key_fields, *and_level, cond_func, (Item_field*) (cond_func->arguments()[0])->real_item(), equal_func, - cond_func->arguments()+1, 1, usable_tables); + cond_func->arguments()+1, 1, usable_tables, + sargables); } if (cond_func->arguments()[1]->real_item()->type() == Item::FIELD_ITEM && cond_func->functype() != Item_func::LIKE_FUNC && @@ -2889,7 +2946,8 @@ add_key_fields(KEY_FIELD **key_fields,uint *and_level, add_key_equal_fields(key_fields, *and_level, cond_func, (Item_field*) (cond_func->arguments()[1])->real_item(), equal_func, - cond_func->arguments(),1,usable_tables); + cond_func->arguments(),1,usable_tables, + sargables); } break; } @@ -2904,7 +2962,7 @@ add_key_fields(KEY_FIELD **key_fields,uint *and_level, add_key_equal_fields(key_fields, *and_level, cond_func, (Item_field*) (cond_func->arguments()[0])->real_item(), cond_func->functype() == Item_func::ISNULL_FUNC, - &tmp, 1, usable_tables); + &tmp, 1, usable_tables, sargables); } break; case Item_func::OPTIMIZE_EQUAL: @@ -2922,7 +2980,7 @@ add_key_fields(KEY_FIELD **key_fields,uint *and_level, while ((item= it++)) { add_key_field(key_fields, *and_level, cond_func, item->field, - TRUE, &const_item, 1, usable_tables); + TRUE, &const_item, 1, usable_tables, sargables); } } else @@ -2942,7 +3000,8 @@ add_key_fields(KEY_FIELD **key_fields,uint *and_level, if (!field->eq(item->field)) { add_key_field(key_fields, *and_level, cond_func, field, - TRUE, (Item **) &item, 1, usable_tables); + TRUE, (Item **) &item, 1, usable_tables, + sargables); } } it.rewind(); @@ -3093,6 +3152,7 @@ sort_keyuse(KEYUSE *a,KEYUSE *b) nested_join_table IN Nested join pseudo-table to process end INOUT End of the key field array and_level INOUT And-level + sargables IN/OUT Array of found sargable candidates DESCRIPTION This function populates KEY_FIELD array with entries generated from the @@ -3116,7 +3176,8 @@ sort_keyuse(KEYUSE *a,KEYUSE *b) */ static void add_key_fields_for_nj(TABLE_LIST *nested_join_table, - KEY_FIELD **end, uint *and_level) + KEY_FIELD **end, uint *and_level, + SARGABLE_PARAM **sargables) { List_iterator li(nested_join_table->nested_join->join_list); table_map tables= 0; @@ -3126,12 +3187,12 @@ static void add_key_fields_for_nj(TABLE_LIST *nested_join_table, while ((table= li++)) { if (table->nested_join) - add_key_fields_for_nj(table, end, and_level); + add_key_fields_for_nj(table, end, and_level, sargables); else if (!table->on_expr) tables |= table->table->map; } - add_key_fields(end, and_level, nested_join_table->on_expr, tables); + add_key_fields(end, and_level, nested_join_table->on_expr, tables, sargables); } @@ -3146,9 +3207,10 @@ static void add_key_fields_for_nj(TABLE_LIST *nested_join_table, tables Number of tables in join cond WHERE condition (note that the function analyzes join_tab[i]->on_expr too) - normal_tables tables not inner w.r.t some outer join (ones for which + normal_tables Tables not inner w.r.t some outer join (ones for which we can make ref access based the WHERE clause) select_lex current SELECT + sargables OUT Array of found sargable candidates RETURN 0 - OK @@ -3157,27 +3219,55 @@ static void add_key_fields_for_nj(TABLE_LIST *nested_join_table, static bool update_ref_and_keys(THD *thd, DYNAMIC_ARRAY *keyuse,JOIN_TAB *join_tab, - uint tables, COND *cond, COND_EQUAL *cond_equal, - table_map normal_tables, SELECT_LEX *select_lex) + uint tables, COND *cond, COND_EQUAL *cond_equal, + table_map normal_tables, SELECT_LEX *select_lex, + SARGABLE_PARAM **sargables) { uint and_level,i,found_eq_constant; KEY_FIELD *key_fields, *end, *field; + uint sz; uint m= 1; if (cond_equal && cond_equal->max_members) m= cond_equal->max_members; - - if (!(key_fields=(KEY_FIELD*) - thd->alloc(sizeof(key_fields[0])* - (thd->lex->current_select->cond_count+1)*2*m))) + + /* + We use the same piece of memory to store both KEY_FIELD + and SARGABLE_PARAM structure. + KEY_FIELD values are placed at the beginning this memory + while SARGABLE_PARAM values are put at the end. + All predicates that are used to fill arrays of KEY_FIELD + and SARGABLE_PARAM structures have at most 2 arguments + except BETWEEN predicates that have 3 arguments and + IN predicates. + This any predicate if it's not BETWEEN/IN can be used + directly to fill at most 2 array elements, either of KEY_FIELD + or SARGABLE_PARAM type. For a BETWEEN predicate 3 elements + can be filled as this predicate is considered as + saragable with respect to each of its argument. + An IN predicate can require at most 1 element as currently + it is considered as sargable only for its first argument. + Multiple equality can add elements that are filled after + substitution of field arguments by equal fields. There + can be not more than cond_equal->max_members such substitutions. + */ + sz= max(sizeof(KEY_FIELD),sizeof(SARGABLE_PARAM))* + (((thd->lex->current_select->cond_count+1)*2 + + thd->lex->current_select->between_count)*m+1); + if (!(key_fields=(KEY_FIELD*) thd->alloc(sz))) return TRUE; /* purecov: inspected */ and_level= 0; field= end= key_fields; + *sargables= (SARGABLE_PARAM *) key_fields + + (sz - sizeof((*sargables)[0].field))/sizeof(SARGABLE_PARAM); + /* set a barrier for the array of SARGABLE_PARAM */ + (*sargables)[0].field= 0; + if (my_init_dynamic_array(keyuse,sizeof(KEYUSE),20,64)) return TRUE; if (cond) { - add_key_fields(&end,&and_level,cond,normal_tables); + add_key_fields(&end,&and_level,cond,normal_tables,sargables); for (; field != end ; field++) { add_key_part(keyuse,field); @@ -3200,7 +3290,7 @@ update_ref_and_keys(THD *thd, DYNAMIC_ARRAY *keyuse,JOIN_TAB *join_tab, */ if (*join_tab[i].on_expr_ref) add_key_fields(&end,&and_level,*join_tab[i].on_expr_ref, - join_tab[i].table->map); + join_tab[i].table->map,sargables); } /* Process ON conditions for the nested joins */ @@ -3210,7 +3300,7 @@ update_ref_and_keys(THD *thd, DYNAMIC_ARRAY *keyuse,JOIN_TAB *join_tab, while ((table= li++)) { if (table->nested_join) - add_key_fields_for_nj(table, &end, &and_level); + add_key_fields_for_nj(table, &end, &and_level, sargables); } } @@ -7334,7 +7424,22 @@ static void update_const_equal_items(COND *cond, JOIN_TAB *tab) ((Item_cond*) cond)->functype() == Item_func::MULT_EQUAL_FUNC) { Item_equal *item_equal= (Item_equal *) cond; + bool contained_const= item_equal->get_const() != NULL; item_equal->update_const(); + if (!contained_const && item_equal->get_const()) + { + /* Update keys for range analysis */ + Item_equal_iterator it(*item_equal); + Item_field *item_field; + while ((item_field= it++)) + { + Field *field= item_field->field; + JOIN_TAB *stat= field->table->reginfo.join_tab; + key_map possible_keys= field->key_start; + possible_keys.intersect(field->table->keys_in_use_for_query); + stat[0].const_keys.merge(possible_keys); + } + } } } From d2198ed9f70bdc41b457f83ae2f31e47b2022a9c Mon Sep 17 00:00:00 2001 From: unknown Date: Tue, 17 Oct 2006 12:06:06 +0300 Subject: [PATCH 12/16] merge changes becuase of the fix for bug 22367 --- mysql-test/r/select.result | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/mysql-test/r/select.result b/mysql-test/r/select.result index 547b4c71895..9bf811a00a1 100644 --- a/mysql-test/r/select.result +++ b/mysql-test/r/select.result @@ -3538,19 +3538,19 @@ FROM t1 JOIN t2 ON t2.fk=t1.pk WHERE t2.fk < 'c' AND t2.pk=t1.fk; id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t1 range PRIMARY PRIMARY 12 NULL 3 Using where -1 SIMPLE t2 ref PRIMARY PRIMARY 18 test.t1.fk 1 Using where +1 SIMPLE t2 eq_ref PRIMARY PRIMARY 18 test.t1.fk 1 Using where EXPLAIN SELECT t2.* FROM t1 JOIN t2 ON t2.fk=t1.pk WHERE t2.fk BETWEEN 'a' AND 'b' AND t2.pk=t1.fk; id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t1 range PRIMARY PRIMARY 12 NULL 2 Using where -1 SIMPLE t2 ref PRIMARY PRIMARY 18 test.t1.fk 1 Using where +1 SIMPLE t2 eq_ref PRIMARY PRIMARY 18 test.t1.fk 1 Using where EXPLAIN SELECT t2.* FROM t1 JOIN t2 ON t2.fk=t1.pk WHERE t2.fk IN ('a','b') AND t2.pk=t1.fk; id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t1 range PRIMARY PRIMARY 12 NULL 2 Using where -1 SIMPLE t2 ref PRIMARY PRIMARY 18 test.t1.fk 1 Using where +1 SIMPLE t2 eq_ref PRIMARY PRIMARY 18 test.t1.fk 1 Using where DROP TABLE t1,t2; CREATE TABLE t1 (a int, b varchar(20) NOT NULL, PRIMARY KEY(a)); CREATE TABLE t2 (a int, b varchar(20) NOT NULL, From 841ea461ce2b6782ce280806039c32e7a5b7dcdd Mon Sep 17 00:00:00 2001 From: unknown Date: Tue, 17 Oct 2006 16:20:26 +0300 Subject: [PATCH 13/16] Bug#21798: memory leak during query execution with subquery in column list using a function When executing dependent subqueries they are re-inited and re-exec() for each row of the outer context. The cause for the bug is that during subquery reinitialization/re-execution, the optimizer reallocates JOIN::join_tab, JOIN::table in make_simple_join() and the local variable in 'sortorder' in create_sort_index(), which is allocated by make_unireg_sortorder(). Care must be taken not to allocate anything into the thread's memory pool while re-initializing query plan structures between subquery re-executions. All such items mush be cached and reused because the thread's memory pool is freed at the end of the whole query. Note that they must be cached and reused even for queries that are not otherwise cacheable because otherwise it will grow the thread's memory pool every time a cacheable query is re-executed. We provide additional members to the JOIN structure to store references to the items that need to be cached. mysql-test/r/subselect.result: Bug#21798: memory leak during query execution with subquery in column list using a function - test case mysql-test/t/subselect.test: Bug#21798: memory leak during query execution with subquery in column list using a function - test case sql/mysql_priv.h: Bug#21798: memory leak during query execution with subquery in column list using a function - cache the entities allocated in the threads memory pool by JOIN::exec (). sql/sql_delete.cc: Bug#21798: memory leak during query execution with subquery in column list using a function - cache the SORT_ORDER, TABLE * and JOIN_TAB allocated in the thread's memory pool by JOIN::exec (). sql/sql_select.cc: Bug#21798: memory leak during query execution with subquery in column list using a function - cache the SORT_ORDER, TABLE * and JOIN_TAB allocated in the thread's memory pool by JOIN::exec (). sql/sql_select.h: Bug#21798: memory leak during query execution with subquery in column list using a function - cache the SORT_ORDER, TABLE * and JOIN_TAB allocated in the thread's memory pool by JOIN::exec (). sql/sql_table.cc: Bug#21798: memory leak during query execution with subquery in column list using a function - cache the SORT_ORDER, TABLE * and JOIN_TAB allocated in the thread's memory pool by JOIN::exec (). sql/sql_update.cc: Bug#21798: memory leak during query execution with subquery in column list using a function - cache the SORT_ORDER, TABLE * and JOIN_TAB allocated in the thread's memory pool by JOIN::exec (). --- mysql-test/r/subselect.result | 26 +++++++++++++++++++++++ mysql-test/t/subselect.test | 26 +++++++++++++++++++++++ sql/mysql_priv.h | 3 ++- sql/sql_delete.cc | 2 +- sql/sql_select.cc | 40 ++++++++++++++++++++++++++++------- sql/sql_select.h | 15 +++++++++++++ sql/sql_table.cc | 2 +- sql/sql_update.cc | 2 +- 8 files changed, 104 insertions(+), 12 deletions(-) diff --git a/mysql-test/r/subselect.result b/mysql-test/r/subselect.result index 2e3ca9b71f0..8027981db38 100644 --- a/mysql-test/r/subselect.result +++ b/mysql-test/r/subselect.result @@ -3393,3 +3393,29 @@ id select_type table type possible_keys key key_len ref rows Extra 4 UNION t12 system NULL NULL NULL NULL 0 const row not found NULL UNION RESULT ALL NULL NULL NULL NULL NULL DROP TABLE t1; +CREATE TABLE t1 (a VARCHAR(250), b INT auto_increment, PRIMARY KEY (b)); +insert into t1 (a) values (FLOOR(rand() * 100)); +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +SELECT a, +(SELECT REPEAT(' ',250) FROM t1 i1 +WHERE i1.b=t1.a ORDER BY RAND() LIMIT 1) AS a +FROM t1 ORDER BY a LIMIT 5; +a a +0 NULL +0 NULL +0 NULL +0 NULL +0 NULL +DROP TABLE t1; diff --git a/mysql-test/t/subselect.test b/mysql-test/t/subselect.test index 740cb08c5bd..eefec96203a 100644 --- a/mysql-test/t/subselect.test +++ b/mysql-test/t/subselect.test @@ -2306,3 +2306,29 @@ explain select * from t1 where not exists ((select t11.i from t1 t11) union (select t12.i from t1 t12)); DROP TABLE t1; + +# +# Bug#21798: memory leak during query execution with subquery in column +# list using a function +# +CREATE TABLE t1 (a VARCHAR(250), b INT auto_increment, PRIMARY KEY (b)); +insert into t1 (a) values (FLOOR(rand() * 100)); +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; +insert into t1 (a) select FLOOR(rand() * 100) from t1; + +SELECT a, + (SELECT REPEAT(' ',250) FROM t1 i1 + WHERE i1.b=t1.a ORDER BY RAND() LIMIT 1) AS a +FROM t1 ORDER BY a LIMIT 5; +DROP TABLE t1; diff --git a/sql/mysql_priv.h b/sql/mysql_priv.h index 620992b8cc7..ab32ef1badf 100644 --- a/sql/mysql_priv.h +++ b/sql/mysql_priv.h @@ -708,7 +708,8 @@ bool mysql_xa_recover(THD *thd); bool check_simple_select(); -SORT_FIELD * make_unireg_sortorder(ORDER *order, uint *length); +SORT_FIELD * make_unireg_sortorder(ORDER *order, uint *length, + SORT_FIELD *sortorder); int setup_order(THD *thd, Item **ref_pointer_array, TABLE_LIST *tables, List &fields, List &all_fields, ORDER *order); int setup_group(THD *thd, Item **ref_pointer_array, TABLE_LIST *tables, diff --git a/sql/sql_delete.cc b/sql/sql_delete.cc index e420022b8a1..33b46080696 100644 --- a/sql/sql_delete.cc +++ b/sql/sql_delete.cc @@ -167,7 +167,7 @@ bool mysql_delete(THD *thd, TABLE_LIST *table_list, COND *conds, MYF(MY_FAE | MY_ZEROFILL)); if (!(sortorder= make_unireg_sortorder((ORDER*) order->first, - &length)) || + &length, NULL)) || (table->sort.found_records = filesort(thd, table, sortorder, length, select, HA_POS_ERROR, &examined_rows)) diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 4d2b3cac254..8f169a9d390 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -1574,6 +1574,7 @@ JOIN::exec() { DBUG_VOID_RETURN; } + sortorder= curr_join->sortorder; } thd->proc_info="Copying to group table"; @@ -1783,6 +1784,7 @@ JOIN::exec() (select_options & OPTION_FOUND_ROWS ? HA_POS_ERROR : unit->select_limit_cnt))) DBUG_VOID_RETURN; + sortorder= curr_join->sortorder; } } /* XXX: When can we have here thd->net.report_error not zero? */ @@ -4949,9 +4951,28 @@ make_simple_join(JOIN *join,TABLE *tmp_table) JOIN_TAB *join_tab; DBUG_ENTER("make_simple_join"); - if (!(tableptr=(TABLE**) join->thd->alloc(sizeof(TABLE*))) || - !(join_tab=(JOIN_TAB*) join->thd->alloc(sizeof(JOIN_TAB)))) - DBUG_RETURN(TRUE); + /* + Reuse TABLE * and JOIN_TAB if already allocated by a previous call + to this function through JOIN::exec (may happen for sub-queries). + */ + if (!join->table_cache) + { + if (!(join->table_cache= (TABLE**) join->thd->alloc(sizeof(TABLE*)))) + DBUG_RETURN(TRUE); /* purecov: inspected */ + if (join->tmp_join) + join->tmp_join->table_cache= join->table_cache; + } + if (!join->join_tab_cache) + { + if (!(join->join_tab_cache= + (JOIN_TAB*) join->thd->alloc(sizeof(JOIN_TAB)))) + DBUG_RETURN(TRUE); /* purecov: inspected */ + if (join->tmp_join) + join->tmp_join->join_tab_cache= join->join_tab_cache; + } + tableptr= join->table_cache; + join_tab= join->join_tab_cache; + join->join_tab=join_tab; join->table=tableptr; tableptr[0]=tmp_table; join->tables=1; @@ -11971,7 +11992,6 @@ static int create_sort_index(THD *thd, JOIN *join, ORDER *order, ha_rows filesort_limit, ha_rows select_limit) { - SORT_FIELD *sortorder; uint length; ha_rows examined_rows; TABLE *table; @@ -11987,7 +12007,8 @@ create_sort_index(THD *thd, JOIN *join, ORDER *order, if (test_if_skip_sort_order(tab,order,select_limit,0)) DBUG_RETURN(0); - if (!(sortorder=make_unireg_sortorder(order,&length))) + if (!(join->sortorder= + make_unireg_sortorder(order,&length,join->sortorder))) goto err; /* purecov: inspected */ /* It's not fatal if the following alloc fails */ table->sort.io_cache=(IO_CACHE*) my_malloc(sizeof(IO_CACHE), @@ -12034,7 +12055,7 @@ create_sort_index(THD *thd, JOIN *join, ORDER *order, if (table->s->tmp_table) table->file->info(HA_STATUS_VARIABLE); // Get record count - table->sort.found_records=filesort(thd, table,sortorder, length, + table->sort.found_records=filesort(thd, table,join->sortorder, length, select, filesort_limit, &examined_rows); tab->records= table->sort.found_records; // For SQL_CALC_ROWS if (select) @@ -12381,7 +12402,8 @@ err: } -SORT_FIELD *make_unireg_sortorder(ORDER *order, uint *length) +SORT_FIELD *make_unireg_sortorder(ORDER *order, uint *length, + SORT_FIELD *sortorder) { uint count; SORT_FIELD *sort,*pos; @@ -12390,7 +12412,9 @@ SORT_FIELD *make_unireg_sortorder(ORDER *order, uint *length) count=0; for (ORDER *tmp = order; tmp; tmp=tmp->next) count++; - pos=sort=(SORT_FIELD*) sql_alloc(sizeof(SORT_FIELD)*(count+1)); + if (!sortorder) + sortorder= (SORT_FIELD*) sql_alloc(sizeof(SORT_FIELD)*(count+1)); + pos=sort=sortorder; if (!pos) return 0; diff --git a/sql/sql_select.h b/sql/sql_select.h index d5a1bf82bc8..e1ae8677a6e 100644 --- a/sql/sql_select.h +++ b/sql/sql_select.h @@ -282,6 +282,18 @@ public: bool union_part; // this subselect is part of union bool optimized; // flag to avoid double optimization in EXPLAIN + /* + storage for caching buffers allocated during query execution. + These buffers allocations need to be cached as the thread memory pool is + cleared only at the end of the execution of the whole query and not caching + allocations that occur in repetition at execution time will result in + excessive memory usage. + */ + SORT_FIELD *sortorder; // make_unireg_sortorder() + TABLE **table_cache; // make_simple_join() + JOIN_TAB *join_tab_cache; // make_simple_join() + /* end of allocation caching storage */ + JOIN(THD *thd_arg, List &fields_arg, ulonglong select_options_arg, select_result *result_arg) :fields_list(fields_arg) @@ -307,6 +319,9 @@ public: examined_rows= 0; exec_tmp_table1= 0; exec_tmp_table2= 0; + sortorder= 0; + table_cache= 0; + join_tab_cache= 0; thd= thd_arg; sum_funcs= sum_funcs2= 0; procedure= 0; diff --git a/sql/sql_table.cc b/sql/sql_table.cc index e065a32c2e8..08c7e03693e 100644 --- a/sql/sql_table.cc +++ b/sql/sql_table.cc @@ -4044,7 +4044,7 @@ copy_data_between_tables(TABLE *from,TABLE *to, if (thd->lex->select_lex.setup_ref_array(thd, order_num) || setup_order(thd, thd->lex->select_lex.ref_pointer_array, &tables, fields, all_fields, order) || - !(sortorder=make_unireg_sortorder(order, &length)) || + !(sortorder=make_unireg_sortorder(order, &length, NULL)) || (from->sort.found_records = filesort(thd, from, sortorder, length, (SQL_SELECT *) 0, HA_POS_ERROR, &examined_rows)) == diff --git a/sql/sql_update.cc b/sql/sql_update.cc index 84b22c56cf9..4a6249410a7 100644 --- a/sql/sql_update.cc +++ b/sql/sql_update.cc @@ -311,7 +311,7 @@ int mysql_update(THD *thd, table->sort.io_cache = (IO_CACHE *) my_malloc(sizeof(IO_CACHE), MYF(MY_FAE | MY_ZEROFILL)); - if (!(sortorder=make_unireg_sortorder(order, &length)) || + if (!(sortorder=make_unireg_sortorder(order, &length, NULL)) || (table->sort.found_records = filesort(thd, table, sortorder, length, select, limit, &examined_rows)) From 71b67e4a534fd4d261a00d682790d5667dbc6c8f Mon Sep 17 00:00:00 2001 From: unknown Date: Tue, 17 Oct 2006 19:22:13 +0300 Subject: [PATCH 14/16] rename of the new members introduced in the fix for bug 21798 --- sql/sql_select.cc | 16 ++++++++-------- sql/sql_select.h | 8 ++++---- 2 files changed, 12 insertions(+), 12 deletions(-) diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 2e959560f2f..4da47e87393 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -4956,23 +4956,23 @@ make_simple_join(JOIN *join,TABLE *tmp_table) Reuse TABLE * and JOIN_TAB if already allocated by a previous call to this function through JOIN::exec (may happen for sub-queries). */ - if (!join->table_cache) + if (!join->table_reexec) { - if (!(join->table_cache= (TABLE**) join->thd->alloc(sizeof(TABLE*)))) + if (!(join->table_reexec= (TABLE**) join->thd->alloc(sizeof(TABLE*)))) DBUG_RETURN(TRUE); /* purecov: inspected */ if (join->tmp_join) - join->tmp_join->table_cache= join->table_cache; + join->tmp_join->table_reexec= join->table_reexec; } - if (!join->join_tab_cache) + if (!join->join_tab_reexec) { - if (!(join->join_tab_cache= + if (!(join->join_tab_reexec= (JOIN_TAB*) join->thd->alloc(sizeof(JOIN_TAB)))) DBUG_RETURN(TRUE); /* purecov: inspected */ if (join->tmp_join) - join->tmp_join->join_tab_cache= join->join_tab_cache; + join->tmp_join->join_tab_reexec= join->join_tab_reexec; } - tableptr= join->table_cache; - join_tab= join->join_tab_cache; + tableptr= join->table_reexec; + join_tab= join->join_tab_reexec; join->join_tab=join_tab; join->table=tableptr; tableptr[0]=tmp_table; diff --git a/sql/sql_select.h b/sql/sql_select.h index e1ae8677a6e..30b8f834ddf 100644 --- a/sql/sql_select.h +++ b/sql/sql_select.h @@ -290,8 +290,8 @@ public: excessive memory usage. */ SORT_FIELD *sortorder; // make_unireg_sortorder() - TABLE **table_cache; // make_simple_join() - JOIN_TAB *join_tab_cache; // make_simple_join() + TABLE **table_reexec; // make_simple_join() + JOIN_TAB *join_tab_reexec; // make_simple_join() /* end of allocation caching storage */ JOIN(THD *thd_arg, List &fields_arg, ulonglong select_options_arg, @@ -320,8 +320,8 @@ public: exec_tmp_table1= 0; exec_tmp_table2= 0; sortorder= 0; - table_cache= 0; - join_tab_cache= 0; + table_reexec= 0; + join_tab_reexec= 0; thd= thd_arg; sum_funcs= sum_funcs2= 0; procedure= 0; From 3dccef3c30c66f4027da97a74b1d5ce4ff34ca62 Mon Sep 17 00:00:00 2001 From: unknown Date: Wed, 18 Oct 2006 00:14:14 +0400 Subject: [PATCH 15/16] sql_rename.cc: Cleanup of fix for bug#14959. sql/sql_rename.cc: Cleanup of fix for bug#14959. --- sql/sql_rename.cc | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/sql/sql_rename.cc b/sql/sql_rename.cc index 1a4f1d82cb5..c87a8696bbc 100644 --- a/sql/sql_rename.cc +++ b/sql/sql_rename.cc @@ -173,7 +173,7 @@ do_rename(THD *thd, TABLE_LIST *ren_table, char *new_db, char *new_table_name, if (!access(name,F_OK)) { my_error(ER_TABLE_EXISTS_ERROR, MYF(0), new_alias); - DBUG_RETURN(ren_table); // This can't be skipped + DBUG_RETURN(1); // This can't be skipped } sprintf(name,"%s/%s/%s%s",mysql_data_home, ren_table->db, old_alias, From 672b61c5757f2f9a78a0764d2809de52b724c691 Mon Sep 17 00:00:00 2001 From: unknown Date: Wed, 18 Oct 2006 17:24:33 -0700 Subject: [PATCH 16/16] Changed test case for bug 22342 to make it platform independent. --- mysql-test/r/group_min_max.result | 6 +++--- mysql-test/t/group_min_max.test | 2 +- 2 files changed, 4 insertions(+), 4 deletions(-) diff --git a/mysql-test/r/group_min_max.result b/mysql-test/r/group_min_max.result index 826e642ce88..0304919baf6 100644 --- a/mysql-test/r/group_min_max.result +++ b/mysql-test/r/group_min_max.result @@ -2143,10 +2143,10 @@ id2 id3 id5 id4 id3 id6 id5 id1 1 1 1 1 1 1 1 1 DROP TABLE t1,t2,t3,t4,t5,t6; CREATE TABLE t1 (a int, b int, PRIMARY KEY (a,b), KEY b (b)); -INSERT INTO t1 VALUES (1,1),(1,2); +INSERT INTO t1 VALUES (1,1),(1,2),(1,0),(1,3); explain SELECT MAX(b), a FROM t1 WHERE b < 2 AND a = 1 GROUP BY a; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 range PRIMARY,b PRIMARY 8 NULL 2 Using where; Using index for group-by +1 SIMPLE t1 range PRIMARY,b PRIMARY 8 NULL 1 Using where; Using index for group-by SELECT MAX(b), a FROM t1 WHERE b < 2 AND a = 1 GROUP BY a; MAX(b) a 1 1 @@ -2157,7 +2157,7 @@ CREATE TABLE t2 (a int, b int, c int, PRIMARY KEY (a,b,c)); INSERT INTO t2 SELECT a,b,b FROM t1; explain SELECT MIN(c) FROM t2 WHERE b = 2 and a = 1 and c > 1 GROUP BY a; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t2 range PRIMARY PRIMARY 12 NULL 2 Using where; Using index for group-by +1 SIMPLE t2 range PRIMARY PRIMARY 12 NULL 1 Using where; Using index for group-by SELECT MIN(c) FROM t2 WHERE b = 2 and a = 1 and c > 1 GROUP BY a; MIN(c) 2 diff --git a/mysql-test/t/group_min_max.test b/mysql-test/t/group_min_max.test index 9f3fb5ea51e..08f0f54df60 100644 --- a/mysql-test/t/group_min_max.test +++ b/mysql-test/t/group_min_max.test @@ -799,7 +799,7 @@ DROP TABLE t1,t2,t3,t4,t5,t6; # Bug#22342: No results returned for query using max and group by # CREATE TABLE t1 (a int, b int, PRIMARY KEY (a,b), KEY b (b)); -INSERT INTO t1 VALUES (1,1),(1,2); +INSERT INTO t1 VALUES (1,1),(1,2),(1,0),(1,3); explain SELECT MAX(b), a FROM t1 WHERE b < 2 AND a = 1 GROUP BY a; SELECT MAX(b), a FROM t1 WHERE b < 2 AND a = 1 GROUP BY a;