Bug #107535 Group by does not use loose scan unless full prefix is given
Submitted: 9 Jun 2022 22:56 Modified: 3 Aug 2023 19:35
Reporter: Manuel Ung Email Updates:
Status: Verified Impact on me:
None 
Category:MySQL Server: Optimizer Severity:S3 (Non-critical)
Version:8.0.29, 5.7.38 OS:Any
Assigned to: CPU Architecture:Any

[9 Jun 2022 22:56] Manuel Ung
Description:
Given an index key(a, b) and a query like
select b from t where a = 1 group by b

We are not able to use loose index scan even though we should be able to. This can be worked around by querying for
select b from t where a = 1 group by a, b;

We get something similar when we use DISTINCT instead of GROUP BY.

This is issue is somewhat similar in spirit to this one (though fix is completely different): https://bugs.mysql.com/bug.php?id=94903

How to repeat:
Run this:

CREATE TABLE t (a INT, b INT, c INT, d INT, KEY k1(a, b, c, d)) ENGINE=innodb;

--disable_query_log
CREATE TEMPORARY TABLE a (a INT);
let $i=10;
while ($i)
{
  --eval INSERT INTO a VALUES ($i)
  dec $i;
}

CREATE TEMPORARY TABLE b (a INT);
let $i=5;
while ($i)
{
  --eval INSERT INTO b VALUES ($i)
  dec $i;
}

CREATE TEMPORARY TABLE c (a INT);
let $i=5;
while ($i)
{
  --eval INSERT INTO c VALUES ($i)
  dec $i;
}

CREATE TEMPORARY TABLE d (a INT);
let $i=10;
while ($i)
{
  --eval INSERT INTO d VALUES ($i)
  dec $i;
}

INSERT INTO t SELECT a.a, b.a, c.a, d.a FROM a, b, c, d;

INSERT INTO t VALUES (11, 2, 3, -10);
INSERT INTO t VALUES (11, 3, 3, 20);
INSERT INTO t VALUES (11, 15, NULL, -20);
INSERT INTO t VALUES (11, NULL, 40, 30);

INSERT INTO t VALUES (12, 15, 3, -15);
INSERT INTO t VALUES (12, 15, 40, -20);
INSERT INTO t VALUES (12, 2, 40, -23);
INSERT INTO t VALUES (12, 2, 3, NULL);

DROP TEMPORARY TABLE a, b, c, d;

--enable_query_log

ANALYZE TABLE t;

explain
select b from t where a = 1 group by b;
select b from t where a = 1 group by b;

explain
select b from t where a = 1 group by a, b;
select b from t where a = 1 group by a, b;

DROP TABLE t;

Relevant results:

explain
select b from t where a = 1 group by b;
id      select_type     table   partitions      type    possible_keys   key     key_len ref     rows    filtered        Extra
1       SIMPLE  t       NULL    ref     k1      k1      5       const   250     100.00  Using index

explain
select b from t where a = 1 group by a, b;
id      select_type     table   partitions      type    possible_keys   key     key_len ref     rows    filtered        Extra
1       SIMPLE  t       NULL    range   k1      k1      10      NULL    6       100.00  Using where; Using index for group-by

Suggested fix:
We should be able to make the check in group_attribute_not_prefix_in_index a little smarter, similar to what we do in in test_if_order_by_key when we examine const_key_parts.
[11 Jun 2022 16:02] MySQL Verification Team
Hello Manuel Ung,

Thank you for the report and feedback.

regards,
Umesh
[3 Aug 2023 19:35] Manuel Ung
The more complete fix to this, is to reuse the functional dependency tracking code to determine whether a column is already implicitly grouped or not. 

The main thing it buys us, are functional dependencies derived from unique keys.