From 970542ec90951c3e9d68ff310cdf181465854aaa Mon Sep 17 00:00:00 2001 From: Sergey Petrunya Date: Fri, 23 Aug 2013 16:32:56 +0400 Subject: [PATCH 1/3] MDEV-4836: Wrong result on IS NULL (old documented hack stopped working) - When applying optimization introduced by MDEV-4817, ignore the conditions that have form "datetime_not_null_col IS NULL". --- mysql-test/r/join_outer.result | 12 +++++ mysql-test/r/join_outer_jcl6.result | 12 +++++ mysql-test/t/join_outer.test | 9 ++++ sql/item_cmpfunc.cc | 27 ++++------ sql/sql_select.cc | 76 +++++++++++++++++++++++++++++ sql/sql_select.h | 1 + 6 files changed, 120 insertions(+), 17 deletions(-) diff --git a/mysql-test/r/join_outer.result b/mysql-test/r/join_outer.result index 170c6f3eb05..5926307bf1d 100644 --- a/mysql-test/r/join_outer.result +++ b/mysql-test/r/join_outer.result @@ -2138,4 +2138,16 @@ id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t0 ALL NULL NULL NULL NULL 10 Using where 1 SIMPLE t1 eq_ref PRIMARY PRIMARY 4 test.t0.a 1 Using index drop table t0, t1; +# +# MDEV-4836: Wrong result on IS NULL (old documented hack stopped working) +# (this is a regression after fix for MDEV-4817) +# +CREATE TABLE t1 (id INT, d DATE NOT NULL); +INSERT INTO t1 VALUES (1,'0000-00-00'),(2,'0000-00-00'); +CREATE TABLE t2 (i INT); +SELECT * FROM t1 LEFT JOIN t2 ON (id=i) WHERE NULL OR d IS NULL; +id d i +1 0000-00-00 NULL +2 0000-00-00 NULL +DROP TABLE t1,t2; SET optimizer_switch=@save_optimizer_switch; diff --git a/mysql-test/r/join_outer_jcl6.result b/mysql-test/r/join_outer_jcl6.result index 82805a883b3..874ca16c39c 100644 --- a/mysql-test/r/join_outer_jcl6.result +++ b/mysql-test/r/join_outer_jcl6.result @@ -2149,6 +2149,18 @@ id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t0 ALL NULL NULL NULL NULL 10 Using where 1 SIMPLE t1 eq_ref PRIMARY PRIMARY 4 test.t0.a 1 Using index drop table t0, t1; +# +# MDEV-4836: Wrong result on IS NULL (old documented hack stopped working) +# (this is a regression after fix for MDEV-4817) +# +CREATE TABLE t1 (id INT, d DATE NOT NULL); +INSERT INTO t1 VALUES (1,'0000-00-00'),(2,'0000-00-00'); +CREATE TABLE t2 (i INT); +SELECT * FROM t1 LEFT JOIN t2 ON (id=i) WHERE NULL OR d IS NULL; +id d i +1 0000-00-00 NULL +2 0000-00-00 NULL +DROP TABLE t1,t2; SET optimizer_switch=@save_optimizer_switch; set join_cache_level=default; show variables like 'join_cache_level'; diff --git a/mysql-test/t/join_outer.test b/mysql-test/t/join_outer.test index b0000b2b943..7b26c9670ac 100644 --- a/mysql-test/t/join_outer.test +++ b/mysql-test/t/join_outer.test @@ -1686,5 +1686,14 @@ explain select * from t1 left join t0 on t0.a=t1.pk where t0.person_id='fooo' or drop table t0, t1; +--echo # +--echo # MDEV-4836: Wrong result on IS NULL (old documented hack stopped working) +--echo # (this is a regression after fix for MDEV-4817) +--echo # +CREATE TABLE t1 (id INT, d DATE NOT NULL); +INSERT INTO t1 VALUES (1,'0000-00-00'),(2,'0000-00-00'); +CREATE TABLE t2 (i INT); +SELECT * FROM t1 LEFT JOIN t2 ON (id=i) WHERE NULL OR d IS NULL; +DROP TABLE t1,t2; SET optimizer_switch=@save_optimizer_switch; diff --git a/sql/item_cmpfunc.cc b/sql/item_cmpfunc.cc index 6f975541c55..15692b454fe 100644 --- a/sql/item_cmpfunc.cc +++ b/sql/item_cmpfunc.cc @@ -4302,7 +4302,8 @@ Item_cond::fix_fields(THD *thd, Item **ref) used_tables_cache|= item->used_tables(); if (item->const_item()) { - if (!item->is_expensive() && item->val_int() == 0) + if (!item->is_expensive() && !cond_is_datetime_is_null(item) && + item->val_int() == 0) { /* This is "... OR false_cond OR ..." @@ -4314,27 +4315,18 @@ Item_cond::fix_fields(THD *thd, Item **ref) /* This is "... OR const_cond OR ..." In this case, cond_or->not_null_tables()=0, because the condition - some_cond_or might be true regardless of what tables are - NULL-complemented. + const_cond might evaluate to true (regardless of whether some tables + were NULL-complemented). */ and_tables_cache= (table_map) 0; } } else { - /* - If an item is a - - constant - - inexpensive - - its value is 0 - then we don't need to account it in not_null_tables_cache - */ - //if (!(item->const_item() && !item->is_expensive() )) - { - table_map tmp_table_map= item->not_null_tables(); - not_null_tables_cache|= tmp_table_map; - and_tables_cache&= tmp_table_map; - } + table_map tmp_table_map= item->not_null_tables(); + not_null_tables_cache|= tmp_table_map; + and_tables_cache&= tmp_table_map; + const_item_cache= FALSE; } @@ -4363,7 +4355,8 @@ Item_cond::eval_not_null_tables(uchar *opt_arg) table_map tmp_table_map; if (item->const_item()) { - if (!item->is_expensive() && item->val_int() == 0) + if (!item->is_expensive() && !cond_is_datetime_is_null(item) && + item->val_int() == 0) { /* This is "... OR false_cond OR ..." diff --git a/sql/sql_select.cc b/sql/sql_select.cc index bdede4e831b..ba72b03c828 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -13523,6 +13523,35 @@ void propagate_new_equalities(THD *thd, Item *cond, } +/* + Check if passed condtition has for of + + not_null_date_col IS NULL + + where not_null_date_col has a datte or datetime type +*/ + +bool cond_is_datetime_is_null(Item *cond) +{ + if (cond->type() == Item::FUNC_ITEM && + ((Item_func*) cond)->functype() == Item_func::ISNULL_FUNC) + { + Item **args= ((Item_func_isnull*) cond)->arguments(); + if (args[0]->type() == Item::FIELD_ITEM) + { + Field *field=((Item_field*) args[0])->field; + + if (((field->type() == MYSQL_TYPE_DATE) || + (field->type() == MYSQL_TYPE_DATETIME)) && + (field->flags & NOT_NULL_FLAG)) + { + return TRUE; + } + } + } + return FALSE; +} + /** @brief @@ -13776,6 +13805,52 @@ internal_remove_eq_conds(THD *thd, COND *cond, Item::cond_result *cond_value) return item; } } + else if (cond_is_datetime_is_null(cond)) + { + /* fix to replace 'NULL' dates with '0' (shreeve@uci.edu) */ + /* + See BUG#12594011 + Documentation says that + SELECT datetime_notnull d FROM t1 WHERE d IS NULL + shall return rows where d=='0000-00-00' + + Thus, 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 outer join) + "date_notnull == 0" (otherwise) + + */ + Item **args= ((Item_func_isnull*) cond)->arguments(); + Field *field=((Item_field*) args[0])->field; + + Item *item0= new(thd->mem_root) Item_int((longlong)0, 1); + Item *eq_cond= new(thd->mem_root) Item_func_eq(args[0], item0); + if (!eq_cond) + return cond; + + if (field->table->pos_in_table_list->outer_join) + { + // outer join: transform "col IS NULL" to "col IS NULL or col=0" + Item *or_cond= new(thd->mem_root) Item_cond_or(eq_cond, cond); + if (!or_cond) + return cond; + cond= or_cond; + } + else + { + // not outer join: transform "col IS NULL" to "col=0" + cond= eq_cond; + } + + cond->fix_fields(thd, &cond); + + if (cond->const_item() && !cond->is_expensive()) + { + *cond_value= eval_const_cond(cond) ? Item::COND_TRUE : Item::COND_FALSE; + return (COND*) 0; + } + } +#if 0 else if (cond->type() == Item::FUNC_ITEM && ((Item_func*) cond)->functype() == Item_func::ISNULL_FUNC) { @@ -13829,6 +13904,7 @@ internal_remove_eq_conds(THD *thd, COND *cond, Item::cond_result *cond_value) return (COND*) 0; } } +#endif else if (cond->const_item() && !cond->is_expensive()) { *cond_value= eval_const_cond(cond) ? Item::COND_TRUE : Item::COND_FALSE; diff --git a/sql/sql_select.h b/sql/sql_select.h index 478eede7108..fd12cfae335 100644 --- a/sql/sql_select.h +++ b/sql/sql_select.h @@ -1795,6 +1795,7 @@ ORDER *simple_remove_const(ORDER *order, COND *where); bool const_expression_in_where(COND *cond, Item *comp_item, Field *comp_field= NULL, Item **const_item= NULL); +bool cond_is_datetime_is_null(Item *cond); /* Table elimination entry point function */ void eliminate_tables(JOIN *join); From edd980225a9895f46754d54677bd76327152c78b Mon Sep 17 00:00:00 2001 From: Sergey Petrunya Date: Mon, 26 Aug 2013 21:38:04 +0400 Subject: [PATCH 2/3] Fix for MDEV-4836 fix: take into account situation where "notnull_col IS NULL" is not a direct child of the WHERE clause item, but rather is embedded inside Item_cond_and or Item_cond_or. --- mysql-test/r/join_outer.result | 8 ++++++++ mysql-test/r/join_outer_jcl6.result | 8 ++++++++ mysql-test/t/join_outer.test | 11 +++++++++++ sql/item_cmpfunc.cc | 4 ++-- sql/sql_select.cc | 22 ++++++++++++++++++++++ sql/sql_select.h | 1 + 6 files changed, 52 insertions(+), 2 deletions(-) diff --git a/mysql-test/r/join_outer.result b/mysql-test/r/join_outer.result index 3cfe2b20a1a..d77f3df1cdf 100644 --- a/mysql-test/r/join_outer.result +++ b/mysql-test/r/join_outer.result @@ -2150,6 +2150,14 @@ id d i 1 0000-00-00 NULL 2 0000-00-00 NULL DROP TABLE t1,t2; +CREATE TABLE t1 (i1 INT, d1 DATE NOT NULL); +INSERT INTO t1 VALUES (1,'2012-12-21'),(2,'0000-00-00'); +CREATE TABLE t2 (i2 INT, j2 INT); +INSERT INTO t2 VALUES (1,10),(2,20); +SELECT * FROM t1 LEFT JOIN t2 ON i1 = j2 WHERE d1 IS NULL AND 1 OR i1 = i2; +i1 d1 i2 j2 +2 0000-00-00 NULL NULL +DROP TABLE t1,t2; # # Bug mdev-4942: LEFT JOIN with conjunctive # IS NULL in WHERE diff --git a/mysql-test/r/join_outer_jcl6.result b/mysql-test/r/join_outer_jcl6.result index 5c20a87f10c..59760470176 100644 --- a/mysql-test/r/join_outer_jcl6.result +++ b/mysql-test/r/join_outer_jcl6.result @@ -2161,6 +2161,14 @@ id d i 1 0000-00-00 NULL 2 0000-00-00 NULL DROP TABLE t1,t2; +CREATE TABLE t1 (i1 INT, d1 DATE NOT NULL); +INSERT INTO t1 VALUES (1,'2012-12-21'),(2,'0000-00-00'); +CREATE TABLE t2 (i2 INT, j2 INT); +INSERT INTO t2 VALUES (1,10),(2,20); +SELECT * FROM t1 LEFT JOIN t2 ON i1 = j2 WHERE d1 IS NULL AND 1 OR i1 = i2; +i1 d1 i2 j2 +2 0000-00-00 NULL NULL +DROP TABLE t1,t2; # # Bug mdev-4942: LEFT JOIN with conjunctive # IS NULL in WHERE diff --git a/mysql-test/t/join_outer.test b/mysql-test/t/join_outer.test index 0ef1ea593a2..f85feb70ccb 100644 --- a/mysql-test/t/join_outer.test +++ b/mysql-test/t/join_outer.test @@ -1696,6 +1696,17 @@ CREATE TABLE t2 (i INT); SELECT * FROM t1 LEFT JOIN t2 ON (id=i) WHERE NULL OR d IS NULL; DROP TABLE t1,t2; + +CREATE TABLE t1 (i1 INT, d1 DATE NOT NULL); +INSERT INTO t1 VALUES (1,'2012-12-21'),(2,'0000-00-00'); + +CREATE TABLE t2 (i2 INT, j2 INT); +INSERT INTO t2 VALUES (1,10),(2,20); + +SELECT * FROM t1 LEFT JOIN t2 ON i1 = j2 WHERE d1 IS NULL AND 1 OR i1 = i2; +DROP TABLE t1,t2; + + --echo # --echo # Bug mdev-4942: LEFT JOIN with conjunctive --echo # IS NULL in WHERE diff --git a/sql/item_cmpfunc.cc b/sql/item_cmpfunc.cc index 6f181c39b67..cd1881e2970 100644 --- a/sql/item_cmpfunc.cc +++ b/sql/item_cmpfunc.cc @@ -4302,7 +4302,7 @@ Item_cond::fix_fields(THD *thd, Item **ref) used_tables_cache|= item->used_tables(); if (item->const_item()) { - if (!item->is_expensive() && !cond_is_datetime_is_null(item) && + if (!item->is_expensive() && !cond_has_datetime_is_null(item) && item->val_int() == 0) { /* @@ -4355,7 +4355,7 @@ Item_cond::eval_not_null_tables(uchar *opt_arg) table_map tmp_table_map; if (item->const_item()) { - if (!item->is_expensive() && !cond_is_datetime_is_null(item) && + if (!item->is_expensive() && !cond_has_datetime_is_null(item) && item->val_int() == 0) { /* diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 51ce9bccf6c..ba0b41fc5df 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -13526,6 +13526,28 @@ void propagate_new_equalities(THD *thd, Item *cond, } } +/* + Check if cond_is_datetime_is_null() is true for the condition cond, or + for any of its AND/OR-children +*/ +bool cond_has_datetime_is_null(Item *cond) +{ + if (cond_is_datetime_is_null(cond)) + return true; + + if (cond->type() == Item::COND_ITEM) + { + List *cond_arg_list= ((Item_cond*) cond)->argument_list(); + List_iterator li(*cond_arg_list); + Item *item; + while ((item= li++)) + { + if (cond_has_datetime_is_null(item)) + return true; + } + } + return false; +} /* Check if passed condtition has for of diff --git a/sql/sql_select.h b/sql/sql_select.h index fd12cfae335..b4709f85560 100644 --- a/sql/sql_select.h +++ b/sql/sql_select.h @@ -1796,6 +1796,7 @@ bool const_expression_in_where(COND *cond, Item *comp_item, Field *comp_field= NULL, Item **const_item= NULL); bool cond_is_datetime_is_null(Item *cond); +bool cond_has_datetime_is_null(Item *cond); /* Table elimination entry point function */ void eliminate_tables(JOIN *join); From d6f7649d3c7f2e055a77ef9432c245928675ef4c Mon Sep 17 00:00:00 2001 From: Sergey Petrunya Date: Wed, 28 Aug 2013 21:21:12 +0400 Subject: [PATCH 3/3] mdev-4942: Add another testcase after merging with other fixes. --- mysql-test/r/join_outer.result | 12 ++++++++++++ mysql-test/r/join_outer_jcl6.result | 12 ++++++++++++ mysql-test/t/join_outer.test | 13 +++++++++++++ 3 files changed, 37 insertions(+) diff --git a/mysql-test/r/join_outer.result b/mysql-test/r/join_outer.result index cc0d7572a92..b193bf057eb 100644 --- a/mysql-test/r/join_outer.result +++ b/mysql-test/r/join_outer.result @@ -2158,6 +2158,18 @@ SELECT * FROM t1 LEFT JOIN t2 ON i1 = j2 WHERE d1 IS NULL AND 1 OR i1 = i2; i1 d1 i2 j2 2 0000-00-00 NULL NULL DROP TABLE t1,t2; +# Another testcase +CREATE TABLE t1 (i1 INT) ENGINE=MyISAM; +INSERT INTO t1 VALUES (NULL); +CREATE TABLE t2 (i2 INT, a INT, b INT) ENGINE=MyISAM; +CREATE ALGORITHM=TEMPTABLE VIEW v2 AS SELECT * FROM t2; +INSERT INTO t2 VALUES (NULL,1,2),(NULL,2,3); +SELECT * FROM t1 LEFT JOIN v2 ON i1 = i2 WHERE a < b; +i1 i2 a b +SELECT * FROM t1 LEFT JOIN t2 ON i1 = i2 WHERE a < b; +i1 i2 a b +drop view v2; +drop table t1,t2; # # Bug mdev-4942: LEFT JOIN with conjunctive # IS NULL in WHERE diff --git a/mysql-test/r/join_outer_jcl6.result b/mysql-test/r/join_outer_jcl6.result index 6c9a0237f35..313ea67c156 100644 --- a/mysql-test/r/join_outer_jcl6.result +++ b/mysql-test/r/join_outer_jcl6.result @@ -2169,6 +2169,18 @@ SELECT * FROM t1 LEFT JOIN t2 ON i1 = j2 WHERE d1 IS NULL AND 1 OR i1 = i2; i1 d1 i2 j2 2 0000-00-00 NULL NULL DROP TABLE t1,t2; +# Another testcase +CREATE TABLE t1 (i1 INT) ENGINE=MyISAM; +INSERT INTO t1 VALUES (NULL); +CREATE TABLE t2 (i2 INT, a INT, b INT) ENGINE=MyISAM; +CREATE ALGORITHM=TEMPTABLE VIEW v2 AS SELECT * FROM t2; +INSERT INTO t2 VALUES (NULL,1,2),(NULL,2,3); +SELECT * FROM t1 LEFT JOIN v2 ON i1 = i2 WHERE a < b; +i1 i2 a b +SELECT * FROM t1 LEFT JOIN t2 ON i1 = i2 WHERE a < b; +i1 i2 a b +drop view v2; +drop table t1,t2; # # Bug mdev-4942: LEFT JOIN with conjunctive # IS NULL in WHERE diff --git a/mysql-test/t/join_outer.test b/mysql-test/t/join_outer.test index 765118d4775..7452e81ca23 100644 --- a/mysql-test/t/join_outer.test +++ b/mysql-test/t/join_outer.test @@ -1706,6 +1706,19 @@ INSERT INTO t2 VALUES (1,10),(2,20); SELECT * FROM t1 LEFT JOIN t2 ON i1 = j2 WHERE d1 IS NULL AND 1 OR i1 = i2; DROP TABLE t1,t2; +--echo # Another testcase +CREATE TABLE t1 (i1 INT) ENGINE=MyISAM; +INSERT INTO t1 VALUES (NULL); + +CREATE TABLE t2 (i2 INT, a INT, b INT) ENGINE=MyISAM; +CREATE ALGORITHM=TEMPTABLE VIEW v2 AS SELECT * FROM t2; + +INSERT INTO t2 VALUES (NULL,1,2),(NULL,2,3); +SELECT * FROM t1 LEFT JOIN v2 ON i1 = i2 WHERE a < b; +SELECT * FROM t1 LEFT JOIN t2 ON i1 = i2 WHERE a < b; + +drop view v2; +drop table t1,t2; --echo # --echo # Bug mdev-4942: LEFT JOIN with conjunctive