Bug #78025 | Special IS NULL logic for 0000-00-00 does not work with merge views and SQ | ||
---|---|---|---|
Submitted: | 11 Aug 2015 17:43 | Modified: | 11 Aug 2015 21:30 |
Reporter: | Elena Stepanova | Email Updates: | |
Status: | Verified | Impact on me: | |
Category: | MySQL Server: Optimizer | Severity: | S3 (Non-critical) |
Version: | 5.5, 5.6, 5.7 | OS: | Any |
Assigned to: | CPU Architecture: | Any |
[11 Aug 2015 17:43]
Elena Stepanova
[11 Aug 2015 21:30]
MySQL Verification Team
Thank you for the bug report. C:\dbs>NET START mysqld57 The MySQLD57 service is starting. The MySQLD57 service was started successfully. C:\dbs>57 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 08/08/2015 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= ''; Query OK, 0 rows affected, 1 warning (0.00 sec) mysql 5.7 > mysql 5.7 > DROP TABLE IF EXISTS t1, v_merge, v_temptable; Query OK, 0 rows affected, 3 warnings (0.00 sec) mysql 5.7 > mysql 5.7 > CREATE TABLE t1 (d DATE NOT NULL) ENGINE=MyISAM; Query OK, 0 rows affected (0.03 sec) mysql 5.7 > INSERT INTO t1 VALUES ('0000-00-00'), ('0000-00-00'); Query OK, 2 rows affected (0.00 sec) Records: 2 Duplicates: 0 Warnings: 0 mysql 5.7 > mysql 5.7 > CREATE ALGORITHM=MERGE VIEW v_merge AS SELECT * FROM t1; Query OK, 0 rows affected (0.04 sec) mysql 5.7 > CREATE ALGORITHM=TEMPTABLE VIEW v_temptable AS SELECT * FROM t1; Query OK, 0 rows affected (0.03 sec) mysql 5.7 > mysql 5.7 > # This works: mysql 5.7 > mysql 5.7 > SELECT * FROM t1 WHERE d IS NULL; +------------+ | d | +------------+ | 0000-00-00 | | 0000-00-00 | +------------+ 2 rows in set (0.00 sec) mysql 5.7 > SELECT * FROM v_temptable WHERE d IS NULL; +------------+ | d | +------------+ | 0000-00-00 | | 0000-00-00 | +------------+ 2 rows in set (0.00 sec) mysql 5.7 > mysql 5.7 > # This does not work: mysql 5.7 > mysql 5.7 > SELECT * FROM v_merge WHERE d IS NULL; Empty set (0.00 sec) mysql 5.7 > mysql 5.7 > # 5.7 part: mysql 5.7 > mysql 5.7 > # This does not work: mysql 5.7 > mysql 5.7 > SET optimizer_switch = 'derived_merge=on'; Query OK, 0 rows affected (0.00 sec) mysql 5.7 > SELECT * FROM ( SELECT * FROM t1 ) AS sq WHERE d IS NULL; Empty set (0.00 sec) mysql 5.7 > mysql 5.7 > # This works: mysql 5.7 > mysql 5.7 > SET optimizer_switch = 'derived_merge=off'; Query OK, 0 rows affected (0.00 sec) mysql 5.7 > SELECT * FROM ( SELECT * FROM t1 ) AS sq WHERE d IS NULL; +------------+ | d | +------------+ | 0000-00-00 | | 0000-00-00 | +------------+ 2 rows in set (0.00 sec)