Skip to content

Commit

Permalink
MDEV-8793 Wrong result set for SELECT ...
Browse files Browse the repository at this point in the history
          WHERE COALESCE(time_column)=TIME('00:00:00')
            AND COALESCE(time_column)=DATE('2015-09-11')
MDEV-8814 Wrong result for WHERE datetime_column > TIME('00:00:00')
  • Loading branch information
Alexander Barkov committed Sep 18, 2015
1 parent f789158 commit 79140b0
Show file tree
Hide file tree
Showing 9 changed files with 452 additions and 112 deletions.
2 changes: 0 additions & 2 deletions mysql-test/r/func_time.result
Original file line number Diff line number Diff line change
Expand Up @@ -1824,8 +1824,6 @@ create table t1 (f1 datetime, key (f1));
insert into t1 values ('2000-09-12 00:00:00'), ('2007-04-25 05:08:49');
select * from t1 where f1 > time('-23:00:06');
f1
2000-09-12 00:00:00
2007-04-25 05:08:49
drop table t1;
select maketime(20,61,10)+0;
maketime(20,61,10)+0
Expand Down
184 changes: 184 additions & 0 deletions mysql-test/r/type_time.result
Original file line number Diff line number Diff line change
Expand Up @@ -969,5 +969,189 @@ Warnings:
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (coalesce(`test`.`t1`.`a`) = TIME'00:00:01')
DROP TABLE t1;
#
# MDEV-8793 Wrong result set for SELECT ... WHERE COALESCE(time_column)=TIME('00:00:00') AND COALESCE(time_column)=DATE('2015-09-11')
#
SET timestamp=UNIX_TIMESTAMP('2015-09-11 20:20:20');
CREATE TABLE t1 (a TIME);
INSERT INTO t1 VALUES('10:20:30'),('00:00:00');
SELECT * FROM t1 WHERE COALESCE(a)=TIME('00:00:00');
a
00:00:00
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11');
a
00:00:00
# TIME cast + DATE cast
SELECT * FROM t1 WHERE COALESCE(a)=TIME('00:00:00') AND COALESCE(a)=DATE('2015-09-11');
a
00:00:00
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=TIME('00:00:00') AND COALESCE(a)=DATE('2015-09-11');
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
Warnings:
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (coalesce(`test`.`t1`.`a`) = <cache>(00:00:00))
# TIME cast + DATE literal
SELECT * FROM t1 WHERE COALESCE(a)=TIME('00:00:00') AND COALESCE(a)=DATE'2015-09-11';
a
00:00:00
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=TIME('00:00:00') AND COALESCE(a)=DATE'2015-09-11';
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
Warnings:
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (coalesce(`test`.`t1`.`a`) = <cache>(00:00:00))
# TIME literal + DATE cast
SELECT * FROM t1 WHERE COALESCE(a)=TIME'00:00:00' AND COALESCE(a)=DATE('2015-09-11');
a
00:00:00
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=TIME'00:00:00' AND COALESCE(a)=DATE('2015-09-11');
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
Warnings:
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (coalesce(`test`.`t1`.`a`) = TIME'00:00:00')
# TIME literal + DATE literal
SELECT * FROM t1 WHERE COALESCE(a)=TIME'00:00:00' AND COALESCE(a)=DATE'2015-09-11';
a
00:00:00
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=TIME'00:00:00' AND COALESCE(a)=DATE'2015-09-11';
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
Warnings:
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (coalesce(`test`.`t1`.`a`) = TIME'00:00:00')
# TIME-alike string literal + DATE cast
SELECT * FROM t1 WHERE COALESCE(a)='00:00:00' AND COALESCE(a)=DATE('2015-09-11');
a
00:00:00
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)='00:00:00' AND COALESCE(a)=DATE('2015-09-11');
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
Warnings:
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where ((coalesce(`test`.`t1`.`a`) = '00:00:00') and (coalesce(`test`.`t1`.`a`) = <cache>(2015-09-11 00:00:00)))
# TIME-alike string literal + DATE literal
SELECT * FROM t1 WHERE COALESCE(a)='00:00:00' AND COALESCE(a)=DATE'2015-09-11';
a
00:00:00
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)='00:00:00' AND COALESCE(a)=DATE'2015-09-11';
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
Warnings:
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where ((coalesce(`test`.`t1`.`a`) = '00:00:00') and (coalesce(`test`.`t1`.`a`) = DATE'2015-09-11'))
# TIME-alike integer literal + DATE cast
SELECT * FROM t1 WHERE COALESCE(a)=0 AND COALESCE(a)=DATE('2015-09-11');
a
00:00:00
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=0 AND COALESCE(a)=DATE('2015-09-11');
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
Warnings:
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where ((coalesce(`test`.`t1`.`a`) = 0) and (coalesce(`test`.`t1`.`a`) = <cache>(2015-09-11 00:00:00)))
# TIME-alike integer literal + DATE literal
SELECT * FROM t1 WHERE COALESCE(a)=0 AND COALESCE(a)=DATE'2015-09-11';
a
00:00:00
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=0 AND COALESCE(a)=DATE'2015-09-11';
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
Warnings:
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where ((coalesce(`test`.`t1`.`a`) = 0) and (coalesce(`test`.`t1`.`a`) = DATE'2015-09-11'))
# DATE cast + TIME cast
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=TIME('00:00:00');
a
00:00:00
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=TIME('00:00:00');
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
Warnings:
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (coalesce(`test`.`t1`.`a`) = <cache>(2015-09-11 00:00:00))
# DATE cast + TIME literal
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=TIME'00:00:00';
a
00:00:00
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=TIME'00:00:00';
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
Warnings:
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (coalesce(`test`.`t1`.`a`) = <cache>(2015-09-11 00:00:00))
# DATE cast + TIME-alike string literal
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)='00:00:00';
a
00:00:00
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)='00:00:00';
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
Warnings:
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where ((coalesce(`test`.`t1`.`a`) = <cache>(2015-09-11 00:00:00)) and (coalesce(`test`.`t1`.`a`) = '00:00:00'))
# DATE cast + TIME-alike integer literal
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=0;
a
00:00:00
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=0;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
Warnings:
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where ((coalesce(`test`.`t1`.`a`) = <cache>(2015-09-11 00:00:00)) and (coalesce(`test`.`t1`.`a`) = 0))
# DATE literal + TIME cast
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=TIME('00:00:00');
a
00:00:00
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=TIME('00:00:00');
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
Warnings:
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (coalesce(`test`.`t1`.`a`) = DATE'2015-09-11')
# DATE literal + TIME literal
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=TIME'00:00:00';
a
00:00:00
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=TIME'00:00:00';
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
Warnings:
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (coalesce(`test`.`t1`.`a`) = DATE'2015-09-11')
# DATE literal + TIME-alike string literal
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)='00:00:00';
a
00:00:00
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)='00:00:00';
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
Warnings:
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where ((coalesce(`test`.`t1`.`a`) = DATE'2015-09-11') and (coalesce(`test`.`t1`.`a`) = '00:00:00'))
# DATE literal + TIME-alike integer literal
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=0;
a
00:00:00
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=0;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
Warnings:
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where ((coalesce(`test`.`t1`.`a`) = DATE'2015-09-11') and (coalesce(`test`.`t1`.`a`) = 0))
DROP TABLE t1;
SET timestamp=DEFAULT;
#
# MDEV-8814 Wrong result for WHERE datetime_column > TIME('00:00:00')
#
CREATE TABLE t1 (a DATETIME);
INSERT INTO t1 VALUES ('2000-09-12 00:00:00'), ('2007-04-25 05:08:49');
SELECT * FROM t1 WHERE a>TIME'00:00:00';
a
SELECT * FROM t1 WHERE a>TIME('00:00:00');
a
DROP TABLE t1;
#
# End of 10.1 tests
#
104 changes: 104 additions & 0 deletions mysql-test/t/type_time.test
Original file line number Diff line number Diff line change
Expand Up @@ -584,6 +584,110 @@ INSERT INTO t1 VALUES ('00:00:01'),('00:00:02');
EXPLAIN EXTENDED SELECT * FROM t1 WHERE COALESCE(a)=TIME'00:00:01' AND COALESCE(a)>=TIME'00:00:01';
DROP TABLE t1;

--echo #
--echo # MDEV-8793 Wrong result set for SELECT ... WHERE COALESCE(time_column)=TIME('00:00:00') AND COALESCE(time_column)=DATE('2015-09-11')
--echo #
SET timestamp=UNIX_TIMESTAMP('2015-09-11 20:20:20');
CREATE TABLE t1 (a TIME);
INSERT INTO t1 VALUES('10:20:30'),('00:00:00');
SELECT * FROM t1 WHERE COALESCE(a)=TIME('00:00:00');
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11');

--echo # TIME cast + DATE cast
SELECT * FROM t1 WHERE COALESCE(a)=TIME('00:00:00') AND COALESCE(a)=DATE('2015-09-11');
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=TIME('00:00:00') AND COALESCE(a)=DATE('2015-09-11');

--echo # TIME cast + DATE literal
SELECT * FROM t1 WHERE COALESCE(a)=TIME('00:00:00') AND COALESCE(a)=DATE'2015-09-11';
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=TIME('00:00:00') AND COALESCE(a)=DATE'2015-09-11';

--echo # TIME literal + DATE cast
SELECT * FROM t1 WHERE COALESCE(a)=TIME'00:00:00' AND COALESCE(a)=DATE('2015-09-11');
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=TIME'00:00:00' AND COALESCE(a)=DATE('2015-09-11');

--echo # TIME literal + DATE literal
SELECT * FROM t1 WHERE COALESCE(a)=TIME'00:00:00' AND COALESCE(a)=DATE'2015-09-11';
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=TIME'00:00:00' AND COALESCE(a)=DATE'2015-09-11';

--echo # TIME-alike string literal + DATE cast
SELECT * FROM t1 WHERE COALESCE(a)='00:00:00' AND COALESCE(a)=DATE('2015-09-11');
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)='00:00:00' AND COALESCE(a)=DATE('2015-09-11');

--echo # TIME-alike string literal + DATE literal
SELECT * FROM t1 WHERE COALESCE(a)='00:00:00' AND COALESCE(a)=DATE'2015-09-11';
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)='00:00:00' AND COALESCE(a)=DATE'2015-09-11';

--echo # TIME-alike integer literal + DATE cast
SELECT * FROM t1 WHERE COALESCE(a)=0 AND COALESCE(a)=DATE('2015-09-11');
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=0 AND COALESCE(a)=DATE('2015-09-11');

--echo # TIME-alike integer literal + DATE literal
SELECT * FROM t1 WHERE COALESCE(a)=0 AND COALESCE(a)=DATE'2015-09-11';
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=0 AND COALESCE(a)=DATE'2015-09-11';


### Now test the opposite order of the two equality expressions

--echo # DATE cast + TIME cast
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=TIME('00:00:00');
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=TIME('00:00:00');

--echo # DATE cast + TIME literal
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=TIME'00:00:00';
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=TIME'00:00:00';

--echo # DATE cast + TIME-alike string literal
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)='00:00:00';
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)='00:00:00';

--echo # DATE cast + TIME-alike integer literal
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=0;
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=0;

--echo # DATE literal + TIME cast
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=TIME('00:00:00');
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=TIME('00:00:00');

--echo # DATE literal + TIME literal
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=TIME'00:00:00';
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=TIME'00:00:00';

--echo # DATE literal + TIME-alike string literal
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)='00:00:00';
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)='00:00:00';

--echo # DATE literal + TIME-alike integer literal
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=0;
EXPLAIN EXTENDED
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=0;

DROP TABLE t1;
SET timestamp=DEFAULT;

--echo #
--echo # MDEV-8814 Wrong result for WHERE datetime_column > TIME('00:00:00')
--echo #
CREATE TABLE t1 (a DATETIME);
INSERT INTO t1 VALUES ('2000-09-12 00:00:00'), ('2007-04-25 05:08:49');
SELECT * FROM t1 WHERE a>TIME'00:00:00';
SELECT * FROM t1 WHERE a>TIME('00:00:00');
DROP TABLE t1;

--echo #
--echo # End of 10.1 tests
--echo #
21 changes: 19 additions & 2 deletions sql/item.cc
Original file line number Diff line number Diff line change
Expand Up @@ -8596,7 +8596,8 @@ void resolve_const_item(THD *thd, Item **ref, Item *comp_item)
bool is_null;
Item **ref_copy= ref;
/* the following call creates a constant and puts it in new_item */
get_datetime_value(thd, &ref_copy, &new_item, comp_item, &is_null);
enum_field_types type= item->field_type_for_temporal_comparison(comp_item);
get_datetime_value(thd, &ref_copy, &new_item, type, &is_null);
if (is_null)
new_item= new (mem_root) Item_null(thd, name);
break;
Expand Down Expand Up @@ -8936,9 +8937,25 @@ Item_cache_temporal::Item_cache_temporal(THD *thd,
}


longlong Item_cache_temporal::val_temporal_packed()
longlong Item_cache_temporal::val_datetime_packed()
{
DBUG_ASSERT(fixed == 1);
if (Item_cache_temporal::field_type() == MYSQL_TYPE_TIME)
return Item::val_datetime_packed(); // TIME-to-DATETIME conversion needed
if ((!value_cached && !cache_value()) || null_value)
{
null_value= TRUE;
return 0;
}
return value;
}


longlong Item_cache_temporal::val_time_packed()
{
DBUG_ASSERT(fixed == 1);
if (Item_cache_temporal::field_type() != MYSQL_TYPE_TIME)
return Item::val_time_packed(); // DATETIME-to-TIME conversion needed
if ((!value_cached && !cache_value()) || null_value)
{
null_value= TRUE;
Expand Down
Loading

0 comments on commit 79140b0

Please sign in to comment.