Details
-
Type:
Bug
-
Status: Closed
-
Priority:
Minor
-
Resolution: Fixed
-
Affects Version/s: None
-
Fix Version/s: None
-
Component/s: None
-
Labels:
Description
The following query:
SELECT alias1.*
FROM (
SELECT t1.*
FROM t1
LEFT JOIN t2
ON ( t1.a = t2.a )
WHERE t2.a <> 0
) AS alias1
RIGHT JOIN t3
ON ( t3.a = alias1.b );
returns the following incorrect result when executed with derived_merge=on:
a b
0 g
the correct result is (NULL , NULL) as the subquery does not return any rows and therefore the RIGHT JOIN between the subquery and a table can not include any rows from the subquery.
explain:
id select_type table type possible_keys key key_len ref rows filtered Extra
1 SIMPLE t3 system NULL NULL NULL NULL 1 100.00
1 SIMPLE t1 ALL NULL NULL NULL NULL 1 100.00 Using where
select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b` from `test`.`t3` left join (`test`.`t1`) on(((`test`.`t2`.`a` <> 0) and (`test`.`t1`.`b` = 'g'))) where 1
minimal switch: derived_merge=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=off,firstmatch=off,loosescan=off,materialization=off,in_to_exists=on,semijoin=off,partial_match_rowid_merge=on,partial_match_table_scan=on,subquery_cache=on,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
bzr version-info
revision-id: <email address hidden>
date: 2011-10-28 12:38:36 +0400
build-date: 2011-10-31 13:55:00 +0200
revno: 3258
branch-nick: maria-5.3
test case:
DROP TABLE IF EXISTS t1;
CREATE TABLE t1 ( a int(11), b varchar(1)) ;
INSERT IGNORE INTO t1 VALUES (0,'g');
DROP TABLE IF EXISTS t3;
CREATE TABLE t3 ( a varchar(1)) ;
INSERT IGNORE INTO t3 VALUES ('g');
DROP TABLE IF EXISTS t2;
CREATE TABLE t2 ( a int(11) NOT NULL, PRIMARY KEY (a)) ;
SET SESSION optimizer_swtich='derived_merge=on';
SELECT alias1.*
FROM (
SELECT t1.*
FROM t1
LEFT JOIN t2
ON ( t1.a = t2.a )
WHERE t2.a <> 0
) AS alias1
RIGHT JOIN t3
ON ( t3.a = alias1.b );
Gliffy Diagrams
Attachments
Activity
- All
- Comments
- Work Log
- History
- Activity
- Transitions
Re: Wrong result with RIGHT JOIN + derived_merge
Changed query from RIGHT JOIN to LEFT JOIN (the bug repeats):
SELECT alias1.*
FROM
t3
LEFT JOIN
(
SELECT t1.*
FROM t1 LEFT JOIN t2 ON ( t1.a = t2.a )
WHERE t2.a <> 0
) AS alias1
ON ( t3.a = alias1.b );