MacLochlainns Weblog

Michael McLaughlin's Technical Blog

Site Admin

MySQL’s List Partition Key

with 6 comments

While reviewing some material and explaining list partitioning in MySQL, I heard a rumor that sounded false. The rumor was that you can’t partition on anything other than the primary key column. That’s untrue, you can partition on another column provided it’s an integer column.

It appears the culprit that led to the rumor is a misunderstanding around ERROR 1503, which returns the following:

ERROR 1503 (HY000): A PRIMARY KEY must include ALL COLUMNS IN the TABLE's partitioning function

The problem can be recreated by defining a table with an inline primary key constraint instead of an INDEX on the auto incrementing column. Here’s an example of how to create the error message:

1
2
3
4
5
6
7
8
9
10
11
CREATE TABLE franchise
( franchise_id     INT UNSIGNED PRIMARY KEY AUTO_INCREMENT
, franchise_number INT UNSIGNED
, franchise_name   VARCHAR(20)
, city             VARCHAR(20)
, state            VARCHAR(20))
PARTITION BY LIST(franchise_number)
( PARTITION offshore VALUES IN (49,50)
, PARTITION west VALUES IN (34,45,48)
, PARTITION desert VALUES IN (46,47)
, PARTITION rockies VALUES IN (38,41,42,44));

The table should be defined without the inline PRIMARY KEY constraint on the auto incrementing column when you want to partition on another column. An index on the auto incrementing column doesn’t conflict with primary key rules. The correct syntax for a list partition would be:

1
2
3
4
5
6
7
8
9
10
11
12
CREATE TABLE franchise
( franchise_id     INT UNSIGNED AUTO_INCREMENT
, franchise_number INT UNSIGNED
, franchise_name   VARCHAR(20)
, city             VARCHAR(20)
, state            VARCHAR(20)
, INDEX idx (franchise_id)) engine=innodb
PARTITION BY LIST(franchise_number)
( PARTITION offshore VALUES IN (49,50)
, PARTITION west VALUES IN (34,45,48)
, PARTITION desert VALUES IN (46,47)
, PARTITION rockies VALUES IN (38,41,42,44));

The same problem can manifest itself on range partitioning. The fix is the same and here’s a code example:

1
2
3
4
5
6
7
8
9
10
CREATE TABLE ordering
( ordering_id      INT UNSIGNED AUTO_INCREMENT
, item_id          INT UNSIGNED
, rental_amount    DECIMAL(15,2)
, rental_date      DATE
, INDEX idx (ordering_id))
PARTITION BY RANGE(item_id)
( PARTITION jan2011 VALUES LESS THAN (10000)
, PARTITION feb2011 VALUES LESS THAN (20000)
, PARTITION mar2011 VALUES LESS THAN (30000));

The MySQL 5.6 Partitioning Keys, Primary Keys, and Unique Keys article is the key reference. It’s unfortunate that MySQL can’t partition on something other than an integer with PARTITION BY LIST syntax (check the changes in MySQL 5.6 online documentation). As you’ll notice in my more recent comment back to Tim, you can when you change the SQL phrase to PARTITION BY LIST COLUMNS. MySQL now has another feature that the Oracle Database 11g supports, that is list partitioning on variable-length string columns.

There are a few required changes but here’s a working example. The index must work against the auto incrementing column. The example comes my reply to Tim, who raised a great question.

CREATE TABLE franchise
( franchise_id     INT UNSIGNED AUTO_INCREMENT
, franchise_number INT UNSIGNED
, franchise_name   VARCHAR(20)
, city             VARCHAR(20)
, state            VARCHAR(20)
, KEY idx (franchise_id)) engine=innodb
PARTITION BY LIST COLUMNS (franchise_name)
( PARTITION m VALUES IN ('McDonald','Maggiano')
, PARTITION p VALUES IN ('Pappa John','Pizza Hut')
, PARTITION t VALUES IN ('Taco Bell','Taco Time'));

While that works, the better approach creates two unique constraints. One unique constraint on the natural key of the franchise_number and franchise_name, which serves to optimize access to data sets looking data up in the table based on a natural key search. Another unique constraint on the surrogate (auto incrementing column) and the two natural key columns, which optimizes joins from foreign keys to the partitioned table’s primary key.

CREATE TABLE franchise
( franchise_id     INT UNSIGNED AUTO_INCREMENT
, franchise_number INT UNSIGNED
, franchise_name   VARCHAR(20)
, city             VARCHAR(20)
, state            VARCHAR(20)
, UNIQUE ink (franchise_number, franchise_name)
, UNIQUE enk (franchise_id, franchise_number, franchise_name)) engine=innodb
PARTITION BY LIST COLUMNS (franchise_name)
( PARTITION m VALUES IN ('McDonald','Maggiano')
, PARTITION p VALUES IN ('Pappa John','Pizza Hut')
, PARTITION t VALUES IN ('Taco Bell','Taco Time'));

Somebody asked for a composite partitioning (MySQL terminology is subpartitioning) example, so here it is:

1
2
3
4
5
6
7
8
9
10
11
12
CREATE TABLE ordering
( ordering_id      INT UNSIGNED AUTO_INCREMENT
, item_id          INT UNSIGNED
, store_id         INT UNSIGNED
, rental_amount    DECIMAL(15,2)
, rental_date      DATE
, INDEX idx (ordering_id))
PARTITION BY RANGE(item_id)
  SUBPARTITION BY HASH(store_id) SUBPARTITIONS 4
( PARTITION jan2011 VALUES LESS THAN (10000)
, PARTITION feb2011 VALUES LESS THAN (20000)
, PARTITION mar2011 VALUES LESS THAN (30000));

Hope this helps those researching ERROR 1503 on list or range partitioning.

Written by maclochlainn

May 9th, 2011 at 8:27 pm

6 Responses to 'MySQL’s List Partition Key'

Subscribe to comments with RSS or TrackBack to 'MySQL’s List Partition Key'.

  1. thanks a lot. it helped

    Mansab Khan

    13 Mar 12 at 5:47 am

  2. Its a good article. But the appaorach has an issue when you have to reference the primary key column in another table. i.e. you want to create a foreign key on another table which references the column from first table which you want to partition.

    Let me know if there is any work around for this.

    Arun

    18 Jul 12 at 5:43 am

  3. Great Hint! Used it but did have one observation.

    You CAN now in 5.6 use Partition on list columns(xxx) where xxx is varchar (etc.). However when I tried to altering an existing table to rearrange existing primary key that was auto-increment I found the following:

    1) First I have to define another index on the id (primary key field)
    2) THen dropped the primary key index
    3) Then I could add my partitions

    One important note: I first tried to make the new “secondary” index on my original auto-increment key defined as UNIQUE. When I did this I could drop the original PK index, but I COULD NOT partition. I had to make the secondary index INDEX as shown above. Making it UNIQUE still gets the Error 1503 when defining the partitions.

    Tim Chambers

    30 Jul 12 at 7:57 am

  4. Tim,

    I was curious how you made the partitioning key a VARCHAR data type. The current MySQL 5.6.5-m8 raises the same problem encountered in the prior release with a PARTITION BY LIST phrase. When I checked the MySQL Reference for List Partitions it appeared to still require an INT as the partitioning key.

    This was my preliminary test case to check out using a VARCHAR data type as the list partitioning key:

    CREATE TABLE franchise
    ( franchise_id     INT UNSIGNED AUTO_INCREMENT
    , franchise_number INT UNSIGNED
    , franchise_name   VARCHAR(20)
    , city             VARCHAR(20)
    , state            VARCHAR(20)
    , INDEX idx (franchise_id)) engine=innodb
    PARTITION BY LIST(franchise_name)
    ( PARTITION m VALUES IN ('McDonald','Maggiano')
    , PARTITION p VALUES IN ('Pappa John','Pizza Hut')
    , PARTITION t VALUES IN ('Taco Bell','Taco Time'));

    It raises the following error:

    ERROR 1697 (HY000): VALUES VALUE FOR partition 'm' must have TYPE INT

    Looking more closely at the documentation, MySQL 5.6 adds a new PARTITION BY LIST COLUMNS phrase. That enables a list partition based on a VARCHAR column:

    CREATE TABLE franchise
    ( franchise_id     INT UNSIGNED AUTO_INCREMENT
    , franchise_number INT UNSIGNED
    , franchise_name   VARCHAR(20)
    , city             VARCHAR(20)
    , state            VARCHAR(20)
    , KEY idx (franchise_id)) engine=innodb
    PARTITION BY LIST COLUMNS (franchise_name)
    ( PARTITION m VALUES IN ('McDonald','Maggiano')
    , PARTITION p VALUES IN ('Pappa John','Pizza Hut')
    , PARTITION t VALUES IN ('Taco Bell','Taco Time'));

    Then, I checked my Oracle Database 11g & MySQL 5.6 Developer Handbook book and found I’d already written about it on pages 176-177 under a subtopic of Columns Partitioning.

    Thanks,
    Michael

    maclochlainn

    1 Aug 12 at 2:02 am

  5. hi,

    I have a table structure like-

    CREATE TABLE `cdr` (
      `id` bigint(20) NOT NULL AUTO_INCREMENT,
      `dataPacketDownLink` bigint(20) DEFAULT NULL,
      `dataPacketUpLink` bigint(20) DEFAULT NULL,
      `dataPlanEndTime` datetime DEFAULT NULL,
      `dataPlanStartTime` datetime DEFAULT NULL,
      `dataVolumeDownLink` bigint(20) DEFAULT NULL,
      `dataVolumeUpLink` bigint(20) DEFAULT NULL,
      `dataplan` varchar(255) DEFAULT NULL,
      `dataplanType` varchar(255) DEFAULT NULL,
      `createdOn` datetime DEFAULT NULL,
      `deviceName` varchar(500) DEFAULT NULL,
      `duration` int(11) NOT NULL,
      `effectiveDuration` int(11) NOT NULL,
      `hour` int(11) DEFAULT NULL,
      `eventDate` datetime DEFAULT NULL,
      `msisdn` bigint(20) DEFAULT NULL,
      `quarter` int(11) DEFAULT NULL,
      `validDays` int(11) DEFAULT NULL,
      `dataLeft` bigint(20) DEFAULT NULL,
      `completedOn` datetime DEFAULT NULL,
      `eve_date` date DEFAULT '2013-01-01',
      PRIMARY KEY (`id`),
      KEY `msisdn_index` (`msisdn`),
      KEY `eventdate_index` (`eventDate`)
    ) ENGINE=MyISAM AUTO_INCREMENT=55925171 DEFAULT CHARSET=latin1

    and when i am creating partition –

    ALTER TABLE cdr PARTITION BY RANGE (TO_DAYS(eventdate))
    (
      PARTITION p01 VALUES LESS THAN (TO_DAYS('2013-09-01')),
      PARTITION p02 VALUES LESS THAN (TO_DAYS('2013-09-15')),
      PARTITION p03 VALUES LESS THAN (TO_DAYS('2013-09-30')),
      PARTITION p04 VALUES LESS THAN (MAXVALUE));

    getting the same

     error 1503:(

    i have read everywhere about this but not getting anything so please let me know how to partition this table. i have 20+ million records in it.

    Thank you.

    Aamir

    28 Nov 13 at 12:12 am

  6. Aamir, This got left unhandled because I was buried writing another book. If you haven’t fixed this yet, I hope this helps. I’m not sure if this returns an integer, but you might try:

    SELECT CAST(TO_DAYS(eventdate) AS UNSIGNED);

    maclochlainn

    23 Feb 14 at 11:13 pm

Leave a Reply