You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
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.
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`))
0 commit comments