Skip to content

Commit 79140b0

Browse files
author
Alexander Barkov
committed
MDEV-8793 Wrong result set for SELECT ...
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')
1 parent f789158 commit 79140b0

File tree

9 files changed

+452
-112
lines changed

9 files changed

+452
-112
lines changed

mysql-test/r/func_time.result

Lines changed: 0 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -1824,8 +1824,6 @@ create table t1 (f1 datetime, key (f1));
18241824
insert into t1 values ('2000-09-12 00:00:00'), ('2007-04-25 05:08:49');
18251825
select * from t1 where f1 > time('-23:00:06');
18261826
f1
1827-
2000-09-12 00:00:00
1828-
2007-04-25 05:08:49
18291827
drop table t1;
18301828
select maketime(20,61,10)+0;
18311829
maketime(20,61,10)+0

mysql-test/r/type_time.result

Lines changed: 184 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -969,5 +969,189 @@ Warnings:
969969
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (coalesce(`test`.`t1`.`a`) = TIME'00:00:01')
970970
DROP TABLE t1;
971971
#
972+
# MDEV-8793 Wrong result set for SELECT ... WHERE COALESCE(time_column)=TIME('00:00:00') AND COALESCE(time_column)=DATE('2015-09-11')
973+
#
974+
SET timestamp=UNIX_TIMESTAMP('2015-09-11 20:20:20');
975+
CREATE TABLE t1 (a TIME);
976+
INSERT INTO t1 VALUES('10:20:30'),('00:00:00');
977+
SELECT * FROM t1 WHERE COALESCE(a)=TIME('00:00:00');
978+
a
979+
00:00:00
980+
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11');
981+
a
982+
00:00:00
983+
# TIME cast + DATE cast
984+
SELECT * FROM t1 WHERE COALESCE(a)=TIME('00:00:00') AND COALESCE(a)=DATE('2015-09-11');
985+
a
986+
00:00:00
987+
EXPLAIN EXTENDED
988+
SELECT * FROM t1 WHERE COALESCE(a)=TIME('00:00:00') AND COALESCE(a)=DATE('2015-09-11');
989+
id select_type table type possible_keys key key_len ref rows filtered Extra
990+
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
991+
Warnings:
992+
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (coalesce(`test`.`t1`.`a`) = <cache>(00:00:00))
993+
# TIME cast + DATE literal
994+
SELECT * FROM t1 WHERE COALESCE(a)=TIME('00:00:00') AND COALESCE(a)=DATE'2015-09-11';
995+
a
996+
00:00:00
997+
EXPLAIN EXTENDED
998+
SELECT * FROM t1 WHERE COALESCE(a)=TIME('00:00:00') AND COALESCE(a)=DATE'2015-09-11';
999+
id select_type table type possible_keys key key_len ref rows filtered Extra
1000+
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
1001+
Warnings:
1002+
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (coalesce(`test`.`t1`.`a`) = <cache>(00:00:00))
1003+
# TIME literal + DATE cast
1004+
SELECT * FROM t1 WHERE COALESCE(a)=TIME'00:00:00' AND COALESCE(a)=DATE('2015-09-11');
1005+
a
1006+
00:00:00
1007+
EXPLAIN EXTENDED
1008+
SELECT * FROM t1 WHERE COALESCE(a)=TIME'00:00:00' AND COALESCE(a)=DATE('2015-09-11');
1009+
id select_type table type possible_keys key key_len ref rows filtered Extra
1010+
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
1011+
Warnings:
1012+
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (coalesce(`test`.`t1`.`a`) = TIME'00:00:00')
1013+
# TIME literal + DATE literal
1014+
SELECT * FROM t1 WHERE COALESCE(a)=TIME'00:00:00' AND COALESCE(a)=DATE'2015-09-11';
1015+
a
1016+
00:00:00
1017+
EXPLAIN EXTENDED
1018+
SELECT * FROM t1 WHERE COALESCE(a)=TIME'00:00:00' AND COALESCE(a)=DATE'2015-09-11';
1019+
id select_type table type possible_keys key key_len ref rows filtered Extra
1020+
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
1021+
Warnings:
1022+
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (coalesce(`test`.`t1`.`a`) = TIME'00:00:00')
1023+
# TIME-alike string literal + DATE cast
1024+
SELECT * FROM t1 WHERE COALESCE(a)='00:00:00' AND COALESCE(a)=DATE('2015-09-11');
1025+
a
1026+
00:00:00
1027+
EXPLAIN EXTENDED
1028+
SELECT * FROM t1 WHERE COALESCE(a)='00:00:00' AND COALESCE(a)=DATE('2015-09-11');
1029+
id select_type table type possible_keys key key_len ref rows filtered Extra
1030+
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
1031+
Warnings:
1032+
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)))
1033+
# TIME-alike string literal + DATE literal
1034+
SELECT * FROM t1 WHERE COALESCE(a)='00:00:00' AND COALESCE(a)=DATE'2015-09-11';
1035+
a
1036+
00:00:00
1037+
EXPLAIN EXTENDED
1038+
SELECT * FROM t1 WHERE COALESCE(a)='00:00:00' AND COALESCE(a)=DATE'2015-09-11';
1039+
id select_type table type possible_keys key key_len ref rows filtered Extra
1040+
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
1041+
Warnings:
1042+
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'))
1043+
# TIME-alike integer literal + DATE cast
1044+
SELECT * FROM t1 WHERE COALESCE(a)=0 AND COALESCE(a)=DATE('2015-09-11');
1045+
a
1046+
00:00:00
1047+
EXPLAIN EXTENDED
1048+
SELECT * FROM t1 WHERE COALESCE(a)=0 AND COALESCE(a)=DATE('2015-09-11');
1049+
id select_type table type possible_keys key key_len ref rows filtered Extra
1050+
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
1051+
Warnings:
1052+
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)))
1053+
# TIME-alike integer literal + DATE literal
1054+
SELECT * FROM t1 WHERE COALESCE(a)=0 AND COALESCE(a)=DATE'2015-09-11';
1055+
a
1056+
00:00:00
1057+
EXPLAIN EXTENDED
1058+
SELECT * FROM t1 WHERE COALESCE(a)=0 AND COALESCE(a)=DATE'2015-09-11';
1059+
id select_type table type possible_keys key key_len ref rows filtered Extra
1060+
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
1061+
Warnings:
1062+
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'))
1063+
# DATE cast + TIME cast
1064+
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=TIME('00:00:00');
1065+
a
1066+
00:00:00
1067+
EXPLAIN EXTENDED
1068+
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=TIME('00:00:00');
1069+
id select_type table type possible_keys key key_len ref rows filtered Extra
1070+
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
1071+
Warnings:
1072+
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (coalesce(`test`.`t1`.`a`) = <cache>(2015-09-11 00:00:00))
1073+
# DATE cast + TIME literal
1074+
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=TIME'00:00:00';
1075+
a
1076+
00:00:00
1077+
EXPLAIN EXTENDED
1078+
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=TIME'00:00:00';
1079+
id select_type table type possible_keys key key_len ref rows filtered Extra
1080+
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
1081+
Warnings:
1082+
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (coalesce(`test`.`t1`.`a`) = <cache>(2015-09-11 00:00:00))
1083+
# DATE cast + TIME-alike string literal
1084+
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)='00:00:00';
1085+
a
1086+
00:00:00
1087+
EXPLAIN EXTENDED
1088+
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)='00:00:00';
1089+
id select_type table type possible_keys key key_len ref rows filtered Extra
1090+
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
1091+
Warnings:
1092+
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'))
1093+
# DATE cast + TIME-alike integer literal
1094+
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=0;
1095+
a
1096+
00:00:00
1097+
EXPLAIN EXTENDED
1098+
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=0;
1099+
id select_type table type possible_keys key key_len ref rows filtered Extra
1100+
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
1101+
Warnings:
1102+
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))
1103+
# DATE literal + TIME cast
1104+
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=TIME('00:00:00');
1105+
a
1106+
00:00:00
1107+
EXPLAIN EXTENDED
1108+
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=TIME('00:00:00');
1109+
id select_type table type possible_keys key key_len ref rows filtered Extra
1110+
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
1111+
Warnings:
1112+
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (coalesce(`test`.`t1`.`a`) = DATE'2015-09-11')
1113+
# DATE literal + TIME literal
1114+
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=TIME'00:00:00';
1115+
a
1116+
00:00:00
1117+
EXPLAIN EXTENDED
1118+
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=TIME'00:00:00';
1119+
id select_type table type possible_keys key key_len ref rows filtered Extra
1120+
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
1121+
Warnings:
1122+
Note 1003 select `test`.`t1`.`a` AS `a` from `test`.`t1` where (coalesce(`test`.`t1`.`a`) = DATE'2015-09-11')
1123+
# DATE literal + TIME-alike string literal
1124+
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)='00:00:00';
1125+
a
1126+
00:00:00
1127+
EXPLAIN EXTENDED
1128+
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)='00:00:00';
1129+
id select_type table type possible_keys key key_len ref rows filtered Extra
1130+
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
1131+
Warnings:
1132+
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'))
1133+
# DATE literal + TIME-alike integer literal
1134+
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=0;
1135+
a
1136+
00:00:00
1137+
EXPLAIN EXTENDED
1138+
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=0;
1139+
id select_type table type possible_keys key key_len ref rows filtered Extra
1140+
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00 Using where
1141+
Warnings:
1142+
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))
1143+
DROP TABLE t1;
1144+
SET timestamp=DEFAULT;
1145+
#
1146+
# MDEV-8814 Wrong result for WHERE datetime_column > TIME('00:00:00')
1147+
#
1148+
CREATE TABLE t1 (a DATETIME);
1149+
INSERT INTO t1 VALUES ('2000-09-12 00:00:00'), ('2007-04-25 05:08:49');
1150+
SELECT * FROM t1 WHERE a>TIME'00:00:00';
1151+
a
1152+
SELECT * FROM t1 WHERE a>TIME('00:00:00');
1153+
a
1154+
DROP TABLE t1;
1155+
#
9721156
# End of 10.1 tests
9731157
#

mysql-test/t/type_time.test

Lines changed: 104 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -584,6 +584,110 @@ INSERT INTO t1 VALUES ('00:00:01'),('00:00:02');
584584
EXPLAIN EXTENDED SELECT * FROM t1 WHERE COALESCE(a)=TIME'00:00:01' AND COALESCE(a)>=TIME'00:00:01';
585585
DROP TABLE t1;
586586

587+
--echo #
588+
--echo # MDEV-8793 Wrong result set for SELECT ... WHERE COALESCE(time_column)=TIME('00:00:00') AND COALESCE(time_column)=DATE('2015-09-11')
589+
--echo #
590+
SET timestamp=UNIX_TIMESTAMP('2015-09-11 20:20:20');
591+
CREATE TABLE t1 (a TIME);
592+
INSERT INTO t1 VALUES('10:20:30'),('00:00:00');
593+
SELECT * FROM t1 WHERE COALESCE(a)=TIME('00:00:00');
594+
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11');
595+
596+
--echo # TIME cast + DATE cast
597+
SELECT * FROM t1 WHERE COALESCE(a)=TIME('00:00:00') AND COALESCE(a)=DATE('2015-09-11');
598+
EXPLAIN EXTENDED
599+
SELECT * FROM t1 WHERE COALESCE(a)=TIME('00:00:00') AND COALESCE(a)=DATE('2015-09-11');
600+
601+
--echo # TIME cast + DATE literal
602+
SELECT * FROM t1 WHERE COALESCE(a)=TIME('00:00:00') AND COALESCE(a)=DATE'2015-09-11';
603+
EXPLAIN EXTENDED
604+
SELECT * FROM t1 WHERE COALESCE(a)=TIME('00:00:00') AND COALESCE(a)=DATE'2015-09-11';
605+
606+
--echo # TIME literal + DATE cast
607+
SELECT * FROM t1 WHERE COALESCE(a)=TIME'00:00:00' AND COALESCE(a)=DATE('2015-09-11');
608+
EXPLAIN EXTENDED
609+
SELECT * FROM t1 WHERE COALESCE(a)=TIME'00:00:00' AND COALESCE(a)=DATE('2015-09-11');
610+
611+
--echo # TIME literal + DATE literal
612+
SELECT * FROM t1 WHERE COALESCE(a)=TIME'00:00:00' AND COALESCE(a)=DATE'2015-09-11';
613+
EXPLAIN EXTENDED
614+
SELECT * FROM t1 WHERE COALESCE(a)=TIME'00:00:00' AND COALESCE(a)=DATE'2015-09-11';
615+
616+
--echo # TIME-alike string literal + DATE cast
617+
SELECT * FROM t1 WHERE COALESCE(a)='00:00:00' AND COALESCE(a)=DATE('2015-09-11');
618+
EXPLAIN EXTENDED
619+
SELECT * FROM t1 WHERE COALESCE(a)='00:00:00' AND COALESCE(a)=DATE('2015-09-11');
620+
621+
--echo # TIME-alike string literal + DATE literal
622+
SELECT * FROM t1 WHERE COALESCE(a)='00:00:00' AND COALESCE(a)=DATE'2015-09-11';
623+
EXPLAIN EXTENDED
624+
SELECT * FROM t1 WHERE COALESCE(a)='00:00:00' AND COALESCE(a)=DATE'2015-09-11';
625+
626+
--echo # TIME-alike integer literal + DATE cast
627+
SELECT * FROM t1 WHERE COALESCE(a)=0 AND COALESCE(a)=DATE('2015-09-11');
628+
EXPLAIN EXTENDED
629+
SELECT * FROM t1 WHERE COALESCE(a)=0 AND COALESCE(a)=DATE('2015-09-11');
630+
631+
--echo # TIME-alike integer literal + DATE literal
632+
SELECT * FROM t1 WHERE COALESCE(a)=0 AND COALESCE(a)=DATE'2015-09-11';
633+
EXPLAIN EXTENDED
634+
SELECT * FROM t1 WHERE COALESCE(a)=0 AND COALESCE(a)=DATE'2015-09-11';
635+
636+
637+
### Now test the opposite order of the two equality expressions
638+
639+
--echo # DATE cast + TIME cast
640+
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=TIME('00:00:00');
641+
EXPLAIN EXTENDED
642+
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=TIME('00:00:00');
643+
644+
--echo # DATE cast + TIME literal
645+
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=TIME'00:00:00';
646+
EXPLAIN EXTENDED
647+
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=TIME'00:00:00';
648+
649+
--echo # DATE cast + TIME-alike string literal
650+
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)='00:00:00';
651+
EXPLAIN EXTENDED
652+
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)='00:00:00';
653+
654+
--echo # DATE cast + TIME-alike integer literal
655+
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=0;
656+
EXPLAIN EXTENDED
657+
SELECT * FROM t1 WHERE COALESCE(a)=DATE('2015-09-11') AND COALESCE(a)=0;
658+
659+
--echo # DATE literal + TIME cast
660+
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=TIME('00:00:00');
661+
EXPLAIN EXTENDED
662+
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=TIME('00:00:00');
663+
664+
--echo # DATE literal + TIME literal
665+
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=TIME'00:00:00';
666+
EXPLAIN EXTENDED
667+
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=TIME'00:00:00';
668+
669+
--echo # DATE literal + TIME-alike string literal
670+
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)='00:00:00';
671+
EXPLAIN EXTENDED
672+
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)='00:00:00';
673+
674+
--echo # DATE literal + TIME-alike integer literal
675+
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=0;
676+
EXPLAIN EXTENDED
677+
SELECT * FROM t1 WHERE COALESCE(a)=DATE'2015-09-11' AND COALESCE(a)=0;
678+
679+
DROP TABLE t1;
680+
SET timestamp=DEFAULT;
681+
682+
--echo #
683+
--echo # MDEV-8814 Wrong result for WHERE datetime_column > TIME('00:00:00')
684+
--echo #
685+
CREATE TABLE t1 (a DATETIME);
686+
INSERT INTO t1 VALUES ('2000-09-12 00:00:00'), ('2007-04-25 05:08:49');
687+
SELECT * FROM t1 WHERE a>TIME'00:00:00';
688+
SELECT * FROM t1 WHERE a>TIME('00:00:00');
689+
DROP TABLE t1;
690+
587691
--echo #
588692
--echo # End of 10.1 tests
589693
--echo #

sql/item.cc

Lines changed: 19 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -8596,7 +8596,8 @@ void resolve_const_item(THD *thd, Item **ref, Item *comp_item)
85968596
bool is_null;
85978597
Item **ref_copy= ref;
85988598
/* the following call creates a constant and puts it in new_item */
8599-
get_datetime_value(thd, &ref_copy, &new_item, comp_item, &is_null);
8599+
enum_field_types type= item->field_type_for_temporal_comparison(comp_item);
8600+
get_datetime_value(thd, &ref_copy, &new_item, type, &is_null);
86008601
if (is_null)
86018602
new_item= new (mem_root) Item_null(thd, name);
86028603
break;
@@ -8936,9 +8937,25 @@ Item_cache_temporal::Item_cache_temporal(THD *thd,
89368937
}
89378938

89388939

8939-
longlong Item_cache_temporal::val_temporal_packed()
8940+
longlong Item_cache_temporal::val_datetime_packed()
89408941
{
89418942
DBUG_ASSERT(fixed == 1);
8943+
if (Item_cache_temporal::field_type() == MYSQL_TYPE_TIME)
8944+
return Item::val_datetime_packed(); // TIME-to-DATETIME conversion needed
8945+
if ((!value_cached && !cache_value()) || null_value)
8946+
{
8947+
null_value= TRUE;
8948+
return 0;
8949+
}
8950+
return value;
8951+
}
8952+
8953+
8954+
longlong Item_cache_temporal::val_time_packed()
8955+
{
8956+
DBUG_ASSERT(fixed == 1);
8957+
if (Item_cache_temporal::field_type() != MYSQL_TYPE_TIME)
8958+
return Item::val_time_packed(); // DATETIME-to-TIME conversion needed
89428959
if ((!value_cached && !cache_value()) || null_value)
89438960
{
89448961
null_value= TRUE;

0 commit comments

Comments
 (0)