From 3cc3bcfcc5f80505fa48681b86d5f486cf9dc248 Mon Sep 17 00:00:00 2001 From: unknown Date: Fri, 11 Oct 2013 15:57:19 +0300 Subject: [PATCH] MDEV-5107:Left Join Yields All Nulls Instead of Appropriate Matches MDEV-5034:Wrong result on LEFT JOIN with a SELECT SQ or a merge view, UNION in IN subquery Make reset null_row same as it was set in evaluate_null_complemented_join_record(). The problem was that view firlds detect null_row by not-yet-reset table. --- mysql-test/r/view.result | 46 ++++++++++++++++++++++++++++++++++++++++ mysql-test/t/view.test | 37 ++++++++++++++++++++++++++++++++ sql/sql_select.cc | 10 ++++++++- 3 files changed, 92 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/view.result b/mysql-test/r/view.result index 2d89c66a226..e0323c305f5 100644 --- a/mysql-test/r/view.result +++ b/mysql-test/r/view.result @@ -4663,6 +4663,52 @@ execute s; deallocate prepare s; drop view v1; drop tables t1,t2; +# +# MDEV-5034 (duplicate of MDEV-5107): +# Left Join Yields All Nulls Instead of Appropriate Matches +# +# test #1 +CREATE TABLE t1 (state VARCHAR(32), INDEX(state)); +INSERT INTO t1 VALUES ('Indiana'),('Vermont'); +CREATE TABLE t2 (state VARCHAR(32)); +INSERT INTO t2 VALUES ('Hawaii'),('Oregon'),('Vermont'); +CREATE ALGORITHM=MERGE VIEW v1 AS SELECT t1.* FROM t2, t1; +SELECT * FROM t1 AS outer_t1 LEFT JOIN v1 AS joined_t1 +ON (joined_t1.state = outer_t1.state AND joined_t1.state IN ( SELECT 'Vermont' UNION SELECT 'Florida' ) ); +state state +Indiana NULL +Vermont Vermont +Vermont Vermont +Vermont Vermont +SELECT * FROM t1 AS outer_t1 LEFT JOIN (SELECT t1.* FROM t2, t1) AS joined_t1 ON (joined_t1.state = outer_t1.state AND joined_t1.state IN ( SELECT 'Vermont' UNION SELECT 'Florida' ) ); +state state +Indiana NULL +Vermont Vermont +Vermont Vermont +Vermont Vermont +drop view v1; +drop table t1, t2; +# test #1 +CREATE TABLE t1 (a INT, b VARCHAR(1), INDEX(b,a)); +INSERT INTO t1 VALUES (4,'p'),(1,'q'),(9,'w'); +CREATE TABLE t2 (c VARCHAR(1), INDEX(c)); +INSERT INTO t2 VALUES ('q'),('a'); +CREATE ALGORITHM=MERGE VIEW v1 AS SELECT t1a.* FROM t1, t1 AS t1a; +SELECT * FROM t2 LEFT JOIN v1 ON ( c=b AND a IN ( 1,6 ) ); +c a b +a NULL NULL +q 1 q +q 1 q +q 1 q +CREATE OR REPLACE ALGORITHM=TEMPTABLE VIEW v1 AS SELECT t1a.* FROM t1, t1 AS t1a; +SELECT * FROM t2 LEFT JOIN v1 ON ( c=b AND a IN ( 1,6 ) ); +c a b +a NULL NULL +q 1 q +q 1 q +q 1 q +drop view v1; +drop table t1,t2; # ----------------------------------------------------------------- # -- End of 5.3 tests. # ----------------------------------------------------------------- diff --git a/mysql-test/t/view.test b/mysql-test/t/view.test index f3f8dbfe77f..0547004cd9c 100644 --- a/mysql-test/t/view.test +++ b/mysql-test/t/view.test @@ -4610,6 +4610,43 @@ deallocate prepare s; drop view v1; drop tables t1,t2; +--echo # +--echo # MDEV-5034 (duplicate of MDEV-5107): +--echo # Left Join Yields All Nulls Instead of Appropriate Matches +--echo # + + --echo # test #1 + +CREATE TABLE t1 (state VARCHAR(32), INDEX(state)); +INSERT INTO t1 VALUES ('Indiana'),('Vermont'); + +CREATE TABLE t2 (state VARCHAR(32)); +INSERT INTO t2 VALUES ('Hawaii'),('Oregon'),('Vermont'); + +CREATE ALGORITHM=MERGE VIEW v1 AS SELECT t1.* FROM t2, t1; +SELECT * FROM t1 AS outer_t1 LEFT JOIN v1 AS joined_t1 +ON (joined_t1.state = outer_t1.state AND joined_t1.state IN ( SELECT 'Vermont' UNION SELECT 'Florida' ) ); + +SELECT * FROM t1 AS outer_t1 LEFT JOIN (SELECT t1.* FROM t2, t1) AS joined_t1 ON (joined_t1.state = outer_t1.state AND joined_t1.state IN ( SELECT 'Vermont' UNION SELECT 'Florida' ) ); + +drop view v1; +drop table t1, t2; + +--echo # test #1 + +CREATE TABLE t1 (a INT, b VARCHAR(1), INDEX(b,a)); +INSERT INTO t1 VALUES (4,'p'),(1,'q'),(9,'w'); + +CREATE TABLE t2 (c VARCHAR(1), INDEX(c)); +INSERT INTO t2 VALUES ('q'),('a'); +CREATE ALGORITHM=MERGE VIEW v1 AS SELECT t1a.* FROM t1, t1 AS t1a; +SELECT * FROM t2 LEFT JOIN v1 ON ( c=b AND a IN ( 1,6 ) ); +CREATE OR REPLACE ALGORITHM=TEMPTABLE VIEW v1 AS SELECT t1a.* FROM t1, t1 AS t1a; +SELECT * FROM t2 LEFT JOIN v1 ON ( c=b AND a IN ( 1,6 ) ); + +drop view v1; +drop table t1,t2; + --echo # ----------------------------------------------------------------- --echo # -- End of 5.3 tests. --echo # ----------------------------------------------------------------- diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 10575bc2d98..82a2471f99b 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -16132,7 +16132,15 @@ sub_select(JOIN *join,JOIN_TAB *join_tab,bool end_of_records) { DBUG_ENTER("sub_select"); - join_tab->table->null_row=0; + if (join_tab->last_inner) + { + JOIN_TAB *last_inner_tab= join_tab->last_inner; + for (JOIN_TAB *jt= join_tab; jt <= last_inner_tab; jt++) + jt->table->null_row= 0; + } + else + join_tab->table->null_row=0; + if (end_of_records) { enum_nested_loop_state nls=