Bug #78417 Valid select with expression in group by under "only_full_group_by" fails
Submitted: 12 Sep 2015 9:48 Modified: 14 Sep 2015 11:44
Reporter: Su Dylan Email Updates:
Status: Won't fix Impact on me:
None 
Category:MySQL Server: Optimizer Severity:S3 (Non-critical)
Version:5.6.22 OS:Any
Assigned to: CPU Architecture:Any
Tags: regression

[12 Sep 2015 9:48] Su Dylan
Description:

Output:
======
mysql> set sql_mode='only_full_group_by';
Query OK, 0 rows affected (0.00 sec)

mysql> drop table if exists t1; create table t1(c1 int, c2 int);
Query OK, 0 rows affected (0.01 sec)
Query OK, 0 rows affected (0.01 sec)

mysql> select count(c1 + c2) from t1 group by c1 + c2  order by c1 + c2;
ERROR 1055 (42000): 'test.t1.c2' isn't in GROUP BY

mysql> select version();
+------------+
| version()  |
+------------+
| 5.6.22-log |
+------------+
1 row in set (0.00 sec)

Problem:
========
The following SQL is valid, but it fails.
select count(c1 + c2) from t1 group by c1 + c2  order by c1 + c2;

How to repeat:
set sql_mode='only_full_group_by';
drop table if exists t1; create table t1(c1 int, c2 int);
select count(c1 + c2) from t1 group by c1 + c2  order by c1 + c2; 

Suggested fix:
The following sql succeeds:
select count(c1 + c2) from t1 group by c1 + c2  order by c1 + c2;
[12 Sep 2015 18:52] MySQL Verification Team
c:\dbs>c:\dbs\5.6\bin\mysql -uroot --port=3560 -p --prompt="mysql 5.6 > "
Enter password:
Welcome to the MySQL monitor.  Commands end with ; or \g.
Your MySQL connection id is 2
Server version: 5.6.27 Source distribution PULL: 2015/08/14

Copyright (c) 2000, 2015, Oracle and/or its affiliates. All rights reserved.

Oracle is a registered trademark of Oracle Corporation and/or its
affiliates. Other names may be trademarks of their respective
owners.

Type 'help;' or '\h' for help. Type '\c' to clear the current input statement.

mysql 5.6 > USE test
Database changed
mysql 5.6 > set sql_mode='only_full_group_by';
Query OK, 0 rows affected (0.00 sec)

mysql 5.6 > drop table if exists t1; create table t1(c1 int, c2 int);
Query OK, 0 rows affected (0.20 sec)

Query OK, 0 rows affected (0.23 sec)

mysql 5.6 > select count(c1 + c2) from t1 group by c1 + c2  order by c1 + c2;
ERROR 1055 (42000): 'test.t1.c2' isn't in GROUP BY
[12 Sep 2015 18:53] MySQL Verification Team
c:\dbs>c:\dbs\5.1\bin\mysql -uroot --port=3510 --debug-info --prompt="mysql 5.1 > "
Welcome to the MySQL monitor.  Commands end with ; or \g.
Your MySQL connection id is 1
Server version: 5.1.74-Win X64 Source distribution

Copyright (c) 2000, 2013, Oracle and/or its affiliates. All rights reserved.

Oracle is a registered trademark of Oracle Corporation and/or its
affiliates. Other names may be trademarks of their respective
owners.

Type 'help;' or '\h' for help. Type '\c' to clear the current input statement.

mysql 5.1 > USE test
Database changed
mysql 5.1 > set sql_mode='only_full_group_by';
Query OK, 0 rows affected (0.00 sec)

mysql 5.1 > drop table if exists t1; create table t1(c1 int, c2 int);
Query OK, 0 rows affected (0.03 sec)

Query OK, 0 rows affected (0.03 sec)

mysql 5.1 > select count(c1 + c2) from t1 group by c1 + c2  order by c1 + c2;
Empty set (0.00 sec)
[12 Sep 2015 18:55] MySQL Verification Team
c:\dbs>c:\dbs\5.7\bin\mysql -uroot -p --port=3570 --prompt="mysql 5.7 > "
Enter password: ******
Welcome to the MySQL monitor.  Commands end with ; or \g.
Your MySQL connection id is 2
Server version: 5.7.9 Source distribution PULL 2015/08/14

Copyright (c) 2000, 2015, Oracle and/or its affiliates. All rights reserved.

Oracle is a registered trademark of Oracle Corporation and/or its
affiliates. Other names may be trademarks of their respective
owners.

Type 'help;' or '\h' for help. Type '\c' to clear the current input statement.

mysql 5.7 > USE test
Database changed
mysql 5.7 > set sql_mode='only_full_group_by';
Query OK, 0 rows affected, 1 warning (0.00 sec)

mysql 5.7 > drop table if exists t1; create table t1(c1 int, c2 int);
Query OK, 0 rows affected (0.25 sec)

Query OK, 0 rows affected (0.20 sec)

mysql 5.7 > select count(c1 + c2) from t1 group by c1 + c2  order by c1 + c2;
Empty set (0.00 sec)
[12 Sep 2015 18:58] MySQL Verification Team
Thank you for the bug report. Only 5.6 affected.
[14 Sep 2015 11:44] Guilhem Bichot
* In 5.7 these queries work fine.

* In 5.6, it's the ORDER BY which causes the problem; its expression
is searched for a match in the SELECT list but not in the GROUP BY
list. A workaround is to make the ORDER BY expression apparent in the SELECT
list: 
select c1+c2, count(c1 + c2) from t1 group by c1 + c2  order by c1 + c2;
After all, it's natural to have in the SELECT list the value by which
we group and order; otherwise, the user doesn't know what each group corresponds to.

* Generally, lots of things have been improved regarding
only_full_group_by in 5.7, compared to 5.6, because the related code
has been rewritten. For more information:
https://dev.mysql.com/doc/refman/5.7/en/group-by-handling.html
https://dev.mysql.com/doc/refman/5.7/en/group-by-functional-dependence.html

* Because the problem is fixed in 5.7 and because of the risk of
destabilizing 5.6 which is GA, we will not attempt to fix the problem
in 5.6.