Skip to content

Commit dcbf282

Browse files
committed
Fixed MDEV-13994 Bad join results with orderby_uses_equalities=on.
This patch effectively blocks the optimization that uses multiple equalities for ORDER BY to remove tmp table in the case when the first table happens to be the result of materialization of a semi-join nest. Currently there is no code at the execution level that would support the optimization in this case.
1 parent 589b0b3 commit dcbf282

File tree

5 files changed

+241
-1
lines changed

5 files changed

+241
-1
lines changed

mysql-test/r/order_by.result

Lines changed: 48 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -3159,3 +3159,51 @@ pk
31593159
2
31603160
3
31613161
DROP TABLE t1;
3162+
#
3163+
# MDEV-13994: Bad join results with orderby_uses_equalities=on
3164+
#
3165+
CREATE TABLE books (
3166+
id int(16) NOT NULL AUTO_INCREMENT,
3167+
library_id int(16) NOT NULL DEFAULT 0,
3168+
wings_id int(12) NOT NULL DEFAULT 0,
3169+
scheduled_for_removal int(1) DEFAULT 0,
3170+
PRIMARY KEY (id),
3171+
KEY library_idx (library_id)
3172+
) ENGINE=MyISAM AUTO_INCREMENT=1 DEFAULT CHARSET=utf8;
3173+
INSERT INTO books VALUES (32625,8663,707,0),(32624,8663,505,1);
3174+
CREATE TABLE wings (
3175+
id int(11) NOT NULL AUTO_INCREMENT,
3176+
department_id int(11) DEFAULT NULL,
3177+
PRIMARY KEY (id)
3178+
) ENGINE=MyISAM AUTO_INCREMENT=1 DEFAULT CHARSET=utf8;
3179+
INSERT INTO wings VALUES (505,11745),(707,11768);
3180+
SET @save_optimizer_switch=@@optimizer_switch;
3181+
SET optimizer_switch='orderby_uses_equalities=off';
3182+
SELECT wings.id as wing_id, wings.department_id FROM wings
3183+
WHERE wings.id IN ( SELECT books.wings_id FROM books
3184+
WHERE books.library_id = 8663 AND
3185+
books.scheduled_for_removal=0 )
3186+
ORDER BY wings.id;
3187+
wing_id department_id
3188+
707 11768
3189+
SET optimizer_switch='orderby_uses_equalities=on';
3190+
SELECT wings.id as wing_id, wings.department_id FROM wings
3191+
WHERE wings.id IN ( SELECT books.wings_id FROM books
3192+
WHERE books.library_id = 8663 AND
3193+
books.scheduled_for_removal=0 )
3194+
ORDER BY wings.id;
3195+
wing_id department_id
3196+
707 11768
3197+
explain extended SELECT wings.id as wing_id, wings.department_id FROM wings
3198+
WHERE wings.id IN ( SELECT books.wings_id FROM books
3199+
WHERE books.library_id = 8663 AND
3200+
books.scheduled_for_removal=0 )
3201+
ORDER BY wings.id;
3202+
id select_type table type possible_keys key key_len ref rows filtered Extra
3203+
1 PRIMARY <subquery2> ALL distinct_key NULL NULL NULL 1 100.00 Using temporary; Using filesort
3204+
1 PRIMARY wings eq_ref PRIMARY PRIMARY 4 test.books.wings_id 1 100.00
3205+
2 MATERIALIZED books ref library_idx library_idx 4 const 1 100.00 Using where
3206+
Warnings:
3207+
Note 1003 select `test`.`wings`.`id` AS `wing_id`,`test`.`wings`.`department_id` AS `department_id` from `test`.`wings` semi join (`test`.`books`) where `test`.`books`.`library_id` = 8663 and `test`.`books`.`scheduled_for_removal` = 0 and `test`.`wings`.`id` = `test`.`books`.`wings_id` order by `test`.`wings`.`id`
3208+
set optimizer_switch= @save_optimizer_switch;
3209+
DROP TABLE books, wings;

mysql-test/r/order_by_innodb.result

Lines changed: 73 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -48,3 +48,76 @@ where key1<3 or key2<3;
4848
id select_type table type possible_keys key key_len ref rows Extra
4949
1 SIMPLE t1 index_merge key1,key2 key1,key2 5,5 NULL # Using sort_union(key1,key2); Using where
5050
drop table t0, t1;
51+
#
52+
# MDEV-14071: wrong results with orderby_uses_equalities=on
53+
# (duplicate of MDEV-13994)
54+
#
55+
CREATE TABLE t1 (i int, j int, z int,PRIMARY KEY (i,j), KEY (z)) ENGINE=InnoDB;
56+
CREATE TABLE t2 (i int, j int, PRIMARY KEY (i,j)) ENGINE=InnoDB;
57+
CREATE TABLE t3 (j int, n varchar(5), PRIMARY KEY (j)) ENGINE=InnoDB;
58+
INSERT INTO t1 VALUES
59+
(127,0,1),(188,0,1),(206,0,1),(218,0,1),(292,0,1),(338,0,1),(375,0,1),
60+
(381,0,1),(409,0,1),(466,0,1),(469,0,1),(498,0,1),(656,0,1);
61+
INSERT INTO t1 VALUES
62+
(77,4,0),(86,7,0),(96,6,0),(96,7,0),(99,9,0),(99,10,0),(99,11,0),(104,4,0),
63+
(106,5,0),(148,6,0),(177,6,0),(181,5,0),(188,8,0),(218,8,0),(253,7,0),
64+
(268,4,0),(338,4,0),(409,7,0),(466,8,0),(469,8,0),(498,8,0),(656,8,0);
65+
INSERT INTO t2 VALUES
66+
(127,7),(188,8),(188,9),(206,6),(218,8),(218,9),(292,7),(338,4),(338,5),
67+
(375,6),(381,5),(409,7),(409,8),(466,8),(466,9),(469,8),(469,9),(498,8),
68+
(498,9),(656,8),(656,9);
69+
INSERT INTO t3 VALUES
70+
(4,'four'),(5,'five'),(6,'six'),(7,'seven'),(8,'eight'),(9,'nine');
71+
SET @save_optimizer_switch=@@optimizer_switch;
72+
SET optimizer_switch='orderby_uses_equalities=off';
73+
SELECT i,n
74+
FROM t1 INNER JOIN t2 USING (i,j) LEFT JOIN t3 USING (j)
75+
WHERE i IN (SELECT i FROM t1 WHERE z=1) AND z=0 ORDER BY i;
76+
i n
77+
188 eight
78+
218 eight
79+
338 four
80+
409 seven
81+
466 eight
82+
469 eight
83+
498 eight
84+
656 eight
85+
SELECT i,n
86+
FROM t1 x INNER JOIN t2 USING (i,j) LEFT JOIN t3 USING (j)
87+
WHERE EXISTS (SELECT * FROM t1 WHERE i=x.i AND z=1) AND z=0 ORDER BY i;
88+
i n
89+
188 eight
90+
218 eight
91+
338 four
92+
409 seven
93+
466 eight
94+
469 eight
95+
498 eight
96+
656 eight
97+
SET optimizer_switch='orderby_uses_equalities=on';
98+
SELECT i,n
99+
FROM t1 INNER JOIN t2 USING (i,j) LEFT JOIN t3 USING (j)
100+
WHERE i IN (SELECT i FROM t1 WHERE z=1) AND z=0 ORDER BY i;
101+
i n
102+
188 eight
103+
218 eight
104+
338 four
105+
409 seven
106+
466 eight
107+
469 eight
108+
498 eight
109+
656 eight
110+
SELECT i,n
111+
FROM t1 x INNER JOIN t2 USING (i,j) LEFT JOIN t3 USING (j)
112+
WHERE EXISTS (SELECT * FROM t1 WHERE i=x.i AND z=1) AND z=0 ORDER BY i;
113+
i n
114+
188 eight
115+
218 eight
116+
338 four
117+
409 seven
118+
466 eight
119+
469 eight
120+
498 eight
121+
656 eight
122+
set optimizer_switch= @save_optimizer_switch;
123+
DROP TABLE t1,t2,t3;

mysql-test/t/order_by.test

Lines changed: 43 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2106,3 +2106,46 @@ INSERT INTO t1 VALUES (1),(2),(3);
21062106
SELECT DISTINCT pk FROM t1 GROUP BY 'foo';
21072107
SELECT DISTINCT pk FROM t1;
21082108
DROP TABLE t1;
2109+
2110+
--echo #
2111+
--echo # MDEV-13994: Bad join results with orderby_uses_equalities=on
2112+
--echo #
2113+
2114+
CREATE TABLE books (
2115+
id int(16) NOT NULL AUTO_INCREMENT,
2116+
library_id int(16) NOT NULL DEFAULT 0,
2117+
wings_id int(12) NOT NULL DEFAULT 0,
2118+
scheduled_for_removal int(1) DEFAULT 0,
2119+
PRIMARY KEY (id),
2120+
KEY library_idx (library_id)
2121+
) ENGINE=MyISAM AUTO_INCREMENT=1 DEFAULT CHARSET=utf8;
2122+
2123+
INSERT INTO books VALUES (32625,8663,707,0),(32624,8663,505,1);
2124+
2125+
CREATE TABLE wings (
2126+
id int(11) NOT NULL AUTO_INCREMENT,
2127+
department_id int(11) DEFAULT NULL,
2128+
PRIMARY KEY (id)
2129+
) ENGINE=MyISAM AUTO_INCREMENT=1 DEFAULT CHARSET=utf8;
2130+
2131+
INSERT INTO wings VALUES (505,11745),(707,11768);
2132+
2133+
let $q=
2134+
SELECT wings.id as wing_id, wings.department_id FROM wings
2135+
WHERE wings.id IN ( SELECT books.wings_id FROM books
2136+
WHERE books.library_id = 8663 AND
2137+
books.scheduled_for_removal=0 )
2138+
ORDER BY wings.id;
2139+
2140+
SET @save_optimizer_switch=@@optimizer_switch;
2141+
2142+
SET optimizer_switch='orderby_uses_equalities=off';
2143+
eval $q;
2144+
2145+
SET optimizer_switch='orderby_uses_equalities=on';
2146+
eval $q;
2147+
eval explain extended $q;
2148+
2149+
set optimizer_switch= @save_optimizer_switch;
2150+
2151+
DROP TABLE books, wings;

mysql-test/t/order_by_innodb.test

Lines changed: 47 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -61,3 +61,50 @@ from t1
6161
where key1<3 or key2<3;
6262

6363
drop table t0, t1;
64+
65+
--echo #
66+
--echo # MDEV-14071: wrong results with orderby_uses_equalities=on
67+
--echo # (duplicate of MDEV-13994)
68+
--echo #
69+
70+
CREATE TABLE t1 (i int, j int, z int,PRIMARY KEY (i,j), KEY (z)) ENGINE=InnoDB;
71+
CREATE TABLE t2 (i int, j int, PRIMARY KEY (i,j)) ENGINE=InnoDB;
72+
CREATE TABLE t3 (j int, n varchar(5), PRIMARY KEY (j)) ENGINE=InnoDB;
73+
74+
INSERT INTO t1 VALUES
75+
(127,0,1),(188,0,1),(206,0,1),(218,0,1),(292,0,1),(338,0,1),(375,0,1),
76+
(381,0,1),(409,0,1),(466,0,1),(469,0,1),(498,0,1),(656,0,1);
77+
INSERT INTO t1 VALUES
78+
(77,4,0),(86,7,0),(96,6,0),(96,7,0),(99,9,0),(99,10,0),(99,11,0),(104,4,0),
79+
(106,5,0),(148,6,0),(177,6,0),(181,5,0),(188,8,0),(218,8,0),(253,7,0),
80+
(268,4,0),(338,4,0),(409,7,0),(466,8,0),(469,8,0),(498,8,0),(656,8,0);
81+
82+
INSERT INTO t2 VALUES
83+
(127,7),(188,8),(188,9),(206,6),(218,8),(218,9),(292,7),(338,4),(338,5),
84+
(375,6),(381,5),(409,7),(409,8),(466,8),(466,9),(469,8),(469,9),(498,8),
85+
(498,9),(656,8),(656,9);
86+
INSERT INTO t3 VALUES
87+
(4,'four'),(5,'five'),(6,'six'),(7,'seven'),(8,'eight'),(9,'nine');
88+
89+
let $q1=
90+
SELECT i,n
91+
FROM t1 INNER JOIN t2 USING (i,j) LEFT JOIN t3 USING (j)
92+
WHERE i IN (SELECT i FROM t1 WHERE z=1) AND z=0 ORDER BY i;
93+
let $q2=
94+
SELECT i,n
95+
FROM t1 x INNER JOIN t2 USING (i,j) LEFT JOIN t3 USING (j)
96+
WHERE EXISTS (SELECT * FROM t1 WHERE i=x.i AND z=1) AND z=0 ORDER BY i;
97+
98+
SET @save_optimizer_switch=@@optimizer_switch;
99+
100+
SET optimizer_switch='orderby_uses_equalities=off';
101+
eval $q1;
102+
eval $q2;
103+
104+
SET optimizer_switch='orderby_uses_equalities=on';
105+
eval $q1;
106+
eval $q2;
107+
108+
set optimizer_switch= @save_optimizer_switch;
109+
110+
DROP TABLE t1,t2,t3;

sql/sql_select.cc

Lines changed: 30 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -12519,8 +12519,37 @@ remove_const(JOIN *join,ORDER *first_order, COND *cond,
1251912519
can be used without tmp. table.
1252012520
*/
1252112521
bool can_subst_to_first_table= false;
12522+
bool first_is_in_sjm_nest= false;
12523+
if (first_is_base_table)
12524+
{
12525+
TABLE_LIST *tbl_for_first=
12526+
join->join_tab[join->const_tables].table->pos_in_table_list;
12527+
first_is_in_sjm_nest= tbl_for_first->sj_mat_info &&
12528+
tbl_for_first->sj_mat_info->is_used;
12529+
}
12530+
/*
12531+
Currently we do not employ the optimization that uses multiple
12532+
equalities for ORDER BY to remove tmp table in the case when
12533+
the first table happens to be the result of materialization of
12534+
a semi-join nest ( <=> first_is_in_sjm_nest == true).
12535+
12536+
When a semi-join nest is materialized and scanned to look for
12537+
possible matches in the remaining tables for every its row
12538+
the fields from the result of materialization are copied
12539+
into the record buffers of tables from the semi-join nest.
12540+
So these copies are used to access the remaining tables rather
12541+
than the fields from the result of materialization.
12542+
12543+
Unfortunately now this so-called 'copy back' technique is
12544+
supported only if the rows are scanned with the rr_sequential
12545+
function, but not with other rr_* functions that are employed
12546+
when the result of materialization is required to be sorted.
12547+
12548+
TODO: either to support 'copy back' technique for the above case,
12549+
or to get rid of this technique altogether.
12550+
*/
1252212551
if (optimizer_flag(join->thd, OPTIMIZER_SWITCH_ORDERBY_EQ_PROP) &&
12523-
first_is_base_table &&
12552+
first_is_base_table && !first_is_in_sjm_nest &&
1252412553
order->item[0]->real_item()->type() == Item::FIELD_ITEM &&
1252512554
join->cond_equal)
1252612555
{

0 commit comments

Comments
 (0)