Skip to content

Commit

Permalink
MDEV-13358: FIRST_V throw SQL Fehler (1292): Incorrect datetime value
Browse files Browse the repository at this point in the history
This is backport of 25ad623 for 10.2.

The issue is similar to the one from MDEV-13240. Item::save_in_field()
returns an error during tmp table population in a create table from select query
as we try to save an empty string as a date value when
force_return_blank is set to true for window functions.

    MDEV-13240 Wrong warning with MAX(datetime_field) OVER (...)

    The problem resided in Item_window_func implementation,
    and it was revealed by bb-10.2-ext specific changes:

    Item_window_func::save_in_field() works differently in bb-10.2-ext vs 10.2:

    - 10.2 goes through val_str()
    - bb-10.2-ext goes through get_date(), due to Type_handler related changes.
      get_date() tries to convert empty string to DATETIME, hence the warning.

    During a discussion with Vicentiu, it was decided to fix
    Item_window_func::val_xxx() to return NULL
    (instead of an "empty" value, such as 0 for numbers and '' for strings)
    when force_return_blank is set.
  • Loading branch information
cvicentiu committed Sep 19, 2017
1 parent 5b9c32e commit 02eda36
Show file tree
Hide file tree
Showing 5 changed files with 72 additions and 17 deletions.
29 changes: 29 additions & 0 deletions mysql-test/r/win.result
Original file line number Diff line number Diff line change
Expand Up @@ -3185,3 +3185,32 @@ fld
1
2
DROP TABLE t1;
#
# MDEV-13240 Wrong warning with MAX(datetime_field) OVER (...)
#
CREATE TABLE t1 (dt DATETIME);
INSERT INTO t1 VALUES ('2017-05-17');
SELECT MAX(dt) OVER (ORDER BY dt ROWS BETWEEN 1 FOLLOWING AND 1 FOLLOWING) FROM t1;
MAX(dt) OVER (ORDER BY dt ROWS BETWEEN 1 FOLLOWING AND 1 FOLLOWING)
NULL
DROP TABLE t1;
#
# MDEV-13358 FIRST_VALUE throws SQL Error (1292): Incorrect datetime value
#
CREATE TABLE IF NOT EXISTS `fv_test` (
`SOME_DATE` datetime NOT NULL
);
INSERT INTO `fv_test` (`SOME_DATE`) VALUES ('2017-07-20 12:47:56');
CREATE TABLE fv_result
SELECT
FIRST_VALUE(SOME_DATE) OVER(ORDER BY SOME_DATE DESC) AS somedate
FROM fv_test;
SHOW CREATE TABLE fv_result;
Table Create Table
fv_result CREATE TABLE `fv_result` (
`somedate` datetime DEFAULT NULL
) ENGINE=MyISAM DEFAULT CHARSET=latin1
SELECT * FROM fv_result;
somedate
2017-07-20 12:47:56
DROP TABLE fv_test, fv_result;
10 changes: 5 additions & 5 deletions mysql-test/r/win_insert_select.result
Original file line number Diff line number Diff line change
@@ -1,16 +1,16 @@
CREATE TABLE t1 (c1 INT, c2 VARCHAR(30));
PREPARE populate_table FROM "INSERT into t1 values (1, 'manual_insert_1'),
(4, 'manual_insert_2')";
INSERT INTO t1 SELECT row_number() over(), "should_have_0" FROM t1;
INSERT INTO t1 SELECT 1 + row_number() over(), "should_have_2" FROM t1;
INSERT INTO t1 SELECT row_number() over(), "should_not_add_any_rows" FROM t1;
INSERT INTO t1 SELECT 1 + row_number() over(), "should_not_add_any_rows" FROM t1;
EXECUTE populate_table;
INSERT INTO t1 SELECT 10 + row_number() over(), "should repeat 4 times [11-14]" FROM t1;
INSERT INTO t1 SELECT 10 + row_number() over(), "should repeat 2 times [11-12]" FROM t1;
SELECT c1, c2 FROM t1 ORDER BY c2, c1;
c1 c2
1 manual_insert_1
4 manual_insert_2
11 should repeat 4 times [11-14]
12 should repeat 4 times [11-14]
11 should repeat 2 times [11-12]
12 should repeat 2 times [11-12]
DELETE FROM t1;
EXECUTE populate_table;
INSERT INTO t1
Expand Down
28 changes: 28 additions & 0 deletions mysql-test/t/win.test
Original file line number Diff line number Diff line change
Expand Up @@ -1965,3 +1965,31 @@ INSERT INTO t1 VALUES (1),(2);
SELECT i AS fld FROM t1 UNION SELECT COUNT(*) AS fld FROM t1;
DROP TABLE t1;

--echo #
--echo # MDEV-13240 Wrong warning with MAX(datetime_field) OVER (...)
--echo #

CREATE TABLE t1 (dt DATETIME);
INSERT INTO t1 VALUES ('2017-05-17');
SELECT MAX(dt) OVER (ORDER BY dt ROWS BETWEEN 1 FOLLOWING AND 1 FOLLOWING) FROM t1;
DROP TABLE t1;

--echo #
--echo # MDEV-13358 FIRST_VALUE throws SQL Error (1292): Incorrect datetime value
--echo #
CREATE TABLE IF NOT EXISTS `fv_test` (
`SOME_DATE` datetime NOT NULL
);

INSERT INTO `fv_test` (`SOME_DATE`) VALUES ('2017-07-20 12:47:56');

CREATE TABLE fv_result
SELECT
FIRST_VALUE(SOME_DATE) OVER(ORDER BY SOME_DATE DESC) AS somedate
FROM fv_test;

SHOW CREATE TABLE fv_result;

SELECT * FROM fv_result;

DROP TABLE fv_test, fv_result;
6 changes: 3 additions & 3 deletions mysql-test/t/win_insert_select.test
Original file line number Diff line number Diff line change
Expand Up @@ -3,12 +3,12 @@ CREATE TABLE t1 (c1 INT, c2 VARCHAR(30));
PREPARE populate_table FROM "INSERT into t1 values (1, 'manual_insert_1'),
(4, 'manual_insert_2')";

INSERT INTO t1 SELECT row_number() over(), "should_have_0" FROM t1;
INSERT INTO t1 SELECT 1 + row_number() over(), "should_have_2" FROM t1;
INSERT INTO t1 SELECT row_number() over(), "should_not_add_any_rows" FROM t1;
INSERT INTO t1 SELECT 1 + row_number() over(), "should_not_add_any_rows" FROM t1;

EXECUTE populate_table;

INSERT INTO t1 SELECT 10 + row_number() over(), "should repeat 4 times [11-14]" FROM t1;
INSERT INTO t1 SELECT 10 + row_number() over(), "should repeat 2 times [11-12]" FROM t1;

SELECT c1, c2 FROM t1 ORDER BY c2, c1;

Expand Down
16 changes: 7 additions & 9 deletions sql/item_windowfunc.h
Original file line number Diff line number Diff line change
Expand Up @@ -851,7 +851,7 @@ class Item_window_func : public Item_func_or_sum
bool is_null()
{
if (force_return_blank)
return false;
return true;

if (read_value_from_result_field)
return result_field->is_null();
Expand All @@ -865,7 +865,7 @@ class Item_window_func : public Item_func_or_sum
if (force_return_blank)
{
res= 0.0;
null_value= false;
null_value= true;
}
else if (read_value_from_result_field)
{
Expand All @@ -886,7 +886,7 @@ class Item_window_func : public Item_func_or_sum
if (force_return_blank)
{
res= 0;
null_value= false;
null_value= true;
}
else if (read_value_from_result_field)
{
Expand All @@ -906,9 +906,8 @@ class Item_window_func : public Item_func_or_sum
String *res;
if (force_return_blank)
{
null_value= false;
str->length(0);
res= str;
null_value= true;
res= NULL;
}
else if (read_value_from_result_field)
{
Expand All @@ -930,9 +929,8 @@ class Item_window_func : public Item_func_or_sum
my_decimal *res;
if (force_return_blank)
{
my_decimal_set_zero(dec);
null_value= false;
res= dec;
null_value= true;
res= NULL;
}
else if (read_value_from_result_field)
{
Expand Down

0 comments on commit 02eda36

Please sign in to comment.