Commit 2ba1616e authored by Igor Babaev's avatar Igor Babaev

Fixed mdev-14281 Wrong result from query with NOT IN predicate in WHERE

Conversion of NOT IN predicates into NOT IN subqueries did not work
correctly: the predicates actually were converted into IN subqueries.
As a result if the conversion was applied for the query with
a NOT IN predicate the query could return a wrong result set.
parent d957a6c1
...@@ -547,5 +547,70 @@ id select_type table type possible_keys key key_len ref rows filtered Extra ...@@ -547,5 +547,70 @@ id select_type table type possible_keys key key_len ref rows filtered Extra
Warnings: Warnings:
Note 1003 /* select#1 */ select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t2`.`c` AS `c` from `test`.`t2` semi join ((values (1,3),(8,0),(5,1)) `tvc_0`) where `test`.`t2`.`a` = `tvc_0`.`1` and `test`.`t2`.`c` = `tvc_0`.`3` and (`tvc_0`.`1`,`test`.`t2`.`b`) in (<cache>((1,2)),<cache>((8,9))) Note 1003 /* select#1 */ select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t2`.`c` AS `c` from `test`.`t2` semi join ((values (1,3),(8,0),(5,1)) `tvc_0`) where `test`.`t2`.`a` = `tvc_0`.`1` and `test`.`t2`.`c` = `tvc_0`.`3` and (`tvc_0`.`1`,`test`.`t2`.`b`) in (<cache>((1,2)),<cache>((8,9)))
set @@in_subquery_conversion_threshold= 2; set @@in_subquery_conversion_threshold= 2;
#
# mdev-14281: conversion of NOT IN predicate into subquery predicate
#
select * from t1
where (a,b) not in ((1,2),(8,9), (5,1));
a b
4 6
9 7
1 1
2 5
7 8
select * from t1
where (a,b) not in (select * from (values (1,2),(8,9), (5,1)) as tvc_0);
a b
4 6
9 7
1 1
2 5
7 8
explain extended select * from t1
where (a,b) not in ((1,2),(8,9), (5,1));
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00 Using where
2 MATERIALIZED <derived3> ALL NULL NULL NULL NULL 2 100.00
3 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used
Warnings:
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where !<expr_cache><`test`.`t1`.`a`,`test`.`t1`.`b`>(<in_optimizer>((`test`.`t1`.`a`,`test`.`t1`.`b`),(`test`.`t1`.`a`,`test`.`t1`.`b`) in ( <materialize> (/* select#2 */ select `tvc_0`.`1`,`tvc_0`.`2` from (values (1,2),(8,9),(5,1)) `tvc_0` ), <primary_index_lookup>(`test`.`t1`.`a` in <temporary table> on distinct_key where `test`.`t1`.`a` = `<subquery2>`.`1` and `test`.`t1`.`b` = `<subquery2>`.`2`))))
explain extended select * from t1
where (a,b) not in (select * from (values (1,2),(8,9), (5,1)) as tvc_0);
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00 Using where
2 MATERIALIZED <derived3> ALL NULL NULL NULL NULL 2 100.00
3 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used
Warnings:
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where !<expr_cache><`test`.`t1`.`a`,`test`.`t1`.`b`>(<in_optimizer>((`test`.`t1`.`a`,`test`.`t1`.`b`),(`test`.`t1`.`a`,`test`.`t1`.`b`) in ( <materialize> (/* select#2 */ select `tvc_0`.`1`,`tvc_0`.`2` from (values (1,2),(8,9),(5,1)) `tvc_0` ), <primary_index_lookup>(`test`.`t1`.`a` in <temporary table> on distinct_key where `test`.`t1`.`a` = `<subquery2>`.`1` and `test`.`t1`.`b` = `<subquery2>`.`2`))))
select * from t1
where b < 7 and (a,b) not in ((1,2),(8,9), (5,1));
a b
4 6
1 1
2 5
explain extended select * from t1
where b < 7 and (a,b) not in ((1,2),(8,9), (5,1));
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 6 100.00 Using where
2 MATERIALIZED <derived3> ALL NULL NULL NULL NULL 2 100.00
3 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used
Warnings:
Note 1003 /* select#1 */ select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t1` where `test`.`t1`.`b` < 7 and !<expr_cache><`test`.`t1`.`a`,`test`.`t1`.`b`>(<in_optimizer>((`test`.`t1`.`a`,`test`.`t1`.`b`),(`test`.`t1`.`a`,`test`.`t1`.`b`) in ( <materialize> (/* select#2 */ select `tvc_0`.`1`,`tvc_0`.`2` from (values (1,2),(8,9),(5,1)) `tvc_0` ), <primary_index_lookup>(`test`.`t1`.`a` in <temporary table> on distinct_key where `test`.`t1`.`a` = `<subquery2>`.`1` and `test`.`t1`.`b` = `<subquery2>`.`2`))))
select * from t2
where (a,c) not in ((1,2),(8,9), (5,1));
a b c
1 2 3
5 1 2
4 3 7
8 9 0
10 7 1
explain extended select * from t2
where (a,c) not in ((1,2),(8,9), (5,1));
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 6 100.00 Using where
2 MATERIALIZED <derived3> ALL NULL NULL NULL NULL 2 100.00
3 DERIVED NULL NULL NULL NULL NULL NULL NULL NULL No tables used
Warnings:
Note 1003 /* select#1 */ select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b`,`test`.`t2`.`c` AS `c` from `test`.`t2` where !<expr_cache><`test`.`t2`.`a`,`test`.`t2`.`c`>(<in_optimizer>((`test`.`t2`.`a`,`test`.`t2`.`c`),(`test`.`t2`.`a`,`test`.`t2`.`c`) in ( <materialize> (/* select#2 */ select `tvc_0`.`1`,`tvc_0`.`2` from (values (1,2),(8,9),(5,1)) `tvc_0` ), <primary_index_lookup>(`test`.`t2`.`a` in <temporary table> on distinct_key where `test`.`t2`.`a` = `<subquery2>`.`1` and `test`.`t2`.`c` = `<subquery2>`.`2`))))
drop table t1, t2, t3; drop table t1, t2, t3;
set @@in_subquery_conversion_threshold= default; set @@in_subquery_conversion_threshold= default;
...@@ -282,5 +282,34 @@ eval $query; ...@@ -282,5 +282,34 @@ eval $query;
eval explain extended $query; eval explain extended $query;
set @@in_subquery_conversion_threshold= 2; set @@in_subquery_conversion_threshold= 2;
--echo #
--echo # mdev-14281: conversion of NOT IN predicate into subquery predicate
--echo #
let $query=
select * from t1
where (a,b) not in ((1,2),(8,9), (5,1));
let $optimized_query=
select * from t1
where (a,b) not in (select * from (values (1,2),(8,9), (5,1)) as tvc_0);
eval $query;
eval $optimized_query;
eval explain extended $query;
eval explain extended $optimized_query;
let $query=
select * from t1
where b < 7 and (a,b) not in ((1,2),(8,9), (5,1));
eval $query;
eval explain extended $query;
let $query=
select * from t2
where (a,c) not in ((1,2),(8,9), (5,1));
eval $query;
eval explain extended $query;
drop table t1, t2, t3; drop table t1, t2, t3;
set @@in_subquery_conversion_threshold= default;
\ No newline at end of file set @@in_subquery_conversion_threshold= default;
...@@ -1043,4 +1043,4 @@ select * from (values (1), (b), (2)) as new_tvc; ...@@ -1043,4 +1043,4 @@ select * from (values (1), (b), (2)) as new_tvc;
--error ER_FIELD_REFERENCE_IN_TVC --error ER_FIELD_REFERENCE_IN_TVC
select * from (values (1), (t1.b), (2)) as new_tvc; select * from (values (1), (t1.b), (2)) as new_tvc;
drop table t1; drop table t1;
\ No newline at end of file
...@@ -728,20 +728,25 @@ Item *Item_func_in::in_predicate_to_in_subs_transformer(THD *thd, ...@@ -728,20 +728,25 @@ Item *Item_func_in::in_predicate_to_in_subs_transformer(THD *thd,
/* Create IN subquery predicate */ /* Create IN subquery predicate */
sq_select->parsing_place= parent_select->parsing_place; sq_select->parsing_place= parent_select->parsing_place;
Item_in_subselect *in_subs; Item_in_subselect *in_subs;
Item *sq;
if (!(in_subs= if (!(in_subs=
new (thd->mem_root) Item_in_subselect(thd, args[0], sq_select))) new (thd->mem_root) Item_in_subselect(thd, args[0], sq_select)))
goto err; goto err;
in_subs->emb_on_expr_nest= emb_on_expr_nest; sq= in_subs;
if (negated)
sq= negate_expression(thd, in_subs);
else
in_subs->emb_on_expr_nest= emb_on_expr_nest;
if (arena) if (arena)
thd->restore_active_arena(arena, &backup); thd->restore_active_arena(arena, &backup);
thd->lex->current_select= parent_select; thd->lex->current_select= parent_select;
if (in_subs->fix_fields(thd, (Item **)&in_subs)) if (sq->fix_fields(thd, (Item **)&sq))
goto err; goto err;
parent_select->curr_tvc_name++; parent_select->curr_tvc_name++;
return in_subs; return sq;
err: err:
if (arena) if (arena)
...@@ -847,3 +852,4 @@ bool JOIN::transform_in_predicates_into_in_subq(THD *thd) ...@@ -847,3 +852,4 @@ bool JOIN::transform_in_predicates_into_in_subq(THD *thd)
thd->lex->current_select= save_current_select; thd->lex->current_select= save_current_select;
DBUG_RETURN(false); DBUG_RETURN(false);
} }
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