Skip to content

Commit

Permalink
MDEV-11958: LEFT JOIN with stored routine produces incorrect result
Browse files Browse the repository at this point in the history
Added forgoten method of Item_func_sp to make it correctly work with LEFT/RIGHT JOIN.
Fixed inconsistency with the null table caches.
  • Loading branch information
sanja-byelkin committed May 23, 2017
1 parent 7d57ba6 commit b8405c8
Show file tree
Hide file tree
Showing 4 changed files with 297 additions and 4 deletions.
95 changes: 95 additions & 0 deletions mysql-test/r/join_outer.result
Original file line number Diff line number Diff line change
Expand Up @@ -2245,4 +2245,99 @@ SELECT * FROM t1 INNER JOIN t2 ON c = b LEFT JOIN t3 ON d = a
WHERE b IN (1,2,3) OR b = d;
a b c d
DROP TABLE t1,t2,t3;
#
# MDEV-11958: LEFT JOIN with stored routine produces incorrect result
#
CREATE TABLE t (x INT);
INSERT INTO t VALUES(1),(NULL);
CREATE FUNCTION f (val INT, ret INT) RETURNS INT DETERMINISTIC RETURN IFNULL(val, ret);
SELECT t1.x, t2.x, IFNULL(t2.x,0), f(t2.x,0)
FROM t t1 LEFT JOIN t t2
ON t1.x = t2.x
WHERE IFNULL(t2.x,0)=0;
x x IFNULL(t2.x,0) f(t2.x,0)
NULL NULL 0 0
explain extended
SELECT t1.x, t2.x, IFNULL(t2.x,0), f(t2.x,0)
FROM t t1 LEFT JOIN t t2
ON t1.x = t2.x
WHERE IFNULL(t2.x,0)=0;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00
1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 Using where
Warnings:
Note 1003 select `test`.`t1`.`x` AS `x`,`test`.`t2`.`x` AS `x`,ifnull(`test`.`t2`.`x`,0) AS `IFNULL(t2.x,0)`,`f`(`test`.`t2`.`x`,0) AS `f(t2.x,0)` from `test`.`t` `t1` left join `test`.`t` `t2` on((`test`.`t2`.`x` = `test`.`t1`.`x`)) where (ifnull(`test`.`t2`.`x`,0) = 0)
SELECT t1.x, t2.x, IFNULL(t2.x,0), f(t2.x,0)
FROM t t1 LEFT JOIN t t2
ON t1.x = t2.x
WHERE f(t2.x,0)=0;
x x IFNULL(t2.x,0) f(t2.x,0)
NULL NULL 0 0
explain extended
SELECT t1.x, t2.x, IFNULL(t2.x,0), f(t2.x,0)
FROM t t1 LEFT JOIN t t2
ON t1.x = t2.x
WHERE f(t2.x,0)=0;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00
1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 Using where
Warnings:
Note 1003 select `test`.`t1`.`x` AS `x`,`test`.`t2`.`x` AS `x`,ifnull(`test`.`t2`.`x`,0) AS `IFNULL(t2.x,0)`,`f`(`test`.`t2`.`x`,0) AS `f(t2.x,0)` from `test`.`t` `t1` left join `test`.`t` `t2` on((`test`.`t2`.`x` = `test`.`t1`.`x`)) where (`f`(`test`.`t2`.`x`,0) = 0)
drop function f;
drop table t;
CREATE TABLE t1 (
col1 DECIMAL(33,5) NULL DEFAULT NULL,
col2 DECIMAL(33,5) NULL DEFAULT NULL
);
CREATE TABLE t2 (
col1 DECIMAL(33,5) NULL DEFAULT NULL,
col2 DECIMAL(33,5) NULL DEFAULT NULL,
col3 DECIMAL(33,5) NULL DEFAULT NULL
);
INSERT INTO t1 VALUES (2, 1.1), (2, 2.1);
INSERT INTO t2 VALUES (3, 3.1, 4), (1, 1, NULL);
CREATE FUNCTION f1 ( p_num DECIMAL(45,15), p_return DECIMAL(45,15))
RETURNS decimal(33,5)
LANGUAGE SQL
DETERMINISTIC
CONTAINS SQL
SQL SECURITY INVOKER
BEGIN
IF p_num IS NULL THEN
RETURN p_return;
ELSE
RETURN p_num;
END IF;
END |
SELECT t1.col1, t2.col1, t2.col3
FROM t1 LEFT OUTER JOIN t2 ON t1.col1 = t2.col2
WHERE IFNULL(t2.col3,0) = 0;
col1 col1 col3
2.00000 NULL NULL
2.00000 NULL NULL
EXPLAIN EXTENDED SELECT t1.col1, t2.col1, t2.col3
FROM t1 LEFT OUTER JOIN t2 ON t1.col1 = t2.col2
WHERE IFNULL(t2.col3,0) = 0;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00
1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 Using where
Warnings:
Note 1003 select `test`.`t1`.`col1` AS `col1`,`test`.`t2`.`col1` AS `col1`,`test`.`t2`.`col3` AS `col3` from `test`.`t1` left join `test`.`t2` on((`test`.`t2`.`col2` = `test`.`t1`.`col1`)) where (ifnull(`test`.`t2`.`col3`,0) = 0)
SELECT t1.col1, t2.col1, t2.col3
FROM t1 LEFT OUTER JOIN t2 ON t1.col1 = t2.col2
WHERE f1(t2.col3,0) = 0;
col1 col1 col3
2.00000 NULL NULL
2.00000 NULL NULL
EXPLAIN EXTENDED SELECT t1.col1, t2.col1, t2.col3
FROM t1 LEFT OUTER JOIN t2 ON t1.col1 = t2.col2
WHERE f1(t2.col3,0) = 0;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00
1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 Using where
Warnings:
Note 1003 select `test`.`t1`.`col1` AS `col1`,`test`.`t2`.`col1` AS `col1`,`test`.`t2`.`col3` AS `col3` from `test`.`t1` left join `test`.`t2` on((`test`.`t2`.`col2` = `test`.`t1`.`col1`)) where (`f1`(`test`.`t2`.`col3`,0) = 0)
DROP FUNCTION f1;
DROP TABLE t1,t2;
# end of 5.5 tests
SET optimizer_switch=@save_optimizer_switch;
95 changes: 95 additions & 0 deletions mysql-test/r/join_outer_jcl6.result
Original file line number Diff line number Diff line change
Expand Up @@ -2256,6 +2256,101 @@ SELECT * FROM t1 INNER JOIN t2 ON c = b LEFT JOIN t3 ON d = a
WHERE b IN (1,2,3) OR b = d;
a b c d
DROP TABLE t1,t2,t3;
#
# MDEV-11958: LEFT JOIN with stored routine produces incorrect result
#
CREATE TABLE t (x INT);
INSERT INTO t VALUES(1),(NULL);
CREATE FUNCTION f (val INT, ret INT) RETURNS INT DETERMINISTIC RETURN IFNULL(val, ret);
SELECT t1.x, t2.x, IFNULL(t2.x,0), f(t2.x,0)
FROM t t1 LEFT JOIN t t2
ON t1.x = t2.x
WHERE IFNULL(t2.x,0)=0;
x x IFNULL(t2.x,0) f(t2.x,0)
NULL NULL 0 0
explain extended
SELECT t1.x, t2.x, IFNULL(t2.x,0), f(t2.x,0)
FROM t t1 LEFT JOIN t t2
ON t1.x = t2.x
WHERE IFNULL(t2.x,0)=0;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00
1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 Using where; Using join buffer (flat, BNL join)
Warnings:
Note 1003 select `test`.`t1`.`x` AS `x`,`test`.`t2`.`x` AS `x`,ifnull(`test`.`t2`.`x`,0) AS `IFNULL(t2.x,0)`,`f`(`test`.`t2`.`x`,0) AS `f(t2.x,0)` from `test`.`t` `t1` left join `test`.`t` `t2` on((`test`.`t2`.`x` = `test`.`t1`.`x`)) where (ifnull(`test`.`t2`.`x`,0) = 0)
SELECT t1.x, t2.x, IFNULL(t2.x,0), f(t2.x,0)
FROM t t1 LEFT JOIN t t2
ON t1.x = t2.x
WHERE f(t2.x,0)=0;
x x IFNULL(t2.x,0) f(t2.x,0)
NULL NULL 0 0
explain extended
SELECT t1.x, t2.x, IFNULL(t2.x,0), f(t2.x,0)
FROM t t1 LEFT JOIN t t2
ON t1.x = t2.x
WHERE f(t2.x,0)=0;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00
1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 Using where; Using join buffer (flat, BNL join)
Warnings:
Note 1003 select `test`.`t1`.`x` AS `x`,`test`.`t2`.`x` AS `x`,ifnull(`test`.`t2`.`x`,0) AS `IFNULL(t2.x,0)`,`f`(`test`.`t2`.`x`,0) AS `f(t2.x,0)` from `test`.`t` `t1` left join `test`.`t` `t2` on((`test`.`t2`.`x` = `test`.`t1`.`x`)) where (`f`(`test`.`t2`.`x`,0) = 0)
drop function f;
drop table t;
CREATE TABLE t1 (
col1 DECIMAL(33,5) NULL DEFAULT NULL,
col2 DECIMAL(33,5) NULL DEFAULT NULL
);
CREATE TABLE t2 (
col1 DECIMAL(33,5) NULL DEFAULT NULL,
col2 DECIMAL(33,5) NULL DEFAULT NULL,
col3 DECIMAL(33,5) NULL DEFAULT NULL
);
INSERT INTO t1 VALUES (2, 1.1), (2, 2.1);
INSERT INTO t2 VALUES (3, 3.1, 4), (1, 1, NULL);
CREATE FUNCTION f1 ( p_num DECIMAL(45,15), p_return DECIMAL(45,15))
RETURNS decimal(33,5)
LANGUAGE SQL
DETERMINISTIC
CONTAINS SQL
SQL SECURITY INVOKER
BEGIN
IF p_num IS NULL THEN
RETURN p_return;
ELSE
RETURN p_num;
END IF;
END |
SELECT t1.col1, t2.col1, t2.col3
FROM t1 LEFT OUTER JOIN t2 ON t1.col1 = t2.col2
WHERE IFNULL(t2.col3,0) = 0;
col1 col1 col3
2.00000 NULL NULL
2.00000 NULL NULL
EXPLAIN EXTENDED SELECT t1.col1, t2.col1, t2.col3
FROM t1 LEFT OUTER JOIN t2 ON t1.col1 = t2.col2
WHERE IFNULL(t2.col3,0) = 0;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00
1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 Using where; Using join buffer (flat, BNL join)
Warnings:
Note 1003 select `test`.`t1`.`col1` AS `col1`,`test`.`t2`.`col1` AS `col1`,`test`.`t2`.`col3` AS `col3` from `test`.`t1` left join `test`.`t2` on((`test`.`t2`.`col2` = `test`.`t1`.`col1`)) where (ifnull(`test`.`t2`.`col3`,0) = 0)
SELECT t1.col1, t2.col1, t2.col3
FROM t1 LEFT OUTER JOIN t2 ON t1.col1 = t2.col2
WHERE f1(t2.col3,0) = 0;
col1 col1 col3
2.00000 NULL NULL
2.00000 NULL NULL
EXPLAIN EXTENDED SELECT t1.col1, t2.col1, t2.col3
FROM t1 LEFT OUTER JOIN t2 ON t1.col1 = t2.col2
WHERE f1(t2.col3,0) = 0;
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 2 100.00
1 SIMPLE t2 ALL NULL NULL NULL NULL 2 100.00 Using where; Using join buffer (flat, BNL join)
Warnings:
Note 1003 select `test`.`t1`.`col1` AS `col1`,`test`.`t2`.`col1` AS `col1`,`test`.`t2`.`col3` AS `col3` from `test`.`t1` left join `test`.`t2` on((`test`.`t2`.`col2` = `test`.`t1`.`col1`)) where (`f1`(`test`.`t2`.`col3`,0) = 0)
DROP FUNCTION f1;
DROP TABLE t1,t2;
# end of 5.5 tests
SET optimizer_switch=@save_optimizer_switch;
set join_cache_level=default;
show variables like 'join_cache_level';
Expand Down
82 changes: 82 additions & 0 deletions mysql-test/t/join_outer.test
Original file line number Diff line number Diff line change
Expand Up @@ -1801,4 +1801,86 @@ SELECT * FROM t1 INNER JOIN t2 ON c = b LEFT JOIN t3 ON d = a
DROP TABLE t1,t2,t3;


--echo #
--echo # MDEV-11958: LEFT JOIN with stored routine produces incorrect result
--echo #

CREATE TABLE t (x INT);
INSERT INTO t VALUES(1),(NULL);
CREATE FUNCTION f (val INT, ret INT) RETURNS INT DETERMINISTIC RETURN IFNULL(val, ret);

SELECT t1.x, t2.x, IFNULL(t2.x,0), f(t2.x,0)
FROM t t1 LEFT JOIN t t2
ON t1.x = t2.x
WHERE IFNULL(t2.x,0)=0;
explain extended
SELECT t1.x, t2.x, IFNULL(t2.x,0), f(t2.x,0)
FROM t t1 LEFT JOIN t t2
ON t1.x = t2.x
WHERE IFNULL(t2.x,0)=0;
SELECT t1.x, t2.x, IFNULL(t2.x,0), f(t2.x,0)
FROM t t1 LEFT JOIN t t2
ON t1.x = t2.x
WHERE f(t2.x,0)=0;
explain extended
SELECT t1.x, t2.x, IFNULL(t2.x,0), f(t2.x,0)
FROM t t1 LEFT JOIN t t2
ON t1.x = t2.x
WHERE f(t2.x,0)=0;

drop function f;
drop table t;
CREATE TABLE t1 (
col1 DECIMAL(33,5) NULL DEFAULT NULL,
col2 DECIMAL(33,5) NULL DEFAULT NULL
);

CREATE TABLE t2 (
col1 DECIMAL(33,5) NULL DEFAULT NULL,
col2 DECIMAL(33,5) NULL DEFAULT NULL,
col3 DECIMAL(33,5) NULL DEFAULT NULL
);

INSERT INTO t1 VALUES (2, 1.1), (2, 2.1);
INSERT INTO t2 VALUES (3, 3.1, 4), (1, 1, NULL);

DELIMITER |;

CREATE FUNCTION f1 ( p_num DECIMAL(45,15), p_return DECIMAL(45,15))
RETURNS decimal(33,5)
LANGUAGE SQL
DETERMINISTIC
CONTAINS SQL
SQL SECURITY INVOKER
BEGIN
IF p_num IS NULL THEN
RETURN p_return;
ELSE
RETURN p_num;
END IF;
END |

DELIMITER ;|

let $q1=
SELECT t1.col1, t2.col1, t2.col3
FROM t1 LEFT OUTER JOIN t2 ON t1.col1 = t2.col2
WHERE IFNULL(t2.col3,0) = 0;

eval $q1;
eval EXPLAIN EXTENDED $q1;

let $q2=
SELECT t1.col1, t2.col1, t2.col3
FROM t1 LEFT OUTER JOIN t2 ON t1.col1 = t2.col2
WHERE f1(t2.col3,0) = 0;
eval $q2;
eval EXPLAIN EXTENDED $q2;

DROP FUNCTION f1;

DROP TABLE t1,t2;

--echo # end of 5.5 tests

SET optimizer_switch=@save_optimizer_switch;
29 changes: 25 additions & 4 deletions sql/item_func.h
Original file line number Diff line number Diff line change
Expand Up @@ -1165,7 +1165,11 @@ class Item_func_coercibility :public Item_int_func
longlong val_int();
const char *func_name() const { return "coercibility"; }
void fix_length_and_dec() { max_length=10; maybe_null= 0; }
table_map not_null_tables() const { return 0; }
bool eval_not_null_tables(uchar *opt_arg)
{
not_null_tables_cache= 0;
return 0;
}
};

class Item_func_locate :public Item_int_func
Expand Down Expand Up @@ -1433,7 +1437,11 @@ class Item_udf_func :public Item_func
}
void cleanup();
Item_result result_type () const { return udf.result_type(); }
table_map not_null_tables() const { return 0; }
bool eval_not_null_tables(uchar *opt_arg)
{
not_null_tables_cache= 0;
return 0;
}
bool is_expensive() { return 1; }
virtual void print(String *str, enum_query_type query_type);
};
Expand Down Expand Up @@ -1889,7 +1897,11 @@ class Item_func_match :public Item_real_func
bool is_expensive_processor(uchar *arg) { return TRUE; }
enum Functype functype() const { return FT_FUNC; }
const char *func_name() const { return "match"; }
table_map not_null_tables() const { return 0; }
bool eval_not_null_tables(uchar *opt_arg)
{
not_null_tables_cache= 0;
return 0;
}
bool fix_fields(THD *thd, Item **ref);
bool eq(const Item *, bool binary_cmp) const;
/* The following should be safe, even if we compare doubles */
Expand Down Expand Up @@ -2091,6 +2103,11 @@ class Item_func_sp :public Item_func
{
return TRUE;
}
bool eval_not_null_tables(uchar *opt_arg)
{
not_null_tables_cache= 0;
return 0;
}
};


Expand Down Expand Up @@ -2138,7 +2155,11 @@ class Item_func_last_value :public Item_func
void fix_length_and_dec();
enum Item_result result_type () const { return last_value->result_type(); }
const char *func_name() const { return "last_value"; }
table_map not_null_tables() const { return 0; }
bool eval_not_null_tables(uchar *opt_arg)
{
not_null_tables_cache= 0;
return 0;
}
enum_field_types field_type() const { return last_value->field_type(); }
bool const_item() const { return 0; }
void evaluate_sideeffects();
Expand Down

0 comments on commit b8405c8

Please sign in to comment.