Commit 37a84e52 authored by timour@mysql.com's avatar timour@mysql.com

Fix for BUG#11044 - "SELECT DISTINCT on indexed column returns inconsistent results"

The problem was that when there was no MIN or MAX function, after finding the
group prefix based on the DISTINCT or GROUP BY attributes we did not search further
for a key in the group that satisfies the equi-join conditions on attributes that
follow the group attributes. Thus we ended up with the wrong rows, and subsequent
calls to select_cond->val_int() in evaluate_join_record() were filtering those
rows. Hence - the query result set was empty.

The problem occured both for GROUP BY queries without MIN/MAX and for queries
with DISTINCT (which were internally executed as GROUP BY queries).
parent 95e62048
...@@ -1954,6 +1954,24 @@ id select_type table type possible_keys key key_len ref rows Extra ...@@ -1954,6 +1954,24 @@ id select_type table type possible_keys key key_len ref rows Extra
explain select sum(ord(a1)) from t1 where (a1 > 'a') group by a1,a2,b; explain select sum(ord(a1)) from t1 where (a1 > 'a') group by a1,a2,b;
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 t1 index idx_t1_0,idx_t1_1,idx_t1_2 idx_t1_1 163 NULL 128 Using where; Using index 1 SIMPLE t1 index idx_t1_0,idx_t1_1,idx_t1_2 idx_t1_1 163 NULL 128 Using where; Using index
explain select a1 from t1 where a2 = 'b' group by a1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range NULL idx_t1_1 130 NULL 5 Using where; Using index for group-by
select a1 from t1 where a2 = 'b' group by a1;
a1
a
b
c
d
explain select distinct a1 from t1 where a2 = 'b';
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range NULL idx_t1_1 130 NULL 5 Using where; Using index for group-by
select distinct a1 from t1 where a2 = 'b';
a1
a
b
c
d
drop table t1; drop table t1;
drop table t2; drop table t2;
drop table t3; drop table t3;
......
...@@ -482,7 +482,6 @@ select a1,a2,b from t2 where (a2 >= 'b') and (b = 'a') group by a1,a2,b; ...@@ -482,7 +482,6 @@ select a1,a2,b from t2 where (a2 >= 'b') and (b = 'a') group by a1,a2,b;
select a1,a2,b,c from t2 where (a2 >= 'b') and (b = 'a') and (c = 'i121') group by a1,a2,b; select a1,a2,b,c from t2 where (a2 >= 'b') and (b = 'a') and (c = 'i121') group by a1,a2,b;
select a1,a2,b from t2 where (a1 > 'a') and (a2 > 'a') and (b = 'c') group by a1,a2,b; select a1,a2,b from t2 where (a1 > 'a') and (a2 > 'a') and (b = 'c') group by a1,a2,b;
-- --
-- DISTINCT queries -- DISTINCT queries
-- --
...@@ -526,6 +525,7 @@ select distinct a1,a1 from t1; ...@@ -526,6 +525,7 @@ select distinct a1,a1 from t1;
select distinct a2,a1,a2,a1 from t1; select distinct a2,a1,a2,a1 from t1;
select distinct t1.a1,t2.a1 from t1,t2; select distinct t1.a1,t2.a1 from t1,t2;
-- --
-- DISTINCT queries with GROUP-BY -- DISTINCT queries with GROUP-BY
-- --
...@@ -641,6 +641,17 @@ explain select a1,a2,count(a2) from t1 group by a1,a2,b; ...@@ -641,6 +641,17 @@ explain select a1,a2,count(a2) from t1 group by a1,a2,b;
explain select a1,a2,count(a2) from t1 where (a1 > 'a') group by a1,a2,b; explain select a1,a2,count(a2) from t1 where (a1 > 'a') group by a1,a2,b;
explain select sum(ord(a1)) from t1 where (a1 > 'a') group by a1,a2,b; explain select sum(ord(a1)) from t1 where (a1 > 'a') group by a1,a2,b;
#
# BUG#11044: DISTINCT or GROUP BY queries with equality predicates instead of MIN/MAX.
#
explain select a1 from t1 where a2 = 'b' group by a1;
select a1 from t1 where a2 = 'b' group by a1;
explain select distinct a1 from t1 where a2 = 'b';
select distinct a1 from t1 where a2 = 'b';
drop table t1; drop table t1;
drop table t2; drop table t2;
drop table t3; drop table t3;
......
...@@ -7612,8 +7612,8 @@ void cost_group_min_max(TABLE* table, KEY *index_info, uint used_key_parts, ...@@ -7612,8 +7612,8 @@ void cost_group_min_max(TABLE* table, KEY *index_info, uint used_key_parts,
*records= num_groups; *records= num_groups;
DBUG_PRINT("info", DBUG_PRINT("info",
("records=%u, keys/block=%u, keys/group=%u, records=%u, blocks=%u", ("table rows=%u, keys/block=%u, keys/group=%u, result rows=%u, blocks=%u",
table_records, keys_per_block, keys_per_group, records, table_records, keys_per_block, keys_per_group, *records,
num_blocks)); num_blocks));
DBUG_VOID_RETURN; DBUG_VOID_RETURN;
} }
...@@ -8120,6 +8120,15 @@ int QUICK_GROUP_MIN_MAX_SELECT::get_next() ...@@ -8120,6 +8120,15 @@ int QUICK_GROUP_MIN_MAX_SELECT::get_next()
DBUG_ASSERT((have_max && !have_min) || DBUG_ASSERT((have_max && !have_min) ||
(have_max && have_min && (max_res == 0))); (have_max && have_min && (max_res == 0)));
} }
/*
If this is a just a GROUP BY or DISTINCT without MIN or MAX and there
are equality predicates for the key parts after the group, find the
first sub-group with the extended prefix.
*/
if (!have_min && !have_max && key_infix_len > 0)
result= file->index_read(record, group_prefix, real_prefix_len,
HA_READ_KEY_EXACT);
result= have_min ? min_res : have_max ? max_res : result; result= have_min ? min_res : have_max ? max_res : result;
} }
while (result == HA_ERR_KEY_NOT_FOUND && is_last_prefix != 0); while (result == HA_ERR_KEY_NOT_FOUND && is_last_prefix != 0);
...@@ -8146,9 +8155,8 @@ int QUICK_GROUP_MIN_MAX_SELECT::get_next() ...@@ -8146,9 +8155,8 @@ int QUICK_GROUP_MIN_MAX_SELECT::get_next()
QUICK_GROUP_MIN_MAX_SELECT::next_min() QUICK_GROUP_MIN_MAX_SELECT::next_min()
DESCRIPTION DESCRIPTION
Load the prefix of the next group into group_prefix and find the minimal Find the minimal key within this group such that the key satisfies the query
key within this group such that the key satisfies the query conditions and conditions and NULL semantics. The found key is loaded into this->record.
NULL semantics. The found key is loaded into this->record.
IMPLEMENTATION IMPLEMENTATION
Depending on the values of min_max_ranges.elements, key_infix_len, and Depending on the values of min_max_ranges.elements, key_infix_len, and
...@@ -8232,9 +8240,7 @@ int QUICK_GROUP_MIN_MAX_SELECT::next_min() ...@@ -8232,9 +8240,7 @@ int QUICK_GROUP_MIN_MAX_SELECT::next_min()
QUICK_GROUP_MIN_MAX_SELECT::next_max() QUICK_GROUP_MIN_MAX_SELECT::next_max()
DESCRIPTION DESCRIPTION
If there was no previous next_min call to determine the next group prefix, Lookup the maximal key of the group, and store it into this->record.
then load the next prefix into group_prefix, then lookup the maximal key of
the group, and store it into this->record.
RETURN RETURN
0 on success 0 on success
......
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