From 994c6db2d17eb035625387f4f5d4bdd8552fb767 Mon Sep 17 00:00:00 2001 From: Sergey Petrunya Date: Thu, 19 Apr 2012 04:50:32 +0400 Subject: [PATCH] BUG#978479: Wrong result (extra rows) with derived_with_keys+loosescan+semijoin=ON, materialization=OFF Part#1: make EXPLAIN's plan match the one by actual execution: Item_subselect::used_tables() should return the same value irrespectively of whether we're running an EXPLAIN or a SELECT. --- mysql-test/r/subselect_sj.result | 27 ++++++++++++++++++++++++ mysql-test/r/subselect_sj_jcl6.result | 27 ++++++++++++++++++++++++ mysql-test/t/subselect_sj.test | 30 +++++++++++++++++++++++++++ sql/item_subselect.cc | 3 ++- 4 files changed, 86 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/subselect_sj.result b/mysql-test/r/subselect_sj.result index 8a2f1f5eaeb..710b2c92677 100644 --- a/mysql-test/r/subselect_sj.result +++ b/mysql-test/r/subselect_sj.result @@ -2661,4 +2661,31 @@ a DEALLOCATE PREPARE pstmt; DROP VIEW v1; DROP TABLE t1, t2; +# +# BUG#978479: Wrong result (extra rows) with derived_with_keys+loosescan+semijoin=ON, materialization=OFF +# +set @tmp_jcl_978479= @@join_cache_level; +set join_cache_level=0; +set @tmp_os_978479= @@optimizer_switch; +set optimizer_switch = 'derived_with_keys=on,loosescan=on,semijoin=on,materialization=off'; +# Part#1: make sure EXPLAIN is using LooseScan: +CREATE TABLE t1 ( a INT, b INT ); +INSERT INTO t1 VALUES +(4,0),(6,8),(3,1),(5,8),(3,9),(2,4), +(2,6),(9,1),(5,4),(7,7),(5,4); +CREATE ALGORITHM=TEMPTABLE +VIEW v1 AS SELECT * FROM t1; +# This will use LooseScan: +EXPLAIN +SELECT * FROM t1 AS t1_1, t1 AS t1_2 +WHERE (t1_1.a, t1_2.a) IN ( SELECT a, b FROM v1 ); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1 ALL NULL NULL NULL NULL 11 +1 PRIMARY ALL NULL NULL NULL NULL 11 Using where; LooseScan +1 PRIMARY t1_2 ALL NULL NULL NULL NULL 11 Using where +3 DERIVED t1 ALL NULL NULL NULL NULL 11 +DROP VIEW v1; +DROP TABLE t1; +set @@join_cache_level= @tmp_jcl_978479; +set @@optimizer_switch= @tmp_os_978479; set optimizer_switch=@subselect_sj_tmp; diff --git a/mysql-test/r/subselect_sj_jcl6.result b/mysql-test/r/subselect_sj_jcl6.result index 704cde2afd2..454e0e36ed7 100644 --- a/mysql-test/r/subselect_sj_jcl6.result +++ b/mysql-test/r/subselect_sj_jcl6.result @@ -2675,6 +2675,33 @@ a DEALLOCATE PREPARE pstmt; DROP VIEW v1; DROP TABLE t1, t2; +# +# BUG#978479: Wrong result (extra rows) with derived_with_keys+loosescan+semijoin=ON, materialization=OFF +# +set @tmp_jcl_978479= @@join_cache_level; +set join_cache_level=0; +set @tmp_os_978479= @@optimizer_switch; +set optimizer_switch = 'derived_with_keys=on,loosescan=on,semijoin=on,materialization=off'; +# Part#1: make sure EXPLAIN is using LooseScan: +CREATE TABLE t1 ( a INT, b INT ); +INSERT INTO t1 VALUES +(4,0),(6,8),(3,1),(5,8),(3,9),(2,4), +(2,6),(9,1),(5,4),(7,7),(5,4); +CREATE ALGORITHM=TEMPTABLE +VIEW v1 AS SELECT * FROM t1; +# This will use LooseScan: +EXPLAIN +SELECT * FROM t1 AS t1_1, t1 AS t1_2 +WHERE (t1_1.a, t1_2.a) IN ( SELECT a, b FROM v1 ); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1_1 ALL NULL NULL NULL NULL 11 +1 PRIMARY ALL NULL NULL NULL NULL 11 Using where; LooseScan +1 PRIMARY t1_2 ALL NULL NULL NULL NULL 11 Using where +3 DERIVED t1 ALL NULL NULL NULL NULL 11 +DROP VIEW v1; +DROP TABLE t1; +set @@join_cache_level= @tmp_jcl_978479; +set @@optimizer_switch= @tmp_os_978479; set optimizer_switch=@subselect_sj_tmp; # # BUG#49129: Wrong result with IN-subquery with join_cache_level=6 and firstmatch=off diff --git a/mysql-test/t/subselect_sj.test b/mysql-test/t/subselect_sj.test index 2fb6f6b53b8..59f36ac3be9 100644 --- a/mysql-test/t/subselect_sj.test +++ b/mysql-test/t/subselect_sj.test @@ -2366,5 +2366,35 @@ DEALLOCATE PREPARE pstmt; DROP VIEW v1; DROP TABLE t1, t2; +--echo # +--echo # BUG#978479: Wrong result (extra rows) with derived_with_keys+loosescan+semijoin=ON, materialization=OFF +--echo # + +set @tmp_jcl_978479= @@join_cache_level; +set join_cache_level=0; + +set @tmp_os_978479= @@optimizer_switch; +set optimizer_switch = 'derived_with_keys=on,loosescan=on,semijoin=on,materialization=off'; + +--echo # Part#1: make sure EXPLAIN is using LooseScan: +CREATE TABLE t1 ( a INT, b INT ); +INSERT INTO t1 VALUES + (4,0),(6,8),(3,1),(5,8),(3,9),(2,4), + (2,6),(9,1),(5,4),(7,7),(5,4); + +CREATE ALGORITHM=TEMPTABLE + VIEW v1 AS SELECT * FROM t1; + +--echo # This will use LooseScan: +EXPLAIN +SELECT * FROM t1 AS t1_1, t1 AS t1_2 + WHERE (t1_1.a, t1_2.a) IN ( SELECT a, b FROM v1 ); + +DROP VIEW v1; +DROP TABLE t1; +set @@join_cache_level= @tmp_jcl_978479; +set @@optimizer_switch= @tmp_os_978479; + + # The following command must be the last one the file set optimizer_switch=@subselect_sj_tmp; diff --git a/sql/item_subselect.cc b/sql/item_subselect.cc index 8b720b350a5..ae3ad3bfcf9 100644 --- a/sql/item_subselect.cc +++ b/sql/item_subselect.cc @@ -757,7 +757,8 @@ void Item_subselect::fix_length_and_dec() table_map Item_subselect::used_tables() const { - return (table_map) (engine->uncacheable() ? used_tables_cache : 0L); + return (table_map) ((engine->uncacheable() & ~UNCACHEABLE_EXPLAIN)? + used_tables_cache : 0L); }