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 t1 JOIN t2 ON (t2.f4 = t1.f3 )
WHERE ( 8 ) IN (
SELECT t3.f1 FROM t3 , t4
);
returns 1 row when executed with materialization=on,semijoin=on,firstmatch=on:
--------------
| f2 | f3 | f4 |
--------------
| NULL | x | x |
--------------
even though it should return 2 rows:
--------------
| f2 | f3 | f4 |
--------------
| 8 | x | x |
| NULL | x | x |
--------------
explain:
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
-----------------------------------------------------------------------------------------+
| 1 | PRIMARY | t2 | ALL | NULL | NULL | NULL | NULL | 1 | Using where |
| 1 | PRIMARY | t1 | ref | f3 | f3 | 4 | test.t2.f4 | 1 | Using index |
| 1 | PRIMARY | t4 | ALL | NULL | NULL | NULL | NULL | 3 | |
| 1 | PRIMARY | t3 | ALL | NULL | NULL | NULL | NULL | 5 | Using where; FirstMatch(t2) |
minimal switch:
materialization=on,semijoin=on,firstmatch=on
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=on,derived_with_keys=on,firstmatch=on,loosescan=off,materialization=on,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
test case:
SET SESSION optimizer_switch='materialization=on,semijoin=on,firstmatch=on';
CREATE TABLE t1 ( f2 int, f3 varchar(1), KEY (f3,f2)) ;
INSERT INTO t1 VALUES (8,'x'),(NULL,'x'),(8,'c');
CREATE TABLE t2 ( f4 varchar(1)) ;
INSERT INTO t2 VALUES ('x');
CREATE TABLE t3 ( f1 int) ;
INSERT INTO t3 VALUES (8),(6),(2),(9),(6);
CREATE TABLE t4 ( f3 varchar(1)) ;
INSERT INTO t4 VALUES ('p'),('j'),('c');
SELECT *
FROM t1 JOIN t2 ON (t2.f4 = t1.f3 )
WHERE ( 8 ) IN (
SELECT t3.f1 FROM t3 , t4
);
revision-id: <email address hidden>
date: 2011-10-06 01:21:15 +0400
build-date: 2011-10-06 12:04:17 +0300
revno: 3213
branch-nick: maria-5.3
Gliffy Diagrams
Attachments
Activity
- All
- Comments
- Work Log
- History
- Activity
- Transitions
Re: Wrong result with semijoin + materialization + firstmatch + multipart key
Not repeatable on work.askmonty.org with tip cset:
revno: 3200
revision-id: wlad@montyprogram.com-20110929105820-czlud9qbisbs3zbl
and debug build.