mirror of
https://github.com/MariaDB/server.git
synced 2025-01-16 12:02:42 +01:00
Fixed LP bug #934342.
An outer join query with a semi-join subquery could return a wrong result if the optimizer chose to materialize the subquery. It happened because when substituting for the best field into a ref item used to build access keys not all COND_EQUAL objects that could be employed at substitution were checked. Also refined some code in the function check_join_cache_usage to make it safer.
This commit is contained in:
parent
bbb3527635
commit
cd81f57830
3 changed files with 150 additions and 5 deletions
|
@ -2753,6 +2753,86 @@ DROP table t1, t2;
|
|||
set @@optimizer_switch= @os_912513;
|
||||
set @@join_cache_level= @jcl_912513;
|
||||
# End
|
||||
#
|
||||
# BUG#934342: outer join + semijoin materialization
|
||||
# + join_cache_level > 2
|
||||
#
|
||||
CREATE TABLE t1 (a varchar(1), b varchar(1), INDEX idx_a(a) );
|
||||
INSERT INTO t1 VALUES ('v','v'), ('w','w'), ('t','t');
|
||||
CREATE TABLE t2 (c varchar(1), INDEX idx_c(c) );
|
||||
INSERT INTO t2 VALUES ('v'), ('v'), ('s'), ('j');
|
||||
CREATE TABLE t3 (c varchar(1), d varchar(1), INDEX idx_c(c) );
|
||||
INSERT INTO t3 VALUES ('v','v'), ('v','v'), ('s','s'), ('j','j');
|
||||
INSERT INTO t3 VALUES ('m','m'), ('d','d'), ('k','k'), ('m','m');
|
||||
set @tmp_otimizer_switch= @@optimizer_switch;
|
||||
set @tmp_join_cache_level=@@join_cache_level;
|
||||
set optimizer_switch = 'materialization=on,semijoin=on,join_cache_hashed=on';
|
||||
set join_cache_level=0;
|
||||
EXPLAIN
|
||||
SELECT * FROM t1 LEFT JOIN t2 ON (c = b)
|
||||
WHERE (a, b) IN (SELECT a, b FROM t1 t);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1 ALL idx_a NULL NULL NULL 3
|
||||
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 10 func,func 1
|
||||
1 PRIMARY t2 ref idx_c idx_c 4 test.t1.b 2 Using where; Using index
|
||||
2 MATERIALIZED t ALL idx_a NULL NULL NULL 3
|
||||
SELECT * FROM t1 LEFT JOIN t2 ON (c = b)
|
||||
WHERE (a, b) IN (SELECT a, b FROM t1 t);
|
||||
a b c
|
||||
v v v
|
||||
v v v
|
||||
w w NULL
|
||||
t t NULL
|
||||
EXPLAIN
|
||||
SELECT * FROM t1 LEFT JOIN t3 ON (c = b)
|
||||
WHERE (a, b) IN (SELECT a, b FROM t1 t);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1 ALL idx_a NULL NULL NULL 3
|
||||
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 10 func,func 1
|
||||
1 PRIMARY t3 ref idx_c idx_c 4 test.t1.b 2 Using where
|
||||
2 MATERIALIZED t ALL idx_a NULL NULL NULL 3
|
||||
SELECT * FROM t1 LEFT JOIN t3 ON (c = b)
|
||||
WHERE (a, b) IN (SELECT a, b FROM t1 t);
|
||||
a b c d
|
||||
v v v v
|
||||
v v v v
|
||||
w w NULL NULL
|
||||
t t NULL NULL
|
||||
set join_cache_level=6;
|
||||
EXPLAIN
|
||||
SELECT * FROM t1 LEFT JOIN t2 ON (c = b)
|
||||
WHERE (a, b) IN (SELECT a, b FROM t1 t);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1 ALL idx_a NULL NULL NULL 3
|
||||
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 10 func,func 1
|
||||
1 PRIMARY t2 ref idx_c idx_c 4 test.t1.b 2 Using where; Using index
|
||||
2 MATERIALIZED t ALL idx_a NULL NULL NULL 3
|
||||
SELECT * FROM t1 LEFT JOIN t2 ON (c = b)
|
||||
WHERE (a, b) IN (SELECT a, b FROM t1 t);
|
||||
a b c
|
||||
v v v
|
||||
v v v
|
||||
w w NULL
|
||||
t t NULL
|
||||
EXPLAIN
|
||||
SELECT * FROM t1 LEFT JOIN t3 ON (c = b)
|
||||
WHERE (a, b) IN (SELECT a, b FROM t1 t);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1 ALL idx_a NULL NULL NULL 3
|
||||
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 10 func,func 1
|
||||
1 PRIMARY t3 ref idx_c idx_c 4 test.t1.b 2 Using where; Using join buffer (flat, BKA join); Key-ordered Rowid-ordered scan
|
||||
2 MATERIALIZED t ALL idx_a NULL NULL NULL 3
|
||||
SELECT * FROM t1 LEFT JOIN t3 ON (c = b)
|
||||
WHERE (a, b) IN (SELECT a, b FROM t1 t);
|
||||
a b c d
|
||||
v v v v
|
||||
v v v v
|
||||
w w NULL NULL
|
||||
t t NULL NULL
|
||||
set optimizer_switch=@tmp_optimizer_switch;
|
||||
set join_cache_level=@tmp_join_cache_level;
|
||||
DROP TABLE t1,t2,t3;
|
||||
# End
|
||||
set join_cache_level=default;
|
||||
show variables like 'join_cache_level';
|
||||
Variable_name Value
|
||||
|
|
|
@ -116,6 +116,60 @@ set @@join_cache_level= @jcl_912513;
|
|||
|
||||
--echo # End
|
||||
|
||||
--echo #
|
||||
--echo # BUG#934342: outer join + semijoin materialization
|
||||
--echo # + join_cache_level > 2
|
||||
--echo #
|
||||
|
||||
CREATE TABLE t1 (a varchar(1), b varchar(1), INDEX idx_a(a) );
|
||||
INSERT INTO t1 VALUES ('v','v'), ('w','w'), ('t','t');
|
||||
|
||||
CREATE TABLE t2 (c varchar(1), INDEX idx_c(c) );
|
||||
INSERT INTO t2 VALUES ('v'), ('v'), ('s'), ('j');
|
||||
|
||||
CREATE TABLE t3 (c varchar(1), d varchar(1), INDEX idx_c(c) );
|
||||
INSERT INTO t3 VALUES ('v','v'), ('v','v'), ('s','s'), ('j','j');
|
||||
INSERT INTO t3 VALUES ('m','m'), ('d','d'), ('k','k'), ('m','m');
|
||||
|
||||
set @tmp_otimizer_switch= @@optimizer_switch;
|
||||
set @tmp_join_cache_level=@@join_cache_level;
|
||||
set optimizer_switch = 'materialization=on,semijoin=on,join_cache_hashed=on';
|
||||
|
||||
set join_cache_level=0;
|
||||
|
||||
EXPLAIN
|
||||
SELECT * FROM t1 LEFT JOIN t2 ON (c = b)
|
||||
WHERE (a, b) IN (SELECT a, b FROM t1 t);
|
||||
SELECT * FROM t1 LEFT JOIN t2 ON (c = b)
|
||||
WHERE (a, b) IN (SELECT a, b FROM t1 t);
|
||||
|
||||
EXPLAIN
|
||||
SELECT * FROM t1 LEFT JOIN t3 ON (c = b)
|
||||
WHERE (a, b) IN (SELECT a, b FROM t1 t);
|
||||
SELECT * FROM t1 LEFT JOIN t3 ON (c = b)
|
||||
WHERE (a, b) IN (SELECT a, b FROM t1 t);
|
||||
|
||||
set join_cache_level=6;
|
||||
|
||||
EXPLAIN
|
||||
SELECT * FROM t1 LEFT JOIN t2 ON (c = b)
|
||||
WHERE (a, b) IN (SELECT a, b FROM t1 t);
|
||||
SELECT * FROM t1 LEFT JOIN t2 ON (c = b)
|
||||
WHERE (a, b) IN (SELECT a, b FROM t1 t);
|
||||
|
||||
EXPLAIN
|
||||
SELECT * FROM t1 LEFT JOIN t3 ON (c = b)
|
||||
WHERE (a, b) IN (SELECT a, b FROM t1 t);
|
||||
SELECT * FROM t1 LEFT JOIN t3 ON (c = b)
|
||||
WHERE (a, b) IN (SELECT a, b FROM t1 t);
|
||||
|
||||
set optimizer_switch=@tmp_optimizer_switch;
|
||||
set join_cache_level=@tmp_join_cache_level;
|
||||
|
||||
DROP TABLE t1,t2,t3;
|
||||
|
||||
--echo # End
|
||||
|
||||
set join_cache_level=default;
|
||||
show variables like 'join_cache_level';
|
||||
|
||||
|
|
|
@ -1266,9 +1266,20 @@ JOIN::optimize()
|
|||
Item *ref_item= *ref_item_ptr;
|
||||
if (!ref_item->used_tables() && !(select_options & SELECT_DESCRIBE))
|
||||
continue;
|
||||
COND_EQUAL *equals= tab->first_inner ? tab->first_inner->cond_equal :
|
||||
cond_equal;
|
||||
ref_item= substitute_for_best_equal_field(tab, ref_item, equals, map2table);
|
||||
COND_EQUAL *equals= cond_equal;
|
||||
JOIN_TAB *first_inner= tab->first_inner;
|
||||
while (equals)
|
||||
{
|
||||
ref_item= substitute_for_best_equal_field(tab, ref_item,
|
||||
equals, map2table);
|
||||
if (first_inner)
|
||||
{
|
||||
equals= first_inner->cond_equal;
|
||||
first_inner= first_inner->first_upper;
|
||||
}
|
||||
else
|
||||
equals= 0;
|
||||
}
|
||||
ref_item->update_used_tables();
|
||||
if (*ref_item_ptr != ref_item)
|
||||
{
|
||||
|
@ -9213,7 +9224,7 @@ uint check_join_cache_usage(JOIN_TAB *tab,
|
|||
Check whether table tab and the previous one belong to the same nest of
|
||||
inner tables and if so do not use join buffer when joining table tab.
|
||||
*/
|
||||
if (tab->first_inner)
|
||||
if (tab->first_inner && tab != tab->first_inner)
|
||||
{
|
||||
for (JOIN_TAB *first_inner= tab[-1].first_inner;
|
||||
first_inner;
|
||||
|
@ -9223,7 +9234,7 @@ uint check_join_cache_usage(JOIN_TAB *tab,
|
|||
goto no_join_cache;
|
||||
}
|
||||
}
|
||||
else if (tab->first_sj_inner_tab &&
|
||||
else if (tab->first_sj_inner_tab && tab != tab->first_sj_inner_tab &&
|
||||
tab->first_sj_inner_tab == tab[-1].first_sj_inner_tab)
|
||||
goto no_join_cache;
|
||||
}
|
||||
|
|
Loading…
Reference in a new issue