MDEV-38426: Clustered PK not used for Loose Index Scan optimization

Loose Index Scan optimization can only be used when the index it is
uses covers all columns used by the query. So, it would not be
attempted for indexes that are not present in table->covering_keys.

Before commit ed0a723566 (pushed to 11.0), Clustered PK would be
present in table->covering_keys if primary key columns are covering.

However, that commit gave Clustered PKs special treatment: they are
no longer present in table->covering_keys. This caused Loose Scan not
to be considered for Clustered PKs.

Fixed this by making the check in get_best_group_min_max() to allow
Loose Scan if all fields used by the query are parts of the Clustered PK.

Also made changes:
- The logic in JOIN_TAB::save_explain_data() assumed that Loose Scan
  could only be used for index-only scans. This is not the case for
  clustered PKs.
- One query in group_min_max_innodb started to use Loose Scan. It did so
  in 10.11, too.
This commit is contained in:
Sergei Petrunia 2025-12-27 15:43:39 +02:00
parent 4cff562f3f
commit 50ee5d1b3f
4 changed files with 121 additions and 11 deletions

View File

@ -180,7 +180,7 @@ F 17
EXPLAIN SELECT c1, max(i2) FROM t1 WHERE (c1 = 'C' OR c1 = 'F' ) AND ( i2 = 17 )
GROUP BY c1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range k1 k1 5 NULL 2 Using where
1 SIMPLE t1 range k1 k1 5 NULL 2 Using where; Using index for group-by
SELECT c1, max(i2) FROM t1 WHERE (c1 = 'C' OR c1 = 'F' ) AND ( i2 = 17 )
GROUP BY c1;
c1 max(i2)
@ -438,6 +438,43 @@ disconnect con1;
connection default;
DROP TABLE t1;
SET GLOBAL innodb_lru_scan_depth= @lru_depth.save;
#
# MDEV-38426: Clustered PK not used for Loose Index Scan optimization
#
create table t1 (
col1 int not null,
col2 int not null,
col3 int,
primary key(col1, col2)
) engine=innodb;
insert into t1 select
A.seq,
B.seq,
A.seq
from
seq_1_to_10 A,
seq_1_to_1000 B;
analyze table t1;
Table Op Msg_type Msg_text
test.t1 analyze status Engine-independent statistics collected
test.t1 analyze status OK
# This must use Loose Scan:
explain select distinct col1 from t1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range NULL PRIMARY 4 NULL 11 Using index for group-by
# This must use Loose Scan:
explain select col1 from t1 group by col1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range NULL PRIMARY 4 NULL 11 Using index for group-by
# This must use Loose Scan:
explain select col1, min(col2) from t1 group by col1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 range NULL PRIMARY 4 NULL 11 Using index for group-by
# This will not use Loose Index Scan as col3 is not in PK:
explain select col1, min(col2), col3 from t1 group by col1;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 index NULL PRIMARY 8 NULL 10000
drop table t1;
set global innodb_stats_persistent= @innodb_stats_persistent_save;
set global innodb_stats_persistent_sample_pages=
@innodb_stats_persistent_sample_pages_save;

View File

@ -323,6 +323,40 @@ while ($run)
DROP TABLE t1;
SET GLOBAL innodb_lru_scan_depth= @lru_depth.save;
--echo #
--echo # MDEV-38426: Clustered PK not used for Loose Index Scan optimization
--echo #
--source include/have_sequence.inc
create table t1 (
col1 int not null,
col2 int not null,
col3 int,
primary key(col1, col2)
) engine=innodb;
insert into t1 select
A.seq,
B.seq,
A.seq
from
seq_1_to_10 A,
seq_1_to_1000 B;
analyze table t1;
--echo # This must use Loose Scan:
explain select distinct col1 from t1;
--echo # This must use Loose Scan:
explain select col1 from t1 group by col1;
--echo # This must use Loose Scan:
explain select col1, min(col2) from t1 group by col1;
--echo # This will not use Loose Index Scan as col3 is not in PK:
explain select col1, min(col2), col3 from t1 group by col1;
drop table t1;
set global innodb_stats_persistent= @innodb_stats_persistent_save;
set global innodb_stats_persistent_sample_pages=
@innodb_stats_persistent_sample_pages_save;

View File

@ -14091,6 +14091,39 @@ cost_group_min_max(TABLE* table, KEY *index_info, uint used_key_parts,
double *read_cost, ha_rows *records);
/*
@brief
Check if index keynr is clustering and the query only uses its
explicitly defined parts.
@detail
Clustering PK indexes are not present in table->covering_keys (one
can say a clustering index is always covering as it has all table's
fields in it).
This function checks if the set of columns in the index definition
PRIMARY KEY(col1, ... colN) is covering for the quey.
*/
static bool index_is_clustering_covering(const TABLE *table, uint keynr)
{
if (!table->file->is_clustering_key(keynr))
return false;
/*
Check that all fields used by the query are explicitly present
in the index.
*/
for (uint i= bitmap_get_first_set(table->read_set);
i != MY_BIT_NONE;
i= bitmap_get_next_set(table->read_set, i))
{
if (!table->field[i]->part_of_key.is_set(keynr))
return false;
}
return true;
}
/**
Test if this access method is applicable to a GROUP query with MIN/MAX
functions, and if so, construct a new TRP object.
@ -14446,7 +14479,8 @@ get_best_group_min_max(PARAM *param, SEL_TREE *tree, double read_time)
(was also: "Exclude UNIQUE indexes ..." but this was removed because
there are cases Loose Scan over a multi-part index is useful).
*/
if (!table->covering_keys.is_set(cur_index) ||
if ((!table->covering_keys.is_set(cur_index) &&
!index_is_clustering_covering(table, cur_index)) ||
!table->keys_in_use_for_group_by.is_set(cur_index))
{
cause= "not covering";

View File

@ -31083,16 +31083,21 @@ bool JOIN_TAB::save_explain_data(Explain_table_access *eta,
else
eta->push_extra(ET_SCANNED_ALL_DATABASES);
}
if (key_read)
if (quick_type == QUICK_SELECT_I::QS_TYPE_GROUP_MIN_MAX)
{
if (quick_type == QUICK_SELECT_I::QS_TYPE_GROUP_MIN_MAX)
{
QUICK_GROUP_MIN_MAX_SELECT *qgs=
(QUICK_GROUP_MIN_MAX_SELECT *) tab_select->quick;
eta->push_extra(ET_USING_INDEX_FOR_GROUP_BY);
eta->loose_scan_is_scanning= qgs->loose_scan_is_scanning();
}
else
QUICK_GROUP_MIN_MAX_SELECT *qgs=
(QUICK_GROUP_MIN_MAX_SELECT *) tab_select->quick;
eta->push_extra(ET_USING_INDEX_FOR_GROUP_BY);
eta->loose_scan_is_scanning= qgs->loose_scan_is_scanning();
}
else
{
/*
Print "Using index" if we haven't already printed "Using index for
group by".
*/
if (key_read)
eta->push_extra(ET_USING_INDEX);
}
if (table->reginfo.not_exists_optimize)