MDEV-23723: Crash when test_if_skip_sort_order() is checked for derived ...
The problem was caused by the following scenario: Subquery's table has two indexes, KEY a(a), KEY a_b(a,b) - LATERAL DERIVED optimization decides to use index a. = The subquery uses ref access over key a. - test_if_skip_sort_order() sees that KEY a_b satisfies the subquery's GROUP BY clause, and attempts to switch to it. = It fails to do so, because KEYUSE objects for index a_b are switched off. Fixed by disallowing to change the ref access key if it uses KEYUSE objects injected by LATERAL DERIVED optimization.
This commit is contained in:
parent
8f9a72a150
commit
2820f30dde
@ -140,3 +140,37 @@ id select_type table type possible_keys key key_len ref rows Extra
|
||||
2 DERIVED t2 index NULL PRIMARY 4 NULL 3
|
||||
drop view v1;
|
||||
drop table t1,t2;
|
||||
#
|
||||
# MDEV-23723: Crash when test_if_skip_sort_order() is checked for derived table subject to split
|
||||
#
|
||||
CREATE TABLE t1 (a INT, b INT, KEY (a), KEY (a,b)) ENGINE=InnoDB;
|
||||
CREATE TABLE t2 (c INT, KEY (c)) ENGINE=InnoDB;
|
||||
SELECT * FROM t1 t1a JOIN t1 t1b;
|
||||
a b a b
|
||||
INSERT INTO t2 VALUES (1),(2);
|
||||
INSERT INTO t1 VALUES (1,2),(3,4),(5,6),(7,8),(9,10),(11,12);
|
||||
set statement optimizer_switch='split_materialized=off' for EXPLAIN
|
||||
SELECT *
|
||||
FROM
|
||||
t1 JOIN
|
||||
(SELECT t1.a, t1.b FROM t1, t2 WHERE t1.b = t2.c GROUP BY t1.a, t1.b) as dt
|
||||
WHERE
|
||||
t1.a = dt.a;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1 index a,a_2 a_2 10 NULL 6 Using where; Using index
|
||||
1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2
|
||||
2 DERIVED t1 index NULL a_2 10 NULL 6 Using where; Using index
|
||||
2 DERIVED t2 ref c c 5 test.t1.b 1 Using index
|
||||
set statement optimizer_switch='split_materialized=on' for EXPLAIN
|
||||
SELECT *
|
||||
FROM
|
||||
t1 JOIN
|
||||
(SELECT t1.a, t1.b FROM t1, t2 WHERE t1.b = t2.c GROUP BY t1.a, t1.b) as dt
|
||||
WHERE
|
||||
t1.a = dt.a;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY t1 index a,a_2 a_2 10 NULL 6 Using where; Using index
|
||||
1 PRIMARY <derived2> ref key0 key0 5 test.t1.a 2
|
||||
2 LATERAL DERIVED t1 ref a,a_2 a 5 test.t1.a 1 Using where; Using temporary; Using filesort
|
||||
2 LATERAL DERIVED t2 ref c c 5 test.t1.b 1 Using index
|
||||
DROP TABLE t1, t2;
|
||||
|
@ -124,3 +124,29 @@ eval set statement optimizer_switch='split_materialized=off' for explain $q;
|
||||
drop view v1;
|
||||
|
||||
drop table t1,t2;
|
||||
|
||||
--echo #
|
||||
--echo # MDEV-23723: Crash when test_if_skip_sort_order() is checked for derived table subject to split
|
||||
--echo #
|
||||
CREATE TABLE t1 (a INT, b INT, KEY (a), KEY (a,b)) ENGINE=InnoDB;
|
||||
CREATE TABLE t2 (c INT, KEY (c)) ENGINE=InnoDB;
|
||||
|
||||
SELECT * FROM t1 t1a JOIN t1 t1b;
|
||||
|
||||
INSERT INTO t2 VALUES (1),(2);
|
||||
INSERT INTO t1 VALUES (1,2),(3,4),(5,6),(7,8),(9,10),(11,12);
|
||||
|
||||
let $query=
|
||||
EXPLAIN
|
||||
SELECT *
|
||||
FROM
|
||||
t1 JOIN
|
||||
(SELECT t1.a, t1.b FROM t1, t2 WHERE t1.b = t2.c GROUP BY t1.a, t1.b) as dt
|
||||
WHERE
|
||||
t1.a = dt.a;
|
||||
|
||||
eval set statement optimizer_switch='split_materialized=off' for $query;
|
||||
eval set statement optimizer_switch='split_materialized=on' for $query;
|
||||
|
||||
DROP TABLE t1, t2;
|
||||
|
||||
|
@ -10102,6 +10102,7 @@ static bool create_ref_for_key(JOIN *join, JOIN_TAB *j,
|
||||
j->ref.disable_cache= FALSE;
|
||||
j->ref.null_ref_part= NO_REF_PART;
|
||||
j->ref.const_ref_part_map= 0;
|
||||
j->ref.uses_splitting= FALSE;
|
||||
keyuse=org_keyuse;
|
||||
|
||||
store_key **ref_key= j->ref.key_copy;
|
||||
@ -10150,6 +10151,7 @@ static bool create_ref_for_key(JOIN *join, JOIN_TAB *j,
|
||||
j->ref.null_rejecting|= (key_part_map)1 << i;
|
||||
|
||||
keyuse_uses_no_tables= keyuse_uses_no_tables && !keyuse->used_tables;
|
||||
j->ref.uses_splitting |= (keyuse->validity_ref != NULL);
|
||||
/*
|
||||
We don't want to compute heavy expressions in EXPLAIN, an example would
|
||||
select * from t1 where t1.key=(select thats very heavy);
|
||||
@ -22536,7 +22538,8 @@ test_if_skip_sort_order(JOIN_TAB *tab,ORDER *order,ha_rows select_limit,
|
||||
todo: why does JT_REF_OR_NULL mean filesort? We could find another index
|
||||
that satisfies the ordering. I would just set ref_key=MAX_KEY here...
|
||||
*/
|
||||
if (tab->type == JT_REF_OR_NULL || tab->type == JT_FT)
|
||||
if (tab->type == JT_REF_OR_NULL || tab->type == JT_FT ||
|
||||
tab->ref.uses_splitting)
|
||||
goto use_filesort;
|
||||
}
|
||||
else if (select && select->quick) // Range found by opt_range
|
||||
|
@ -178,6 +178,12 @@ typedef struct st_table_ref
|
||||
*/
|
||||
bool disable_cache;
|
||||
|
||||
/*
|
||||
If true, this ref access was constructed from equalities generated by
|
||||
LATERAL DERIVED (aka GROUP BY splitting) optimization
|
||||
*/
|
||||
bool uses_splitting;
|
||||
|
||||
bool tmp_table_index_lookup_init(THD *thd, KEY *tmp_key, Item_iterator &it,
|
||||
bool value, uint skip= 0);
|
||||
bool is_access_triggered();
|
||||
|
Loading…
x
Reference in New Issue
Block a user