summaryrefslogtreecommitdiff
diff options
context:
space:
mode:
-rw-r--r--mysql-test/r/select.result160
-rw-r--r--mysql-test/t/select.test78
-rw-r--r--sql-common/my_time.c34
-rw-r--r--sql/item_cmpfunc.cc67
4 files changed, 282 insertions, 57 deletions
diff --git a/mysql-test/r/select.result b/mysql-test/r/select.result
index cb13f01562f..745819107f0 100644
--- a/mysql-test/r/select.result
+++ b/mysql-test/r/select.result
@@ -3241,40 +3241,40 @@ drop table t1, t2 ,t3;
create table t1(f1 int, f2 date);
insert into t1 values(1,'2005-01-01'),(2,'2005-09-01'),(3,'2005-09-30'),
(4,'2005-10-01'),(5,'2005-12-30');
-select * from t1 where f2 >= 0;
+select * from t1 where f2 >= 0 order by f2;
f1 f2
1 2005-01-01
2 2005-09-01
3 2005-09-30
4 2005-10-01
5 2005-12-30
-select * from t1 where f2 >= '0000-00-00';
+select * from t1 where f2 >= '0000-00-00' order by f2;
f1 f2
1 2005-01-01
2 2005-09-01
3 2005-09-30
4 2005-10-01
5 2005-12-30
-select * from t1 where f2 >= '2005-09-31';
+select * from t1 where f2 >= '2005-09-31' order by f2;
f1 f2
4 2005-10-01
5 2005-12-30
-select * from t1 where f2 >= '2005-09-3a';
+select * from t1 where f2 >= '2005-09-3a' order by f2;
f1 f2
+3 2005-09-30
4 2005-10-01
5 2005-12-30
Warnings:
Warning 1292 Incorrect date value: '2005-09-3a' for column 'f2' at row 1
-select * from t1 where f2 <= '2005-09-31';
+select * from t1 where f2 <= '2005-09-31' order by f2;
f1 f2
1 2005-01-01
2 2005-09-01
3 2005-09-30
-select * from t1 where f2 <= '2005-09-3a';
+select * from t1 where f2 <= '2005-09-3a' order by f2;
f1 f2
1 2005-01-01
2 2005-09-01
-3 2005-09-30
Warnings:
Warning 1292 Incorrect date value: '2005-09-3a' for column 'f2' at row 1
drop table t1;
@@ -4087,6 +4087,152 @@ x
ALTER VIEW v1 AS SELECT 1 AS ` `;
ERROR 42000: Incorrect column name ' '
DROP VIEW v1;
+select str_to_date('2007-10-09','%Y-%m-%d') between '2007/10/01 00:00:00 GMT'
+ and '2007/10/20 00:00:00 GMT';
+str_to_date('2007-10-09','%Y-%m-%d') between '2007/10/01 00:00:00 GMT'
+ and '2007/10/20 00:00:00 GMT'
+1
+Warnings:
+Warning 1292 Truncated incorrect datetime value: '2007/10/01 00:00:00 GMT'
+Warning 1292 Truncated incorrect datetime value: '2007/10/20 00:00:00 GMT'
+select str_to_date('2007-10-09','%Y-%m-%d') > '2007/10/01 00:00:00 GMT-6';
+str_to_date('2007-10-09','%Y-%m-%d') > '2007/10/01 00:00:00 GMT-6'
+1
+Warnings:
+Warning 1292 Truncated incorrect date value: '2007/10/01 00:00:00 GMT-6'
+select str_to_date('2007-10-09','%Y-%m-%d') <= '2007/10/2000:00:00 GMT-6';
+str_to_date('2007-10-09','%Y-%m-%d') <= '2007/10/2000:00:00 GMT-6'
+1
+Warnings:
+Warning 1292 Truncated incorrect date value: '2007/10/2000:00:00 GMT-6'
+select str_to_date('2007-10-01','%Y-%m-%d') = '2007-10-1 00:00:00 GMT-6';
+str_to_date('2007-10-01','%Y-%m-%d') = '2007-10-1 00:00:00 GMT-6'
+1
+Warnings:
+Warning 1292 Truncated incorrect date value: '2007-10-1 00:00:00 GMT-6'
+select str_to_date('2007-10-01','%Y-%m-%d') = '2007-10-01 x00:00:00 GMT-6';
+str_to_date('2007-10-01','%Y-%m-%d') = '2007-10-01 x00:00:00 GMT-6'
+1
+Warnings:
+Warning 1292 Truncated incorrect date value: '2007-10-01 x00:00:00 GMT-6'
+select str_to_date('2007-10-01','%Y-%m-%d %H:%i:%s') = '2007-10-01 00:00:00 GMT-6';
+str_to_date('2007-10-01','%Y-%m-%d %H:%i:%s') = '2007-10-01 00:00:00 GMT-6'
+1
+Warnings:
+Warning 1292 Truncated incorrect datetime value: '2007-10-01 00:00:00 GMT-6'
+select str_to_date('2007-10-01','%Y-%m-%d %H:%i:%s') = '2007-10-01 00:x00:00 GMT-6';
+str_to_date('2007-10-01','%Y-%m-%d %H:%i:%s') = '2007-10-01 00:x00:00 GMT-6'
+1
+Warnings:
+Warning 1292 Truncated incorrect datetime value: '2007-10-01 00:x00:00 GMT-6'
+select str_to_date('2007-10-01','%Y-%m-%d %H:%i:%s') = '2007-10-01 x12:34:56 GMT-6';
+str_to_date('2007-10-01','%Y-%m-%d %H:%i:%s') = '2007-10-01 x12:34:56 GMT-6'
+1
+Warnings:
+Warning 1292 Truncated incorrect datetime value: '2007-10-01 x12:34:56 GMT-6'
+select str_to_date('2007-10-01 12:34:00','%Y-%m-%d %H:%i:%s') = '2007-10-01 12:34x:56 GMT-6';
+str_to_date('2007-10-01 12:34:00','%Y-%m-%d %H:%i:%s') = '2007-10-01 12:34x:56 GMT-6'
+1
+Warnings:
+Warning 1292 Truncated incorrect datetime value: '2007-10-01 12:34x:56 GMT-6'
+select str_to_date('2007-10-01 12:34:56','%Y-%m-%d %H:%i:%s') = '2007-10-01 12:34x:56 GMT-6';
+str_to_date('2007-10-01 12:34:56','%Y-%m-%d %H:%i:%s') = '2007-10-01 12:34x:56 GMT-6'
+0
+Warnings:
+Warning 1292 Truncated incorrect datetime value: '2007-10-01 12:34x:56 GMT-6'
+select str_to_date('2007-10-01 12:34:56','%Y-%m-%d %H:%i:%s') = '2007-10-01 12:34:56';
+str_to_date('2007-10-01 12:34:56','%Y-%m-%d %H:%i:%s') = '2007-10-01 12:34:56'
+1
+select str_to_date('2007-10-01','%Y-%m-%d') = '2007-10-01 12:00:00';
+str_to_date('2007-10-01','%Y-%m-%d') = '2007-10-01 12:00:00'
+0
+select str_to_date('2007-10-01 12','%Y-%m-%d %H') = '2007-10-01 12:00:00';
+str_to_date('2007-10-01 12','%Y-%m-%d %H') = '2007-10-01 12:00:00'
+1
+select str_to_date('2007-10-01 12:34','%Y-%m-%d %H') = '2007-10-01 12:00:00';
+str_to_date('2007-10-01 12:34','%Y-%m-%d %H') = '2007-10-01 12:00:00'
+1
+Warnings:
+Warning 1292 Truncated incorrect datetime value: '2007-10-01 12:34'
+select str_to_date('2007-02-30 12:34','%Y-%m-%d %H:%i') = '2007-02-30 12:34';
+str_to_date('2007-02-30 12:34','%Y-%m-%d %H:%i') = '2007-02-30 12:34'
+1
+select str_to_date('2007-10-00 12:34','%Y-%m-%d %H:%i') = '2007-10-00 12:34';
+str_to_date('2007-10-00 12:34','%Y-%m-%d %H:%i') = '2007-10-00 12:34'
+1
+select str_to_date('2007-10-00','%Y-%m-%d') between '2007/09/01 00:00:00'
+ and '2007/10/20 00:00:00';
+str_to_date('2007-10-00','%Y-%m-%d') between '2007/09/01 00:00:00'
+ and '2007/10/20 00:00:00'
+1
+set SQL_MODE=TRADITIONAL;
+select str_to_date('2007-10-00 12:34','%Y-%m-%d %H:%i') = '2007-10-00 12:34';
+str_to_date('2007-10-00 12:34','%Y-%m-%d %H:%i') = '2007-10-00 12:34'
+0
+Warnings:
+Warning 1292 Truncated incorrect datetime value: '2007-10-00 12:34'
+select str_to_date('2007-10-01 12:34','%Y-%m-%d %H:%i') = '2007-10-00 12:34';
+str_to_date('2007-10-01 12:34','%Y-%m-%d %H:%i') = '2007-10-00 12:34'
+0
+Warnings:
+Warning 1292 Truncated incorrect datetime value: '2007-10-00 12:34'
+select str_to_date('2007-10-00 12:34','%Y-%m-%d %H:%i') = '2007-10-01 12:34';
+str_to_date('2007-10-00 12:34','%Y-%m-%d %H:%i') = '2007-10-01 12:34'
+0
+Warnings:
+Warning 1292 Truncated incorrect datetime value: '2007-10-00 12:34:00'
+select str_to_date('2007-10-00','%Y-%m-%d') between '2007/09/01'
+ and '2007/10/20';
+str_to_date('2007-10-00','%Y-%m-%d') between '2007/09/01'
+ and '2007/10/20'
+0
+Warnings:
+Warning 1292 Incorrect datetime value: '2007-10-00' for column '2007/09/01' at row 1
+Warning 1292 Incorrect datetime value: '2007-10-00' for column '2007/10/20' at row 1
+set SQL_MODE=DEFAULT;
+select str_to_date('2007-10-00','%Y-%m-%d') between '' and '2007/10/20';
+str_to_date('2007-10-00','%Y-%m-%d') between '' and '2007/10/20'
+1
+Warnings:
+Warning 1292 Truncated incorrect datetime value: ''
+select str_to_date('','%Y-%m-%d') between '2007/10/01' and '2007/10/20';
+str_to_date('','%Y-%m-%d') between '2007/10/01' and '2007/10/20'
+0
+select str_to_date('','%Y-%m-%d %H:%i') = '2007-10-01 12:34';
+str_to_date('','%Y-%m-%d %H:%i') = '2007-10-01 12:34'
+0
+select str_to_date(NULL,'%Y-%m-%d %H:%i') = '2007-10-01 12:34';
+str_to_date(NULL,'%Y-%m-%d %H:%i') = '2007-10-01 12:34'
+NULL
+select str_to_date('2007-10-00 12:34','%Y-%m-%d %H:%i') = '';
+str_to_date('2007-10-00 12:34','%Y-%m-%d %H:%i') = ''
+0
+Warnings:
+Warning 1292 Truncated incorrect datetime value: ''
+select str_to_date('1','%Y-%m-%d') = '1';
+str_to_date('1','%Y-%m-%d') = '1'
+0
+Warnings:
+Warning 1292 Truncated incorrect date value: '1'
+select str_to_date('1','%Y-%m-%d') = '1';
+str_to_date('1','%Y-%m-%d') = '1'
+0
+Warnings:
+Warning 1292 Truncated incorrect date value: '1'
+select str_to_date('','%Y-%m-%d') = '';
+str_to_date('','%Y-%m-%d') = ''
+0
+Warnings:
+Warning 1292 Truncated incorrect date value: ''
+select str_to_date('1000-01-01','%Y-%m-%d') between '0000-00-00' and NULL;
+str_to_date('1000-01-01','%Y-%m-%d') between '0000-00-00' and NULL
+0
+select str_to_date('1000-01-01','%Y-%m-%d') between NULL and '2000-00-00';
+str_to_date('1000-01-01','%Y-%m-%d') between NULL and '2000-00-00'
+0
+select str_to_date('1000-01-01','%Y-%m-%d') between NULL and NULL;
+str_to_date('1000-01-01','%Y-%m-%d') between NULL and NULL
+0
End of 5.0 tests
create table t1(a INT, KEY (a));
INSERT INTO t1 VALUES (1),(2),(3),(4),(5);
diff --git a/mysql-test/t/select.test b/mysql-test/t/select.test
index eebf4a1d5ab..4929fb355fc 100644
--- a/mysql-test/t/select.test
+++ b/mysql-test/t/select.test
@@ -2764,14 +2764,14 @@ create table t1(f1 int, f2 date);
insert into t1 values(1,'2005-01-01'),(2,'2005-09-01'),(3,'2005-09-30'),
(4,'2005-10-01'),(5,'2005-12-30');
# should return all records
-select * from t1 where f2 >= 0;
-select * from t1 where f2 >= '0000-00-00';
+select * from t1 where f2 >= 0 order by f2;
+select * from t1 where f2 >= '0000-00-00' order by f2;
# should return 4,5
-select * from t1 where f2 >= '2005-09-31';
-select * from t1 where f2 >= '2005-09-3a';
+select * from t1 where f2 >= '2005-09-31' order by f2;
+select * from t1 where f2 >= '2005-09-3a' order by f2;
# should return 1,2,3
-select * from t1 where f2 <= '2005-09-31';
-select * from t1 where f2 <= '2005-09-3a';
+select * from t1 where f2 <= '2005-09-31' order by f2;
+select * from t1 where f2 <= '2005-09-3a' order by f2;
drop table t1;
#
@@ -3501,6 +3501,72 @@ ALTER VIEW v1 AS SELECT 1 AS ` `;
DROP VIEW v1;
+#
+# Bug#31800: Date comparison fails with timezone and slashes for greater
+# than comparison
+#
+
+# On DATETIME-like literals with trailing garbage, BETWEEN fudged in a
+# DATETIME comparator, while greater/less-than used bin-string comparisons.
+# Should correctly be compared as DATE or DATETIME, but throw a warning:
+
+select str_to_date('2007-10-09','%Y-%m-%d') between '2007/10/01 00:00:00 GMT'
+ and '2007/10/20 00:00:00 GMT';
+select str_to_date('2007-10-09','%Y-%m-%d') > '2007/10/01 00:00:00 GMT-6';
+select str_to_date('2007-10-09','%Y-%m-%d') <= '2007/10/2000:00:00 GMT-6';
+
+# We have all we need -- and trailing garbage:
+# (leaving out a leading zero in first example to prove it's a
+# value-comparison, not a string-comparison!)
+select str_to_date('2007-10-01','%Y-%m-%d') = '2007-10-1 00:00:00 GMT-6';
+select str_to_date('2007-10-01','%Y-%m-%d') = '2007-10-01 x00:00:00 GMT-6';
+select str_to_date('2007-10-01','%Y-%m-%d %H:%i:%s') = '2007-10-01 00:00:00 GMT-6';
+select str_to_date('2007-10-01','%Y-%m-%d %H:%i:%s') = '2007-10-01 00:x00:00 GMT-6';
+# no time at all:
+select str_to_date('2007-10-01','%Y-%m-%d %H:%i:%s') = '2007-10-01 x12:34:56 GMT-6';
+# partial time:
+select str_to_date('2007-10-01 12:34:00','%Y-%m-%d %H:%i:%s') = '2007-10-01 12:34x:56 GMT-6';
+# fail, different second part:
+select str_to_date('2007-10-01 12:34:56','%Y-%m-%d %H:%i:%s') = '2007-10-01 12:34x:56 GMT-6';
+# correct syntax, no trailing nonsense -- this one must throw no warning:
+select str_to_date('2007-10-01 12:34:56','%Y-%m-%d %H:%i:%s') = '2007-10-01 12:34:56';
+# no warning, but failure (different hour parts):
+select str_to_date('2007-10-01','%Y-%m-%d') = '2007-10-01 12:00:00';
+# succeed:
+select str_to_date('2007-10-01 12','%Y-%m-%d %H') = '2007-10-01 12:00:00';
+# succeed, but warn for "trailing garbage" (":34"):
+select str_to_date('2007-10-01 12:34','%Y-%m-%d %H') = '2007-10-01 12:00:00';
+# invalid date (Feb 30) succeeds
+select str_to_date('2007-02-30 12:34','%Y-%m-%d %H:%i') = '2007-02-30 12:34';
+# 0-day for both, just works in default SQL mode.
+select str_to_date('2007-10-00 12:34','%Y-%m-%d %H:%i') = '2007-10-00 12:34';
+# 0-day, succeed
+select str_to_date('2007-10-00','%Y-%m-%d') between '2007/09/01 00:00:00'
+ and '2007/10/20 00:00:00';
+set SQL_MODE=TRADITIONAL;
+# 0-day throws warning in traditional mode, and fails
+select str_to_date('2007-10-00 12:34','%Y-%m-%d %H:%i') = '2007-10-00 12:34';
+select str_to_date('2007-10-01 12:34','%Y-%m-%d %H:%i') = '2007-10-00 12:34';
+# different code-path: get_datetime_value() with 0-day
+select str_to_date('2007-10-00 12:34','%Y-%m-%d %H:%i') = '2007-10-01 12:34';
+select str_to_date('2007-10-00','%Y-%m-%d') between '2007/09/01'
+ and '2007/10/20';
+set SQL_MODE=DEFAULT;
+select str_to_date('2007-10-00','%Y-%m-%d') between '' and '2007/10/20';
+select str_to_date('','%Y-%m-%d') between '2007/10/01' and '2007/10/20';
+select str_to_date('','%Y-%m-%d %H:%i') = '2007-10-01 12:34';
+select str_to_date(NULL,'%Y-%m-%d %H:%i') = '2007-10-01 12:34';
+select str_to_date('2007-10-00 12:34','%Y-%m-%d %H:%i') = '';
+
+select str_to_date('1','%Y-%m-%d') = '1';
+select str_to_date('1','%Y-%m-%d') = '1';
+select str_to_date('','%Y-%m-%d') = '';
+
+# these three should work!
+select str_to_date('1000-01-01','%Y-%m-%d') between '0000-00-00' and NULL;
+select str_to_date('1000-01-01','%Y-%m-%d') between NULL and '2000-00-00';
+select str_to_date('1000-01-01','%Y-%m-%d') between NULL and NULL;
+
--echo End of 5.0 tests
#
diff --git a/sql-common/my_time.c b/sql-common/my_time.c
index a1a3e0b6c77..48d1b198dfc 100644
--- a/sql-common/my_time.c
+++ b/sql-common/my_time.c
@@ -54,24 +54,24 @@ uint calc_days_in_year(uint year)
366 : 365);
}
-/*
- Check datetime value for validity according to flags.
-
- SYNOPSIS
- check_date()
- ltime Date to check.
- not_zero_date ltime is not the zero date
- flags flags to check
- was_cut set to 2 if value was truncated.
- NOTE: This is not touched if value was not truncated
- NOTES
- Here we assume that year and month is ok !
+/**
+ @brief Check datetime value for validity according to flags.
+
+ @param[in] ltime Date to check.
+ @param[in] not_zero_date ltime is not the zero date
+ @param[in] flags flags to check
+ (see str_to_datetime() flags in my_time.h)
+ @param[out] was_cut set to 2 if value was invalid according to flags.
+ (Feb 29 in non-leap etc.) This remains unchanged
+ if value is not invalid.
+
+ @details Here we assume that year and month is ok!
If month is 0 we allow any date. (This only happens if we allow zero
date parts in str_to_datetime())
Disallow dates with zero year and non-zero month and/or day.
- RETURN
- 0 ok
+ @return
+ 0 OK
1 error
*/
@@ -117,9 +117,9 @@ my_bool check_date(const MYSQL_TIME *ltime, my_bool not_zero_date,
TIME_NO_ZERO_IN_DATE Don't allow partial dates
TIME_NO_ZERO_DATE Don't allow 0000-00-00 date
TIME_INVALID_DATES Allow 2000-02-31
- was_cut 0 Value ok
+ was_cut 0 Value OK
1 If value was cut during conversion
- 2 Date part was within ranges but date was wrong
+ 2 check_date(date,flags) considers date invalid
DESCRIPTION
At least the following formats are recogniced (based on number of digits)
@@ -1084,7 +1084,7 @@ int my_TIME_to_str(const MYSQL_TIME *l_time, char *to)
flags - flags to use in validating date, as in str_to_datetime()
was_cut 0 Value ok
1 If value was cut during conversion
- 2 Date part was within ranges but date was wrong
+ 2 check_date(date,flags) considers date invalid
DESCRIPTION
Convert a datetime value of formats YYMMDD, YYYYMMDD, YYMMDDHHMSS,
diff --git a/sql/item_cmpfunc.cc b/sql/item_cmpfunc.cc
index 04e0011f1a7..172302a9fe0 100644
--- a/sql/item_cmpfunc.cc
+++ b/sql/item_cmpfunc.cc
@@ -604,26 +604,26 @@ int Arg_comparator::set_compare_func(Item_bool_func2 *item, Item_result type)
}
-/*
- Convert date provided in a string to the int representation.
-
- SYNOPSIS
- get_date_from_str()
- thd Thread handle
- str a string to convert
- warn_type type of the timestamp for issuing the warning
- warn_name field name for issuing the warning
- error_arg [out] TRUE if string isn't a DATETIME or clipping occur
-
- DESCRIPTION
- Convert date provided in the string str to the int representation.
- if the string contains wrong date or doesn't contain it at all
- then the warning is issued and TRUE returned in the error_arg argument.
- The warn_type and the warn_name arguments are used as the name and the
- type of the field when issuing the warning.
-
- RETURN
- converted value.
+/**
+ @brief Convert date provided in a string to the int representation.
+
+ @param[in] thd thread handle
+ @param[in] str a string to convert
+ @param[in] warn_type type of the timestamp for issuing the warning
+ @param[in] warn_name field name for issuing the warning
+ @param[out] error_arg could not extract a DATE or DATETIME
+
+ @details Convert date provided in the string str to the int
+ representation. If the string contains wrong date or doesn't
+ contain it at all then a warning is issued. The warn_type and
+ the warn_name arguments are used as the name and the type of the
+ field when issuing the warning. If any input was discarded
+ (trailing or non-timestampy characters), was_cut will be non-zero.
+ was_type will return the type str_to_datetime() could correctly
+ extract.
+
+ @return
+ converted value. 0 on error and on zero-dates -- check 'failure'
*/
static ulonglong
@@ -634,26 +634,33 @@ get_date_from_str(THD *thd, String *str, timestamp_type warn_type,
int error;
MYSQL_TIME l_time;
enum_mysql_timestamp_type ret;
- *error_arg= TRUE;
ret= str_to_datetime(str->ptr(), str->length(), &l_time,
(TIME_FUZZY_DATE | MODE_INVALID_DATES |
(thd->variables.sql_mode &
(MODE_NO_ZERO_IN_DATE | MODE_NO_ZERO_DATE))),
&error);
- if ((ret == MYSQL_TIMESTAMP_DATETIME || ret == MYSQL_TIMESTAMP_DATE))
+
+ if (ret == MYSQL_TIMESTAMP_DATETIME || ret == MYSQL_TIMESTAMP_DATE)
{
- value= TIME_to_ulonglong_datetime(&l_time);
+ /*
+ Do not return yet, we may still want to throw a "trailing garbage"
+ warning.
+ */
*error_arg= FALSE;
+ value= TIME_to_ulonglong_datetime(&l_time);
}
-
- if (error || *error_arg)
+ else
{
+ *error_arg= TRUE;
+ error= 1; /* force warning */
+ }
+
+ if (error > 0)
make_truncated_value_warning(thd, MYSQL_ERROR::WARN_LEVEL_WARN,
str->ptr(), str->length(),
warn_type, warn_name);
- *error_arg= TRUE;
- }
+
return value;
}
@@ -954,6 +961,12 @@ get_datetime_value(THD *thd, Item ***item_arg, Item **cache_arg,
timestamp_type t_type= f_type ==
MYSQL_TYPE_DATE ? MYSQL_TIMESTAMP_DATE : MYSQL_TIMESTAMP_DATETIME;
value= get_date_from_str(thd, str, t_type, warn_item->name, &error);
+ /*
+ If str did not contain a valid date according to the current
+ SQL_MODE, get_date_from_str() has already thrown a warning,
+ and we don't want to throw NULL on invalid date (see 5.2.6
+ "SQL modes" in the manual), so we're done here.
+ */
}
/*
Do not cache GET_USER_VAR() function as its const_item() may return TRUE