Skip to content

Commit 6267be4

Browse files
committed
Fixed mdev-14911: zero_date is considered as NULL, depending on
optimizer_switch For DATE and DATETIME columns defined as NOT NULL, "date_notnull IS NULL" has to be modified to: "date_notnull IS NULL OR date_notnull == 0" if date_notnull is from an inner table of outer join); "date_notnull == 0" - otherwise. This must hold for such columns of mergeable views and derived tables as well. So far the code did the above re-writing only for columns of base tables and temporary tables.
1 parent d800110 commit 6267be4

File tree

3 files changed

+135
-5
lines changed

3 files changed

+135
-5
lines changed

mysql-test/r/func_isnull.result

Lines changed: 84 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -24,3 +24,87 @@ INSERT INTO t1( id ) VALUES ( NULL );
2424
SELECT t1.id FROM t1 WHERE (id is not null and id is null );
2525
id
2626
DROP TABLE t1;
27+
# End of 5.1 tests
28+
#
29+
# MDEV-14911: IS NULL for field from mergeable view
30+
#
31+
CREATE TABLE t1 (d1 datetime NOT NULL);
32+
INSERT INTO t1 VALUES
33+
('0000-00-00 00:00:00'), ('0000-00-00 00:00:00'), ('1979-09-03 20:49:36');
34+
SELECT * FROM t1;
35+
d1
36+
0000-00-00 00:00:00
37+
0000-00-00 00:00:00
38+
1979-09-03 20:49:36
39+
SELECT * FROM t1 WHERE d1 IS NULL;
40+
d1
41+
0000-00-00 00:00:00
42+
0000-00-00 00:00:00
43+
EXPLAIN EXTENDED SELECT * FROM t1 WHERE d1 IS NULL;
44+
id select_type table type possible_keys key key_len ref rows filtered Extra
45+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 Using where
46+
Warnings:
47+
Note 1003 select `test`.`t1`.`d1` AS `d1` from `test`.`t1` where (`test`.`t1`.`d1` = 0)
48+
SELECT count(*) FROM t1 WHERE d1 IS NULL;
49+
count(*)
50+
2
51+
CREATE VIEW v1 AS (SELECT * FROM t1);
52+
SELECT * FROM v1;
53+
d1
54+
0000-00-00 00:00:00
55+
0000-00-00 00:00:00
56+
1979-09-03 20:49:36
57+
SELECT * FROM v1 WHERE d1 IS NULL;
58+
d1
59+
0000-00-00 00:00:00
60+
0000-00-00 00:00:00
61+
EXPLAIN EXTENDED SELECT * FROM v1 WHERE d1 IS NULL;
62+
id select_type table type possible_keys key key_len ref rows filtered Extra
63+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 Using where
64+
Warnings:
65+
Note 1003 select `test`.`t1`.`d1` AS `d1` from `test`.`t1` where (`test`.`t1`.`d1` = 0)
66+
SELECT count(*) FROM v1 WHERE d1 IS NULL;
67+
count(*)
68+
2
69+
SET @save_optimizer_switch=@@optimizer_switch;
70+
SET SESSION optimizer_switch='derived_merge=off';
71+
SELECT count(*) FROM ( SELECT * FROM t1 ) AS a1 WHERE d1 IS NULL;
72+
count(*)
73+
2
74+
SET SESSION optimizer_switch='derived_merge=on';
75+
SELECT count(*) FROM ( SELECT * FROM t1 ) AS a1 WHERE d1 IS NULL;
76+
count(*)
77+
2
78+
SET optimizer_switch=@save_optimizer_switch;
79+
CREATE TABLE t2 (d1 datetime NOT NULL);
80+
INSERT INTO t2 VALUES
81+
('1980-09-03 20:49:36'), ('0000-00-00 00:00:00'), ('1979-09-03 20:49:36');
82+
SELECT * FROM t2 LEFT JOIN t1 ON t2.d1=t1.d1 WHERE t1.d1 IS NULL;
83+
d1 d1
84+
0000-00-00 00:00:00 0000-00-00 00:00:00
85+
0000-00-00 00:00:00 0000-00-00 00:00:00
86+
1980-09-03 20:49:36 NULL
87+
EXPLAIN EXTENDED
88+
SELECT * FROM t2 LEFT JOIN t1 ON t2.d1=t1.d1 WHERE t1.d1 IS NULL;
89+
id select_type table type possible_keys key key_len ref rows filtered Extra
90+
1 SIMPLE t2 ALL NULL NULL NULL NULL 3 100.00
91+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (flat, BNL join)
92+
Warnings:
93+
Note 1003 select `test`.`t2`.`d1` AS `d1`,`test`.`t1`.`d1` AS `d1` from `test`.`t2` left join `test`.`t1` on((`test`.`t1`.`d1` = `test`.`t2`.`d1`)) where ((`test`.`t1`.`d1` = 0) or isnull(`test`.`t1`.`d1`))
94+
SELECT * FROM t2 LEFT JOIN v1 ON t2.d1=v1.d1 WHERE v1.d1 IS NULL;
95+
d1 d1
96+
0000-00-00 00:00:00 0000-00-00 00:00:00
97+
0000-00-00 00:00:00 0000-00-00 00:00:00
98+
1980-09-03 20:49:36 NULL
99+
EXPLAIN EXTENDED
100+
SELECT * FROM t2 LEFT JOIN v1 ON t2.d1=v1.d1 WHERE v1.d1 IS NULL;
101+
id select_type table type possible_keys key key_len ref rows filtered Extra
102+
1 SIMPLE t2 ALL NULL NULL NULL NULL 3 100.00
103+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 Using where; Using join buffer (flat, BNL join)
104+
Warnings:
105+
Note 1003 select `test`.`t2`.`d1` AS `d1`,`test`.`t1`.`d1` AS `d1` from `test`.`t2` left join (`test`.`t1`) on((`test`.`t1`.`d1` = `test`.`t2`.`d1`)) where ((`test`.`t1`.`d1` = 0) or isnull(`test`.`t1`.`d1`))
106+
DROP VIEW v1;
107+
DROP TABLE t1,t2;
108+
#
109+
# End of 5.5 tests
110+
#

mysql-test/t/func_isnull.test

Lines changed: 47 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -38,5 +38,51 @@ INSERT INTO t1( id ) VALUES ( NULL );
3838
SELECT t1.id FROM t1 WHERE (id is not null and id is null );
3939
DROP TABLE t1;
4040

41-
# End of 5.1 tests
41+
--echo # End of 5.1 tests
4242

43+
--echo #
44+
--echo # MDEV-14911: IS NULL for field from mergeable view
45+
--echo #
46+
47+
CREATE TABLE t1 (d1 datetime NOT NULL);
48+
INSERT INTO t1 VALUES
49+
('0000-00-00 00:00:00'), ('0000-00-00 00:00:00'), ('1979-09-03 20:49:36');
50+
51+
SELECT * FROM t1;
52+
SELECT * FROM t1 WHERE d1 IS NULL;
53+
EXPLAIN EXTENDED SELECT * FROM t1 WHERE d1 IS NULL;
54+
SELECT count(*) FROM t1 WHERE d1 IS NULL;
55+
56+
CREATE VIEW v1 AS (SELECT * FROM t1);
57+
SELECT * FROM v1;
58+
SELECT * FROM v1 WHERE d1 IS NULL;
59+
EXPLAIN EXTENDED SELECT * FROM v1 WHERE d1 IS NULL;
60+
SELECT count(*) FROM v1 WHERE d1 IS NULL;
61+
62+
SET @save_optimizer_switch=@@optimizer_switch;
63+
64+
SET SESSION optimizer_switch='derived_merge=off';
65+
SELECT count(*) FROM ( SELECT * FROM t1 ) AS a1 WHERE d1 IS NULL;
66+
SET SESSION optimizer_switch='derived_merge=on';
67+
SELECT count(*) FROM ( SELECT * FROM t1 ) AS a1 WHERE d1 IS NULL;
68+
69+
SET optimizer_switch=@save_optimizer_switch;
70+
71+
CREATE TABLE t2 (d1 datetime NOT NULL);
72+
INSERT INTO t2 VALUES
73+
('1980-09-03 20:49:36'), ('0000-00-00 00:00:00'), ('1979-09-03 20:49:36');
74+
75+
SELECT * FROM t2 LEFT JOIN t1 ON t2.d1=t1.d1 WHERE t1.d1 IS NULL;
76+
EXPLAIN EXTENDED
77+
SELECT * FROM t2 LEFT JOIN t1 ON t2.d1=t1.d1 WHERE t1.d1 IS NULL;
78+
79+
SELECT * FROM t2 LEFT JOIN v1 ON t2.d1=v1.d1 WHERE v1.d1 IS NULL;
80+
EXPLAIN EXTENDED
81+
SELECT * FROM t2 LEFT JOIN v1 ON t2.d1=v1.d1 WHERE v1.d1 IS NULL;
82+
83+
DROP VIEW v1;
84+
DROP TABLE t1,t2;
85+
86+
--echo #
87+
--echo # End of 5.5 tests
88+
--echo #

sql/sql_select.cc

Lines changed: 4 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -13980,9 +13980,9 @@ bool cond_is_datetime_is_null(Item *cond)
1398013980
((Item_func*) cond)->functype() == Item_func::ISNULL_FUNC)
1398113981
{
1398213982
Item **args= ((Item_func_isnull*) cond)->arguments();
13983-
if (args[0]->type() == Item::FIELD_ITEM)
13983+
if (args[0]->real_item()->type() == Item::FIELD_ITEM)
1398413984
{
13985-
Field *field=((Item_field*) args[0])->field;
13985+
Field *field=((Item_field*) (args[0]->real_item()))->field;
1398613986

1398713987
if (((field->type() == MYSQL_TYPE_DATE) ||
1398813988
(field->type() == MYSQL_TYPE_DATETIME)) &&
@@ -14308,14 +14308,14 @@ internal_remove_eq_conds(THD *thd, COND *cond, Item::cond_result *cond_value)
1430814308

1430914309
*/
1431014310
Item **args= ((Item_func_isnull*) cond)->arguments();
14311-
Field *field=((Item_field*) args[0])->field;
14311+
Field *field=((Item_field*) (args[0]->real_item()))->field;
1431214312

1431314313
Item *item0= new(thd->mem_root) Item_int((longlong)0, 1);
1431414314
Item *eq_cond= new(thd->mem_root) Item_func_eq(args[0], item0);
1431514315
if (!eq_cond)
1431614316
return cond;
1431714317

14318-
if (field->table->pos_in_table_list->is_inner_table_of_outer_join())
14318+
if (field->table->pos_in_table_list->is_inner_table_of_outer_join())
1431914319
{
1432014320
// outer join: transform "col IS NULL" to "col IS NULL or col=0"
1432114321
Item *or_cond= new(thd->mem_root) Item_cond_or(eq_cond, cond);

0 commit comments

Comments
 (0)