From 02e194cea215910dedf35f5141ecf442d6ef5407 Mon Sep 17 00:00:00 2001 From: "timour/timka@lamia.home" <> Date: Fri, 1 Sep 2006 15:07:04 +0300 Subject: [PATCH] Fix for BUG#21787: COUNT(*) + ORDER BY + LIMIT returns wrong result The problem was due to a prior fix for BUG 9676, which limited the rows stored in a temporary table to the LIMIT clause. This optimization is not applicable to non-group queries with aggregate functions. The fix disables the optimization in this case. --- mysql-test/r/limit.result | 14 ++++++++++++++ mysql-test/t/limit.test | 10 ++++++++++ sql/sql_select.cc | 19 ++++++++++++++----- 3 files changed, 38 insertions(+), 5 deletions(-) diff --git a/mysql-test/r/limit.result b/mysql-test/r/limit.result index 6a3d2bffab0..92803ec3449 100644 --- a/mysql-test/r/limit.result +++ b/mysql-test/r/limit.result @@ -76,3 +76,17 @@ a a 1 drop table t1; +create table t1 (a int); +insert into t1 values (1),(2),(3),(4),(5),(6),(7); +explain select count(*) c FROM t1 WHERE a > 0 ORDER BY c LIMIT 3; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 7 Using where; Using temporary +select count(*) c FROM t1 WHERE a > 0 ORDER BY c LIMIT 3; +c +7 +explain select sum(a) c FROM t1 WHERE a > 0 ORDER BY c LIMIT 3; +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE t1 ALL NULL NULL NULL NULL 7 Using where; Using temporary +select sum(a) c FROM t1 WHERE a > 0 ORDER BY c LIMIT 3; +c +28 diff --git a/mysql-test/t/limit.test b/mysql-test/t/limit.test index ef9f63067a4..f70cf835588 100644 --- a/mysql-test/t/limit.test +++ b/mysql-test/t/limit.test @@ -60,4 +60,14 @@ select 1 as a from t1 union all select 1 from dual limit 1; (select 1 as a from t1) union all (select 1 from dual) limit 1; drop table t1; +# +# Bug #21787: COUNT(*) + ORDER BY + LIMIT returns wrong result +# +create table t1 (a int); +insert into t1 values (1),(2),(3),(4),(5),(6),(7); +explain select count(*) c FROM t1 WHERE a > 0 ORDER BY c LIMIT 3; +select count(*) c FROM t1 WHERE a > 0 ORDER BY c LIMIT 3; +explain select sum(a) c FROM t1 WHERE a > 0 ORDER BY c LIMIT 3; +select sum(a) c FROM t1 WHERE a > 0 ORDER BY c LIMIT 3; + # End of 4.1 tests diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 605ef49bb07..4c086f08af3 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -5612,11 +5612,6 @@ create_tmp_table(THD *thd,TMP_TABLE_PARAM *param,List &fields, keyinfo->key_length+= key_part_info->length; } } - else - { - set_if_smaller(table->max_rows, rows_limit); - param->end_write_records= rows_limit; - } if (distinct && field_count != param->hidden_field_count) { @@ -5679,6 +5674,20 @@ create_tmp_table(THD *thd,TMP_TABLE_PARAM *param,List &fields, 0 : FIELDFLAG_BINARY; } } + + /* + Push the LIMIT clause to the temporary table creation, so that we + materialize only up to 'rows_limit' records instead of all result records. + This optimization is not applicable when there is GROUP BY or there is + no GROUP BY, but there are aggregate functions, because both must be + computed for all result rows. + */ + if (!group && !thd->lex->current_select->with_sum_func) + { + set_if_smaller(table->max_rows, rows_limit); + param->end_write_records= rows_limit; + } + if (thd->is_fatal_error) // If end of memory goto err; /* purecov: inspected */ table->db_record_offset=1;