Partitioning by key is similar to partitioning by hash, except
that where hash partitioning employs a user-defined expression,
the hashing function for key partitioning is supplied by the
MySQL server. MySQL Cluster uses
MD5()
for this purpose; for
tables using other storage engines, the server employs its own
internal hashing function which is based on the same algorithm
as PASSWORD()
.
The syntax rules for CREATE TABLE ... PARTITION BY
KEY
are similar to those for creating a table that is
partitioned by hash. The major differences are that:
KEY
is used rather than
HASH
.
KEY
takes only a list of one or more
column names. The column or columns used as the partitioning
key must comprise part or all of the table's primary key, if
the table has one.
KEY
takes a list of zero or more column
names. Where no column name is specified as the partitioning
key, the table's primary key is used, if there is one. For
example, the following CREATE
TABLE
statement is valid in MySQL
5.4:
CREATE TABLE k1 ( id INT NOT NULL PRIMARY KEY, name VARCHAR(20) ) PARTITION BY KEY() PARTITIONS 2;
If there is no primary key but there is a unique key, then the unique key is used for the partitioning key:
CREATE TABLE k1 ( id INT NOT NULL, name VARCHAR(20), UNIQUE KEY (id) ) PARTITION BY KEY() PARTITIONS 2;
However, if the unique key column were not defined as
NOT NULL
, then the previous statement
would fail.
In both of these cases, the partitioning key is the
id
column, even though it is not shown in
the output of SHOW CREATE
TABLE
or in the
PARTITION_EXPRESSION
column of the
INFORMATION_SCHEMA.PARTITIONS
table.
Unlike the case with other partitioning types, columns used
for partitioning by KEY
are not
restricted to integer or NULL
values. For
example, the following CREATE
TABLE
statement is valid:
CREATE TABLE tm1 ( s1 CHAR(32) PRIMARY KEY ) PARTITION BY KEY(s1) PARTITIONS 10;
The preceding statement would not be valid, were a different partitioning type to be specified.
In this case, simply using PARTITION BY
KEY()
would also be valid and have the same
effect as PARTITION BY KEY(s1)
, since
s1
is the table's primary key.
For additional information about this issue, see Section 17.5, “Restrictions and Limitations on Partitioning”.
Tables using the NDBCLUSTER
storage engine are implicitly partitioned by
KEY
, again using the table's
primary key as the partitioning key. In the event that the
Cluster table has no explicit primary key, the
“hidden” primary key generated by the
NDBCLUSTER
storage engine for
each MySQL Cluster table is used as the partitioning key.
For a key-partitioned table using any MySQL storage engine
other than NDBCLUSTER
, you
cannot execute an ALTER TABLE DROP PRIMARY
KEY
, as doing so generates the error
ERROR 1466 (HY000): Field in list of fields for
partition function not found in table. This is
not an issue for MySQL Cluster tables which are
partitioned by KEY
; in such cases, the
table is reorganized using the “hidden”
primary key as the table's new partitioning key. See
MySQL Cluster NDB 6.X/7.X.
It is also possible to partition a table by linear key. Here is a simple example:
CREATE TABLE tk ( col1 INT NOT NULL, col2 CHAR(5), col3 DATE ) PARTITION BY LINEAR KEY (col1) PARTITIONS 3;
Using LINEAR
has the same effect on
KEY
partitioning as it does on
HASH
partitioning, with the partition number
being derived using a powers-of-two algorithm rather than modulo
arithmetic. See Section 17.2.3.1, “LINEAR HASH
Partitioning”, for
a description of this algorithm and its implications.
User Comments
Add your own comment.