Bug #66932 GREATEST produces invalid result if in subquery with utf8_hungarian_ci collation
Submitted: 23 Sep 2012 13:32 Modified: 23 Sep 2012 23:18
Reporter: Marton Balint Email Updates:
Status: Verified Impact on me:
None 
Category:MySQL Server: Charsets Severity:S3 (Non-critical)
Version:5.5.25a OS:Linux
Assigned to: CPU Architecture:Any
Tags: collation, GREATEST, LEAST, subquery, utf8

[23 Sep 2012 13:32] Marton Balint
Description:
If the UTF8 charset is set with SET NAMES, the GREATEST (or LEAST) expression in a subquery produces invalid results. On the other hand, if the connection charset is explicitly set, the issue does not occur.

How to repeat:
SET NAMES utf8 COLLATE utf8_hungarian_ci;

DROP TABLE IF EXISTS `mysqlbug`;

CREATE TABLE `mysqlbug` (
  `date1` date NOT NULL,
  `date2` date NOT NULL
) ENGINE=MyISAM DEFAULT CHARSET=utf8 COLLATE=utf8_hungarian_ci;

INSERT INTO `mysqlbug` (`date1`, `date2`) VALUES ('2000-01-01', '2012-09-01');

SELECT * FROM
  (
    SELECT
      GREATEST(mysqlbug.`date1`, mysqlbug.`date2`) AS `badcolumn`
    FROM
      mysqlbug
  ) AS `badtable`;

The result is:
badcolumn
201

Expected result:
badcolumn
2012-09-01

Suggested fix:
A workaround is to set connection charset explicitly:

SET character_set_connection = utf8;
[23 Sep 2012 13:37] Marton Balint
Disregard the workaround. It resets the collation, which seems to be the root cause of this problem.
[23 Sep 2012 14:05] Peter Laursen
I get same on 5.5.23 using "SET NAMES utf8 COLLATE utf8_danish_ci;" and even "SET NAMES utf8 COLLATE utf8_unicode_ci;" - but with "SET NAMES utf8 COLLATE utf8_general_ci;" expected results are returned.

Peter
(not a MySQL/Oracle person)
[23 Sep 2012 14:07] Peter Laursen
5.1.63 returns expect result with all collations.
[23 Sep 2012 14:11] Peter Laursen
.. and 5.6.6 not affected either.
[23 Sep 2012 23:18] MySQL Verification Team
Thank you for the bug report.

d:\dbs>d:\dbs\5.5\bin\mysql -uroot --port=3541 --prompt="mysql 5.5 >"
Welcome to the MySQL monitor.  Commands end with ; or \g.
Your MySQL connection id is 11
Server version: 5.5.29 Source distribution

Copyright (c) 2000, 2012, 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.5 >use test
Database changed
mysql 5.5 >SET NAMES utf8 COLLATE utf8_hungarian_ci;
Query OK, 0 rows affected (0.00 sec)

mysql 5.5 >
mysql 5.5 >DROP TABLE IF EXISTS `mysqlbug`;
Query OK, 0 rows affected, 1 warning (0.00 sec)

mysql 5.5 >
mysql 5.5 >CREATE TABLE `mysqlbug` (
    ->   `date1` date NOT NULL,
    ->   `date2` date NOT NULL
    -> ) ENGINE=MyISAM DEFAULT CHARSET=utf8 COLLATE=utf8_hungarian_ci;
Query OK, 0 rows affected (0.04 sec)

mysql 5.5 >
mysql 5.5 >INSERT INTO `mysqlbug` (`date1`, `date2`) VALUES ('2000-01-01', '2012-09-01');
Query OK, 1 row affected (0.09 sec)

mysql 5.5 >
mysql 5.5 >SELECT * FROM
    ->   (
    ->     SELECT
    ->       GREATEST(mysqlbug.`date1`, mysqlbug.`date2`) AS `badcolumn`
    ->     FROM
    ->       mysqlbug
    ->   ) AS `badtable`;
+-----------+
| badcolumn |
+-----------+
| 201       |
+-----------+
1 row in set (0.03 sec)

mysql 5.5 >

---------------------------------------------------------------------------------------
d:\dbs>d:\dbs\5.6\bin\mysql -uroot --port=3540 --prompt="mysql 5.6 >"
Welcome to the MySQL monitor.  Commands end with ; or \g.
Your MySQL connection id is 1
Server version: 5.7.0-m10 Source distribution

Copyright (c) 2000, 2012, 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 NAMES utf8 COLLATE utf8_hungarian_ci;
Query OK, 0 rows affected (0.03 sec)

mysql 5.6 >
mysql 5.6 >DROP TABLE IF EXISTS `mysqlbug`;
Query OK, 0 rows affected, 1 warning (0.04 sec)

mysql 5.6 >
mysql 5.6 >CREATE TABLE `mysqlbug` (
    ->   `date1` date NOT NULL,
    ->   `date2` date NOT NULL
    -> ) ENGINE=MyISAM DEFAULT CHARSET=utf8 COLLATE=utf8_hungarian_ci;
Query OK, 0 rows affected (0.10 sec)

mysql 5.6 >
mysql 5.6 >INSERT INTO `mysqlbug` (`date1`, `date2`) VALUES ('2000-01-01', '2012-09-01');
Query OK, 1 row affected (0.02 sec)

mysql 5.6 >
mysql 5.6 >SELECT * FROM
    ->   (
    ->     SELECT
    ->       GREATEST(mysqlbug.`date1`, mysqlbug.`date2`) AS `badcolumn`
    ->     FROM
    ->       mysqlbug
    ->   ) AS `badtable`;
+------------+
| badcolumn  |
+------------+
| 2012-09-01 |
+------------+
1 row in set (0.05 sec)