mirror of
https://github.com/MariaDB/server.git
synced 2025-07-29 05:21:33 +03:00
Bug #21302: Result not properly sorted when using an ORDER BY on a second
table in a join The optimizer removes redundant columns in ORDER BY. It is considering redundant every reference to const table column, e.g b in : create table t1 (a int, b int, primary key(a)); select 1 from t1 order by b where a = 1 But it must not remove references to const table columns if the const table is an outer table because there still can be 2 values : the const value and NULL. e.g.: create table t1 (a int, b int, primary key(a)); select t2.b c from t1 left join t1 t2 on (t1.a = t2.a and t2.a = 5) order by c; mysql-test/r/join_outer.result: Bug #21302: Result not properly sorted when using an ORDER BY on a second table in a join - don't remove columns of const tables in ORDER BY if the const table is an outer table. mysql-test/r/order_by.result: Bug #21302: Result not properly sorted when using an ORDER BY on a second table in a join - test case mysql-test/t/order_by.test: Bug #21302: Result not properly sorted when using an ORDER BY on a second table in a join - test case sql/sql_select.cc: Bug #21302: Result not properly sorted when using an ORDER BY on a second table in a join - don't remove columns of const tables in ORDER BY if the const table is an outer table.
This commit is contained in:
@ -735,7 +735,7 @@ explain select s.*, '*', m.*, (s.match_1_h - m.home) UUX from
|
|||||||
(t2 s left join t1 m on m.match_id = 1)
|
(t2 s left join t1 m on m.match_id = 1)
|
||||||
order by m.match_id desc;
|
order by m.match_id desc;
|
||||||
id select_type table type possible_keys key key_len ref rows Extra
|
id select_type table type possible_keys key key_len ref rows Extra
|
||||||
1 SIMPLE s ALL NULL NULL NULL NULL 10
|
1 SIMPLE s ALL NULL NULL NULL NULL 10 Using temporary; Using filesort
|
||||||
1 SIMPLE m const match_id,match_id_2 match_id 1 const 1
|
1 SIMPLE m const match_id,match_id_2 match_id 1 const 1
|
||||||
explain select s.*, '*', m.*, (s.match_1_h - m.home) UUX from
|
explain select s.*, '*', m.*, (s.match_1_h - m.home) UUX from
|
||||||
(t2 s left join t1 m on m.match_id = 1)
|
(t2 s left join t1 m on m.match_id = 1)
|
||||||
|
@ -852,3 +852,40 @@ b a
|
|||||||
20 1
|
20 1
|
||||||
10 2
|
10 2
|
||||||
DROP TABLE t1;
|
DROP TABLE t1;
|
||||||
|
CREATE TABLE t1 (a int, b int, PRIMARY KEY (a));
|
||||||
|
INSERT INTO t1 VALUES (1,1), (2,2), (3,3);
|
||||||
|
explain SELECT t1.b as a, t2.b as c FROM
|
||||||
|
t1 LEFT JOIN t1 t2 ON (t1.a = t2.a AND t2.a = 2)
|
||||||
|
ORDER BY c;
|
||||||
|
id select_type table type possible_keys key key_len ref rows Extra
|
||||||
|
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 Using temporary; Using filesort
|
||||||
|
1 SIMPLE t2 const PRIMARY PRIMARY 4 const 1
|
||||||
|
SELECT t1.b as a, t2.b as c FROM
|
||||||
|
t1 LEFT JOIN t1 t2 ON (t1.a = t2.a AND t2.a = 2)
|
||||||
|
ORDER BY c;
|
||||||
|
a c
|
||||||
|
1 NULL
|
||||||
|
3 NULL
|
||||||
|
2 2
|
||||||
|
explain SELECT t1.b as a, t2.b as c FROM
|
||||||
|
t1 JOIN t1 t2 ON (t1.a = t2.a AND t2.a = 2)
|
||||||
|
ORDER BY c;
|
||||||
|
id select_type table type possible_keys key key_len ref rows Extra
|
||||||
|
1 SIMPLE t1 const PRIMARY PRIMARY 4 const 1
|
||||||
|
1 SIMPLE t2 const PRIMARY PRIMARY 4 const 1
|
||||||
|
CREATE TABLE t2 LIKE t1;
|
||||||
|
INSERT INTO t2 SELECT * from t1;
|
||||||
|
CREATE TABLE t3 LIKE t1;
|
||||||
|
INSERT INTO t3 SELECT * from t1;
|
||||||
|
CREATE TABLE t4 LIKE t1;
|
||||||
|
INSERT INTO t4 SELECT * from t1;
|
||||||
|
INSERT INTO t1 values (0,0),(4,4);
|
||||||
|
SELECT t1.*,t2.* FROM t1 LEFT JOIN (t2, t3 LEFT JOIN t4 ON t3.a=t4.a)
|
||||||
|
ON (t1.a=t2.a AND t1.b=t3.b) order by t2.b;
|
||||||
|
a b a b
|
||||||
|
0 0 NULL NULL
|
||||||
|
4 4 NULL NULL
|
||||||
|
1 1 1 1
|
||||||
|
2 2 2 2
|
||||||
|
3 3 3 3
|
||||||
|
DROP TABLE t1,t2,t3,t4;
|
||||||
|
@ -578,3 +578,35 @@ INSERT INTO t1 VALUES (1,30), (2,20), (1,10), (2,30), (1,20), (2,10);
|
|||||||
DROP TABLE t1;
|
DROP TABLE t1;
|
||||||
|
|
||||||
# End of 4.1 tests
|
# End of 4.1 tests
|
||||||
|
|
||||||
|
#
|
||||||
|
# Bug#21302: Result not properly sorted when using an ORDER BY on a second
|
||||||
|
# table in a join
|
||||||
|
#
|
||||||
|
CREATE TABLE t1 (a int, b int, PRIMARY KEY (a));
|
||||||
|
INSERT INTO t1 VALUES (1,1), (2,2), (3,3);
|
||||||
|
|
||||||
|
explain SELECT t1.b as a, t2.b as c FROM
|
||||||
|
t1 LEFT JOIN t1 t2 ON (t1.a = t2.a AND t2.a = 2)
|
||||||
|
ORDER BY c;
|
||||||
|
SELECT t1.b as a, t2.b as c FROM
|
||||||
|
t1 LEFT JOIN t1 t2 ON (t1.a = t2.a AND t2.a = 2)
|
||||||
|
ORDER BY c;
|
||||||
|
|
||||||
|
# check that it still removes sort of const table
|
||||||
|
explain SELECT t1.b as a, t2.b as c FROM
|
||||||
|
t1 JOIN t1 t2 ON (t1.a = t2.a AND t2.a = 2)
|
||||||
|
ORDER BY c;
|
||||||
|
|
||||||
|
CREATE TABLE t2 LIKE t1;
|
||||||
|
INSERT INTO t2 SELECT * from t1;
|
||||||
|
CREATE TABLE t3 LIKE t1;
|
||||||
|
INSERT INTO t3 SELECT * from t1;
|
||||||
|
CREATE TABLE t4 LIKE t1;
|
||||||
|
INSERT INTO t4 SELECT * from t1;
|
||||||
|
INSERT INTO t1 values (0,0),(4,4);
|
||||||
|
|
||||||
|
SELECT t1.*,t2.* FROM t1 LEFT JOIN (t2, t3 LEFT JOIN t4 ON t3.a=t4.a)
|
||||||
|
ON (t1.a=t2.a AND t1.b=t3.b) order by t2.b;
|
||||||
|
|
||||||
|
DROP TABLE t1,t2,t3,t4;
|
||||||
|
@ -5976,7 +5976,8 @@ eq_ref_table(JOIN *join, ORDER *start_order, JOIN_TAB *tab)
|
|||||||
if (tab->cached_eq_ref_table) // If cached
|
if (tab->cached_eq_ref_table) // If cached
|
||||||
return tab->eq_ref_table;
|
return tab->eq_ref_table;
|
||||||
tab->cached_eq_ref_table=1;
|
tab->cached_eq_ref_table=1;
|
||||||
if (tab->type == JT_CONST) // We can skip const tables
|
/* We can skip const tables only if not an outer table */
|
||||||
|
if (tab->type == JT_CONST && !tab->first_inner)
|
||||||
return (tab->eq_ref_table=1); /* purecov: inspected */
|
return (tab->eq_ref_table=1); /* purecov: inspected */
|
||||||
if (tab->type != JT_EQ_REF || tab->table->maybe_null)
|
if (tab->type != JT_EQ_REF || tab->table->maybe_null)
|
||||||
return (tab->eq_ref_table=0); // We must use this
|
return (tab->eq_ref_table=0); // We must use this
|
||||||
|
Reference in New Issue
Block a user