Bug #79001 | Wrong sort order with CONCAT and CASE-based sort column | ||
---|---|---|---|
Submitted: | 28 Oct 2015 12:36 | Modified: | 31 Jan 2020 13:33 |
Reporter: | Matthias Pigulla | Email Updates: | |
Status: | Closed | Impact on me: | |
Category: | MySQL Server: DML | Severity: | S3 (Non-critical) |
Version: | 5.0/5.1/5.5/5.6 | OS: | Ubuntu |
Assigned to: | CPU Architecture: | Any |
[28 Oct 2015 12:36]
Matthias Pigulla
[28 Oct 2015 19:55]
MySQL Verification Team
C:\dbs>5.6\bin\mysql -uroot -p --port=3560 test Enter password: Welcome to the MySQL monitor. Commands end with ; or \g. Your MySQL connection id is 5 Server version: 5.6.28 Source distribution PULL: 2015-OCT-24 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> SELECT CONCAT( -> (CASE "foo" when "bar" then 1 -> else 2 END) , "-", -> test -> ) AS bogus FROM test ORDER BY bogus DESC; +--------------+ | bogus | +--------------+ | 2-2015-10-15 | | 2-2015-10-16 | | 2-2015-10-15 | +--------------+ 3 rows in set (0.00 sec) mysql> SELECT CONCAT( -> 2 , "-", -> test -> ) AS bogus FROM test ORDER BY bogus DESC; +--------------+ | bogus | +--------------+ | 2-2015-10-16 | | 2-2015-10-15 | | 2-2015-10-15 | +--------------+ 3 rows in set (0.00 sec)
[28 Oct 2015 20:11]
MySQL Verification Team
Only repeatable on 5.0/5.1/5.5/5.6 and no anymore on 5.7. Thank you for the bug report. 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 3 Server version: 5.7.10 Source distribution PULL: 2015-OCT-24 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 > CREATE TABLE `test` ( -> `test` date DEFAULT NULL -> ); Query OK, 0 rows affected (0.03 sec) mysql 5.7 > INSERT INTO `test` VALUES ('2015-10-15'),('2015-10-16'),('2015-10-15'); Query OK, 3 rows affected (0.01 sec) Records: 3 Duplicates: 0 Warnings: 0 mysql 5.7 > SELECT CONCAT( -> (CASE "foo" when "bar" then 1 -> else 2 END) , "-", -> test -> ) AS bogus FROM test ORDER BY bogus DESC; +--------------+ | bogus | +--------------+ | 2-2015-10-16 | | 2-2015-10-15 | | 2-2015-10-15 | +--------------+ 3 rows in set (0.10 sec)
[28 Oct 2015 20:37]
Matthias Pigulla
Can we expect a fix for <5.7, or is the impact not severe enough?
[31 Jan 2020 13:33]
Erlend Dahl
Fixed in 5.7.19.