Commit 8db600f9 authored by Alexander Barkov's avatar Alexander Barkov

MDEV-5041 Inserting a TIME with hour>24 into a DATETIME column produces a wrong value

parent 13dc299a
...@@ -345,5 +345,51 @@ Warning 1292 Incorrect datetime value: '0' ...@@ -345,5 +345,51 @@ Warning 1292 Incorrect datetime value: '0'
Warning 1292 Incorrect datetime value: '0' Warning 1292 Incorrect datetime value: '0'
SET @@timestamp=DEFAULT; SET @@timestamp=DEFAULT;
# #
# MDEV-5041 Inserting a TIME with hour>24 into a DATETIME column produces a wrong value
#
SELECT CAST(TIME('-800:20:30') AS DATE);
CAST(TIME('-800:20:30') AS DATE)
NULL
Warnings:
Warning 1292 Truncated incorrect date value: '-800:20:30'
SELECT CAST(TIME('800:20:30') AS DATE);
CAST(TIME('800:20:30') AS DATE)
0000-01-02
SELECT CAST(TIME('33 08:20:30') AS DATE);
CAST(TIME('33 08:20:30') AS DATE)
0000-01-02
CREATE TABLE t1 (a DATE);
INSERT INTO t1 VALUES (TIME('800:20:30'));
Warnings:
Note 1265 Data truncated for column 'a' at row 1
INSERT INTO t1 VALUES (TIME('33 08:20:30'));
Warnings:
Note 1265 Data truncated for column 'a' at row 1
SET SQL_MODE=NO_ZERO_IN_DATE;
INSERT INTO t1 VALUES (TIME('48:20:30'));
Warnings:
Warning 1265 Data truncated for column 'a' at row 1
SET SQL_MODE=DEFAULT;
SELECT * FROM t1;
a
0000-01-02
0000-01-02
0000-00-00
DROP TABLE t1;
CREATE PROCEDURE test5041()
BEGIN
DECLARE t TIME;
DECLARE d DATE;
SET t= TIME('800:00:00');
SET d= t;
SELECT d;
END;|
call test5041();
d
0000-01-02
Warnings:
Note 1265 Data truncated for column 'd' at row 1
drop procedure test5041;
#
# End of 5.3 tests # End of 5.3 tests
# #
...@@ -684,4 +684,44 @@ CONVERT_TZ(GREATEST(TIMESTAMP('2021-00-00'),TIMESTAMP('2022-00-00')),'+00:00','+ ...@@ -684,4 +684,44 @@ CONVERT_TZ(GREATEST(TIMESTAMP('2021-00-00'),TIMESTAMP('2022-00-00')),'+00:00','+
NULL NULL
Warnings: Warnings:
Warning 1292 Incorrect datetime value: '2022-00-00 00:00:00' Warning 1292 Incorrect datetime value: '2022-00-00 00:00:00'
#
# MDEV-5041 Inserting a TIME with hour>24 into a DATETIME column produces a wrong value
#
SELECT CAST(TIME('-800:20:30') AS DATETIME);
CAST(TIME('-800:20:30') AS DATETIME)
NULL
Warnings:
Warning 1292 Truncated incorrect datetime value: '-800:20:30'
SELECT CAST(TIME('800:20:30') AS DATETIME);
CAST(TIME('800:20:30') AS DATETIME)
0000-01-02 08:20:30
SELECT CAST(TIME('33 08:20:30') AS DATETIME);
CAST(TIME('33 08:20:30') AS DATETIME)
0000-01-02 08:20:30
CREATE TABLE t1 (a DATETIME);
INSERT INTO t1 VALUES (TIME('800:20:30'));
INSERT INTO t1 VALUES (TIME('33 08:20:30'));
SET SQL_MODE=NO_ZERO_IN_DATE;
INSERT INTO t1 VALUES (TIME('48:20:30'));
Warnings:
Warning 1265 Data truncated for column 'a' at row 1
SET SQL_MODE=DEFAULT;
SELECT * FROM t1;
a
0000-01-02 08:20:30
0000-01-02 08:20:30
0000-00-00 00:00:00
DROP TABLE t1;
CREATE PROCEDURE test5041()
BEGIN
DECLARE t TIME;
DECLARE dt DATETIME;
SET t= TIME('800:20:30');
SET dt= t;
SELECT dt;
END;|
call test5041();
dt
0000-01-02 08:20:30
drop procedure test5041;
End of 5.3 tests End of 5.3 tests
...@@ -309,6 +309,34 @@ SELECT ...@@ -309,6 +309,34 @@ SELECT
DATE('20011107')>IFNULL(DATE('0'),CURRENT_DATE) AS cmp; DATE('20011107')>IFNULL(DATE('0'),CURRENT_DATE) AS cmp;
SET @@timestamp=DEFAULT; SET @@timestamp=DEFAULT;
--echo #
--echo # MDEV-5041 Inserting a TIME with hour>24 into a DATETIME column produces a wrong value
--echo #
SELECT CAST(TIME('-800:20:30') AS DATE);
SELECT CAST(TIME('800:20:30') AS DATE);
SELECT CAST(TIME('33 08:20:30') AS DATE);
CREATE TABLE t1 (a DATE);
INSERT INTO t1 VALUES (TIME('800:20:30'));
INSERT INTO t1 VALUES (TIME('33 08:20:30'));
SET SQL_MODE=NO_ZERO_IN_DATE;
INSERT INTO t1 VALUES (TIME('48:20:30'));
SET SQL_MODE=DEFAULT;
SELECT * FROM t1;
DROP TABLE t1;
DELIMITER |;
CREATE PROCEDURE test5041()
BEGIN
DECLARE t TIME;
DECLARE d DATE;
SET t= TIME('800:00:00');
SET d= t;
SELECT d;
END;|
DELIMITER ;|
call test5041();
drop procedure test5041;
--echo # --echo #
--echo # End of 5.3 tests --echo # End of 5.3 tests
--echo # --echo #
...@@ -491,5 +491,34 @@ drop table t1,t2; ...@@ -491,5 +491,34 @@ drop table t1,t2;
--echo # --echo #
SELECT CONVERT_TZ(GREATEST(TIMESTAMP('2021-00-00'),TIMESTAMP('2022-00-00')),'+00:00','+7:5'); SELECT CONVERT_TZ(GREATEST(TIMESTAMP('2021-00-00'),TIMESTAMP('2022-00-00')),'+00:00','+7:5');
--echo #
--echo # MDEV-5041 Inserting a TIME with hour>24 into a DATETIME column produces a wrong value
--echo #
SELECT CAST(TIME('-800:20:30') AS DATETIME);
SELECT CAST(TIME('800:20:30') AS DATETIME);
SELECT CAST(TIME('33 08:20:30') AS DATETIME);
CREATE TABLE t1 (a DATETIME);
INSERT INTO t1 VALUES (TIME('800:20:30'));
INSERT INTO t1 VALUES (TIME('33 08:20:30'));
SET SQL_MODE=NO_ZERO_IN_DATE;
INSERT INTO t1 VALUES (TIME('48:20:30'));
SET SQL_MODE=DEFAULT;
SELECT * FROM t1;
DROP TABLE t1;
DELIMITER |;
CREATE PROCEDURE test5041()
BEGIN
DECLARE t TIME;
DECLARE dt DATETIME;
SET t= TIME('800:20:30');
SET dt= t;
SELECT dt;
END;|
DELIMITER ;|
call test5041();
drop procedure test5041;
--echo End of 5.3 tests --echo End of 5.3 tests
...@@ -5173,6 +5173,13 @@ int Field_temporal::store_time_dec(MYSQL_TIME *ltime, uint dec) ...@@ -5173,6 +5173,13 @@ int Field_temporal::store_time_dec(MYSQL_TIME *ltime, uint dec)
int error = 0, have_smth_to_conv= 1; int error = 0, have_smth_to_conv= 1;
MYSQL_TIME l_time= *ltime; MYSQL_TIME l_time= *ltime;
Lazy_string_time str(ltime); Lazy_string_time str(ltime);
if (l_time.time_type == MYSQL_TIMESTAMP_TIME && time_to_datetime(&l_time))
{
have_smth_to_conv= 0;
error= 1;
goto store;
}
/* /*
We don't perform range checking here since values stored in TIME We don't perform range checking here since values stored in TIME
structure always fit into DATETIME range. structure always fit into DATETIME range.
...@@ -5181,6 +5188,7 @@ int Field_temporal::store_time_dec(MYSQL_TIME *ltime, uint dec) ...@@ -5181,6 +5188,7 @@ int Field_temporal::store_time_dec(MYSQL_TIME *ltime, uint dec)
(current_thd->variables.sql_mode & (current_thd->variables.sql_mode &
(MODE_NO_ZERO_IN_DATE | MODE_NO_ZERO_DATE | (MODE_NO_ZERO_IN_DATE | MODE_NO_ZERO_DATE |
MODE_INVALID_DATES)), &error); MODE_INVALID_DATES)), &error);
store:
return store_TIME_with_warning(&l_time, &str, error, have_smth_to_conv); return store_TIME_with_warning(&l_time, &str, error, have_smth_to_conv);
} }
......
...@@ -2317,10 +2317,11 @@ bool Item_date_typecast::get_date(MYSQL_TIME *ltime, uint fuzzy_date) ...@@ -2317,10 +2317,11 @@ bool Item_date_typecast::get_date(MYSQL_TIME *ltime, uint fuzzy_date)
{ {
if (get_arg0_date(ltime, fuzzy_date & ~TIME_TIME_ONLY)) if (get_arg0_date(ltime, fuzzy_date & ~TIME_TIME_ONLY))
return 1; return 1;
ltime->hour= ltime->minute= ltime->second= ltime->second_part= 0;
ltime->time_type= MYSQL_TIMESTAMP_DATE; if (make_date_with_warn(ltime, fuzzy_date, MYSQL_TIMESTAMP_DATE))
return (null_value= check_date_with_warn(ltime, fuzzy_date, return (null_value= 1);
MYSQL_TIMESTAMP_DATE));
return 0;
} }
...@@ -2332,28 +2333,9 @@ bool Item_datetime_typecast::get_date(MYSQL_TIME *ltime, uint fuzzy_date) ...@@ -2332,28 +2333,9 @@ bool Item_datetime_typecast::get_date(MYSQL_TIME *ltime, uint fuzzy_date)
if (decimals < TIME_SECOND_PART_DIGITS) if (decimals < TIME_SECOND_PART_DIGITS)
ltime->second_part= sec_part_truncate(ltime->second_part, decimals); ltime->second_part= sec_part_truncate(ltime->second_part, decimals);
if (make_date_with_warn(ltime, fuzzy_date, MYSQL_TIMESTAMP_DATETIME))
/*
ltime is valid MYSQL_TYPE_TIME (according to fuzzy_date).
But not every valid TIME value is a valid DATETIME value!
*/
if (ltime->time_type == MYSQL_TIMESTAMP_TIME)
{
if (ltime->neg)
{
Lazy_string_time str(ltime);
make_truncated_value_warning(current_thd, MYSQL_ERROR::WARN_LEVEL_WARN,
&str, MYSQL_TIMESTAMP_DATETIME, 0);
return (null_value= 1); return (null_value= 1);
}
uint day= ltime->hour/24;
ltime->hour %= 24;
ltime->month= day / 31;
ltime->day= day % 31;
}
ltime->time_type= MYSQL_TIMESTAMP_DATETIME;
return 0; return 0;
} }
......
...@@ -2526,6 +2526,7 @@ bool str_to_time_with_warn(const char *str,uint length,MYSQL_TIME *l_time, ...@@ -2526,6 +2526,7 @@ bool str_to_time_with_warn(const char *str,uint length,MYSQL_TIME *l_time,
ulong fuzzydate); ulong fuzzydate);
timestamp_type str_to_datetime_with_warn(const char *str, uint length, timestamp_type str_to_datetime_with_warn(const char *str, uint length,
MYSQL_TIME *l_time, ulong flags); MYSQL_TIME *l_time, ulong flags);
bool time_to_datetime(MYSQL_TIME *l_time);
void time_to_daytime_interval(MYSQL_TIME *l_time); void time_to_daytime_interval(MYSQL_TIME *l_time);
void localtime_to_TIME(MYSQL_TIME *to, struct tm *from); void localtime_to_TIME(MYSQL_TIME *to, struct tm *from);
void calc_time_from_sec(MYSQL_TIME *to, long seconds, long microseconds); void calc_time_from_sec(MYSQL_TIME *to, long seconds, long microseconds);
...@@ -2581,6 +2582,8 @@ check_date(const MYSQL_TIME *ltime, ulonglong flags, int *was_cut) ...@@ -2581,6 +2582,8 @@ check_date(const MYSQL_TIME *ltime, ulonglong flags, int *was_cut)
} }
bool check_date_with_warn(const MYSQL_TIME *ltime, uint fuzzy_date, bool check_date_with_warn(const MYSQL_TIME *ltime, uint fuzzy_date,
timestamp_type ts_type); timestamp_type ts_type);
bool make_date_with_warn(MYSQL_TIME *ltime,
uint fuzzy_date, timestamp_type ts_type);
bool adjust_time_range_with_warn(MYSQL_TIME *ltime, uint dec); bool adjust_time_range_with_warn(MYSQL_TIME *ltime, uint dec);
int test_if_number(char *str,int *res,bool allow_wildcards); int test_if_number(char *str,int *res,bool allow_wildcards);
void change_byte(uchar *,uint,char,char); void change_byte(uchar *,uint,char,char);
......
...@@ -1060,6 +1060,56 @@ int my_time_compare(MYSQL_TIME *a, MYSQL_TIME *b) ...@@ -1060,6 +1060,56 @@ int my_time_compare(MYSQL_TIME *a, MYSQL_TIME *b)
} }
/**
Convert TIME to DATETIME.
@param ltime The value to convert.
@return false on success, true of error (negative time).
*/
bool time_to_datetime(MYSQL_TIME *ltime)
{
DBUG_ASSERT(ltime->time_type == MYSQL_TIMESTAMP_TIME);
DBUG_ASSERT(ltime->year == 0);
DBUG_ASSERT(ltime->month == 0);
DBUG_ASSERT(ltime->day == 0);
if (ltime->neg)
return true;
uint day= ltime->hour / 24;
ltime->hour%= 24;
ltime->month= day / 31;
ltime->day= day % 31;
return false;
}
/**
Return a valid DATE or DATETIME value from an arbitrary MYSQL_TIME.
If ltime is TIME, it's first converted to DATETIME.
If ts_type is DATE, yymmss is set to zero.
The date part of the result is checked against fuzzy_date.
@param ltime The value to convert.
@param fuzzy_date Flags to check date.
@param ts_type The type to convert to.
@return false on success, true of error (negative time).*/
bool
make_date_with_warn(MYSQL_TIME *ltime, uint fuzzy_date, timestamp_type ts_type)
{
DBUG_ASSERT(ts_type == MYSQL_TIMESTAMP_DATE ||
ts_type == MYSQL_TIMESTAMP_DATETIME);
if (ltime->time_type == MYSQL_TIMESTAMP_TIME && time_to_datetime(ltime))
{
/* e.g. negative time */
Lazy_string_time str(ltime);
make_truncated_value_warning(current_thd, MYSQL_ERROR::WARN_LEVEL_WARN,
&str, ts_type, 0);
return true;
}
if ((ltime->time_type= ts_type) == MYSQL_TIMESTAMP_DATE)
ltime->hour= ltime->minute= ltime->second= ltime->second_part= 0;
return check_date_with_warn(ltime, fuzzy_date, ts_type);
}
/* /*
Convert a TIME value to DAY-TIME interval, e.g. for extraction: Convert a TIME value to DAY-TIME interval, e.g. for extraction:
EXTRACT(DAY FROM x), EXTRACT(HOUR FROM x), etc. EXTRACT(DAY FROM x), EXTRACT(HOUR FROM x), etc.
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment