Fixed mdev-6706 Wrong result (missing rows)
with joins, SQ, ORDER BY, semijoin=on A bug in get_sort_by_table() could mislead the function setup_semijoin_dups_elimination(). As a result the optimizer could produce invalid execution plans for queries with ORDER BY and subquery predicates that could be converted to semi-joins.
This commit is contained in:
parent
6293e3bbcf
commit
abc123391f
@ -2061,4 +2061,50 @@ ORDER BY NULL, @a0 := 3, @a1 := 3, @a2 := 3, @a3 := 3, @a4 := 3,
|
|||||||
1
|
1
|
||||||
1
|
1
|
||||||
2
|
2
|
||||||
|
#
|
||||||
|
# mdev-6706: semi-join with duplicate weedout + ORDER BY
|
||||||
|
#
|
||||||
|
CREATE TABLE t1 (f1 VARCHAR(3)) ENGINE=MyISAM;
|
||||||
|
INSERT INTO t1 VALUES ('foo');
|
||||||
|
CREATE TABLE t2 (f2 VARCHAR(3)) ENGINE=MyISAM;
|
||||||
|
INSERT INTO t2 VALUES ('bar'),('baz');
|
||||||
|
CREATE TABLE t3
|
||||||
|
(i3_key INT, f3_key VARCHAR(3), f3 VARCHAR(3), KEY(f3_key,i3_key))
|
||||||
|
ENGINE=MyISAM;
|
||||||
|
INSERT INTO t3 VALUES (0,'qux','qux'),(8,'bar','bar');
|
||||||
|
SELECT CONCAT( f1, f2 ) AS field FROM t1, t2
|
||||||
|
WHERE f1 = ANY ( SELECT f1
|
||||||
|
FROM t1
|
||||||
|
LEFT JOIN ( t3 AS t3a, t3 AS t3b )
|
||||||
|
ON ( t3b.f3_key = t3a.f3 )
|
||||||
|
WHERE t3a.f3 < f1 OR t3b.f3 != f1 );
|
||||||
|
field
|
||||||
|
foobar
|
||||||
|
foobaz
|
||||||
|
SELECT CONCAT( f1, f2 ) AS field FROM t1, t2
|
||||||
|
WHERE f1 = ANY ( SELECT f1
|
||||||
|
FROM t1
|
||||||
|
LEFT JOIN ( t3 AS t3a, t3 AS t3b )
|
||||||
|
ON ( t3b.f3_key = t3a.f3 )
|
||||||
|
WHERE t3a.f3 < f1 OR t3b.f3 != f1 )
|
||||||
|
ORDER BY field;
|
||||||
|
field
|
||||||
|
foobar
|
||||||
|
foobaz
|
||||||
|
EXPLAIN EXTENDED SELECT CONCAT( f1, f2 ) AS field FROM t1, t2
|
||||||
|
WHERE f1 = ANY ( SELECT f1
|
||||||
|
FROM t1
|
||||||
|
LEFT JOIN ( t3 AS t3a, t3 AS t3b )
|
||||||
|
ON ( t3b.f3_key = t3a.f3 )
|
||||||
|
WHERE t3a.f3 < f1 OR t3b.f3 != f1 )
|
||||||
|
ORDER BY field;
|
||||||
|
id select_type table type possible_keys key key_len ref rows filtered Extra
|
||||||
|
1 PRIMARY t1 system NULL NULL NULL NULL 1 100.00 Using temporary; Using filesort
|
||||||
|
1 PRIMARY t1 system NULL NULL NULL NULL 1 100.00
|
||||||
|
1 PRIMARY t2 ALL NULL NULL NULL NULL 2 100.00
|
||||||
|
1 PRIMARY t3a ALL NULL NULL NULL NULL 2 100.00 Using where; Start temporary
|
||||||
|
1 PRIMARY t3b ref f3_key f3_key 6 test.t3a.f3 1 100.00 Using where; End temporary
|
||||||
|
Warnings:
|
||||||
|
Note 1003 select concat('foo',`test`.`t2`.`f2`) AS `field` from `test`.`t2` semi join ((`test`.`t3` `t3a` join `test`.`t3` `t3b`)) where ((`test`.`t3a`.`f3` < 'foo') or (`test`.`t3b`.`f3` <> 'foo')) order by concat('foo',`test`.`t2`.`f2`)
|
||||||
|
DROP TABLE t1,t2,t3;
|
||||||
End of 5.5 tests
|
End of 5.5 tests
|
||||||
|
@ -1756,6 +1756,44 @@ UNION
|
|||||||
ORDER BY NULL, @a0 := 3, @a1 := 3, @a2 := 3, @a3 := 3, @a4 := 3,
|
ORDER BY NULL, @a0 := 3, @a1 := 3, @a2 := 3, @a3 := 3, @a4 := 3,
|
||||||
@a5 := 3, @a6 := 3, @a7 := 3, @a8 := 3, @a9 := 3, @a10 := 3 );
|
@a5 := 3, @a6 := 3, @a7 := 3, @a8 := 3, @a9 := 3, @a10 := 3 );
|
||||||
|
|
||||||
|
|
||||||
|
--echo #
|
||||||
|
--echo # mdev-6706: semi-join with duplicate weedout + ORDER BY
|
||||||
|
--echo #
|
||||||
|
|
||||||
|
CREATE TABLE t1 (f1 VARCHAR(3)) ENGINE=MyISAM;
|
||||||
|
INSERT INTO t1 VALUES ('foo');
|
||||||
|
|
||||||
|
CREATE TABLE t2 (f2 VARCHAR(3)) ENGINE=MyISAM;
|
||||||
|
INSERT INTO t2 VALUES ('bar'),('baz');
|
||||||
|
|
||||||
|
CREATE TABLE t3
|
||||||
|
(i3_key INT, f3_key VARCHAR(3), f3 VARCHAR(3), KEY(f3_key,i3_key))
|
||||||
|
ENGINE=MyISAM;
|
||||||
|
INSERT INTO t3 VALUES (0,'qux','qux'),(8,'bar','bar');
|
||||||
|
|
||||||
|
let $q1=
|
||||||
|
SELECT CONCAT( f1, f2 ) AS field FROM t1, t2
|
||||||
|
WHERE f1 = ANY ( SELECT f1
|
||||||
|
FROM t1
|
||||||
|
LEFT JOIN ( t3 AS t3a, t3 AS t3b )
|
||||||
|
ON ( t3b.f3_key = t3a.f3 )
|
||||||
|
WHERE t3a.f3 < f1 OR t3b.f3 != f1 );
|
||||||
|
let $q2=
|
||||||
|
SELECT CONCAT( f1, f2 ) AS field FROM t1, t2
|
||||||
|
WHERE f1 = ANY ( SELECT f1
|
||||||
|
FROM t1
|
||||||
|
LEFT JOIN ( t3 AS t3a, t3 AS t3b )
|
||||||
|
ON ( t3b.f3_key = t3a.f3 )
|
||||||
|
WHERE t3a.f3 < f1 OR t3b.f3 != f1 )
|
||||||
|
ORDER BY field;
|
||||||
|
|
||||||
|
eval $q1;
|
||||||
|
eval $q2;
|
||||||
|
eval EXPLAIN EXTENDED $q2;
|
||||||
|
|
||||||
|
DROP TABLE t1,t2,t3;
|
||||||
|
|
||||||
--echo End of 5.5 tests
|
--echo End of 5.5 tests
|
||||||
|
|
||||||
|
|
||||||
|
@ -21159,6 +21159,7 @@ get_sort_by_table(ORDER *a,ORDER *b, List<TABLE_LIST> &tables,
|
|||||||
if (!map || (map & (RAND_TABLE_BIT | OUTER_REF_TABLE_BIT)))
|
if (!map || (map & (RAND_TABLE_BIT | OUTER_REF_TABLE_BIT)))
|
||||||
DBUG_RETURN(0);
|
DBUG_RETURN(0);
|
||||||
|
|
||||||
|
map&= ~const_tables;
|
||||||
while ((table= ti++) && !(map & table->table->map)) ;
|
while ((table= ti++) && !(map & table->table->map)) ;
|
||||||
if (map != table->table->map)
|
if (map != table->table->map)
|
||||||
DBUG_RETURN(0); // More than one table
|
DBUG_RETURN(0); // More than one table
|
||||||
|
Loading…
x
Reference in New Issue
Block a user