summaryrefslogtreecommitdiff
diff options
context:
space:
mode:
authorIgor Babaev <igor@askmonty.org>2017-11-10 13:58:00 -0800
committerIgor Babaev <igor@askmonty.org>2017-11-10 14:01:29 -0800
commitdcbf2823c7d64380f06372d77d1522e97fb8f066 (patch)
tree601e8b1ae2212eb4d93d8f6c7a66cdd185008fab
parent589b0b365589d5a0a355a7155ece83b95d6e8510 (diff)
downloadmariadb-git-dcbf2823c7d64380f06372d77d1522e97fb8f066.tar.gz
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.
-rw-r--r--mysql-test/r/order_by.result48
-rw-r--r--mysql-test/r/order_by_innodb.result73
-rw-r--r--mysql-test/t/order_by.test43
-rw-r--r--mysql-test/t/order_by_innodb.test47
-rw-r--r--sql/sql_select.cc31
5 files changed, 241 insertions, 1 deletions
diff --git a/mysql-test/r/order_by.result b/mysql-test/r/order_by.result
index f43e6ce18af..5a9f2fae1e0 100644
--- a/mysql-test/r/order_by.result
+++ b/mysql-test/r/order_by.result
@@ -3159,3 +3159,51 @@ pk
2
3
DROP TABLE t1;
+#
+# MDEV-13994: Bad join results with orderby_uses_equalities=on
+#
+CREATE TABLE books (
+id int(16) NOT NULL AUTO_INCREMENT,
+library_id int(16) NOT NULL DEFAULT 0,
+wings_id int(12) NOT NULL DEFAULT 0,
+scheduled_for_removal int(1) DEFAULT 0,
+PRIMARY KEY (id),
+KEY library_idx (library_id)
+) ENGINE=MyISAM AUTO_INCREMENT=1 DEFAULT CHARSET=utf8;
+INSERT INTO books VALUES (32625,8663,707,0),(32624,8663,505,1);
+CREATE TABLE wings (
+id int(11) NOT NULL AUTO_INCREMENT,
+department_id int(11) DEFAULT NULL,
+PRIMARY KEY (id)
+) ENGINE=MyISAM AUTO_INCREMENT=1 DEFAULT CHARSET=utf8;
+INSERT INTO wings VALUES (505,11745),(707,11768);
+SET @save_optimizer_switch=@@optimizer_switch;
+SET optimizer_switch='orderby_uses_equalities=off';
+SELECT wings.id as wing_id, wings.department_id FROM wings
+WHERE wings.id IN ( SELECT books.wings_id FROM books
+WHERE books.library_id = 8663 AND
+books.scheduled_for_removal=0 )
+ORDER BY wings.id;
+wing_id department_id
+707 11768
+SET optimizer_switch='orderby_uses_equalities=on';
+SELECT wings.id as wing_id, wings.department_id FROM wings
+WHERE wings.id IN ( SELECT books.wings_id FROM books
+WHERE books.library_id = 8663 AND
+books.scheduled_for_removal=0 )
+ORDER BY wings.id;
+wing_id department_id
+707 11768
+explain extended SELECT wings.id as wing_id, wings.department_id FROM wings
+WHERE wings.id IN ( SELECT books.wings_id FROM books
+WHERE books.library_id = 8663 AND
+books.scheduled_for_removal=0 )
+ORDER BY wings.id;
+id select_type table type possible_keys key key_len ref rows filtered Extra
+1 PRIMARY <subquery2> ALL distinct_key NULL NULL NULL 1 100.00 Using temporary; Using filesort
+1 PRIMARY wings eq_ref PRIMARY PRIMARY 4 test.books.wings_id 1 100.00
+2 MATERIALIZED books ref library_idx library_idx 4 const 1 100.00 Using where
+Warnings:
+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`
+set optimizer_switch= @save_optimizer_switch;
+DROP TABLE books, wings;
diff --git a/mysql-test/r/order_by_innodb.result b/mysql-test/r/order_by_innodb.result
index 4f59a2f8c20..3ff1f92e94a 100644
--- a/mysql-test/r/order_by_innodb.result
+++ b/mysql-test/r/order_by_innodb.result
@@ -48,3 +48,76 @@ where key1<3 or key2<3;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index_merge key1,key2 key1,key2 5,5 NULL # Using sort_union(key1,key2); Using where
drop table t0, t1;
+#
+# MDEV-14071: wrong results with orderby_uses_equalities=on
+# (duplicate of MDEV-13994)
+#
+CREATE TABLE t1 (i int, j int, z int,PRIMARY KEY (i,j), KEY (z)) ENGINE=InnoDB;
+CREATE TABLE t2 (i int, j int, PRIMARY KEY (i,j)) ENGINE=InnoDB;
+CREATE TABLE t3 (j int, n varchar(5), PRIMARY KEY (j)) ENGINE=InnoDB;
+INSERT INTO t1 VALUES
+(127,0,1),(188,0,1),(206,0,1),(218,0,1),(292,0,1),(338,0,1),(375,0,1),
+(381,0,1),(409,0,1),(466,0,1),(469,0,1),(498,0,1),(656,0,1);
+INSERT INTO t1 VALUES
+(77,4,0),(86,7,0),(96,6,0),(96,7,0),(99,9,0),(99,10,0),(99,11,0),(104,4,0),
+(106,5,0),(148,6,0),(177,6,0),(181,5,0),(188,8,0),(218,8,0),(253,7,0),
+(268,4,0),(338,4,0),(409,7,0),(466,8,0),(469,8,0),(498,8,0),(656,8,0);
+INSERT INTO t2 VALUES
+(127,7),(188,8),(188,9),(206,6),(218,8),(218,9),(292,7),(338,4),(338,5),
+(375,6),(381,5),(409,7),(409,8),(466,8),(466,9),(469,8),(469,9),(498,8),
+(498,9),(656,8),(656,9);
+INSERT INTO t3 VALUES
+(4,'four'),(5,'five'),(6,'six'),(7,'seven'),(8,'eight'),(9,'nine');
+SET @save_optimizer_switch=@@optimizer_switch;
+SET optimizer_switch='orderby_uses_equalities=off';
+SELECT i,n
+FROM t1 INNER JOIN t2 USING (i,j) LEFT JOIN t3 USING (j)
+WHERE i IN (SELECT i FROM t1 WHERE z=1) AND z=0 ORDER BY i;
+i n
+188 eight
+218 eight
+338 four
+409 seven
+466 eight
+469 eight
+498 eight
+656 eight
+SELECT i,n
+FROM t1 x INNER JOIN t2 USING (i,j) LEFT JOIN t3 USING (j)
+WHERE EXISTS (SELECT * FROM t1 WHERE i=x.i AND z=1) AND z=0 ORDER BY i;
+i n
+188 eight
+218 eight
+338 four
+409 seven
+466 eight
+469 eight
+498 eight
+656 eight
+SET optimizer_switch='orderby_uses_equalities=on';
+SELECT i,n
+FROM t1 INNER JOIN t2 USING (i,j) LEFT JOIN t3 USING (j)
+WHERE i IN (SELECT i FROM t1 WHERE z=1) AND z=0 ORDER BY i;
+i n
+188 eight
+218 eight
+338 four
+409 seven
+466 eight
+469 eight
+498 eight
+656 eight
+SELECT i,n
+FROM t1 x INNER JOIN t2 USING (i,j) LEFT JOIN t3 USING (j)
+WHERE EXISTS (SELECT * FROM t1 WHERE i=x.i AND z=1) AND z=0 ORDER BY i;
+i n
+188 eight
+218 eight
+338 four
+409 seven
+466 eight
+469 eight
+498 eight
+656 eight
+set optimizer_switch= @save_optimizer_switch;
+DROP TABLE t1,t2,t3;
diff --git a/mysql-test/t/order_by.test b/mysql-test/t/order_by.test
index 8722401ccae..914911648b2 100644
--- a/mysql-test/t/order_by.test
+++ b/mysql-test/t/order_by.test
@@ -2106,3 +2106,46 @@ INSERT INTO t1 VALUES (1),(2),(3);
SELECT DISTINCT pk FROM t1 GROUP BY 'foo';
SELECT DISTINCT pk FROM t1;
DROP TABLE t1;
+
+--echo #
+--echo # MDEV-13994: Bad join results with orderby_uses_equalities=on
+--echo #
+
+CREATE TABLE books (
+ id int(16) NOT NULL AUTO_INCREMENT,
+ library_id int(16) NOT NULL DEFAULT 0,
+ wings_id int(12) NOT NULL DEFAULT 0,
+ scheduled_for_removal int(1) DEFAULT 0,
+ PRIMARY KEY (id),
+ KEY library_idx (library_id)
+) ENGINE=MyISAM AUTO_INCREMENT=1 DEFAULT CHARSET=utf8;
+
+INSERT INTO books VALUES (32625,8663,707,0),(32624,8663,505,1);
+
+CREATE TABLE wings (
+ id int(11) NOT NULL AUTO_INCREMENT,
+ department_id int(11) DEFAULT NULL,
+ PRIMARY KEY (id)
+) ENGINE=MyISAM AUTO_INCREMENT=1 DEFAULT CHARSET=utf8;
+
+INSERT INTO wings VALUES (505,11745),(707,11768);
+
+let $q=
+SELECT wings.id as wing_id, wings.department_id FROM wings
+ WHERE wings.id IN ( SELECT books.wings_id FROM books
+ WHERE books.library_id = 8663 AND
+ books.scheduled_for_removal=0 )
+ORDER BY wings.id;
+
+SET @save_optimizer_switch=@@optimizer_switch;
+
+SET optimizer_switch='orderby_uses_equalities=off';
+eval $q;
+
+SET optimizer_switch='orderby_uses_equalities=on';
+eval $q;
+eval explain extended $q;
+
+set optimizer_switch= @save_optimizer_switch;
+
+DROP TABLE books, wings;
diff --git a/mysql-test/t/order_by_innodb.test b/mysql-test/t/order_by_innodb.test
index 097eddd24f1..0debb777749 100644
--- a/mysql-test/t/order_by_innodb.test
+++ b/mysql-test/t/order_by_innodb.test
@@ -61,3 +61,50 @@ from t1
where key1<3 or key2<3;
drop table t0, t1;
+
+--echo #
+--echo # MDEV-14071: wrong results with orderby_uses_equalities=on
+--echo # (duplicate of MDEV-13994)
+--echo #
+
+CREATE TABLE t1 (i int, j int, z int,PRIMARY KEY (i,j), KEY (z)) ENGINE=InnoDB;
+CREATE TABLE t2 (i int, j int, PRIMARY KEY (i,j)) ENGINE=InnoDB;
+CREATE TABLE t3 (j int, n varchar(5), PRIMARY KEY (j)) ENGINE=InnoDB;
+
+INSERT INTO t1 VALUES
+ (127,0,1),(188,0,1),(206,0,1),(218,0,1),(292,0,1),(338,0,1),(375,0,1),
+ (381,0,1),(409,0,1),(466,0,1),(469,0,1),(498,0,1),(656,0,1);
+INSERT INTO t1 VALUES
+ (77,4,0),(86,7,0),(96,6,0),(96,7,0),(99,9,0),(99,10,0),(99,11,0),(104,4,0),
+ (106,5,0),(148,6,0),(177,6,0),(181,5,0),(188,8,0),(218,8,0),(253,7,0),
+ (268,4,0),(338,4,0),(409,7,0),(466,8,0),(469,8,0),(498,8,0),(656,8,0);
+
+INSERT INTO t2 VALUES
+ (127,7),(188,8),(188,9),(206,6),(218,8),(218,9),(292,7),(338,4),(338,5),
+ (375,6),(381,5),(409,7),(409,8),(466,8),(466,9),(469,8),(469,9),(498,8),
+ (498,9),(656,8),(656,9);
+INSERT INTO t3 VALUES
+ (4,'four'),(5,'five'),(6,'six'),(7,'seven'),(8,'eight'),(9,'nine');
+
+let $q1=
+SELECT i,n
+FROM t1 INNER JOIN t2 USING (i,j) LEFT JOIN t3 USING (j)
+WHERE i IN (SELECT i FROM t1 WHERE z=1) AND z=0 ORDER BY i;
+let $q2=
+SELECT i,n
+FROM t1 x INNER JOIN t2 USING (i,j) LEFT JOIN t3 USING (j)
+WHERE EXISTS (SELECT * FROM t1 WHERE i=x.i AND z=1) AND z=0 ORDER BY i;
+
+SET @save_optimizer_switch=@@optimizer_switch;
+
+SET optimizer_switch='orderby_uses_equalities=off';
+eval $q1;
+eval $q2;
+
+SET optimizer_switch='orderby_uses_equalities=on';
+eval $q1;
+eval $q2;
+
+set optimizer_switch= @save_optimizer_switch;
+
+DROP TABLE t1,t2,t3;
diff --git a/sql/sql_select.cc b/sql/sql_select.cc
index 21e48c1ade7..676b26e7db0 100644
--- a/sql/sql_select.cc
+++ b/sql/sql_select.cc
@@ -12519,8 +12519,37 @@ remove_const(JOIN *join,ORDER *first_order, COND *cond,
can be used without tmp. table.
*/
bool can_subst_to_first_table= false;
+ bool first_is_in_sjm_nest= false;
+ if (first_is_base_table)
+ {
+ TABLE_LIST *tbl_for_first=
+ join->join_tab[join->const_tables].table->pos_in_table_list;
+ first_is_in_sjm_nest= tbl_for_first->sj_mat_info &&
+ tbl_for_first->sj_mat_info->is_used;
+ }
+ /*
+ Currently we do not employ 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 ( <=> first_is_in_sjm_nest == true).
+
+ When a semi-join nest is materialized and scanned to look for
+ possible matches in the remaining tables for every its row
+ the fields from the result of materialization are copied
+ into the record buffers of tables from the semi-join nest.
+ So these copies are used to access the remaining tables rather
+ than the fields from the result of materialization.
+
+ Unfortunately now this so-called 'copy back' technique is
+ supported only if the rows are scanned with the rr_sequential
+ function, but not with other rr_* functions that are employed
+ when the result of materialization is required to be sorted.
+
+ TODO: either to support 'copy back' technique for the above case,
+ or to get rid of this technique altogether.
+ */
if (optimizer_flag(join->thd, OPTIMIZER_SWITCH_ORDERBY_EQ_PROP) &&
- first_is_base_table &&
+ first_is_base_table && !first_is_in_sjm_nest &&
order->item[0]->real_item()->type() == Item::FIELD_ITEM &&
join->cond_equal)
{