CACHE INDEXtbl_index_list
[,tbl_index_list
] ... [PARTITION (partition_list
| ALL)] INkey_cache_name
tbl_index_list
:tbl_name
[[INDEX|KEY] (index_name
[,index_name
] ...)]partition_list
:partition_name
[,partition_name
][, ...]
The CACHE INDEX
statement assigns
table indexes to a specific key cache. It is used only for
MyISAM
tables.
The following statement assigns indexes from the tables
t1
, t2
, and
t3
to the key cache named
hot_cache
:
mysql> CACHE INDEX t1, t2, t3 IN hot_cache;
+---------+--------------------+----------+----------+
| Table | Op | Msg_type | Msg_text |
+---------+--------------------+----------+----------+
| test.t1 | assign_to_keycache | status | OK |
| test.t2 | assign_to_keycache | status | OK |
| test.t3 | assign_to_keycache | status | OK |
+---------+--------------------+----------+----------+
The syntax of CACHE INDEX
enables
you to specify that only particular indexes from a table should
be assigned to the cache. The current implementation assigns all
the table's indexes to the cache, so there is no reason to
specify anything other than the table name.
The key cache referred to in a CACHE
INDEX
statement can be created by setting its size
with a parameter setting statement or in the server parameter
settings. For example:
mysql> SET GLOBAL keycache1.key_buffer_size=128*1024;
Key cache parameters can be accessed as members of a structured system variable. See Section 5.1.6.1, “Structured System Variables”.
A key cache must exist before you can assign indexes to it:
mysql> CACHE INDEX t1 IN non_existent_cache;
ERROR 1284 (HY000): Unknown key cache 'non_existent_cache'
By default, table indexes are assigned to the main (default) key cache created at the server startup. When a key cache is destroyed, all indexes assigned to it become assigned to the default key cache again.
Index assignment affects the server globally: If one client assigns an index to a given cache, this cache is used for all queries involving the index, no matter which client issues the queries.
Beginning with MySQL 5.5.0, this statement is also supported for
partitioned MyISAM
tables. You can assign one
or more indexes for one, several, or all partitions to a given
key cache. For example, you can do the following:
CREATE TABLE pt (c1 INT, c2 VARCHAR(50), INDEX i(c1)) PARTITION BY HASH(c1) PARTITIONS 4; SET GLOBAL kc_fast.key_buffer_size = 128 * 1024; SET GLOBAL kc_slow.key_buffer_size = 128 * 1024; CACHE INDEX pt PARTITION (p0) IN kc_fast; CACHE INDEX pt PARTITION (p1, p3) IN kc_slow;
The previous set of statements performs the following actions:
Creates a partitioned table with 4 partitions; these
partitions are automatically named p0
,
..., p3
; this table has an index named
i
on column c1
.
Creates 2 key caches named kc_fast
and
kc_slow
Assigns the index for partition p0
to the
kc_fast
key cache and the index for
partitions p1
and p3
to the kc_slow
key cache; the index for
the remaining partition (p2
) uses the
server's default key cache.
If you wish instead to assign the indexes for all partitions in
table pt
to a single key cache named
kc_all
, you can use either one of the
following 2 statements:
CACHE INDEX pt PARTITION (ALL) IN kc_all; CACHE INDEX pt IN kc_all;
The two statements just shown are equivalent, and issuing either
one of them has exactly the same effect. In other words, if you
wish to assign indexes for all partitions of a partitioned table
to the same key cache, then the PARTITION
(ALL)
clause is optional.
When assigning indexes for multiple partitions to a key cache, the partitions do not have to be contiguous, and you are not required to list their names in any particular order. Indexes for any partitions that are not explicitly assigned to a key cache automatically use the server's default key cache.
Preloading of indexes is also supported for partitioned
MyISAM
tables in MySQL 5.5.0 and later. See
Section 12.4.6.5, “LOAD INDEX INTO
CACHE
Syntax”, for more information.
User Comments
Add your own comment.