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. NDB Cluster uses
MD5()
for this purpose; for
tables using other storage engines, the server employs its own
internal hashing function.
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 listed here:
KEY
is used rather thanHASH
.KEY
takes only a list of zero or more column names. Any columns used as the partitioning key must comprise part or all of the table's primary key, if the table has one. Where no column name is specified as the partitioning key, the table's primary key is used, if there is one. For example, the followingCREATE TABLE
statement is valid in MySQL 8.0: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 ofSHOW CREATE TABLE
or in thePARTITION_EXPRESSION
column of the Information SchemaPARTITIONS
table.Unlike the case with other partitioning types, columns used for partitioning by
KEY
are not restricted to integer orNULL
values. For example, the followingCREATE 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 asPARTITION BY KEY(s1)
, sinces1
is the table's primary key.)For additional information about this issue, see Chapter 6, Restrictions and Limitations on Partitioning.
Columns with index prefixes are not supported in partitioning keys. This means that
CHAR
,VARCHAR
,BINARY
, andVARBINARY
columns can be used in a partitioning key, as long as they do not employ prefixes; because a prefix must be specified forBLOB
andTEXT
columns in index definitions, it is not possible to use columns of these two types in partitioning keys. Prior to MySQL 8.0.21, columns using prefixes were permitted when creating, altering, or upgrading a partitioned table, even though they were not included in the table's partitioning key; in MySQL 8.0.21 and later, this permissive behavior is deprecated, and the server displays appropriate warnings or errors when one or more such columns are used. See Column index prefixes not supported for key partitioning, for more information and examples.NoteTables using the
NDB
storage engine are implicitly partitioned byKEY
, using the table's primary key as the partitioning key (as with other MySQL storage engines). In the event that the NDB Cluster table has no explicit primary key, the “hidden” primary key generated by theNDB
storage engine for each NDB Cluster table is used as the partitioning key.If you define an explicit partitioning scheme for an
NDB
table, the table must have an explicit primary key, and any columns used in the partitioning expression must be part of this key. However, if the table uses an “empty” partitioning expression—that is,PARTITION BY KEY()
with no column references—then no explicit primary key is required.You can observe this partitioning using the ndb_desc utility (with the
-p
option).ImportantFor a key-partitioned table, 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 NDB Cluster tables which are partitioned byKEY
; in such cases, the table is reorganized using the “hidden” primary key as the table's new partitioning key. See MySQL NDB Cluster 8.0.
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;
The LINEAR
keyword 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 3.4.1, “LINEAR HASH Partitioning”, for
a description of this algorithm and its implications.