mirror of
https://github.com/MariaDB/server.git
synced 2025-01-17 20:42:30 +01:00
Bug #30596 GROUP BY optimization gives wrong result order
The optimization that uses a unique index to remove GROUP BY, did not ensure that the index was actually used, thus violating the ORDER BY that is impled by GROUP BY. Fixed by replacing GROUP BY with ORDER BY if the GROUP BY clause contains a unique index. In case GROUP BY ... ORDER BY null is used, GROUP BY is simply removed.
This commit is contained in:
parent
c40fe57fb5
commit
a4d5d9204d
7 changed files with 168 additions and 3 deletions
|
@ -1345,3 +1345,8 @@ zlib/*.vcproj
|
|||
debian/control
|
||||
debian/defs.mk
|
||||
include/abi_check
|
||||
support-files/mysqld_multi.server
|
||||
tests/bug25714
|
||||
cscope.in.out
|
||||
cscope.out
|
||||
cscope.po.out
|
||||
|
|
|
@ -526,10 +526,10 @@ id select_type table type possible_keys key key_len ref rows Extra
|
|||
1 SIMPLE t1 index NULL PRIMARY 4 NULL 3 Using index
|
||||
EXPLAIN SELECT a,b FROM t1 GROUP BY a,b;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort
|
||||
EXPLAIN SELECT DISTINCT a,b FROM t1 GROUP BY a,b;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort
|
||||
CREATE TABLE t2(a INT, b INT NOT NULL, c INT NOT NULL, d INT,
|
||||
PRIMARY KEY (a,b));
|
||||
INSERT INTO t2 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4);
|
||||
|
@ -554,7 +554,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
|||
CREATE UNIQUE INDEX c_b_unq ON t2 (c,b);
|
||||
EXPLAIN SELECT DISTINCT a,b,d FROM t2 GROUP BY c,b,d;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 3
|
||||
1 SIMPLE t2 ALL NULL NULL NULL NULL 3 Using filesort
|
||||
DROP TABLE t1,t2;
|
||||
create table t1 (id int, dsc varchar(50));
|
||||
insert into t1 values (1, "line number one"), (2, "line number two"), (3, "line number three");
|
||||
|
|
|
@ -1064,3 +1064,52 @@ select t1.f1,t.* from t1, t1 t group by 1;
|
|||
ERROR 42000: 'test.t.f1' isn't in GROUP BY
|
||||
drop table t1;
|
||||
SET SQL_MODE = '';
|
||||
CREATE TABLE t1(
|
||||
a INT,
|
||||
b INT NOT NULL,
|
||||
c INT NOT NULL,
|
||||
d INT,
|
||||
UNIQUE KEY (c,b)
|
||||
);
|
||||
INSERT INTO t1 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4);
|
||||
EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort
|
||||
SELECT c,b,d FROM t1 GROUP BY c,b,d;
|
||||
c b d
|
||||
1 1 50
|
||||
3 1 4
|
||||
3 2 40
|
||||
EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3
|
||||
SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL;
|
||||
c b d
|
||||
1 1 50
|
||||
3 2 40
|
||||
3 1 4
|
||||
EXPLAIN SELECT c,b,d FROM t1 ORDER BY c,b,d;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort
|
||||
SELECT c,b,d FROM t1 ORDER BY c,b,d;
|
||||
c b d
|
||||
1 1 50
|
||||
3 1 4
|
||||
3 2 40
|
||||
EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort
|
||||
SELECT c,b,d FROM t1 GROUP BY c,b;
|
||||
c b d
|
||||
1 1 50
|
||||
3 1 4
|
||||
3 2 40
|
||||
EXPLAIN SELECT c,b FROM t1 GROUP BY c,b;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 index NULL c 8 NULL 3 Using index
|
||||
SELECT c,b FROM t1 GROUP BY c,b;
|
||||
c b
|
||||
1 1
|
||||
3 1
|
||||
3 2
|
||||
DROP TABLE t1;
|
||||
|
|
|
@ -1047,4 +1047,53 @@ t1 CREATE TABLE `t1` (
|
|||
KEY `a` (`a`(255))
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8
|
||||
drop table t1;
|
||||
CREATE TABLE t1(
|
||||
a INT,
|
||||
b INT NOT NULL,
|
||||
c INT NOT NULL,
|
||||
d INT,
|
||||
UNIQUE KEY (c,b)
|
||||
) engine=innodb;
|
||||
INSERT INTO t1 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4);
|
||||
EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort
|
||||
SELECT c,b,d FROM t1 GROUP BY c,b,d;
|
||||
c b d
|
||||
1 1 50
|
||||
3 1 4
|
||||
3 2 40
|
||||
EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3
|
||||
SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL;
|
||||
c b d
|
||||
1 1 50
|
||||
3 1 4
|
||||
3 2 40
|
||||
EXPLAIN SELECT c,b,d FROM t1 ORDER BY c,b,d;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using filesort
|
||||
SELECT c,b,d FROM t1 ORDER BY c,b,d;
|
||||
c b d
|
||||
1 1 50
|
||||
3 1 4
|
||||
3 2 40
|
||||
EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 index NULL c 8 NULL 3
|
||||
SELECT c,b,d FROM t1 GROUP BY c,b;
|
||||
c b d
|
||||
1 1 50
|
||||
3 1 4
|
||||
3 2 40
|
||||
EXPLAIN SELECT c,b FROM t1 GROUP BY c,b;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 index NULL c 8 NULL 3 Using index
|
||||
SELECT c,b FROM t1 GROUP BY c,b;
|
||||
c b
|
||||
1 1
|
||||
3 1
|
||||
3 2
|
||||
DROP TABLE t1;
|
||||
End of 5.0 tests
|
||||
|
|
|
@ -788,3 +788,30 @@ select * from t1 group by f1, f2;
|
|||
select t1.f1,t.* from t1, t1 t group by 1;
|
||||
drop table t1;
|
||||
SET SQL_MODE = '';
|
||||
|
||||
#
|
||||
# Bug#30596: GROUP BY optimization gives wrong result order
|
||||
#
|
||||
CREATE TABLE t1(
|
||||
a INT,
|
||||
b INT NOT NULL,
|
||||
c INT NOT NULL,
|
||||
d INT,
|
||||
UNIQUE KEY (c,b)
|
||||
);
|
||||
|
||||
INSERT INTO t1 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4);
|
||||
|
||||
EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d;
|
||||
SELECT c,b,d FROM t1 GROUP BY c,b,d;
|
||||
EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL;
|
||||
SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL;
|
||||
EXPLAIN SELECT c,b,d FROM t1 ORDER BY c,b,d;
|
||||
SELECT c,b,d FROM t1 ORDER BY c,b,d;
|
||||
|
||||
EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b;
|
||||
SELECT c,b,d FROM t1 GROUP BY c,b;
|
||||
EXPLAIN SELECT c,b FROM t1 GROUP BY c,b;
|
||||
SELECT c,b FROM t1 GROUP BY c,b;
|
||||
|
||||
DROP TABLE t1;
|
||||
|
|
|
@ -882,4 +882,31 @@ alter table t1 add index(a(1024));
|
|||
show create table t1;
|
||||
drop table t1;
|
||||
|
||||
#
|
||||
# Bug#30596: GROUP BY optimization gives wrong result order
|
||||
#
|
||||
CREATE TABLE t1(
|
||||
a INT,
|
||||
b INT NOT NULL,
|
||||
c INT NOT NULL,
|
||||
d INT,
|
||||
UNIQUE KEY (c,b)
|
||||
) engine=innodb;
|
||||
|
||||
INSERT INTO t1 VALUES (1,1,1,50), (1,2,3,40), (2,1,3,4);
|
||||
|
||||
EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d;
|
||||
SELECT c,b,d FROM t1 GROUP BY c,b,d;
|
||||
EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL;
|
||||
SELECT c,b,d FROM t1 GROUP BY c,b,d ORDER BY NULL;
|
||||
EXPLAIN SELECT c,b,d FROM t1 ORDER BY c,b,d;
|
||||
SELECT c,b,d FROM t1 ORDER BY c,b,d;
|
||||
|
||||
EXPLAIN SELECT c,b,d FROM t1 GROUP BY c,b;
|
||||
SELECT c,b,d FROM t1 GROUP BY c,b;
|
||||
EXPLAIN SELECT c,b FROM t1 GROUP BY c,b;
|
||||
SELECT c,b FROM t1 GROUP BY c,b;
|
||||
|
||||
DROP TABLE t1;
|
||||
|
||||
--echo End of 5.0 tests
|
||||
|
|
|
@ -1030,6 +1030,14 @@ JOIN::optimize()
|
|||
find_field_in_order_list,
|
||||
(void *) group_list))
|
||||
{
|
||||
/*
|
||||
We have found that grouping can be removed since groups correspond to
|
||||
only one row anyway, but we still have to guarantee correct result
|
||||
order. The line below effectively rewrites the query from GROUP BY
|
||||
<fields> to ORDER BY <fields>. One exception is if skip_sort_order is
|
||||
set (see above), then we can simply skip GROUP BY.
|
||||
*/
|
||||
order= skip_sort_order ? 0 : group_list;
|
||||
group_list= 0;
|
||||
group= 0;
|
||||
}
|
||||
|
|
Loading…
Reference in a new issue