Commit 41445430 authored by unknown's avatar unknown

Bug #17212 results not sorted correctly by ORDER BY when using index

  * don't use join cache when the incoming data set is already ordered
    for ORDER BY
    This choice must be made because join cache will effectively
    reverse the join order and the results will be sorted by the index
    of the table that uses join cache.


mysql-test/r/innodb_mysql.result:
  Bug #17212 results not sorted correctly by ORDER BY when using index
    * Test suite for the bug
mysql-test/t/innodb_mysql.test:
  Bug #17212 results not sorted correctly by ORDER BY when using index
    * Test suite for the bug
sql/sql_select.cc:
  Bug #17212 results not sorted correctly by ORDER BY when using index
    * don't use join cache when the incoming data set is already sorted
parent 03dbc219
......@@ -54,3 +54,32 @@ c.c_id = 218 and expiredate is null;
slai_id
12
drop table t1, t2;
CREATE TABLE t1 (a int, b int, KEY b (b)) Engine=InnoDB;
CREATE TABLE t2 (a int, b int, PRIMARY KEY (a,b)) Engine=InnoDB;
CREATE TABLE t3 (a int, b int, c int, PRIMARY KEY (a),
UNIQUE KEY b (b,c), KEY a (a,b,c)) Engine=InnoDB;
INSERT INTO t1 VALUES (1, 1);
INSERT INTO t1 SELECT a + 1, b + 1 FROM t1;
INSERT INTO t1 SELECT a + 2, b + 2 FROM t1;
INSERT INTO t2 VALUES (1,1),(1,2),(1,3),(1,4),(1,5),(1,6),(1,7),(1,8);
INSERT INTO t2 SELECT a + 1, b FROM t2;
DELETE FROM t2 WHERE a = 1 AND b < 2;
INSERT INTO t3 VALUES (1,1,1),(2,1,2);
INSERT INTO t3 SELECT a + 2, a + 2, 3 FROM t3;
INSERT INTO t3 SELECT a + 4, a + 4, 3 FROM t3;
SELECT STRAIGHT_JOIN SQL_NO_CACHE t1.b, t1.a FROM t1, t3, t2 WHERE
t3.a = t2.a AND t2.b = t1.a AND t3.b = 1 AND t3.c IN (1, 2)
ORDER BY t1.b LIMIT 2;
b a
1 1
2 2
SELECT STRAIGHT_JOIN SQL_NO_CACHE t1.b, t1.a FROM t1, t3, t2 WHERE
t3.a = t2.a AND t2.b = t1.a AND t3.b = 1 AND t3.c IN (1, 2)
ORDER BY t1.b LIMIT 5;
b a
1 1
2 2
2 2
3 3
3 3
DROP TABLE t1, t2, t3;
......@@ -57,3 +57,36 @@ where
c.c_id = 218 and expiredate is null;
drop table t1, t2;
#
# Bug#17212: results not sorted correctly by ORDER BY when using index
# (repeatable only w/innodb because of index props)
#
CREATE TABLE t1 (a int, b int, KEY b (b)) Engine=InnoDB;
CREATE TABLE t2 (a int, b int, PRIMARY KEY (a,b)) Engine=InnoDB;
CREATE TABLE t3 (a int, b int, c int, PRIMARY KEY (a),
UNIQUE KEY b (b,c), KEY a (a,b,c)) Engine=InnoDB;
INSERT INTO t1 VALUES (1, 1);
INSERT INTO t1 SELECT a + 1, b + 1 FROM t1;
INSERT INTO t1 SELECT a + 2, b + 2 FROM t1;
INSERT INTO t2 VALUES (1,1),(1,2),(1,3),(1,4),(1,5),(1,6),(1,7),(1,8);
INSERT INTO t2 SELECT a + 1, b FROM t2;
DELETE FROM t2 WHERE a = 1 AND b < 2;
INSERT INTO t3 VALUES (1,1,1),(2,1,2);
INSERT INTO t3 SELECT a + 2, a + 2, 3 FROM t3;
INSERT INTO t3 SELECT a + 4, a + 4, 3 FROM t3;
# demonstrate a problem when a must-use-sort table flag
# (sort_by_table=1) is being neglected.
SELECT STRAIGHT_JOIN SQL_NO_CACHE t1.b, t1.a FROM t1, t3, t2 WHERE
t3.a = t2.a AND t2.b = t1.a AND t3.b = 1 AND t3.c IN (1, 2)
ORDER BY t1.b LIMIT 2;
# demonstrate the problem described in the bug report
SELECT STRAIGHT_JOIN SQL_NO_CACHE t1.b, t1.a FROM t1, t3, t2 WHERE
t3.a = t2.a AND t2.b = t1.a AND t3.b = 1 AND t3.c IN (1, 2)
ORDER BY t1.b LIMIT 5;
DROP TABLE t1, t2, t3;
......@@ -3845,6 +3845,7 @@ make_join_readinfo(JOIN *join, uint options)
{
uint i;
bool statistics= test(!(join->select_options & SELECT_DESCRIBE));
bool ordered_set= 0;
DBUG_ENTER("make_join_readinfo");
for (i=join->const_tables ; i < join->tables ; i++)
......@@ -3854,6 +3855,22 @@ make_join_readinfo(JOIN *join, uint options)
tab->read_record.table= table;
tab->read_record.file=table->file;
tab->next_select=sub_select; /* normal select */
/*
Determine if the set is already ordered for ORDER BY, so it can
disable join cache because it will change the ordering of the results.
Code handles sort table that is at any location (not only first after
the const tables) despite the fact that it's currently prohibited.
*/
if (!ordered_set &&
(table == join->sort_by_table &&
(!join->order || join->skip_sort_order ||
test_if_skip_sort_order(tab, join->order, join->select_limit,
1))
) ||
(join->sort_by_table == (TABLE *) 1 && i != join->const_tables))
ordered_set= 1;
switch (tab->type) {
case JT_SYSTEM: // Only happens with left join
table->status=STATUS_NO_RECORD;
......@@ -3924,10 +3941,11 @@ make_join_readinfo(JOIN *join, uint options)
case JT_ALL:
/*
If previous table use cache
If the incoming data set is already sorted don't use cache.
*/
table->status=STATUS_NO_RECORD;
if (i != join->const_tables && !(options & SELECT_NO_JOIN_CACHE) &&
tab->use_quick != 2 && !tab->on_expr)
tab->use_quick != 2 && !tab->on_expr && !ordered_set)
{
if ((options & SELECT_DESCRIBE) ||
!join_init_cache(join->thd,join->join_tab+join->const_tables,
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment