Commit b1c8ea83 authored by Igor Babaev's avatar Igor Babaev

MDEV-32064 Crash when searching for the best split of derived table

This bug could affect queries with IN subqueries in WHERE clause and using
derived tables to which split optimization potentially could be applied.

When looking for the best split of a splittable derived table T any key
access from a semi-join materialized table used for lookups S to table T
must be excluded from consideration because in the current implementation
of such tables as S the values from its records cannot be used to access
other tables.

Approved by Oleksandr Byelkin <sanja@mariadb.com>
parent 0ca699bf
......@@ -18442,4 +18442,120 @@ a SUBQ
4 1=11373
5 1=11612
drop table t1,t2,t3;
#
# MDEV-32064: usage of splittable derived table in query
# with IN subquery in WHERE
#
CREATE TABLE t1 (
id int unsigned NOT NULL,
valint1 int unsigned,
valdouble double,
valdate datetime,
PRIMARY KEY (id),
KEY (valint1),
KEY (valint1,valdate)
) ENGINE=MyISAM;
INSERT INTO t1 VALUES
(1,3289763,1,'2021-02-09 18:31:35'),(2,3289750,1,'2021-02-09 18:31:35'),
(3,3289780,1173,'2021-02-09 18:31:35'),(4,3289762,2,'2021-02-09 18:31:36'),
(5,3289774,2334,'2021-02-09 18:31:36'),(6,3289739,1934,'2021-02-09 18:31:36'),
(7,3289761,1,'2021-02-09 18:31:37'),(8,3289763,1,'2021-02-10 11:05:19'),
(9,3289750,1,'2021-02-10 11:05:19'),(10,3289780,0,'2021-02-10 11:05:35'),
(11,3289762,2,'2021-02-10 11:05:47'),(12,3289774,429,'2021-02-10 11:05:47'),
(13,3289739,1958,'2021-02-10 11:06:00'),(14,3289761,1,'2021-02-10 11:06:08'),
(15,3289957,0,'2021-02-10 13:04:44'),(16,3289988,1993,'2021-02-10 13:04:45'),
(17,3289951,1896,'2021-02-10 13:04:59'),(18,3289957,1994,'2021-02-10 13:07:40'),
(19,3289988,5,'2021-02-10 13:07:40'),(20,3289951,1897,'2021-02-10 13:07:40'),
(21,3289594,0,'2021-02-11 14:19:38'),(22,3289642,0,'2021-02-11 14:19:38'),
(23,3289626,2150,'2021-02-11 14:19:38'),(24,3289562,0,'2021-02-11 14:19:39'),
(25,3289593,1046,'2021-02-11 14:19:39'),(26,3289496,1,'2021-02-11 14:19:45'),
(27,3289475,1074,'2021-02-11 14:19:50'),(28,3289658,1155,'2021-02-11 14:19:56'),
(29,3289595,0,'2021-02-11 14:20:01'),(30,3290334,903,'2021-02-11 16:22:44'),
(31,3290284,479,'2021-02-11 16:23:00'),(32,3290327,236,'2021-02-11 16:23:00'),
(33,3290854,0,'2021-02-15 17:29:59'),(34,3290824,0,'2021-02-15 17:30:13'),
(35,3290875,0,'2021-02-15 17:30:14'),(36,3290897,2,'2021-02-15 17:30:19'),
(37,3290800,0,'2021-02-15 17:30:24'),(38,3290822,0,'2021-02-15 17:30:25'),
(39,3290901,2667,'2021-02-15 17:30:30'),(40,3290835,0,'2021-02-15 17:30:36'),
(41,3290875,0,'2021-02-15 17:35:33'),(42,3290824,1330,'2021-02-15 17:35:39'),
(43,3290854,769,'2021-02-15 17:35:44'),(44,3290897,2,'2021-02-15 17:35:50'),
(45,3290822,748,'2021-02-15 17:35:50'),(46,3290800,1007,'2021-02-15 17:35:56'),
(47,3290901,7018,'2021-02-15 17:35:56'),(48,3290835,779,'2021-02-15 17:36:17'),
(49,3290824,1329,'2021-02-15 17:40:30'),(50,3290875,764,'2021-02-15 17:40:31'),
(51,3290854,763,'2021-02-15 17:40:36'),(52,3290897,2347,'2021-02-15 17:40:47'),
(53,3290822,1,'2021-02-15 17:41:01'),(54,3290800,1018,'2021-02-15 17:41:07'),
(55,3290901,3936,'2021-02-15 17:41:08'),(56,3290835,784,'2021-02-15 17:41:24'),
(57,3290824,1313,'2021-02-15 17:44:47'),(58,3290875,758,'2021-02-15 17:44:48'),
(59,3290854,767,'2021-02-15 17:44:48'),(60,3290897,2438,'2021-02-15 17:44:48'),
(61,3290822,738,'2021-02-15 17:44:49'),(62,3290800,1003,'2021-02-15 17:44:54'),
(63,3290901,4686,'2021-02-15 17:44:55'),(64,3290835,778,'2021-02-15 17:45:13'),
(65,3290824,1303,'2021-02-15 17:51:16'),(66,3290875,753,'2021-02-15 17:51:16'),
(67,3290854,766,'2021-02-15 17:51:22'),(68,3290897,1,'2021-02-15 17:51:22'),
(69,3290822,743,'2021-02-15 17:51:28'),(70,3290901,5718,'2021-02-15 17:51:33'),
(71,3290800,1018,'2021-02-15 17:51:34'),(72,3290835,785,'2021-02-15 17:51:48'),
(73,3290824,1310,'2021-02-15 18:21:30'),(74,3290875,754,'2021-02-15 18:21:30'),
(75,3290854,782,'2021-02-15 18:21:36'),(76,3290897,2,'2021-02-15 18:21:36'),
(77,3290822,745,'2021-02-15 18:21:53'),(78,3290800,1011,'2021-02-15 18:21:54'),
(79,3290901,8998,'2021-02-15 18:21:54'),(80,3290835,0,'2021-02-15 18:22:00'),
(81,3290936,0,'2021-02-15 18:25:28'),(82,3290895,0,'2021-02-15 18:25:28'),
(83,3290832,0,'2021-02-15 18:25:28'),(84,3290878,796,'2021-02-15 18:25:52'),
(85,3290900,730,'2021-02-15 18:25:52'),(86,3290856,0,'2021-02-15 18:26:11'),
(87,3290904,816,'2021-02-15 18:26:17'),(88,3290882,0,'2021-02-15 18:26:25'),
(89,3290883,1031,'2021-02-15 18:27:16'),(90,3290918,1749,'2021-02-15 18:27:17'),
(91,3290831,0,'2021-02-15 18:59:11'),(92,3290884,477,'2021-02-15 18:59:12'),
(93,3290899,483,'2021-02-15 18:59:12'),(94,3290848,486,'2021-02-15 18:59:35'),
(95,3290880,487,'2021-02-15 18:59:35'),(96,3290798,0,'2021-02-15 18:59:52'),
(97,3290777,983,'2021-02-15 19:00:10'),(98,3290811,488,'2021-02-15 19:00:10'),
(99,3290917,1283,'2021-02-15 19:00:36'),(100,3290858,482,'2021-02-15 19:00:42');
CREATE TABLE t2 (a int) ENGINE=MYISAM;
INSERT INTO t2 VALUES
(3289475),(3289496),(3289562),(3289593),(3289594),(3289595),(3289626),
(3289642),(3289658),(3289739),(3289750),(3289761),(3289762),(3289763),
(3289774),(3289780),(3289951),(3289957),(3289988),(3290034),(1231562);
ANALYZE TABLE t1,t2;
Table Op Msg_type Msg_text
test.t1 analyze status Engine-independent statistics collected
test.t1 analyze status Table is already up to date
test.t2 analyze status Engine-independent statistics collected
test.t2 analyze status OK
EXPLAIN SELECT t1.valdouble, t1.valint1
FROM t1,
(SELECT max(t.valdate) AS maxdate, t.valint1 FROM t1 t GROUP BY t.valint1)
AS dt
WHERE t1.valint1 = dt.valint1 AND
t1.valdate = dt.maxdate AND
t1.valint1 IN (SELECT * FROM t2);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY <subquery3> ALL distinct_key NULL NULL NULL 21
1 PRIMARY t1 ref valint1,valint1_2 valint1 5 test.t2.a 2 Using index condition; Using where
1 PRIMARY <derived2> ref key0 key0 11 test.t1.valdate,test.t1.valint1 10
3 MATERIALIZED t2 ALL NULL NULL NULL NULL 21 Using where
2 DERIVED t index valint1,valint1_2 valint1_2 11 NULL 100 Using index; Using temporary; Using filesort
SELECT t1.valdouble, t1.valint1
FROM t1,
(SELECT max(t.valdate) AS maxdate, t.valint1 FROM t1 t GROUP BY t.valint1)
AS dt
WHERE t1.valint1 = dt.valint1 AND
t1.valdate = dt.maxdate AND
t1.valint1 IN (SELECT * FROM t2);
valdouble valint1
1074 3289475
1 3289496
0 3289562
1046 3289593
0 3289594
0 3289595
2150 3289626
0 3289642
1155 3289658
1958 3289739
1 3289750
1 3289761
2 3289762
1 3289763
429 3289774
0 3289780
1897 3289951
1994 3289957
5 3289988
DROP TABLE t1,t2;
# End of 10.4 tests
......@@ -4013,4 +4013,92 @@ eval $q;
drop table t1,t2,t3;
--echo #
--echo # MDEV-32064: usage of splittable derived table in query
--echo # with IN subquery in WHERE
--echo #
CREATE TABLE t1 (
id int unsigned NOT NULL,
valint1 int unsigned,
valdouble double,
valdate datetime,
PRIMARY KEY (id),
KEY (valint1),
KEY (valint1,valdate)
) ENGINE=MyISAM;
INSERT INTO t1 VALUES
(1,3289763,1,'2021-02-09 18:31:35'),(2,3289750,1,'2021-02-09 18:31:35'),
(3,3289780,1173,'2021-02-09 18:31:35'),(4,3289762,2,'2021-02-09 18:31:36'),
(5,3289774,2334,'2021-02-09 18:31:36'),(6,3289739,1934,'2021-02-09 18:31:36'),
(7,3289761,1,'2021-02-09 18:31:37'),(8,3289763,1,'2021-02-10 11:05:19'),
(9,3289750,1,'2021-02-10 11:05:19'),(10,3289780,0,'2021-02-10 11:05:35'),
(11,3289762,2,'2021-02-10 11:05:47'),(12,3289774,429,'2021-02-10 11:05:47'),
(13,3289739,1958,'2021-02-10 11:06:00'),(14,3289761,1,'2021-02-10 11:06:08'),
(15,3289957,0,'2021-02-10 13:04:44'),(16,3289988,1993,'2021-02-10 13:04:45'),
(17,3289951,1896,'2021-02-10 13:04:59'),(18,3289957,1994,'2021-02-10 13:07:40'),
(19,3289988,5,'2021-02-10 13:07:40'),(20,3289951,1897,'2021-02-10 13:07:40'),
(21,3289594,0,'2021-02-11 14:19:38'),(22,3289642,0,'2021-02-11 14:19:38'),
(23,3289626,2150,'2021-02-11 14:19:38'),(24,3289562,0,'2021-02-11 14:19:39'),
(25,3289593,1046,'2021-02-11 14:19:39'),(26,3289496,1,'2021-02-11 14:19:45'),
(27,3289475,1074,'2021-02-11 14:19:50'),(28,3289658,1155,'2021-02-11 14:19:56'),
(29,3289595,0,'2021-02-11 14:20:01'),(30,3290334,903,'2021-02-11 16:22:44'),
(31,3290284,479,'2021-02-11 16:23:00'),(32,3290327,236,'2021-02-11 16:23:00'),
(33,3290854,0,'2021-02-15 17:29:59'),(34,3290824,0,'2021-02-15 17:30:13'),
(35,3290875,0,'2021-02-15 17:30:14'),(36,3290897,2,'2021-02-15 17:30:19'),
(37,3290800,0,'2021-02-15 17:30:24'),(38,3290822,0,'2021-02-15 17:30:25'),
(39,3290901,2667,'2021-02-15 17:30:30'),(40,3290835,0,'2021-02-15 17:30:36'),
(41,3290875,0,'2021-02-15 17:35:33'),(42,3290824,1330,'2021-02-15 17:35:39'),
(43,3290854,769,'2021-02-15 17:35:44'),(44,3290897,2,'2021-02-15 17:35:50'),
(45,3290822,748,'2021-02-15 17:35:50'),(46,3290800,1007,'2021-02-15 17:35:56'),
(47,3290901,7018,'2021-02-15 17:35:56'),(48,3290835,779,'2021-02-15 17:36:17'),
(49,3290824,1329,'2021-02-15 17:40:30'),(50,3290875,764,'2021-02-15 17:40:31'),
(51,3290854,763,'2021-02-15 17:40:36'),(52,3290897,2347,'2021-02-15 17:40:47'),
(53,3290822,1,'2021-02-15 17:41:01'),(54,3290800,1018,'2021-02-15 17:41:07'),
(55,3290901,3936,'2021-02-15 17:41:08'),(56,3290835,784,'2021-02-15 17:41:24'),
(57,3290824,1313,'2021-02-15 17:44:47'),(58,3290875,758,'2021-02-15 17:44:48'),
(59,3290854,767,'2021-02-15 17:44:48'),(60,3290897,2438,'2021-02-15 17:44:48'),
(61,3290822,738,'2021-02-15 17:44:49'),(62,3290800,1003,'2021-02-15 17:44:54'),
(63,3290901,4686,'2021-02-15 17:44:55'),(64,3290835,778,'2021-02-15 17:45:13'),
(65,3290824,1303,'2021-02-15 17:51:16'),(66,3290875,753,'2021-02-15 17:51:16'),
(67,3290854,766,'2021-02-15 17:51:22'),(68,3290897,1,'2021-02-15 17:51:22'),
(69,3290822,743,'2021-02-15 17:51:28'),(70,3290901,5718,'2021-02-15 17:51:33'),
(71,3290800,1018,'2021-02-15 17:51:34'),(72,3290835,785,'2021-02-15 17:51:48'),
(73,3290824,1310,'2021-02-15 18:21:30'),(74,3290875,754,'2021-02-15 18:21:30'),
(75,3290854,782,'2021-02-15 18:21:36'),(76,3290897,2,'2021-02-15 18:21:36'),
(77,3290822,745,'2021-02-15 18:21:53'),(78,3290800,1011,'2021-02-15 18:21:54'),
(79,3290901,8998,'2021-02-15 18:21:54'),(80,3290835,0,'2021-02-15 18:22:00'),
(81,3290936,0,'2021-02-15 18:25:28'),(82,3290895,0,'2021-02-15 18:25:28'),
(83,3290832,0,'2021-02-15 18:25:28'),(84,3290878,796,'2021-02-15 18:25:52'),
(85,3290900,730,'2021-02-15 18:25:52'),(86,3290856,0,'2021-02-15 18:26:11'),
(87,3290904,816,'2021-02-15 18:26:17'),(88,3290882,0,'2021-02-15 18:26:25'),
(89,3290883,1031,'2021-02-15 18:27:16'),(90,3290918,1749,'2021-02-15 18:27:17'),
(91,3290831,0,'2021-02-15 18:59:11'),(92,3290884,477,'2021-02-15 18:59:12'),
(93,3290899,483,'2021-02-15 18:59:12'),(94,3290848,486,'2021-02-15 18:59:35'),
(95,3290880,487,'2021-02-15 18:59:35'),(96,3290798,0,'2021-02-15 18:59:52'),
(97,3290777,983,'2021-02-15 19:00:10'),(98,3290811,488,'2021-02-15 19:00:10'),
(99,3290917,1283,'2021-02-15 19:00:36'),(100,3290858,482,'2021-02-15 19:00:42');
CREATE TABLE t2 (a int) ENGINE=MYISAM;
INSERT INTO t2 VALUES
(3289475),(3289496),(3289562),(3289593),(3289594),(3289595),(3289626),
(3289642),(3289658),(3289739),(3289750),(3289761),(3289762),(3289763),
(3289774),(3289780),(3289951),(3289957),(3289988),(3290034),(1231562);
ANALYZE TABLE t1,t2;
let $q=
SELECT t1.valdouble, t1.valint1
FROM t1,
(SELECT max(t.valdate) AS maxdate, t.valint1 FROM t1 t GROUP BY t.valint1)
AS dt
WHERE t1.valint1 = dt.valint1 AND
t1.valdate = dt.maxdate AND
t1.valint1 IN (SELECT * FROM t2);
eval EXPLAIN $q;
eval $q;
DROP TABLE t1,t2;
--echo # End of 10.4 tests
......@@ -987,7 +987,8 @@ SplM_plan_info * JOIN_TAB::choose_best_splitting(uint idx,
table_map needed_in_prefix= 0;
do
{
if (keyuse_ext->needed_in_prefix & remaining_tables)
if (keyuse_ext->needed_in_prefix &
(remaining_tables | this->join->sjm_lookup_tables))
{
keyuse_ext++;
continue;
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment