Wrong result with semijoin + materialization + multipart key

Bug #877288 reported by Philip Stoev
6
This bug affects 1 person
Affects Status Importance Assigned to Milestone
MariaDB
Fix Released
High
Sergey Petrunia

Bug Description

The following query:

SELECT * FROM t1
WHERE (a) IN (
 SELECT a
 FROM t2
 JOIN t3 ON b = a
);

returns

| a |
+------+
| 19 |
| 19 |
| 19 |

when executed with semijoin+materialization and

| a |
+------+
| 19 |
| 19 |
| 19 |
| 20 |
| 20 |
| 20 |
| 20 |
| 20 |
| 20 |

when executed otherwise (which seems to be the correct result).

Offending explain:

| 1 | PRIMARY | t1 | ALL | NULL | NULL | NULL | NULL | 9 | Using where |
| 1 | PRIMARY | <subquery2> | eq_ref | distinct_key | distinct_key | 5 | func | 1 | |
| 2 | SUBQUERY | t3 | ALL | NULL | NULL | NULL | NULL | 13 | |
| 2 | SUBQUERY | t2 | ref | b | b | 4 | test.t1.a | 1 | Using where; Using index |

minimal switch: semijoin=on,materialization=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=off,derived_with_keys=off,firstmatch=off,loosescan=off,materialization=on,in_to_exists=on,semijoin=on,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-17 03:42:56 -0700
build-date: 2011-10-18 13:05:59 +0300
revno: 3239
branch-nick: maria-5.3

test case:

CREATE TABLE t1 ( a int) ;
INSERT INTO t1 VALUES (19),(19),(19),(20),(20),(20),(20),(20),(20);

CREATE TABLE t2 ( b int NOT NULL , c int NOT NULL , KEY (b,c)) ;
INSERT INTO t2 VALUES (14,1),(15,1),(16,1),(17,1),(18,1),(19,1),(20,1);

CREATE TABLE t3 ( a int, d int) ;
INSERT INTO t3 VALUES (19,1),(7,1),(3,1),(3,1),(20,1),(3,1),(16,1),(17,1),(9,1),(4,1),(6,1),(15,1),(17,1);

SET SESSION optimizer_switch='semijoin=ON,materialization=ON';
SELECT * FROM t1
WHERE (a) IN (
 SELECT a
 FROM t2
 JOIN t3 ON b = a );

Changed in maria:
milestone: none → 5.3
assignee: nobody → Sergey Petrunia (sergefp)
Changed in maria:
importance: Undecided → High
Revision history for this message
Sergey Petrunia (sergefp) wrote :

MariaDB [bug877288]> explain SELECT * FROM t1 WHERE (a) IN ( SELECT a FROM t2 JOIN t3 ON b = a );
+----+-------------+-------------+--------+---------------+--------------+---------+----------------+------+--------------------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+-------------+--------+---------------+--------------+---------+----------------+------+--------------------------+
| 1 | PRIMARY | t1 | ALL | NULL | NULL | NULL | NULL | 9 | Using where |
| 1 | PRIMARY | <subquery2> | eq_ref | distinct_key | distinct_key | 5 | func | 1 | |
| 2 | SUBQUERY | t3 | ALL | NULL | NULL | NULL | NULL | 13 | |
| 2 | SUBQUERY | t2 | ref | b | b | 4 | bug877288.t1.a | 1 | Using where; Using index |
+----+-------------+-------------+--------+---------------+--------------+---------+----------------+------+--------------------------+

Changed in maria:
status: New → Confirmed
Revision history for this message
Sergey Petrunia (sergefp) wrote :

The EXPLAIN is incorrect: t2 is inside semi-join materialization nest, yet it uses ref access based on t1.a

Changed in maria:
status: Confirmed → Fix Committed
Changed in maria:
status: Fix Committed → Fix Released
To post a comment you must log in.
This report contains Public information  
Everyone can see this information.

Other bug subscribers

Remote bug watches

Bug watches keep track of this bug in other bug trackers.