Commit 2fbf2277 authored by Sergei Petrunia's avatar Sergei Petrunia

MDEV-15982: Incorrect results when subquery is materialized

fix_semijoin_strategies_for_picked_join_order() should set
join->sjm_lookup_tables to be a bitmap of tables inside
SJ-Materialization-Lookup nests.
parent 24a0a74f
......@@ -1658,3 +1658,54 @@ id
12
13
drop table t1;
#
# MDEV-15982: Incorrect results when subquery is materialized
#
CREATE TABLE `t1` (`id` int(32) NOT NULL primary key);
INSERT INTO `t1` VALUES
(45), (46), (47), (48), (49), (50), (51), (52), (53), (54), (55), (56), (57), (58), (59), (60), (61), (62),
(63), (64), (65), (66), (67), (68), (69), (70), (71), (72), (73), (74), (75), (76), (77), (78), (79), (80),
(81), (82), (83), (84), (85), (86), (87), (88), (89), (90), (91), (92),(93),(94),(95),(96), (97), (98),
(99), (100), (101), (102), (103), (104), (105), (106), (107), (108), (109), (110), (111), (112), (113),
(114), (115), (116), (117), (118), (119), (120), (121), (122), (123), (124), (125), (126), (127), (128),
(129), (130), (131), (132), (133), (134), (135), (136), (137), (138), (139), (140), (141), (142), (143), (144), (145), (146),
(147), (148), (149), (150), (151), (152), (153), (154), (155), (156), (157), (158), (159), (160), (161),
(162), (163), (164), (165), (166), (167), (168), (169), (170), (171), (172), (173),
(174), (175), (176), (177), (178), (179), (180), (181), (182), (183), (2), (3), (4), (5), (6), (19), (35),
(7), (20), (8), (36), (219), (22), (10), (23), (37), (11), (24);
CREATE TABLE `t2` (`type` int , `id` int(32) NOT NULL primary key);
INSERT INTO `t2` VALUES
(2,2),(2,3),(1,4),(2,5),(1,6),(1,19),(5,7),(1,20),(1,8),(1,21),(1,9),
(1,22),(2,10),(1,23),(2,11),(1,24),(1,12),(1,25),(2,13),(2,26),(2,14),
(2,27),(1,15),(1,28),(3,16),(1,29),(2,17),(1,30),(5,18),(2,1);
CREATE TABLE `t3` (`ref_id` int(32) unsigned ,`type` varchar(80),`id` int(32) NOT NULL );
INSERT INTO `t3` VALUES
(1,'incident',31),(2,'faux pas',32),
(5,'oopsies',33),(3,'deniable',34),
(11,'wasntme',35),(10,'wasntme',36),
(17,'faux pas',37),(13,'unlikely',38),
(13,'improbable',39),(14,'incident',40),
(26,'problem',41),(14,'problem',42),
(26,'incident',43),(27,'incident',44);
explain
SELECT t2.id FROM t2,t1
WHERE t2.id IN (SELECT t3.ref_id FROM t3,t1 where t3.id = t1.id) and t2.id = t1.id;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t2 index PRIMARY PRIMARY 4 NULL 30 Using index
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1 Using where
1 PRIMARY t1 eq_ref PRIMARY PRIMARY 4 test.t2.id 1 Using index
2 MATERIALIZED t3 ALL NULL NULL NULL NULL 14
2 MATERIALIZED t1 eq_ref PRIMARY PRIMARY 4 test.t3.id 1 Using index
SELECT t2.id FROM t2,t1
WHERE t2.id IN (SELECT t3.ref_id FROM t3,t1 where t3.id = t1.id) and t2.id = t1.id;
id
10
11
set optimizer_switch='materialization=off';
SELECT t2.id FROM t2,t1
WHERE t2.id IN (SELECT t3.ref_id FROM t3,t1 where t3.id = t1.id) and t2.id = t1.id;
id
11
10
set optimizer_switch='materialization=on';
DROP TABLE t1,t2,t3;
......@@ -345,3 +345,52 @@ WHERE (
(t.id IN (0,4,12,13,1,10,3,11))
);
drop table t1;
--echo #
--echo # MDEV-15982: Incorrect results when subquery is materialized
--echo #
CREATE TABLE `t1` (`id` int(32) NOT NULL primary key);
INSERT INTO `t1` VALUES
(45), (46), (47), (48), (49), (50), (51), (52), (53), (54), (55), (56), (57), (58), (59), (60), (61), (62),
(63), (64), (65), (66), (67), (68), (69), (70), (71), (72), (73), (74), (75), (76), (77), (78), (79), (80),
(81), (82), (83), (84), (85), (86), (87), (88), (89), (90), (91), (92),(93),(94),(95),(96), (97), (98),
(99), (100), (101), (102), (103), (104), (105), (106), (107), (108), (109), (110), (111), (112), (113),
(114), (115), (116), (117), (118), (119), (120), (121), (122), (123), (124), (125), (126), (127), (128),
(129), (130), (131), (132), (133), (134), (135), (136), (137), (138), (139), (140), (141), (142), (143), (144), (145), (146),
(147), (148), (149), (150), (151), (152), (153), (154), (155), (156), (157), (158), (159), (160), (161),
(162), (163), (164), (165), (166), (167), (168), (169), (170), (171), (172), (173),
(174), (175), (176), (177), (178), (179), (180), (181), (182), (183), (2), (3), (4), (5), (6), (19), (35),
(7), (20), (8), (36), (219), (22), (10), (23), (37), (11), (24);
CREATE TABLE `t2` (`type` int , `id` int(32) NOT NULL primary key);
INSERT INTO `t2` VALUES
(2,2),(2,3),(1,4),(2,5),(1,6),(1,19),(5,7),(1,20),(1,8),(1,21),(1,9),
(1,22),(2,10),(1,23),(2,11),(1,24),(1,12),(1,25),(2,13),(2,26),(2,14),
(2,27),(1,15),(1,28),(3,16),(1,29),(2,17),(1,30),(5,18),(2,1);
CREATE TABLE `t3` (`ref_id` int(32) unsigned ,`type` varchar(80),`id` int(32) NOT NULL );
INSERT INTO `t3` VALUES
(1,'incident',31),(2,'faux pas',32),
(5,'oopsies',33),(3,'deniable',34),
(11,'wasntme',35),(10,'wasntme',36),
(17,'faux pas',37),(13,'unlikely',38),
(13,'improbable',39),(14,'incident',40),
(26,'problem',41),(14,'problem',42),
(26,'incident',43),(27,'incident',44);
explain
SELECT t2.id FROM t2,t1
WHERE t2.id IN (SELECT t3.ref_id FROM t3,t1 where t3.id = t1.id) and t2.id = t1.id;
SELECT t2.id FROM t2,t1
WHERE t2.id IN (SELECT t3.ref_id FROM t3,t1 where t3.id = t1.id) and t2.id = t1.id;
set optimizer_switch='materialization=off';
SELECT t2.id FROM t2,t1
WHERE t2.id IN (SELECT t3.ref_id FROM t3,t1 where t3.id = t1.id) and t2.id = t1.id;
set optimizer_switch='materialization=on';
DROP TABLE t1,t2,t3;
......@@ -3532,7 +3532,8 @@ void fix_semijoin_strategies_for_picked_join_order(JOIN *join)
first= tablenr - sjm->tables + 1;
join->best_positions[first].n_sj_tables= sjm->tables;
join->best_positions[first].sj_strategy= SJ_OPT_MATERIALIZE;
join->sjm_lookup_tables|= s->table->map;
for (uint i= first; i < first+ sjm->tables; i++)
join->sjm_lookup_tables |= join->best_positions[i].table->table->map;
}
else if (pos->sj_strategy == SJ_OPT_MATERIALIZE_SCAN)
{
......
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