Bug #31023 Bug when using date function on datetime field in the where clause
Submitted: 14 Sep 2007 8:12 Modified: 14 Sep 2007 12:32
Reporter: Patrick Antivackis Email Updates:
Status: Duplicate Impact on me:
None 
Category:MySQL Server: DML Severity:S1 (Critical)
Version:5.0.45 OS:Any
Assigned to: Assigned Account CPU Architecture:Any
Tags: date(), datetime, null

[14 Sep 2007 8:12] Patrick Antivackis
Description:
I repeated the following bug on different linux servers with :
bin/mysqladmin  Ver 8.41 Distrib 5.0.45, for pc-linux-gnu on i686

I have the following table :
mysql> desc Buggy;
+-----------+------------+------+-----+---------+----------------+
| Field     | Type       | Null | Key | Default | Extra          |
+-----------+------------+------+-----+---------+----------------+
| ID        | bigint(20) | NO   | PRI | NULL    | auto_increment | 
| FLAG      | tinyint(4) | YES  |     | NULL    |                | 
| DATETIME1 | datetime   | YES  |     | NULL    |                | 
| DATETIME2 | datetime   | YES  |     | NULL    |                | 
+-----------+------------+------+-----+---------+----------------+
4 rows in set (0.00 sec)

With the following values :
mysql> select * from Buggy;+----+------+---------------------+---------------------+
| ID | FLAG | DATETIME1           | DATETIME2           |
+----+------+---------------------+---------------------+
|  1 | NULL | 2007-09-17 00:00:00 | 2007-09-17 23:59:00 | 
|  2 | NULL | 2007-09-18 00:00:00 | 2007-09-18 23:59:00 | 
|  3 |    1 | 2007-09-28 18:36:00 | 2007-09-29 00:50:00 | 
|  5 | NULL | NULL                | NULL                | 
|  4 |    1 | 2007-12-11 16:00:00 | 2007-12-12 08:00:00 | 
+----+------+---------------------+---------------------+
5 rows in set (0.00 sec)

the following select gives 1 instead of 2 :
mysql> select count(*) from Buggy where date(DATETIME1)<>date(DATETIME2);+----------+
| count(*) |
+----------+
|        1 | 
+----------+
1 row in set (0.00 sec)

whereas a more strict select gives the good result :
mysql> select count(*) from Buggy where date(DATETIME1)<>date(DATETIME2) AND FLAG=1;
+----------+
| count(*) |
+----------+
|        2 | 
+----------+
1 row in set (0.00 sec)

The bug seems to come from ID 5 with NULL value in the datetime fields.
But a :
mysql> select count(*) from Buggy where date(DATETIME1)<>date(DATETIME2) AND DATETIME1 IS NOT NULL;
+----------+
| count(*) |
+----------+
|        1 | 
+----------+
1 row in set (0.00 sec)

still gives a bad answer

But when we delete the null value record :
mysql> delete from Buggy where DATETIME1 IS NULL;
Query OK, 1 row affected (0.00 sec)

the original select becomes good :
mysql> select count(*) from Buggy where date(DATETIME1)<>date(DATETIME2);
+----------+
| count(*) |
+----------+
|        2 | 
+----------+
1 row in set (0.00 sec)

How to repeat:
See up.
Here a mysqldump of the script database/table creation

-- MySQL dump 10.11
--
-- Host: localhost    Database: bug
-- ------------------------------------------------------
-- Server version       5.0.45

/*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */;
/*!40101 SET @OLD_CHARACTER_SET_RESULTS=@@CHARACTER_SET_RESULTS */;
/*!40101 SET @OLD_COLLATION_CONNECTION=@@COLLATION_CONNECTION */;
/*!40101 SET NAMES utf8 */;
/*!40103 SET @OLD_TIME_ZONE=@@TIME_ZONE */;
/*!40103 SET TIME_ZONE='+00:00' */;
/*!40014 SET @OLD_UNIQUE_CHECKS=@@UNIQUE_CHECKS, UNIQUE_CHECKS=0 */;
/*!40014 SET @OLD_FOREIGN_KEY_CHECKS=@@FOREIGN_KEY_CHECKS, FOREIGN_KEY_CHECKS=0 
*/;
/*!40101 SET @OLD_SQL_MODE=@@SQL_MODE, SQL_MODE='NO_AUTO_VALUE_ON_ZERO' */;
/*!40111 SET @OLD_SQL_NOTES=@@SQL_NOTES, SQL_NOTES=0 */;

--
-- Current Database: `bug`
--

/*!40000 DROP DATABASE IF EXISTS `bug`*/;

CREATE DATABASE /*!32312 IF NOT EXISTS*/ `bug` /*!40100 DEFAULT CHARACTER SET la
tin1 */;

USE `bug`;

--
-- Table structure for table `Buggy`
--

DROP TABLE IF EXISTS `Buggy`;
CREATE TABLE `Buggy` (
  `ID` bigint(20) NOT NULL auto_increment,
  `FLAG` tinyint(4) default NULL,
  `DATETIME1` datetime default NULL,
  `DATETIME2` datetime default NULL,
  PRIMARY KEY  (`ID`)
) ENGINE=MyISAM AUTO_INCREMENT=6 DEFAULT CHARSET=latin1;

--
-- Dumping data for table `Buggy`
--

LOCK TABLES `Buggy` WRITE;
/*!40000 ALTER TABLE `Buggy` DISABLE KEYS */;
INSERT INTO `Buggy` (`ID`, `FLAG`, `DATETIME1`, `DATETIME2`) VALUES (1,NULL,'200
7-09-17 00:00:00','2007-09-17 23:59:00'),(2,NULL,'2007-09-18 00:00:00','2007-09-
18 23:59:00'),(3,1,'2007-09-28 18:36:00','2007-09-29 00:50:00'),(5,NULL,NULL,NUL
L),(4,1,'2007-12-11 16:00:00','2007-12-12 08:00:00');
/*!40000 ALTER TABLE `Buggy` ENABLE KEYS */;
UNLOCK TABLES;
/*!40103 SET TIME_ZONE=@OLD_TIME_ZONE */;

/*!40101 SET SQL_MODE=@OLD_SQL_MODE */;
/*!40014 SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS */;
/*!40014 SET UNIQUE_CHECKS=@OLD_UNIQUE_CHECKS */;
/*!40101 SET CHARACTER_SET_CLIENT=@OLD_CHARACTER_SET_CLIENT */;
/*!40101 SET CHARACTER_SET_RESULTS=@OLD_CHARACTER_SET_RESULTS */;
/*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */;
/*!40111 SET SQL_NOTES=@OLD_SQL_NOTES */;

-- Dump completed on 2007-09-14  7:43:07
[14 Sep 2007 8:13] Patrick Antivackis
Mysqdump file

Attachment: bug.sql (text/x-sql), 2.13 KiB.

[14 Sep 2007 8:15] Patrick Antivackis
Mysqladmin variables

Attachment: mysqladminvariables.txt (text/plain), 23.64 KiB.

[14 Sep 2007 11:30] Patrick Antivackis
I forgot :
This was working on at least mysql 5.0.20
result with the != comparator is the same
[14 Sep 2007 12:32] Hartmut Holzgraefe
This is a duplicate of bug #29898 which is fixed starting with MySQL 5.0.48