This section discusses the relationship of partitioning keys with primary keys and unique keys. The rule governing this relationship can be expressed as follows: All columns used in the partitioning expression for a partitioned table must be part of every unique key that the table may have.
In other words, every unique key on the table must use every column in the table's partitioning expression. (This also includes the table's primary key, since it is by definition a unique key. This particular case is discussed later in this section.) For example, each of the following table creation statements is invalid:
CREATE TABLE t1 (
    col1 INT NOT NULL,
    col2 DATE NOT NULL,
    col3 INT NOT NULL,
    col4 INT NOT NULL,
    UNIQUE KEY (col1, col2)
)
PARTITION BY HASH(col3)
PARTITIONS 4;
CREATE TABLE t2 (
    col1 INT NOT NULL,
    col2 DATE NOT NULL,
    col3 INT NOT NULL,
    col4 INT NOT NULL,
    UNIQUE KEY (col1),
    UNIQUE KEY (col3)
)
PARTITION BY HASH(col1 + col3)
PARTITIONS 4;
In each case, the proposed table would have at least one unique key that does not include all columns used in the partitioning expression.
Each of the following statements is valid, and represents one way in which the corresponding invalid table creation statement could be made to work:
CREATE TABLE t1 (
    col1 INT NOT NULL,
    col2 DATE NOT NULL,
    col3 INT NOT NULL,
    col4 INT NOT NULL,
    UNIQUE KEY (col1, col2, col3)
)
PARTITION BY HASH(col3)
PARTITIONS 4;
CREATE TABLE t2 (
    col1 INT NOT NULL,
    col2 DATE NOT NULL,
    col3 INT NOT NULL,
    col4 INT NOT NULL,
    UNIQUE KEY (col1, col3)
)
PARTITION BY HASH(col1 + col3)
PARTITIONS 4;
This example shows the error produced in such cases:
mysql>CREATE TABLE t3 (->col1 INT NOT NULL,->col2 DATE NOT NULL,->col3 INT NOT NULL,->col4 INT NOT NULL,->UNIQUE KEY (col1, col2),->UNIQUE KEY (col3)->)->PARTITION BY HASH(col1 + col3)->PARTITIONS 4;ERROR 1491 (HY000): A PRIMARY KEY must include all columns in the table's partitioning function
        The CREATE statement fails because both
        col1 and col3 are included
        in the proposed partitioning key, but neither of these columns
        is part of both of unique keys on the table. This shows one
        possible fix for the invalid table definition;
mysql> CREATE TABLE t3 (
    ->     col1 INT NOT NULL,
    ->     col2 DATE NOT NULL,
    ->     col3 INT NOT NULL,
    ->     col4 INT NOT NULL,
    ->     UNIQUE KEY (col1, col2, col3),
    ->     UNIQUE KEY (col3)
    -> )
    -> PARTITION BY HASH(col3)
    -> PARTITIONS 4;
Query OK, 0 rows affected (0.05 sec)
        In this case, the proposed partitioning key
        col3 is part of both unique keys, and the
        table creation statement succeeds.
      
Since every primary key is by definition a unique key, this restriction also includes the table's primary key, if it has one. For example, the next two statements are invalid:
CREATE TABLE t4 (
    col1 INT NOT NULL,
    col2 DATE NOT NULL,
    col3 INT NOT NULL,
    col4 INT NOT NULL,
    PRIMARY KEY(col1, col2)
)
PARTITION BY HASH(col3)
PARTITIONS 4;
CREATE TABLE t5 (
    col1 INT NOT NULL,
    col2 DATE NOT NULL,
    col3 INT NOT NULL,
    col4 INT NOT NULL,
    PRIMARY KEY(col1, col3),
    UNIQUE KEY(col2)
)
PARTITION BY HASH( YEAR(col2) )
PARTITIONS 4;
In both cases, the primary key does not include all columns referenced in the partitioning expression. However, both of the next two statements are valid:
CREATE TABLE t6 (
    col1 INT NOT NULL,
    col2 DATE NOT NULL,
    col3 INT NOT NULL,
    col4 INT NOT NULL,
    PRIMARY KEY(col1, col2)
)
PARTITION BY HASH(col1 + YEAR(col2))
PARTITIONS 4;
CREATE TABLE t7 (
    col1 INT NOT NULL,
    col2 DATE NOT NULL,
    col3 INT NOT NULL,
    col4 INT NOT NULL,
    PRIMARY KEY(col1, col2, col4),
    UNIQUE KEY(col2, col1)
)
PARTITION BY HASH(col1 + YEAR(col2))
PARTITIONS 4;
If a table has no unique keys — this includes having no primary key — then this restriction does not apply, and you may use any column or columns in the partitioning expression as long as the column type is compatible with the partitioning type.
For the same reason, you cannot later add a unique key to a partitioned table unless the key includes all columns used by the table's partitioning expression. Consider given the partitioned table defined as shown here:
mysql>CREATE TABLE t_no_pk (c1 INT, c2 INT)->PARTITION BY RANGE(c1) (->PARTITION p0 VALUES LESS THAN (10),->PARTITION p1 VALUES LESS THAN (20),->PARTITION p2 VALUES LESS THAN (30),->PARTITION p3 VALUES LESS THAN (40)->);Query OK, 0 rows affected (0.12 sec)
        It is possible to add a primary key to
        t_no_pk using either of these
        ALTER TABLE statements:
      
# possible PK mysql>ALTER TABLE t_no_pk ADD PRIMARY KEY(c1);Query OK, 0 rows affected (0.13 sec) Records: 0 Duplicates: 0 Warnings: 0 # drop this PK mysql>ALTER TABLE t_no_pk DROP PRIMARY KEY;Query OK, 0 rows affected (0.10 sec) Records: 0 Duplicates: 0 Warnings: 0 # use another possible PK mysql>ALTER TABLE t_no_pk ADD PRIMARY KEY(c1, c2);Query OK, 0 rows affected (0.12 sec) Records: 0 Duplicates: 0 Warnings: 0 # drop this PK mysql>ALTER TABLE t_no_pk DROP PRIMARY KEY;Query OK, 0 rows affected (0.09 sec) Records: 0 Duplicates: 0 Warnings: 0
        However, the next statement fails, because c1
        is part of the partitioning key, but is not part of the proposed
        primary key:
      
#  fails with error 1503
mysql> ALTER TABLE t_no_pk ADD PRIMARY KEY(c2);
ERROR 1503 (HY000): A PRIMARY KEY must include all columns in the table's partitioning function
        Since t_no_pk has only c1
        in its partitioning expression, attempting to adding a unique
        key on c2 alone fails. However, you can add a
        unique key that uses both c1 and
        c2.
      
        These rules also apply to existing nonpartitioned tables that
        you wish to partition using ALTER TABLE ... PARTITION
        BY. Consider a table np_pk defined
        as shown here:
      
mysql>CREATE TABLE np_pk (->id INT NOT NULL AUTO_INCREMENT,->name VARCHAR(50),->added DATE,->PRIMARY KEY (id)->);Query OK, 0 rows affected (0.08 sec)
        The following ALTER TABLE
        statements fails with an error, because the
        added column is not part of any unique key in
        the table:
      
mysql>ALTER TABLE np_pk->PARTITION BY HASH( TO_DAYS(added) )->PARTITIONS 4;ERROR 1503 (HY000): A PRIMARY KEY must include all columns in the table's partitioning function
        However, this statement using the id column
        for the partitioning column is valid, as shown here:
      
mysql>ALTER TABLE np_pk->PARTITION BY HASH(id)->PARTITIONS 4;Query OK, 0 rows affected (0.11 sec) Records: 0 Duplicates: 0 Warnings: 0
        In the case of np_pk, the only column that
        may be used as part of a partitioning expression is
        id; if you wish to partition this table using
        any other column or columns in the partitioning expression, you
        must first modify the table, either by adding the desired column
        or columns to the primary key, or by dropping the primary key
        altogether.
      
We are working to remove this limitation in a future MySQL release series.


User Comments
If you have a table with an auto_increment column and you want to partition on a date column in that table, make sure you put both of those columns in your primary key like this:
CREATE TABLE stuff (id INT AUTO_INCREMENT, d DATE, PRIMARY KEY (id, d))
PARTITION BY RANGE(to_days(d)) (PARTITION p0 VALUES LESS THAN (733332), PARTITION p1 VALUES LESS THAN MAXVALUE);
This may seem to be stating the obvious and repeating what's written above, but I used to (incorrectly) believe that you had to create a primary key on just your auto_increment column, which would have made it impossible to partition on the date column as shown above.
5.1.22-rc
Add your own comment.