Commit 5fb2c586 authored by Varun Gupta's avatar Varun Gupta

MDEV-16225: wrong resultset from query with semijoin=on

For non-semi-join subquery optimization we do a cost based decision between
Materialisation and IN -> EXIST transformation. The issue in this case is that for IN->EXIST transformation
we run JOIN::reoptimize with the IN->EXISt conditions and we come up with a new query plan. But when we compare
the cost with Materialization, we make the decision to chose Materialization so we need to restore the query plan
for Materilization.
The saving and restoring for keyuse array and join_tab keyuse is only done when we have atleast
one element in the keyuse_array , we are now changing to do it even for 0 elements to main the generality.
parent 1ada4afb
...@@ -1601,3 +1601,60 @@ id select_type table type possible_keys key key_len ref rows Extra ...@@ -1601,3 +1601,60 @@ id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 11 func 1 1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 11 func 1
2 MATERIALIZED t2 ALL NULL NULL NULL NULL 3 Using where 2 MATERIALIZED t2 ALL NULL NULL NULL NULL 3 Using where
DROP TABLE t1,t2; DROP TABLE t1,t2;
#
# MDEV-16225: wrong resultset from query with semijoin=on
#
CREATE TABLE t1 (
`id` int(10) NOT NULL AUTO_INCREMENT,
`local_name` varchar(64) NOT NULL,
PRIMARY KEY (`id`)
) ENGINE=InnoDB AUTO_INCREMENT=14 DEFAULT CHARSET=latin1;
insert into t1(`id`,`local_name`) values
(1,'Cash Advance'),
(2,'Cash Advance'),
(3,'Rollover'),
(4,'AL Installment'),
(5,'AL Installment'),
(6,'AL Installment'),
(7,'AL Installment'),
(8,'AL Installment'),
(9,'AL Installment'),
(10,'Internet Payday'),
(11,'Rollover - Internet Payday'),
(12,'AL Monthly Installment'),
(13,'AL Semi-Monthly Installment');
explain
SELECT SQL_NO_CACHE t.id
FROM t1 t
WHERE (
t.id IN (SELECT A.id FROM t1 AS A WHERE A.local_name IN (SELECT B.local_name FROM t1 AS B WHERE B.id IN (0,4,12,13,1,10,3,11)))
OR
(t.id IN (0,4,12,13,1,10,3,11))
);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t index PRIMARY PRIMARY 4 NULL 13 Using where; Using index
2 MATERIALIZED <subquery3> ALL distinct_key NULL NULL NULL 8
2 MATERIALIZED A ALL PRIMARY NULL NULL NULL 13 Using where; Using join buffer (flat, BNL join)
3 MATERIALIZED B ALL PRIMARY NULL NULL NULL 13 Using where
SELECT SQL_NO_CACHE t.id
FROM t1 t
WHERE (
t.id IN (SELECT A.id FROM t1 AS A WHERE A.local_name IN (SELECT B.local_name FROM t1 AS B WHERE B.id IN (0,4,12,13,1,10,3,11)))
OR
(t.id IN (0,4,12,13,1,10,3,11))
);
id
1
2
3
4
5
6
7
8
9
10
11
12
13
drop table t1;
...@@ -303,3 +303,45 @@ eval $q; ...@@ -303,3 +303,45 @@ eval $q;
eval explain $q; eval explain $q;
DROP TABLE t1,t2; DROP TABLE t1,t2;
--echo #
--echo # MDEV-16225: wrong resultset from query with semijoin=on
--echo #
CREATE TABLE t1 (
`id` int(10) NOT NULL AUTO_INCREMENT,
`local_name` varchar(64) NOT NULL,
PRIMARY KEY (`id`)
) ENGINE=InnoDB AUTO_INCREMENT=14 DEFAULT CHARSET=latin1;
insert into t1(`id`,`local_name`) values
(1,'Cash Advance'),
(2,'Cash Advance'),
(3,'Rollover'),
(4,'AL Installment'),
(5,'AL Installment'),
(6,'AL Installment'),
(7,'AL Installment'),
(8,'AL Installment'),
(9,'AL Installment'),
(10,'Internet Payday'),
(11,'Rollover - Internet Payday'),
(12,'AL Monthly Installment'),
(13,'AL Semi-Monthly Installment');
explain
SELECT SQL_NO_CACHE t.id
FROM t1 t
WHERE (
t.id IN (SELECT A.id FROM t1 AS A WHERE A.local_name IN (SELECT B.local_name FROM t1 AS B WHERE B.id IN (0,4,12,13,1,10,3,11)))
OR
(t.id IN (0,4,12,13,1,10,3,11))
);
SELECT SQL_NO_CACHE t.id
FROM t1 t
WHERE (
t.id IN (SELECT A.id FROM t1 AS A WHERE A.local_name IN (SELECT B.local_name FROM t1 AS B WHERE B.id IN (0,4,12,13,1,10,3,11)))
OR
(t.id IN (0,4,12,13,1,10,3,11))
);
drop table t1;
...@@ -23739,8 +23739,6 @@ void JOIN::set_allowed_join_cache_types() ...@@ -23739,8 +23739,6 @@ void JOIN::set_allowed_join_cache_types()
void JOIN::save_query_plan(Join_plan_state *save_to) void JOIN::save_query_plan(Join_plan_state *save_to)
{ {
if (keyuse.elements)
{
DYNAMIC_ARRAY tmp_keyuse; DYNAMIC_ARRAY tmp_keyuse;
/* Swap the current and the backup keyuse internal arrays. */ /* Swap the current and the backup keyuse internal arrays. */
tmp_keyuse= keyuse; tmp_keyuse= keyuse;
...@@ -23754,7 +23752,6 @@ void JOIN::save_query_plan(Join_plan_state *save_to) ...@@ -23754,7 +23752,6 @@ void JOIN::save_query_plan(Join_plan_state *save_to)
save_to->join_tab_checked_keys[i]= join_tab[i].checked_keys; save_to->join_tab_checked_keys[i]= join_tab[i].checked_keys;
join_tab[i].checked_keys.clear_all(); join_tab[i].checked_keys.clear_all();
} }
}
memcpy((uchar*) save_to->best_positions, (uchar*) best_positions, memcpy((uchar*) save_to->best_positions, (uchar*) best_positions,
sizeof(POSITION) * (table_count + 1)); sizeof(POSITION) * (table_count + 1));
memset(best_positions, 0, sizeof(POSITION) * (table_count + 1)); memset(best_positions, 0, sizeof(POSITION) * (table_count + 1));
...@@ -23791,8 +23788,6 @@ void JOIN::reset_query_plan() ...@@ -23791,8 +23788,6 @@ void JOIN::reset_query_plan()
void JOIN::restore_query_plan(Join_plan_state *restore_from) void JOIN::restore_query_plan(Join_plan_state *restore_from)
{ {
if (restore_from->keyuse.elements)
{
DYNAMIC_ARRAY tmp_keyuse; DYNAMIC_ARRAY tmp_keyuse;
tmp_keyuse= keyuse; tmp_keyuse= keyuse;
keyuse= restore_from->keyuse; keyuse= restore_from->keyuse;
...@@ -23804,7 +23799,6 @@ void JOIN::restore_query_plan(Join_plan_state *restore_from) ...@@ -23804,7 +23799,6 @@ void JOIN::restore_query_plan(Join_plan_state *restore_from)
join_tab[i].checked_keys= restore_from->join_tab_checked_keys[i]; join_tab[i].checked_keys= restore_from->join_tab_checked_keys[i];
} }
}
memcpy((uchar*) best_positions, (uchar*) restore_from->best_positions, memcpy((uchar*) best_positions, (uchar*) restore_from->best_positions,
sizeof(POSITION) * (table_count + 1)); sizeof(POSITION) * (table_count + 1));
/* Restore SJM nests */ /* Restore SJM nests */
......
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