mysql> SHOW VARIABLES LIKE '%partition%'; +-------------------+-------+ | Variable_name | Value | +-------------------+-------+ | have_partitioning | YES | +-------------------+-------+ 1 row in set (0.00 sec)
18.5.1. Partitioning Keys, Primary Keys, and Unique Keys 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: SQL code: mysql> create table tx ( -> id int not null , -> info_time date, -> primary key(id,info_time) -> ) -> PARTITION BY RANGE(info_time div 100) -> ( -> PARTITION p_2008_11 VALUES LESS THAN (200812), -> PARTITION p_2008_12 VALUES LESS THAN (200901), -> PARTITION p_2009_01 VALUES LESS THAN (200902), -> PARTITION p_2009_02 VALUES LESS THAN (200903), -> PARTITION p_2009_03 VALUES LESS THAN (200904), -> PARTITION p_2009_04 VALUES LESS THAN (200905), -> PARTITION p_catch_all VALUES LESS THAN MAXVALUE -> ); Query OK, 0 rows affected (0.17 sec) mysql>
CREATE TABLE t1 ( year_col INT, some_data INT ) PARTITION BY RANGE (year_col) ( PARTITION p0 VALUES LESS THAN (1991), PARTITION p1 VALUES LESS THAN (1995), PARTITION p2 VALUES LESS THAN (1999), PARTITION p3 VALUES LESS THAN (2002), PARTITION p4 VALUES LESS THAN (2006), PARTITION p5 VALUES LESS THAN MAXVALUE );
e.g.2
CREATE TABLE rc ( a INT NOT NULL, b INT NOT NULL ) PARTITION BY RANGE COLUMNS(a,b) ( PARTITION p0 VALUES LESS THAN (10,5), PARTITION p1 VALUES LESS THAN (20,10), PARTITION p2 VALUES LESS THAN (MAXVALUE,15), PARTITION p3 VALUES LESS THAN (MAXVALUE,MAXVALUE) );
CREATE TABLE part_tab ( c1 int default NULL, c2 varchar(30) default NULL, c3 date default NULL ) engine=myisam PARTITION BY RANGE (year(c3)) ( PARTITION p0 VALUES LESS THAN (2000) , PARTITION p1 VALUES LESS THAN (2001) , PARTITION p2 VALUES LESS THAN (2002) , PARTITION p3 VALUES LESS THAN (2003) , PARTITION p4 VALUES LESS THAN (2004) , PARTITION p12 VALUES LESS THAN (2012), PARTITION p13 VALUES LESS THAN MAXVALUE );
CREATE TABLE client_firms ( id INT, name VARCHAR(35) ) PARTITION BY LIST (id) ( PARTITION r0 VALUES IN (1, 5, 9, 13, 17, 21), PARTITION r1 VALUES IN (2, 6, 10, 14, 18, 22), PARTITION r2 VALUES IN (3, 7, 11, 15, 19, 23), PARTITION r3 VALUES IN (4, 8, 12, 16, 20, 24) );
CREATE TABLE lc ( a INT NULL, b INT NULL ) PARTITION BY LIST COLUMNS(a,b) ( PARTITION p0 VALUES IN( (0,0), (NULL,NULL) ), PARTITION p1 VALUES IN( (0,1), (0,2), (0,3), (1,1), (1,2) ), PARTITION p2 VALUES IN( (1,0), (2,0), (2,1), (3,0), (3,1) ), PARTITION p3 VALUES IN( (1,3), (2,2), (2,3), (3,2), (3,3) ) );
CREATE TABLE th (id INT, name VARCHAR(30), adate DATE) PARTITION BY LIST(YEAR(adate)) ( PARTITION p1999 VALUES IN (1995, 1999, 2003) DATA DIRECTORY = '/var/appdata/95/data' INDEX DIRECTORY = '/var/appdata/95/idx', PARTITION p2000 VALUES IN (1996, 2000, 2004) DATA DIRECTORY = '/var/appdata/96/data' INDEX DIRECTORY = '/var/appdata/96/idx', PARTITION p2001 VALUES IN (1997, 2001, 2005) DATA DIRECTORY = '/var/appdata/97/data' INDEX DIRECTORY = '/var/appdata/97/idx', PARTITION p2000 VALUES IN (1998, 2002, 2006) DATA DIRECTORY = '/var/appdata/98/data' INDEX DIRECTORY = '/var/appdata/98/idx' );
CREATE TABLE `test` ( `userid` int(10) unsigned NOT NULL auto_increment, `username` int(10) unsigned NOT NULL DEFAULT '0', `password` int(10) unsigned NOT NULL DEFAULT '0', primary key (`userid`), KEY `userid` (`username`) ) ENGINE=InnoDB PARTITION BY HASH(userid) PARTITIONS 8;
使用HASH (year(created)) 替代 RANGE(year(created))
CREATE TABLE stuff ( id INT AUTO_INCREMENT, name varchar(50), password varchar(50), created DATE, PRIMARY KEY (id, created) ) PARTITION BY RANGE(year(created)) ( PARTITION p0 VALUES LESS THAN (2010), PARTITION p1 VALUES LESS THAN (2012), PARTITION p2 VALUES LESS THAN MAXVALUE ); 更好的方法 CREATE TABLE stuff ( id INT AUTO_INCREMENT, name varchar(50), password varchar(50), created DATE, PRIMARY KEY (id, created) ) PARTITION BY HASH (year(created)) PARTITIONS 10; 我們演示一下 mysql> CREATE TABLE stuff ( -> id INT AUTO_INCREMENT, -> name varchar(50), -> password varchar(50), -> created DATE, -> PRIMARY KEY (id, created) -> ) -> PARTITION BY HASH (year(created)) PARTITIONS 10; Query OK, 0 rows affected (0.08 sec) mysql> insert into stuff (name,password,created) values('neo','test','2010-10-1'); Query OK, 1 row affected (0.06 sec) mysql> insert into stuff (name,password,created) values('neo1','test','2012-2-1'); Query OK, 1 row affected (0.00 sec) mysql> insert into stuff (name,password,created) values('neo2','test','2012-3-5'); Query OK, 1 row affected (0.00 sec) mysql> insert into stuff (name,password,created) values('neo4','test','2011-1-5'); Query OK, 1 row affected (0.00 sec) mysql> SELECT -> partition_name part, -> partition_expression expr, -> partition_description descr, -> table_rows -> FROM -> INFORMATION_SCHEMA.partitions -> WHERE -> TABLE_SCHEMA = schema() -> AND TABLE_NAME='stuff'; +------+---------------+-------+------------+ | part | expr | descr | table_rows | +------+---------------+-------+------------+ | p0 | year(created) | NULL | 1 | | p1 | year(created) | NULL | 1 | | p2 | year(created) | NULL | 2 | | p3 | year(created) | NULL | 0 | | p4 | year(created) | NULL | 0 | | p5 | year(created) | NULL | 0 | | p6 | year(created) | NULL | 0 | | p7 | year(created) | NULL | 0 | | p8 | year(created) | NULL | 0 | | p9 | year(created) | NULL | 0 | +------+---------------+-------+------------+ 10 rows in set (0.02 sec) mysql> EXPLAIN PARTITIONS SELECT * FROM stuff WHERE created='2011-01-05'\G *************************** 1. row *************************** id: 1 select_type: SIMPLE table: stuff partitions: p1 type: system possible_keys: NULL key: NULL key_len: NULL ref: NULL rows: 1 Extra: 1 row in set (0.08 sec) mysql> EXPLAIN PARTITIONS SELECT * FROM stuff WHERE created='2012-03-05'\G *************************** 1. row *************************** id: 1 select_type: SIMPLE table: stuff partitions: p2 type: ALL possible_keys: NULL key: NULL key_len: NULL ref: NULL rows: 2 Extra: Using where 1 row in set (0.00 sec)
按照KEY進行分區類似於按照HASH分區,除了HASH分區使用的用戶定義的表達式,而KEY分區的 哈希函數是由MySQL 伺服器提供。MySQL 簇(Cluster)使用函數MD5()來實現KEY分區;
CREATE TABLE tk ( col1 INT NOT NULL, col2 CHAR(5), col3 DATE ) PARTITION BY LINEAR KEY (col1) PARTITIONS 3;
CREATE TABLE ts (id INT, purchased DATE) PARTITION BY RANGE( YEAR(purchased) ) SUBPARTITION BY HASH( TO_DAYS(purchased) ) SUBPARTITIONS 2 ( PARTITION p0 VALUES LESS THAN (1990), PARTITION p1 VALUES LESS THAN (2000), PARTITION p2 VALUES LESS THAN MAXVALUE ); CREATE TABLE ts1 (id INT, purchased DATE) PARTITION BY RANGE( YEAR(purchased) ) SUBPARTITION BY HASH( MONTH(purchased) ) SUBPARTITIONS 2 ( PARTITION p0 VALUES LESS THAN (1990), PARTITION p1 VALUES LESS THAN (2000), PARTITION p2 VALUES LESS THAN MAXVALUE );
mysql 5.5+
為已經存在表添加分區
ALTER TABLE tbl_name ADD PARTITION PARTITIONS 6;
新增 RANGE分區
ALTER TABLE category ADD PARTITION (PARTITION p4 VALUES IN (100,200,300,400) DATA DIRECTORY = '/data/category' INDEX DIRECTORY = '/data/category');
新增 LIST分區
CREATE TABLE expenses ( expense_date DATE NOT NULL, category VARCHAR(30), amount DECIMAL (10,3) ); ALTER TABLE expenses PARTITION BY LIST COLUMNS (category) ( PARTITION p01 VALUES IN ( 'lodging', 'food'), PARTITION p02 VALUES IN ( 'flights', 'ground transportation'), PARTITION p03 VALUES IN ( 'leisure', 'customer entertainment'), PARTITION p04 VALUES IN ( 'communications'), PARTITION p05 VALUES IN ( 'fees') );
新增 HASH分區
CREATE TABLE t1 ( id INT, year_col INT ); ALTER TABLE t1 PARTITION BY HASH(id) PARTITIONS 8;
/* 在MySQL 5.1中*/ CREATE TABLE t2 ( dt DATE ) PARTITION BY RANGE (TO_DAYS(dt)) ( PARTITION p01 VALUES LESS THAN (TO_DAYS('2007-01-01')), PARTITION p02 VALUES LESS THAN (TO_DAYS('2008-01-01')), PARTITION p03 VALUES LESS THAN (TO_DAYS('2009-01-01')), PARTITION p04 VALUES LESS THAN (MAXVALUE)); SHOW CREATE TABLE t2 \G *************************** 1. row *************************** Table: t2 Create Table: CREATE TABLE `t2` ( `dt` date DEFAULT NULL ) ENGINE=MyISAM DEFAULT CHARSET=latin1 /*!50100 PARTITION BY RANGE (TO_DAYS(dt)) (PARTITION p01 VALUES LESS THAN (733042) ENGINE = MyISAM, PARTITION p02 VALUES LESS THAN (733407) ENGINE = MyISAM, PARTITION p03 VALUES LESS THAN (733773) ENGINE = MyISAM, PARTITION p04 VALUES LESS THAN MAXVALUE ENGINE = MyISAM) */ /*在MySQL 5.5中*/ CREATE TABLE t2 ( dt DATE ) PARTITION BY RANGE COLUMNS (dt) ( PARTITION p01 VALUES LESS THAN ('2007-01-01'), PARTITION p02 VALUES LESS THAN ('2008-01-01'), PARTITION p03 VALUES LESS THAN ('2009-01-01'), PARTITION p04 VALUES LESS THAN (MAXVALUE)); SHOW CREATE TABLE t2 \G *************************** 1. row *************************** Table: t2 Create Table: CREATE TABLE `t2` ( `dt` date DEFAULT NULL ) ENGINE=MyISAM DEFAULT CHARSET=latin1 /*!50500 PARTITION BY RANGE COLUMNS(dt) (PARTITION p01 VALUES LESS THAN ('2007-01-01') ENGINE = MyISAM, PARTITION p02 VALUES LESS THAN ('2008-01-01') ENGINE = MyISAM, PARTITION p03 VALUES LESS THAN ('2009-01-01') ENGINE = MyISAM, PARTITION p04 VALUES LESS THAN (MAXVALUE) ENGINE = MyISAM) */
使用 REORGANIZE 重建分區。
RANGE 分區重建 ALTER TABLE users REORGANIZE PARTITION p0,p1 INTO (PARTITION p0 VALUES LESS THAN (6000000)); 將原來的 p0,p1 分區合併起來,放到新的 p0 分區中。 LIST 分區重建 ALTER TABLE users REORGANIZE PARTITION p0,p1 INTO (PARTITION p0 VALUES IN(0,1,4,5,8,9,12,13)); 將原來的 p0,p1 分區合併起來,放到新的 p0 分區中。 HASH/KEY 分區重建 ALTER TABLE users REORGANIZE PARTITION COALESCE PARTITION 2; 分區的數量改為2, 注意:在這裡數量只能減少不能增加。想要增加可以用 ADD PARTITION 方法
調整HASH/KEY分區數量,將分區總數擴展到8個。
ALTER TABLE users ADD PARTITION PARTITIONS 8;
重建分區: 這和先刪除保存在分區中的所有記錄,然後重新插入它們,具有同樣的效果。它可用於整理分區碎片。 示例: ALTER TABLE t1 REBUILD PARTITION (p0, p1); · 優化分區:如果從分區中刪除了大量的行,或者對一個帶有可變長度的行(也就是說,有VARCHAR,BLOB,或TEXT類型的列)作了許多修改,可以使用“ALTER TABLE ... OPTIMIZE PARTITION”來收回沒有使用的空間,並整理分區數據檔案的碎片。 示例: ALTER TABLE t1 OPTIMIZE PARTITION (p0, p1); 在一個給定的分區表上使用“OPTIMIZE PARTITION”等同於在那個分區上運行CHECK PARTITION,ANALYZE PARTITION,和REPAIR PARTITION。 · 分析分區:讀取並保存分區的鍵分佈。 示例: ALTER TABLE t1 ANALYZE PARTITION (p3); · 修補分區: 修補被破壞的分區。 示例: ALTER TABLE t1 REPAIR PARTITION (p0,p1); · 檢查分區: 可以使用几乎與對非分區表使用CHECK TABLE 相同的方式檢查分區。 示例: ALTER TABLE trb3 CHECK PARTITION (p1);
EXPLAIN PARTITIONS
mysql> EXPLAIN PARTITIONS SELECT * FROM users\G *************************** 1. row *************************** id: 1 select_type: SIMPLE table: users partitions: p0,p1,p2,p3,p4,p5,p6 type: ALL possible_keys: NULL key: NULL key_len: NULL ref: NULL rows: 7 Extra: 1 row in set (0.03 sec) mysql> EXPLAIN PARTITIONS SELECT * FROM users WHERE id < 5\G *************************** 1. row *************************** id: 1 select_type: SIMPLE table: users partitions: p0,p1,p2,p3,p4,p5,p6 type: range possible_keys: PRIMARY key: PRIMARY key_len: 4 ref: NULL rows: 7 Extra: Using where 1 row in set (0.00 sec)
SHOW CREATE TABLE
mysql> SHOW CREATE TABLE users\G *************************** 1. row *************************** Table: users Create Table: CREATE TABLE `users` ( `id` int(11) NOT NULL AUTO_INCREMENT, `username` varchar(20) NOT NULL DEFAULT '', `birthday` datetime DEFAULT NULL, PRIMARY KEY (`id`,`username`) ) ENGINE=InnoDB AUTO_INCREMENT=4 DEFAULT CHARSET=latin1 /*!50100 PARTITION BY KEY (id,username) PARTITIONS 7 */ 1 row in set (0.00 sec)
SELECT partition_name part, partition_expression expr, partition_description descr, table_rows FROM INFORMATION_SCHEMA.partitions WHERE TABLE_SCHEMA = schema() AND TABLE_NAME='employees';
select partition_name part, partition_expression expr, from_seconds(partition_description) descr, table_rows FROM INFORMATION_SCHEMA.partitions WHERE TABLE_SCHEMA = 'test' AND TABLE_NAME='t2';
指定分區查詢
SELECT * FROM employees PARTITION (p0, p2); SELECT count(1) FROM employees PARTITION (p0); SELECT count(1) FROM employees PARTITION (p0, p2); SELECT count(1) FROM employees PARTITION (p0, p2, p1);
刪除分區中的記錄
DELETE FROM employees PARTITION (p0, p1);
更新指定分區
UPDATE employees PARTITION (p0) SET store_id = 2 WHERE fname = 'Jill';
指定分區連表查詢
SELECT e.id, s.city FROM employees AS e JOIN stores PARTITION (p1) AS s ...;
將某個表遷移到分區上
ALTER TABLE employees EXCHANGE PARTITION p0 WITH TABLE employees2;