Commit d3fa2453 authored by igor@rurik.mysql.com's avatar igor@rurik.mysql.com

subselect.result, subselect.test:

  Added test cases for bug #7351.
item_cmpfunc.cc:
  Fixed bug #7351: incorrect result for a query with a
  subquery returning empty set.
  If in the predicate v IN (SELECT a FROM t WHERE cond)
  v is null, then the result of the predicate is either
  INKNOWN or FALSE. It is FALSE if the subquery returns
  an empty set.
item_subselect.cc:
  Fixed bug #7351: incorrect result for a query with a
  subquery returning empty set.
  The problem was due to not a quite legal transformation
  for 'IN' subqueries. A subquery containing a predicate
  of the form
  v IN (SELECT a FROM t WHERE cond)
  was transformed into
  EXISTS(SELECT a FROM t WHERE cond AND (a=v OR a IS NULL)).
  Yet, this transformation is valid only if v is not null.
  If v is null, then, in the case when
  (SELECT a FROM t WHERE cond) returns an empty set the value
  of the predicate is FALSE, otherwise the result of the
  predicate is INKNOWN.
  The fix resolves this problem by changing the result
  of the transformation to
  EXISTS(SELECT a FROM t WHERE cond AND (v IS NULL OR (a=v OR a IS NULL)))
  in the case when v is nullable.
  The new transformation prevents applying the lookup
  optimization for IN subqueries. To make it still
  applicable we have to introduce guarded access methods.
parent f1fe6e17
...@@ -1425,7 +1425,7 @@ Note 1003 (select test.t1.s1 AS `s1` from test.t1) ...@@ -1425,7 +1425,7 @@ Note 1003 (select test.t1.s1 AS `s1` from test.t1)
s1 s1
tttt tttt
drop table t1; drop table t1;
create table t1 (s1 char(5), index s1(s1)); create table t1 (s1 char(5) not null, index s1(s1));
create table t2 (s1 char(5), index s1(s1)); create table t2 (s1 char(5), index s1(s1));
insert into t1 values ('a1'),('a2'),('a3'); insert into t1 values ('a1'),('a2'),('a3');
insert into t2 values ('a1'),('a2'); insert into t2 values ('a1'),('a2');
...@@ -1451,25 +1451,25 @@ a2 1 ...@@ -1451,25 +1451,25 @@ a2 1
a3 1 a3 1
explain extended select s1, s1 NOT IN (SELECT s1 FROM t2) from t1; explain extended select s1, s1 NOT IN (SELECT s1 FROM t2) from t1;
id select_type table type possible_keys key key_len ref rows Extra id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 index NULL s1 6 NULL 3 Using index 1 PRIMARY t1 index NULL s1 5 NULL 3 Using index
2 DEPENDENT SUBQUERY t2 index_subquery s1 s1 6 func 2 Using index 2 DEPENDENT SUBQUERY t2 index_subquery s1 s1 6 func 2 Using index
Warnings: Warnings:
Note 1003 select test.t1.s1 AS `s1`,not(<in_optimizer>(test.t1.s1,<exists>(<index_lookup>(<cache>(test.t1.s1) in t2 on s1 chicking NULL)))) AS `s1 NOT IN (SELECT s1 FROM t2)` from test.t1 Note 1003 select test.t1.s1 AS `s1`,not(<in_optimizer>(test.t1.s1,<exists>(<index_lookup>(<cache>(test.t1.s1) in t2 on s1 chicking NULL)))) AS `s1 NOT IN (SELECT s1 FROM t2)` from test.t1
explain extended select s1, s1 = ANY (SELECT s1 FROM t2) from t1; explain extended select s1, s1 = ANY (SELECT s1 FROM t2) from t1;
id select_type table type possible_keys key key_len ref rows Extra id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 index NULL s1 6 NULL 3 Using index 1 PRIMARY t1 index NULL s1 5 NULL 3 Using index
2 DEPENDENT SUBQUERY t2 index_subquery s1 s1 6 func 2 Using index 2 DEPENDENT SUBQUERY t2 index_subquery s1 s1 6 func 2 Using index
Warnings: Warnings:
Note 1003 select test.t1.s1 AS `s1`,<in_optimizer>(test.t1.s1,<exists>(<index_lookup>(<cache>(test.t1.s1) in t2 on s1 chicking NULL))) AS `s1 = ANY (SELECT s1 FROM t2)` from test.t1 Note 1003 select test.t1.s1 AS `s1`,<in_optimizer>(test.t1.s1,<exists>(<index_lookup>(<cache>(test.t1.s1) in t2 on s1 chicking NULL))) AS `s1 = ANY (SELECT s1 FROM t2)` from test.t1
explain extended select s1, s1 <> ALL (SELECT s1 FROM t2) from t1; explain extended select s1, s1 <> ALL (SELECT s1 FROM t2) from t1;
id select_type table type possible_keys key key_len ref rows Extra id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 index NULL s1 6 NULL 3 Using index 1 PRIMARY t1 index NULL s1 5 NULL 3 Using index
2 DEPENDENT SUBQUERY t2 index_subquery s1 s1 6 func 2 Using index 2 DEPENDENT SUBQUERY t2 index_subquery s1 s1 6 func 2 Using index
Warnings: Warnings:
Note 1003 select test.t1.s1 AS `s1`,not(<in_optimizer>(test.t1.s1,<exists>(<index_lookup>(<cache>(test.t1.s1) in t2 on s1 chicking NULL)))) AS `s1 <> ALL (SELECT s1 FROM t2)` from test.t1 Note 1003 select test.t1.s1 AS `s1`,not(<in_optimizer>(test.t1.s1,<exists>(<index_lookup>(<cache>(test.t1.s1) in t2 on s1 chicking NULL)))) AS `s1 <> ALL (SELECT s1 FROM t2)` from test.t1
explain extended select s1, s1 NOT IN (SELECT s1 FROM t2 WHERE s1 < 'a2') from t1; explain extended select s1, s1 NOT IN (SELECT s1 FROM t2 WHERE s1 < 'a2') from t1;
id select_type table type possible_keys key key_len ref rows Extra id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 index NULL s1 6 NULL 3 Using index 1 PRIMARY t1 index NULL s1 5 NULL 3 Using index
2 DEPENDENT SUBQUERY t2 index_subquery s1 s1 6 func 1 Using index; Using where 2 DEPENDENT SUBQUERY t2 index_subquery s1 s1 6 func 1 Using index; Using where
Warnings: Warnings:
Note 1003 select test.t1.s1 AS `s1`,not(<in_optimizer>(test.t1.s1,<exists>(<index_lookup>(<cache>(test.t1.s1) in t2 on s1 chicking NULL where (test.t2.s1 < _latin1'a2'))))) AS `s1 NOT IN (SELECT s1 FROM t2 WHERE s1 < 'a2')` from test.t1 Note 1003 select test.t1.s1 AS `s1`,not(<in_optimizer>(test.t1.s1,<exists>(<index_lookup>(<cache>(test.t1.s1) in t2 on s1 chicking NULL where (test.t2.s1 < _latin1'a2'))))) AS `s1 NOT IN (SELECT s1 FROM t2 WHERE s1 < 'a2')` from test.t1
...@@ -2125,3 +2125,18 @@ SELECT DISTINCT Continent AS c FROM t1 WHERE Code <> SOME ( SELECT Code FROM t1 ...@@ -2125,3 +2125,18 @@ SELECT DISTINCT Continent AS c FROM t1 WHERE Code <> SOME ( SELECT Code FROM t1
c c
Oceania Oceania
drop table t1; drop table t1;
CREATE TABLE t1 ( f1 BIGINT );
INSERT INTO t1 SET f1= NULL;
INSERT INTO t1 SET f1= 1;
CREATE TABLE t2 ( f1 BIGINT );
SELECT f1 FROM t1
WHERE f1 <> ALL ( SELECT f1 FROM t2 );
f1
NULL
1
INSERT INTO t2 VALUES (1), (2);
SELECT f1 FROM t1
WHERE f1 <> ALL ( SELECT f1 FROM t2 WHERE f1 > 2 );
f1
NULL
1
...@@ -889,7 +889,7 @@ drop table t1; ...@@ -889,7 +889,7 @@ drop table t1;
# #
# IN optimisation test results # IN optimisation test results
# #
create table t1 (s1 char(5), index s1(s1)); create table t1 (s1 char(5) not null, index s1(s1));
create table t2 (s1 char(5), index s1(s1)); create table t2 (s1 char(5), index s1(s1));
insert into t1 values ('a1'),('a2'),('a3'); insert into t1 values ('a1'),('a2'),('a3');
insert into t2 values ('a1'),('a2'); insert into t2 values ('a1'),('a2');
...@@ -1386,3 +1386,22 @@ INSERT INTO t1 VALUES ('UMI','United States Minor Outlying Islands','Oceania','M ...@@ -1386,3 +1386,22 @@ INSERT INTO t1 VALUES ('UMI','United States Minor Outlying Islands','Oceania','M
/*!40000 ALTER TABLE t1 ENABLE KEYS */; /*!40000 ALTER TABLE t1 ENABLE KEYS */;
SELECT DISTINCT Continent AS c FROM t1 WHERE Code <> SOME ( SELECT Code FROM t1 WHERE Continent = c AND Population < 200); SELECT DISTINCT Continent AS c FROM t1 WHERE Code <> SOME ( SELECT Code FROM t1 WHERE Continent = c AND Population < 200);
drop table t1; drop table t1;
#
# Test cases for bug #7351:
# quantified predicate with subquery returning empty result set
#
CREATE TABLE t1 ( f1 BIGINT );
INSERT INTO t1 SET f1= NULL;
INSERT INTO t1 SET f1= 1;
CREATE TABLE t2 ( f1 BIGINT );
SELECT f1 FROM t1
WHERE f1 <> ALL ( SELECT f1 FROM t2 );
INSERT INTO t2 VALUES (1), (2);
SELECT f1 FROM t1
WHERE f1 <> ALL ( SELECT f1 FROM t2 WHERE f1 > 2 );
...@@ -636,12 +636,13 @@ longlong Item_in_optimizer::val_int() ...@@ -636,12 +636,13 @@ longlong Item_in_optimizer::val_int()
{ {
DBUG_ASSERT(fixed == 1); DBUG_ASSERT(fixed == 1);
cache->store(args[0]); cache->store(args[0]);
longlong tmp= args[1]->val_int_result();
if (cache->null_value) if (cache->null_value)
{ {
null_value= 1; if (tmp)
null_value= 1;
return 0; return 0;
} }
longlong tmp= args[1]->val_int_result();
null_value= args[1]->null_value; null_value= args[1]->null_value;
return tmp; return tmp;
} }
......
...@@ -824,6 +824,8 @@ Item_in_subselect::single_value_transformer(JOIN *join, ...@@ -824,6 +824,8 @@ Item_in_subselect::single_value_transformer(JOIN *join,
select_lex->ref_pointer_array, select_lex->ref_pointer_array,
(char *)"<ref>", (char *)"<ref>",
this->full_name())); this->full_name()));
if (!abort_on_null && left_expr->maybe_null)
item= new Item_cond_or(new Item_func_isnull(left_expr), item);
/* /*
AND and comparison functions can't be changed during fix_fields() AND and comparison functions can't be changed during fix_fields()
we can assign select_lex->having here, and pass 0 as last we can assign select_lex->having here, and pass 0 as last
...@@ -869,6 +871,8 @@ Item_in_subselect::single_value_transformer(JOIN *join, ...@@ -869,6 +871,8 @@ Item_in_subselect::single_value_transformer(JOIN *join,
select_lex->having_fix_field= 0; select_lex->having_fix_field= 0;
item= new Item_cond_or(item, item= new Item_cond_or(item,
new Item_func_isnull(orig_item)); new Item_func_isnull(orig_item));
if (left_expr->maybe_null)
item= new Item_cond_or(new Item_func_isnull(left_expr), item);
} }
item->name= (char *)in_additional_cond; item->name= (char *)in_additional_cond;
/* /*
...@@ -889,12 +893,13 @@ Item_in_subselect::single_value_transformer(JOIN *join, ...@@ -889,12 +893,13 @@ Item_in_subselect::single_value_transformer(JOIN *join,
we can assign select_lex->having here, and pass 0 as last we can assign select_lex->having here, and pass 0 as last
argument (reference) to fix_fields() argument (reference) to fix_fields()
*/ */
select_lex->having= item= func->create(expr,
join->having= new Item_null_helper(this, item,
func->create(expr,
new Item_null_helper(this, item,
(char *)"<no matter>", (char *)"<no matter>",
(char *)"<result>")); (char *)"<result>"));
if (!abort_on_null && left_expr->maybe_null)
item= new Item_cond_or(new Item_func_isnull(left_expr), item);
select_lex->having= join->having= item;
select_lex->having_fix_field= 1; select_lex->having_fix_field= 1;
if (join->having->fix_fields(thd, join->tables_list, if (join->having->fix_fields(thd, join->tables_list,
0)) 0))
......
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