MDEV-36169: Two subqueries with LOOSESCAN hints create invalid query plan
LooseScan strategy doesn't support join orders where tables from two subqueries interleave. There is a check in LooseScan_picker::check_qep() to prevent use of LooseScan for such join orders. However for two subqueries with one table each a join order of subquery1_table subquery2_table outer_table was not rejected (although the POSITION object for the last table in the join order clearly had pos->dups_producing_tables!=0). Modified the no-interleaving check to catch more cases.
This commit is contained in:
parent
453a86f68e
commit
b89a1e7f35
@ -1318,7 +1318,7 @@ ta3.f2 IN (SELECT /*+ QB_NAME(qb2) */ f2 FROM t2);
|
|||||||
id select_type table type possible_keys key key_len ref rows filtered Extra
|
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||||
1 PRIMARY t2 index f2 f2 5 NULL 3 100.00 Using where; Using index; Start temporary
|
1 PRIMARY t2 index f2 f2 5 NULL 3 100.00 Using where; Using index; Start temporary
|
||||||
1 PRIMARY t4 ALL NULL NULL NULL NULL 1 100.00 Using where; Using join buffer (flat, BNL join)
|
1 PRIMARY t4 ALL NULL NULL NULL NULL 1 100.00 Using where; Using join buffer (flat, BNL join)
|
||||||
1 PRIMARY ta3 ref f2 f2 5 test.t2.f2 1 33.33 Using index
|
1 PRIMARY ta3 ref f2 f2 5 test.t2.f2 1 100.00 Using index
|
||||||
1 PRIMARY ta4 eq_ref PRIMARY PRIMARY 4 test.t4.f1 1 33.33 End temporary
|
1 PRIMARY ta4 eq_ref PRIMARY PRIMARY 4 test.t4.f1 1 33.33 End temporary
|
||||||
1 PRIMARY t1 ALL NULL NULL NULL NULL 1 100.00 Using join buffer (flat, BNL join)
|
1 PRIMARY t1 ALL NULL NULL NULL NULL 1 100.00 Using join buffer (flat, BNL join)
|
||||||
Warnings:
|
Warnings:
|
||||||
|
22
mysql-test/main/opt_hints_subquery_innodb.result
Normal file
22
mysql-test/main/opt_hints_subquery_innodb.result
Normal file
@ -0,0 +1,22 @@
|
|||||||
|
#
|
||||||
|
# MDEV-36169: LooseScan optimization picks invalid plan
|
||||||
|
#
|
||||||
|
CREATE TABLE t1 (a INTEGER NOT NULL, b INT, UNIQUE KEY (a)) engine=InnoDB;
|
||||||
|
CREATE TABLE t2 (a INTEGER NOT NULL, KEY (a));
|
||||||
|
CREATE TABLE t3 (a INTEGER NOT NULL, b INT, KEY (a));
|
||||||
|
INSERT INTO t1 VALUES (1,10), (2,20), (3,30), (4,40);
|
||||||
|
INSERT INTO t2 VALUES (2), (2), (3), (3), (4), (5);
|
||||||
|
INSERT INTO t3 VALUES (10,3), (15,3), (20,4), (30,5);
|
||||||
|
# Must not be: t3, t3(LooseScan), t1
|
||||||
|
EXPLAIN EXTENDED
|
||||||
|
SELECT * FROM t1
|
||||||
|
WHERE
|
||||||
|
t1.a IN (SELECT /*+ SEMIJOIN(LOOSESCAN) */ a FROM t2) AND
|
||||||
|
t1.b IN (SELECT /*+ SEMIJOIN(LOOSESCAN) */ a FROM t3);
|
||||||
|
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||||
|
1 PRIMARY t2 index a a 4 NULL 6 100.00 Using index; LooseScan
|
||||||
|
1 PRIMARY t1 eq_ref a a 4 test.t2.a 1 16.67 Using where
|
||||||
|
1 PRIMARY t3 ref a a 4 test.t1.b 1 100.00 Using index; Start temporary; End temporary
|
||||||
|
Warnings:
|
||||||
|
Note 1003 select /*+ SEMIJOIN(@`select#2` LOOSESCAN) SEMIJOIN(@`select#3` LOOSESCAN) */ `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` semi join (`test`.`t2`) semi join (`test`.`t3`) where `test`.`t1`.`a` = `test`.`t2`.`a` and `test`.`t3`.`a` = `test`.`t1`.`b`
|
||||||
|
DROP TABLE t1,t2,t3;
|
21
mysql-test/main/opt_hints_subquery_innodb.test
Normal file
21
mysql-test/main/opt_hints_subquery_innodb.test
Normal file
@ -0,0 +1,21 @@
|
|||||||
|
--echo #
|
||||||
|
--echo # MDEV-36169: LooseScan optimization picks invalid plan
|
||||||
|
--echo #
|
||||||
|
|
||||||
|
--source include/have_innodb.inc
|
||||||
|
|
||||||
|
CREATE TABLE t1 (a INTEGER NOT NULL, b INT, UNIQUE KEY (a)) engine=InnoDB;
|
||||||
|
CREATE TABLE t2 (a INTEGER NOT NULL, KEY (a));
|
||||||
|
CREATE TABLE t3 (a INTEGER NOT NULL, b INT, KEY (a));
|
||||||
|
INSERT INTO t1 VALUES (1,10), (2,20), (3,30), (4,40);
|
||||||
|
INSERT INTO t2 VALUES (2), (2), (3), (3), (4), (5);
|
||||||
|
INSERT INTO t3 VALUES (10,3), (15,3), (20,4), (30,5);
|
||||||
|
|
||||||
|
--echo # Must not be: t3, t3(LooseScan), t1
|
||||||
|
EXPLAIN EXTENDED
|
||||||
|
SELECT * FROM t1
|
||||||
|
WHERE
|
||||||
|
t1.a IN (SELECT /*+ SEMIJOIN(LOOSESCAN) */ a FROM t2) AND
|
||||||
|
t1.b IN (SELECT /*+ SEMIJOIN(LOOSESCAN) */ a FROM t3);
|
||||||
|
|
||||||
|
DROP TABLE t1,t2,t3;
|
@ -3402,11 +3402,24 @@ bool LooseScan_picker::check_qep(JOIN *join,
|
|||||||
then
|
then
|
||||||
stop considering loose scan
|
stop considering loose scan
|
||||||
*/
|
*/
|
||||||
if ((first_loosescan_table != MAX_TABLES) && // (1)
|
if (first_loosescan_table != MAX_TABLES)
|
||||||
(first->table->emb_sj_nest->sj_inner_tables & remaining_tables) && //(2)
|
//(first->table->emb_sj_nest->sj_inner_tables & remaining_tables) && //(2)
|
||||||
new_join_tab->emb_sj_nest != first->table->emb_sj_nest) //(2)
|
{
|
||||||
|
bool interleaving=false;
|
||||||
|
if (new_join_tab->emb_sj_nest)
|
||||||
|
{
|
||||||
|
interleaving=
|
||||||
|
MY_TEST(new_join_tab->emb_sj_nest != first->table->emb_sj_nest);
|
||||||
|
}
|
||||||
|
else
|
||||||
|
{
|
||||||
|
interleaving= (first->table->emb_sj_nest->sj_inner_tables & remaining_tables);
|
||||||
|
}
|
||||||
|
if (interleaving)
|
||||||
{
|
{
|
||||||
first_loosescan_table= MAX_TABLES;
|
first_loosescan_table= MAX_TABLES;
|
||||||
|
return FALSE;
|
||||||
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
/*
|
/*
|
||||||
|
Loading…
x
Reference in New Issue
Block a user