Skip to content

Commit

Permalink
MDEV-23878 Wrong result with semi-join and splittable derived table
Browse files Browse the repository at this point in the history
Due to this bug a wrong result might be expected from queries with
an IN subquery predicate in the WHERE clause and a derived table in the
FROM clause to which split optimization could be applied.

The function JOIN::fix_all_splittings_in_plan() used the value of the
bitmap JOIN::sjm_lookup_tables() such as it had been left after the
search for the best plan for the select containing the splittable
derived table. That value could not be guaranteed to be correct. So the
recalculation of this bitmap is needed to exclude the plans with key
accesses from SJM lookup tables.

Approved by Igor Babaev <igor@maridb.com>
  • Loading branch information
mariadb-galinashalygina committed May 7, 2024
1 parent 10a7599 commit 4bc1860
Show file tree
Hide file tree
Showing 3 changed files with 103 additions and 1 deletion.
57 changes: 57 additions & 0 deletions mysql-test/main/derived_split_innodb.result
Original file line number Diff line number Diff line change
Expand Up @@ -848,4 +848,61 @@ SELECT * FROM t1 WHERE t1.a IN (SELECT b FROM
(SELECT t2.b FROM t2 WHERE NOT EXISTS (SELECT 1 FROM t3) GROUP BY b) sq);
a
DROP TABLE t1, t2, t3;
#
# MDEV-23878: Wrong result with semi-join and splittable derived table
#
CREATE TABLE t1 (
groupId int,
id int unsigned,
PRIMARY KEY (groupId, id)
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
INSERT INTO t1 VALUES
(8,1),(8,2),(8,3),(8,4),(8,5),(8,6),(8,7),(8,8),(8,9),(8,10),
(8,11),(8,12),(8,13),(8,14),(8,15),(8,16),(8,17),(8,18),(8,19);
set statement in_predicate_conversion_threshold=2 for SELECT COUNT(*) AS cnt FROM t1
JOIN
(
SELECT groupId, id
FROM t1
WHERE id IN (1,2,3,4,5,6)
GROUP BY groupId, id
) AS t2
USING (groupId, id)
WHERE id IN (1,2,3,4,5,6,7,8);
cnt
6
set statement in_predicate_conversion_threshold=2 for EXPLAIN SELECT COUNT(*) AS cnt FROM t1
JOIN
(
SELECT groupId, id
FROM t1
WHERE id IN (1,2,3,4,5,6)
GROUP BY groupId, id
) AS t2
USING (groupId, id)
WHERE id IN (1,2,3,4,5,6,7,8);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 index PRIMARY PRIMARY 8 NULL 19 Using index
1 PRIMARY <subquery4> eq_ref distinct_key distinct_key 4 func 1 Using where
1 PRIMARY <derived3> ref key0 key0 8 test.t1.groupId,test.t1.id 2
4 MATERIALIZED <derived5> ALL NULL NULL NULL NULL 8
5 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used
3 LATERAL DERIVED t1 eq_ref PRIMARY PRIMARY 8 test.t1.groupId,test.t1.id 1 Using index
3 LATERAL DERIVED <derived7> ref key0 key0 4 test.t1.id 2 Using where; FirstMatch(t1)
7 DERIVED NULL NULL NULL NULL NULL NULL NULL No tables used
set statement optimizer_switch='split_materialized=off, loosescan=off' for
set statement in_predicate_conversion_threshold=2 for
SELECT COUNT(*) AS cnt FROM t1
JOIN
(
SELECT groupId, id
FROM t1
WHERE id IN (1,2,3,4,5,6)
GROUP BY groupId, id
) AS t2
USING (groupId, id)
WHERE id IN (1,2,3,4,5,6,7,8);
cnt
6
DROP TABLE t1;
# End of 10.4 tests
42 changes: 42 additions & 0 deletions mysql-test/main/derived_split_innodb.test
Original file line number Diff line number Diff line change
Expand Up @@ -503,4 +503,46 @@ SELECT * FROM t1 WHERE t1.a IN (SELECT b FROM

DROP TABLE t1, t2, t3;

--echo #
--echo # MDEV-23878: Wrong result with semi-join and splittable derived table
--echo #

CREATE TABLE t1 (
groupId int,
id int unsigned,
PRIMARY KEY (groupId, id)
) ENGINE=InnoDB DEFAULT CHARSET=latin1;

INSERT INTO t1 VALUES
(8,1),(8,2),(8,3),(8,4),(8,5),(8,6),(8,7),(8,8),(8,9),(8,10),
(8,11),(8,12),(8,13),(8,14),(8,15),(8,16),(8,17),(8,18),(8,19);

let $query=
SELECT COUNT(*) AS cnt FROM t1
JOIN
(
SELECT groupId, id
FROM t1
WHERE id IN (1,2,3,4,5,6)
GROUP BY groupId, id
) AS t2
USING (groupId, id)
WHERE id IN (1,2,3,4,5,6,7,8);

let $tvc_conversion_threshold =
set statement in_predicate_conversion_threshold=2 for;

eval $tvc_conversion_threshold $query;
eval $tvc_conversion_threshold EXPLAIN $query;

let $no_split_materialized_loosescan=
set statement optimizer_switch='split_materialized=off, loosescan=off' for;

# Correct result with split materializied optimization disabled
eval $no_split_materialized_loosescan
$tvc_conversion_threshold
$query;

DROP TABLE t1;

--echo # End of 10.4 tests
5 changes: 4 additions & 1 deletion sql/opt_split.cc
Original file line number Diff line number Diff line change
Expand Up @@ -1332,6 +1332,7 @@ bool JOIN::fix_all_splittings_in_plan()
{
table_map prev_tables= 0;
table_map all_tables= (table_map(1) << table_count) - 1;
table_map prev_sjm_lookup_tables= 0;
for (uint tablenr= 0; tablenr < table_count; tablenr++)
{
POSITION *cur_pos= &best_positions[tablenr];
Expand All @@ -1340,7 +1341,7 @@ bool JOIN::fix_all_splittings_in_plan()
{
SplM_plan_info *spl_plan= cur_pos->spl_plan;
table_map excluded_tables= (all_tables & ~prev_tables) |
sjm_lookup_tables;
prev_sjm_lookup_tables;
;
if (spl_plan)
{
Expand All @@ -1358,6 +1359,8 @@ bool JOIN::fix_all_splittings_in_plan()
return true;
}
prev_tables|= tab->table->map;
if (cur_pos->sj_strategy == SJ_OPT_MATERIALIZE)
prev_sjm_lookup_tables|= tab->table->map;
}
return false;
}
Expand Down

0 comments on commit 4bc1860

Please sign in to comment.