MySQL 5.7 Reference Manual Including MySQL NDB Cluster 7.5 and NDB Cluster 7.6
Understanding the B-tree and hash data structures can help
predict how different queries perform on different storage
engines that use these data structures in their indexes,
particularly for the MEMORY storage engine
that lets you choose B-tree or hash indexes.
A B-tree index can be used for column comparisons in
expressions that use the
=,
>,
>=,
<,
<=,
or BETWEEN operators. The index
also can be used for LIKE
comparisons if the argument to
LIKE is a constant string that
does not start with a wildcard character. For example, the
following SELECT statements use
indexes:
SELECT * FROMtbl_nameWHEREkey_colLIKE 'Patrick%'; SELECT * FROMtbl_nameWHEREkey_colLIKE 'Pat%_ck%';
In the first statement, only rows with 'Patrick'
<= are considered. In the second statement,
only rows with key_col <
'Patricl''Pat' <=
are
considered.
key_col < 'Pau'
The following SELECT statements
do not use indexes:
SELECT * FROMtbl_nameWHEREkey_colLIKE '%Patrick%'; SELECT * FROMtbl_nameWHEREkey_colLIKEother_col;
In the first statement, the LIKE
value begins with a wildcard character. In the second
statement, the LIKE value is not
a constant.
If you use ... LIKE
'% and
string%'string is longer than three
characters, MySQL uses the Turbo
Boyer-Moore algorithm to initialize the pattern for
the string and then uses this pattern to perform the search
more quickly.
A search using employs indexes if
col_name IS
NULLcol_name is indexed.
Any index that does not span all
AND levels in the
WHERE clause is not used to optimize the
query. In other words, to be able to use an index, a prefix of
the index must be used in every
AND group.
The following WHERE clauses use indexes:
... WHEREindex_part1=1 ANDindex_part2=2 ANDother_column=3 /*index= 1 ORindex= 2 */ ... WHEREindex=1 OR A=10 ANDindex=2 /* optimized like "index_part1='hello'" */ ... WHEREindex_part1='hello' ANDindex_part3=5 /* Can use index onindex1but not onindex2orindex3*/ ... WHEREindex1=1 ANDindex2=2 ORindex1=3 ANDindex3=3;
These WHERE clauses do
not use indexes:
/*index_part1is not used */ ... WHEREindex_part2=1 ANDindex_part3=2 /* Index is not used in both parts of the WHERE clause */ ... WHEREindex=1 OR A=10 /* No index spans all rows */ ... WHEREindex_part1=1 ORindex_part2=10
Sometimes MySQL does not use an index, even if one is
available. One circumstance under which this occurs is when
the optimizer estimates that using the index would require
MySQL to access a very large percentage of the rows in the
table. (In this case, a table scan is likely to be much faster
because it requires fewer seeks.) However, if such a query
uses LIMIT to retrieve only some of the
rows, MySQL uses an index anyway, because it can much more
quickly find the few rows to return in the result.
Hash indexes have somewhat different characteristics from those just discussed:
They are used only for equality comparisons that use the
= or <=>
operators (but are very fast). They
are not used for comparison operators such as
< that find a range of values.
Systems that rely on this type of single-value lookup are
known as “key-value stores”; to use MySQL for
such applications, use hash indexes wherever possible.
The optimizer cannot use a hash index to speed up
ORDER BY operations. (This type of
index cannot be used to search for the next entry in
order.)
MySQL cannot determine approximately how many rows there
are between two values (this is used by the range
optimizer to decide which index to use). This may affect
some queries if you change a MyISAM or
InnoDB table to a hash-indexed
MEMORY table.
Only whole keys can be used to search for a row. (With a B-tree index, any leftmost prefix of the key can be used to find rows.)