diff --git a/mysql-test/r/derived_view.result b/mysql-test/r/derived_view.result index ba12e48fd98..3ec274acb9d 100644 --- a/mysql-test/r/derived_view.result +++ b/mysql-test/r/derived_view.result @@ -1701,4 +1701,44 @@ WHERE t.b <> 0 AND t.c = t1.a; b c a 8 c c DROP TABLE t1,t2,t3; +# +# Bug #880724: materialized const view as inner table of outer join +# +CREATE TABLE t1 (a int, b varchar(1)); +INSERT INTO t1 VALUES (9,NULL), (6,'r'), (7,'c'); +CREATE TABLE t2 (a int); +INSERT INTO t2 VALUES (6); +CREATE ALGORITHM=TEMPTABLE VIEW v2 AS SELECT * FROM t2; +SET SESSION optimizer_switch = 'derived_with_keys=on'; +SET SESSION join_cache_level = 4; +EXPLAIN +SELECT t1.b,v2.a FROM t1 LEFT JOIN v2 ON v2.a = t1.a; +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 3 +1 PRIMARY ALL NULL NULL NULL NULL 1 Using where +2 DERIVED t2 system NULL NULL NULL NULL 1 +SELECT t1.b,v2.a FROM t1 LEFT JOIN v2 ON v2.a = t1.a; +b a +NULL NULL +r 6 +c NULL +CREATE TABLE t3 (a int, b varchar(1)); +INSERT INTO t3 VALUES (8,'x'), (5,'r'), (9,'y'); +EXPLAIN +SELECT * FROM t3 +WHERE t3.b <> ANY (SELECT t1.b FROM t1 LEFT JOIN v2 ON v2.a = t1.a); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t3 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY t1 ALL NULL NULL NULL NULL 3 Using where +2 DEPENDENT SUBQUERY ALL NULL NULL NULL NULL 1 Using where +3 DERIVED t2 system NULL NULL NULL NULL 1 +SELECT * FROM t3 +WHERE t3.b <> ANY (SELECT t1.b FROM t1 LEFT JOIN v2 ON v2.a = t1.a); +a b +8 x +5 r +9 y +SET SESSION join_cache_level = default; +DROP VIEW v2; +DROP TABLE t1,t2,t3; set optimizer_switch=@exit_optimizer_switch; diff --git a/mysql-test/t/derived_view.test b/mysql-test/t/derived_view.test index c8df7035e09..7f70fbef35a 100644 --- a/mysql-test/t/derived_view.test +++ b/mysql-test/t/derived_view.test @@ -1107,5 +1107,38 @@ FROM t1, (SELECT t2.b, t2.c FROM t3 RIGHT JOIN t2 ON t2.a = t3.b) AS t DROP TABLE t1,t2,t3; +--echo # +--echo # Bug #880724: materialized const view as inner table of outer join +--echo # + +CREATE TABLE t1 (a int, b varchar(1)); +INSERT INTO t1 VALUES (9,NULL), (6,'r'), (7,'c'); + +CREATE TABLE t2 (a int); +INSERT INTO t2 VALUES (6); + +CREATE ALGORITHM=TEMPTABLE VIEW v2 AS SELECT * FROM t2; + +SET SESSION optimizer_switch = 'derived_with_keys=on'; +SET SESSION join_cache_level = 4; + +EXPLAIN +SELECT t1.b,v2.a FROM t1 LEFT JOIN v2 ON v2.a = t1.a; +SELECT t1.b,v2.a FROM t1 LEFT JOIN v2 ON v2.a = t1.a; + +CREATE TABLE t3 (a int, b varchar(1)); +INSERT INTO t3 VALUES (8,'x'), (5,'r'), (9,'y'); + +EXPLAIN +SELECT * FROM t3 + WHERE t3.b <> ANY (SELECT t1.b FROM t1 LEFT JOIN v2 ON v2.a = t1.a); +SELECT * FROM t3 + WHERE t3.b <> ANY (SELECT t1.b FROM t1 LEFT JOIN v2 ON v2.a = t1.a); + +SET SESSION join_cache_level = default; + +DROP VIEW v2; +DROP TABLE t1,t2,t3; + # The following command must be the last one the file set optimizer_switch=@exit_optimizer_switch; diff --git a/sql/sql_select.cc b/sql/sql_select.cc index aa77013ed49..29db90452a2 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -3827,7 +3827,9 @@ add_key_field(JOIN *join, uint optimize= 0; if (eq_func && ((join->is_allowed_hash_join_access() && - field->hash_join_is_possible()) || + field->hash_join_is_possible() && + !(field->table->pos_in_table_list->is_materialized_derived() && + field->table->created)) || (field->table->pos_in_table_list->is_materialized_derived() && !field->table->created))) {