Beginning with MySQL 5.5.0, MySQL provides support for
LIST COLUMNS
partitioning. This is a
variant of LIST
partitioning that allows
the use of multiple columns as partition keys, and for columns
of data types other than integer types to be used as
partitioning columns; you can use string types,
DATE
, and
DATETIME
columns. (For more
information about allowed data types for
COLUMNS
partitioning columns, see
Section 17.2.3, “COLUMNS
Partitioning”.)
Suppose that you have a business that has customers in 12 cities which, for sales and marketing purposes, you organize into 4 regions of 3 cities each as shown in the following table:
Region | Cities |
---|---|
1 | Oskarshamn, Högsby, Mönsterås |
2 | Vimmerby, Hultsfred, Västervik |
3 | Nässjö, Eksjö, Vetlanda |
4 | Uppvidinge, Alvesta, Växjo |
With LIST COLUMNS
partitioning, you can
create a table for customer data that assigns a row to any of
4 partitions corresponding to these regions based on the name
of the city where a customer resides, as shown here:
CREATE TABLE customers_1 ( first_name VARCHAR(25), last_name VARCHAR(25), street_1 VARCHAR(30), street_2 VARCHAR(30), city VARCHAR(15), renewal DATE ) PARTITION BY LIST COLUMNS(city) ( PARTITION pRegion_1 VALUES IN('Oskarshamn', 'Högsby', 'Mönsterås'), PARTITION pRegion_2 VALUES IN('Vimmerby', 'Hultsfred', 'Västervik'), PARTITION pRegion_3 VALUES IN('Nässjö', 'Eksjö', 'Vetlanda'), PARTITION pRegion_4 VALUES IN('Uppvidinge', 'Alvesta', 'Växjo') );
As with partitioning by RANGE COLUMNS
, you
do not need to use expressions in the
COLUMNS()
clause to convert column values
into integers. (In fact, the use of expressions other than
column names is not allowed with
COLUMNS()
.)
It is also possible to use DATE
and DATETIME
columns, as shown
in the following example that uses the same name and columns
as the customers_1
table shown previously,
but employs LIST COLUMNS
partitioning based
on the renewal
column to store rows in one
of 4 partitions depending on the week in February 2010 the
customer's account is scheduled to renew:
CREATE TABLE customers_2 ( first_name VARCHAR(25), last_name VARCHAR(25), street_1 VARCHAR(30), street_2 VARCHAR(30), city VARCHAR(15), renewal DATE ) PARTITION BY LIST COLUMNS(renewal) ( PARTITION pWeek_1 VALUES IN('2010-02-01', '2010-02-02', '2010-02-03', '2010-02-04', '2010-02-05', '2010-02-06', '2010-02-07'), PARTITION pWeek_2 VALUES IN('2010-02-08', '2010-02-09', '2010-02-10', '2010-02-11', '2010-02-12', '2010-02-13', '2010-02-14'), PARTITION pWeek_3 VALUES IN('2010-02-15', '2010-02-16', '2010-02-17', '2010-02-18', '2010-02-19', '2010-02-20', '2010-02-21'), PARTITION pWeek_4 VALUES IN('2010-02-22', '2010-02-23', '2010-02-24', '2010-02-25', '2010-02-26', '2010-02-27', '2010-02-28') );
This works, but becomes cumbersome to define and maintain if
the number of dates involved grows very large; in such cases,
it is usually more practical to employ
RANGE
or RANGE COLUMNS
partitioning instead:
CREATE TABLE customers_3 ( first_name VARCHAR(25), last_name VARCHAR(25), street_1 VARCHAR(30), street_2 VARCHAR(30), city VARCHAR(15), renewal DATE ) PARTITION BY RANGE COLUMNS(renewal) ( PARTITION pWeek_1 VALUES LESS THAN('2010-02-09'), PARTITION pWeek_2 VALUES LESS THAN('2010-02-15'), PARTITION pWeek_3 VALUES LESS THAN('2010-02-22'), PARTITION pWeek_4 VALUES LESS THAN('2010-03-01') );
See Section 17.2.3.1, “Range columns partitioning”, for more information.
In addition (as with RANGE COLUMNS
partitioning), you can use multiple columns in the
COLUMNS()
clause.
See Section 12.1.14, “CREATE TABLE
Syntax”, for additional information
about PARTITION BY LIST COLUMNS()
syntax.
User Comments
Add your own comment.