mirror of
https://github.com/MariaDB/server.git
synced 2025-01-16 20:12:31 +01:00
Fix for Bug#14636211 WRONG RESULT (EXTRA ROW) ON A FROM SUBQUERY
WITH A VARIABLE AND ORDER BY Bug#16035412 MYSQL SERVER 5.5.29 WRONG SORTING USING COMPLEX INDEX This is a fix for a regression introduced by Bug#12667154: Bug#12667154 attempted to fix a performance problem with subqueries that did filesort. For doing filesort, the optimizer creates a quick select object to use when building the sort index. This quick select object was deleted after the first call to create_sort_index(). Thus, for queries where the subquery was executed multiple times, the quick object was only used for the first execution. For all later executions of the subquery, filesort used a complete table scan for building the sort index. The fix for Bug#12667154 tried to fix this by not deleting the quick object after the first execution of create_sort_index() so that it would be re-used for building the sort index by the following executions of the subquery. This regression introduced in Bug#12667154 is that due to not deleting the quick select object after building the sort index, the quick object could in some cases be used also during the second phase of the execution of the subquery instead of using the created sort index. This caused wrong results to be returned. The fix for this issue is to delete the reference to the select object after it has been used in create_sort_index(). In this way the select and quick objects will not be available when doing the second phase of the execution of the select operation. To ensure that the select object can be re-used for the following executions of the subquery we make a copy of the select pointer. This is used for restoring the select object after the select operation is completed.
This commit is contained in:
parent
18a9945c5b
commit
e810f7f4eb
3 changed files with 54 additions and 14 deletions
|
@ -1738,7 +1738,7 @@ SELECT 1 FROM (SELECT COUNT(DISTINCT c1)
|
|||
FROM t1 WHERE c2 IN (1, 1) AND c3 = 2 GROUP BY c2) x;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY <derived2> system NULL NULL NULL NULL 1
|
||||
2 DERIVED t1 ALL c3,c2 c3 5 5 Using filesort
|
||||
2 DERIVED t1 ALL c3,c2 c3 5 5 Using where; Using filesort
|
||||
DROP TABLE t1;
|
||||
CREATE TABLE t1 (c1 REAL, c2 REAL, c3 REAL, KEY (c3), KEY (c2, c3))
|
||||
ENGINE=InnoDB;
|
||||
|
@ -1752,7 +1752,7 @@ SELECT 1 FROM (SELECT COUNT(DISTINCT c1)
|
|||
FROM t1 WHERE c2 IN (1, 1) AND c3 = 2 GROUP BY c2) x;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY <derived2> system NULL NULL NULL NULL 1
|
||||
2 DERIVED t1 ALL c3,c2 c3 9 5 Using filesort
|
||||
2 DERIVED t1 ALL c3,c2 c3 9 5 Using where; Using filesort
|
||||
DROP TABLE t1;
|
||||
CREATE TABLE t1 (c1 DECIMAL(12,2), c2 DECIMAL(12,2), c3 DECIMAL(12,2),
|
||||
KEY (c3), KEY (c2, c3))
|
||||
|
@ -1767,7 +1767,7 @@ SELECT 1 FROM (SELECT COUNT(DISTINCT c1)
|
|||
FROM t1 WHERE c2 IN (1, 1) AND c3 = 2 GROUP BY c2) x;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 PRIMARY <derived2> system NULL NULL NULL NULL 1
|
||||
2 DERIVED t1 ALL c3,c2 c3 7 5 Using filesort
|
||||
2 DERIVED t1 ALL c3,c2 c3 7 5 Using where; Using filesort
|
||||
DROP TABLE t1;
|
||||
End of 5.1 tests
|
||||
#
|
||||
|
|
|
@ -1,4 +1,4 @@
|
|||
/* Copyright (c) 2000, 2012, Oracle and/or its affiliates. All rights reserved.
|
||||
/* Copyright (c) 2000, 2013, Oracle and/or its affiliates. All rights reserved.
|
||||
|
||||
This program is free software; you can redistribute it and/or modify
|
||||
it under the terms of the GNU General Public License as published by
|
||||
|
@ -1829,6 +1829,8 @@ JOIN::exec()
|
|||
{
|
||||
List<Item> *columns_list= &fields_list;
|
||||
int tmp_error;
|
||||
bool sort_index_created= false;
|
||||
|
||||
DBUG_ENTER("JOIN::exec");
|
||||
|
||||
thd_proc_info(thd, "executing");
|
||||
|
@ -2123,6 +2125,7 @@ JOIN::exec()
|
|||
{
|
||||
DBUG_VOID_RETURN;
|
||||
}
|
||||
sort_index_created= true;
|
||||
sortorder= curr_join->sortorder;
|
||||
}
|
||||
|
||||
|
@ -2350,6 +2353,7 @@ JOIN::exec()
|
|||
HA_POS_ERROR : unit->select_limit_cnt),
|
||||
curr_join->group_list ? TRUE : FALSE))
|
||||
DBUG_VOID_RETURN;
|
||||
sort_index_created= true;
|
||||
sortorder= curr_join->sortorder;
|
||||
if (curr_join->const_tables != curr_join->tables &&
|
||||
!curr_join->join_tab[curr_join->const_tables].table->sort.io_cache)
|
||||
|
@ -2381,6 +2385,16 @@ JOIN::exec()
|
|||
error= do_select(curr_join, curr_fields_list, NULL, procedure);
|
||||
thd->limit_found_rows= curr_join->send_records;
|
||||
|
||||
if (sort_index_created && curr_join->tables != curr_join->const_tables )
|
||||
{
|
||||
// Restore the original "select" used by create_sort_index():
|
||||
JOIN_TAB *const tab= curr_join->join_tab + curr_join->const_tables;
|
||||
if (tab->saved_select)
|
||||
{
|
||||
tab->select= tab->saved_select;
|
||||
tab->saved_select= NULL;
|
||||
}
|
||||
}
|
||||
/* Accumulate the counts from all join iterations of all join parts. */
|
||||
thd->examined_row_count+= curr_join->examined_rows;
|
||||
DBUG_PRINT("counts", ("thd->examined_row_count: %lu",
|
||||
|
@ -14134,7 +14148,7 @@ create_sort_index(THD *thd, JOIN *join, ORDER *order,
|
|||
tab= join->join_tab + join->const_tables;
|
||||
table= tab->table;
|
||||
select= tab->select;
|
||||
|
||||
tab->saved_select= NULL;
|
||||
/*
|
||||
If we have a select->quick object that is created outside of
|
||||
create_sort_index() and this is part of a subquery that
|
||||
|
@ -14233,16 +14247,28 @@ create_sort_index(THD *thd, JOIN *join, ORDER *order,
|
|||
if (!keep_quick)
|
||||
{
|
||||
select->cleanup();
|
||||
/*
|
||||
The select object should now be ready for the next use. If it
|
||||
is re-used then there exists a backup copy of this join tab
|
||||
which has the pointer to it. The join tab will be restored in
|
||||
JOIN::reset(). So here we just delete the pointer to it.
|
||||
*/
|
||||
tab->select= NULL;
|
||||
// If we deleted the quick select object we need to clear quick_keys
|
||||
|
||||
// If we deleted the quick object we need to clear quick_keys
|
||||
table->quick_keys.clear_all();
|
||||
}
|
||||
else
|
||||
{
|
||||
// Need to close the index scan in order to re-use the handler
|
||||
tab->select->quick->range_end();
|
||||
}
|
||||
|
||||
/*
|
||||
The select object is now ready for the next use. To avoid that
|
||||
the select object is used when reading the records in sorted
|
||||
order we set the pointer to it to NULL. The select pointer will
|
||||
be restored from the saved_select pointer when this select
|
||||
operation is completed (@see JOIN::exec). This ensures that it
|
||||
will be re-used when filesort is used by subqueries that are
|
||||
executed multiple times.
|
||||
*/
|
||||
tab->saved_select= tab->select;
|
||||
tab->select= NULL;
|
||||
|
||||
// Restore the output resultset
|
||||
table->sort.io_cache= tablesort_result_cache;
|
||||
}
|
||||
|
|
|
@ -1,7 +1,7 @@
|
|||
#ifndef SQL_SELECT_INCLUDED
|
||||
#define SQL_SELECT_INCLUDED
|
||||
|
||||
/* Copyright (c) 2000, 2011, Oracle and/or its affiliates. All rights reserved.
|
||||
/* Copyright (c) 2000, 2013, Oracle and/or its affiliates. All rights reserved.
|
||||
|
||||
This program is free software; you can redistribute it and/or modify
|
||||
it under the terms of the GNU General Public License as published by
|
||||
|
@ -160,6 +160,20 @@ typedef struct st_join_table {
|
|||
TABLE *table;
|
||||
KEYUSE *keyuse; /**< pointer to first used key */
|
||||
SQL_SELECT *select;
|
||||
/**
|
||||
When doing filesort, the select object is used for building the
|
||||
sort index. After the sort index is built, the pointer to the
|
||||
select object is set to NULL to avoid that it is used when reading
|
||||
the result records (@see create_sort_index()). For subqueries that
|
||||
do filesort and that are executed multiple times, the pointer to
|
||||
the select object must be restored before the next execution both
|
||||
to ensure that the select object is used and to be able to cleanup
|
||||
the select object after the final execution of the subquery. In
|
||||
order to be able to restore the pointer to the select object, it
|
||||
is saved in saved_select in create_sort_index() and restored in
|
||||
JOIN::exec() after the main select is done.
|
||||
*/
|
||||
SQL_SELECT *saved_select;
|
||||
COND *select_cond;
|
||||
QUICK_SELECT_I *quick;
|
||||
Item **on_expr_ref; /**< pointer to the associated on expression */
|
||||
|
|
Loading…
Reference in a new issue