MySQL 8.4 Reference Manual Including MySQL NDB Cluster 8.4
The adaptive hash index enables InnoDB
to
perform more like an in-memory database on systems with
appropriate combinations of workload and sufficient memory for the
buffer pool without sacrificing transactional features or
reliability. The adaptive hash index is disabled by the
innodb_adaptive_hash_index
variable, or turned on at server startup by
--innodb-adaptive-hash-index
.
Based on the observed pattern of searches, a hash index is built using a prefix of the index key. The prefix can be any length, and it may be that only some values in the B-tree appear in the hash index. Hash indexes are built on demand for the pages of the index that are accessed often.
If a table fits almost entirely in main memory, a hash index
speeds up queries by enabling direct lookup of any element,
turning the index value into a sort of pointer.
InnoDB
has a mechanism that monitors index
searches. If InnoDB
notices that queries could
benefit from building a hash index, it does so automatically.
With some workloads, the speedup from hash index lookups greatly
outweighs the extra work to monitor index lookups and maintain the
hash index structure. Access to the adaptive hash index can
sometimes become a source of contention under heavy workloads,
such as multiple concurrent joins. Queries with
LIKE
operators and %
wildcards also tend not to benefit. For workloads that do not
benefit from the adaptive hash index, turning it off reduces
unnecessary performance overhead. Because it is difficult to
predict in advance whether the adaptive hash index is appropriate
for a particular system and workload, consider running benchmarks
with it enabled and disabled.
The adaptive hash index feature is partitioned. Each index is
bound to a specific partition, and each partition is protected by
a separate latch. Partitioning is controlled by the
innodb_adaptive_hash_index_parts
variable. The
innodb_adaptive_hash_index_parts
variable is set to 8 by default. The maximum setting is 512.
You can monitor adaptive hash index use and contention in the
SEMAPHORES
section of
SHOW ENGINE INNODB
STATUS
output. If there are numerous threads waiting on
rw-latches created in btr0sea.c
, consider
increasing the number of adaptive hash index partitions or
disabling the adaptive hash index.
For information about the performance characteristics of hash indexes, see Section 10.3.9, “Comparison of B-Tree and Hash Indexes”.