Skip to content

Commit 6cd219a

Browse files
spetruniaOlernov
authored andcommitted
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.
1 parent 7f3ce94 commit 6cd219a

File tree

4 files changed

+61
-5
lines changed

4 files changed

+61
-5
lines changed

mysql-test/main/opt_hints_join_order.result

+1-1
Original file line numberDiff line numberDiff line change
@@ -1318,7 +1318,7 @@ ta3.f2 IN (SELECT /*+ QB_NAME(qb2) */ f2 FROM t2);
13181318
id select_type table type possible_keys key key_len ref rows filtered Extra
13191319
1 PRIMARY t2 index f2 f2 5 NULL 3 100.00 Using where; Using index; Start temporary
13201320
1 PRIMARY t4 ALL NULL NULL NULL NULL 1 100.00 Using where; Using join buffer (flat, BNL join)
1321-
1 PRIMARY ta3 ref f2 f2 5 test.t2.f2 1 33.33 Using index
1321+
1 PRIMARY ta3 ref f2 f2 5 test.t2.f2 1 100.00 Using index
13221322
1 PRIMARY ta4 eq_ref PRIMARY PRIMARY 4 test.t4.f1 1 33.33 End temporary
13231323
1 PRIMARY t1 ALL NULL NULL NULL NULL 1 100.00 Using join buffer (flat, BNL join)
13241324
Warnings:
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,22 @@
1+
#
2+
# MDEV-36169: LooseScan optimization picks invalid plan
3+
#
4+
CREATE TABLE t1 (a INTEGER NOT NULL, b INT, UNIQUE KEY (a)) engine=InnoDB;
5+
CREATE TABLE t2 (a INTEGER NOT NULL, KEY (a));
6+
CREATE TABLE t3 (a INTEGER NOT NULL, b INT, KEY (a));
7+
INSERT INTO t1 VALUES (1,10), (2,20), (3,30), (4,40);
8+
INSERT INTO t2 VALUES (2), (2), (3), (3), (4), (5);
9+
INSERT INTO t3 VALUES (10,3), (15,3), (20,4), (30,5);
10+
# Must not be: t3, t3(LooseScan), t1
11+
EXPLAIN EXTENDED
12+
SELECT * FROM t1
13+
WHERE
14+
t1.a IN (SELECT /*+ SEMIJOIN(LOOSESCAN) */ a FROM t2) AND
15+
t1.b IN (SELECT /*+ SEMIJOIN(LOOSESCAN) */ a FROM t3);
16+
id select_type table type possible_keys key key_len ref rows filtered Extra
17+
1 PRIMARY t2 index a a 4 NULL 6 100.00 Using index; LooseScan
18+
1 PRIMARY t1 eq_ref a a 4 test.t2.a 1 16.67 Using where
19+
1 PRIMARY t3 ref a a 4 test.t1.b 1 100.00 Using index; Start temporary; End temporary
20+
Warnings:
21+
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`
22+
DROP TABLE t1,t2,t3;
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,21 @@
1+
--echo #
2+
--echo # MDEV-36169: LooseScan optimization picks invalid plan
3+
--echo #
4+
5+
--source include/have_innodb.inc
6+
7+
CREATE TABLE t1 (a INTEGER NOT NULL, b INT, UNIQUE KEY (a)) engine=InnoDB;
8+
CREATE TABLE t2 (a INTEGER NOT NULL, KEY (a));
9+
CREATE TABLE t3 (a INTEGER NOT NULL, b INT, KEY (a));
10+
INSERT INTO t1 VALUES (1,10), (2,20), (3,30), (4,40);
11+
INSERT INTO t2 VALUES (2), (2), (3), (3), (4), (5);
12+
INSERT INTO t3 VALUES (10,3), (15,3), (20,4), (30,5);
13+
14+
--echo # Must not be: t3, t3(LooseScan), t1
15+
EXPLAIN EXTENDED
16+
SELECT * FROM t1
17+
WHERE
18+
t1.a IN (SELECT /*+ SEMIJOIN(LOOSESCAN) */ a FROM t2) AND
19+
t1.b IN (SELECT /*+ SEMIJOIN(LOOSESCAN) */ a FROM t3);
20+
21+
DROP TABLE t1,t2,t3;

sql/opt_subselect.cc

+17-4
Original file line numberDiff line numberDiff line change
@@ -3401,11 +3401,24 @@ bool LooseScan_picker::check_qep(JOIN *join,
34013401
then
34023402
stop considering loose scan
34033403
*/
3404-
if ((first_loosescan_table != MAX_TABLES) && // (1)
3405-
(first->table->emb_sj_nest->sj_inner_tables & remaining_tables) && //(2)
3406-
new_join_tab->emb_sj_nest != first->table->emb_sj_nest) //(2)
3404+
if (first_loosescan_table != MAX_TABLES)
3405+
//(first->table->emb_sj_nest->sj_inner_tables & remaining_tables) && //(2)
34073406
{
3408-
first_loosescan_table= MAX_TABLES;
3407+
bool interleaving=false;
3408+
if (new_join_tab->emb_sj_nest)
3409+
{
3410+
interleaving=
3411+
MY_TEST(new_join_tab->emb_sj_nest != first->table->emb_sj_nest);
3412+
}
3413+
else
3414+
{
3415+
interleaving= (first->table->emb_sj_nest->sj_inner_tables & remaining_tables);
3416+
}
3417+
if (interleaving)
3418+
{
3419+
first_loosescan_table= MAX_TABLES;
3420+
return FALSE;
3421+
}
34093422
}
34103423

34113424
/*

0 commit comments

Comments
 (0)