Details
-
Type:
Bug
-
Status: Closed
-
Priority:
Major
-
Resolution: Fixed
-
Affects Version/s: None
-
Fix Version/s: None
-
Component/s: None
-
Labels:
Description
The following query:
SELECT *
FROM t2 , t1
WHERE t1.pk != ANY (
SELECT DISTINCT col_int_key
FROM t3
);
incorrectly returns
8 28
9 28
8 29
when executed with semijoin=off and
8 28
9 28
8 29
9 29
otherwise. Repeatable in maria-5.3. Not repeatable in maria-5.2, mysql-5.5
EXPLAIN:
id select_type table type possible_keys key key_len ref rows filtered Extra
1 PRIMARY t2 ALL NULL NULL NULL NULL 2 100.00
1 PRIMARY t1 ALL NULL NULL NULL NULL 2 100.00 Using where; Using join buffer (flat, BNL join)
2 DEPENDENT SUBQUERY t3 range col_int_key col_int_key 5 NULL 6 100.00 Using where; Using index for group-by
select `test`.`t2`.`col_int_key` AS `col_int_key`,`test`.`t1`.`pk` AS `pk` from `test`.`t2` join `test`.`t1` where <nop>(<in_optimizer>(`test`.`t1`.`pk`,<exists>(select distinct `test`.`t3`.`col_int_key` from `test`.`t3` where ((<cache>(`test`.`t1`.`pk`) <> `test`.`t3`.`col_int_key`) or isnull(`test`.`t3`.`col_int_key`)) having <is_not_null_test>(`test`.`t3`.`col_int_key`))))
minimal switch: subquery_cache=off
full switch: index_merge=on,index_merge_union=on,index_merge_sort_union=on,index_merge_intersection=on,index_merge_sort_intersection=off,index_condition_pushdown=off,derived_merge=off,derived_with_keys=off,firstmatch=on,loosescan=on,materialization=off,in_to_exists=on,semijoin=on,partial_match_rowid_merge=on,partial_match_table_scan=on,subquery_cache=off,mrr=off,mrr_cost_based=off,mrr_sort_keys=off,outer_join_with_cache=off,semijoin_with_cache=off,join_cache_incremental=on,join_cache_hashed=on,join_cache_bka=on,optimize_join_buffer_size=off,table_elimination=on
revision-id: <email address hidden>
date: 2011-11-07 16:39:02 +0400
build-date: 2011-11-10 11:21:11 +0200
revno: 3273
branch-nick: maria-5.3
test case:
CREATE TABLE t1 ( a int NOT NULL) ;
INSERT INTO t1 VALUES (28),(29);
CREATE TABLE t2 ( a int) ;
INSERT INTO t2 VALUES (8),(9);
CREATE TABLE t3 ( a int, KEY (a)) ;
INSERT INTO t3 VALUES (1),(1),(1),(4),(4),(5),(5),(8),(8),(9);
SELECT *
FROM t2 , t1
WHERE t1.a != ANY (
SELECT DISTINCT t3.a
FROM t3
);
Gliffy Diagrams
Attachments
Activity
- All
- Comments
- Work Log
- History
- Activity
- Transitions
Re: Wrong result with DISTINCT , ANY , subquery_cache=off , NOT NULL
the problem was in resetting QUICK_GROUP_MIN_MAX_SELECT, fix is:
=== modified file 'sql/opt_range.cc'
— sql/opt_range.cc 2011-11-18 17:35:51 +0000
+++ sql/opt_range.cc 2011-11-29 07:19:01 +0000
@@ -12915,6 +12915,7 @@ int QUICK_GROUP_MIN_MAX_SELECT::reset(vo
int result;
DBUG_ENTER("QUICK_GROUP_MIN_MAX_SELECT::reset");
+ seen_first_key= FALSE;
if (!head->key_read)
{
doing_key_read= 1;
But there is 2 strange things:
1) why the bug is visible only on 5.3?
2) are there something else which should be reset?