mysql支持的分区类型一共有四种:range,list,hash,key。其中,range又可分为原生range和range columns,list分为原生list和list columns,hash分为原生hash和linear hash,key包含原生key和linear hash。关于这些分区之间的差别,改日另写文章进行阐述。
最近,碰到一个需求,要对表的时间字段(类型:datetime)基于天进行分区。于是遍历mysql官方文档分区章节,总结如下:
实现方式
主要是以下几种:
1. 基于range
2. 基于range columns
3. 基于hash
测试数据
为了测试以上三种方案,特构造了100万的测试数据,放在test表中,test表只有两列:id和hiredate,其中hiredate只包含10天的数据,从2015-12-01到2015-12-10。具体信息如下:
mysql> show create table test\g*************************** 1. row *************************** table: testcreate table: create table `test` ( `id` int(11) default null, `hiredate` datetime default null) engine=innodb default charset=latin11 row in set (0.00 sec)mysql> select min(hiredate),max(hiredate) from test;+---------------------+---------------------+| min(hiredate) | max(hiredate) |+---------------------+---------------------+| 2015-12-01 00:00:00 | 2015-12-10 23:59:56 |+---------------------+---------------------+1 row in set (0.44 sec)mysql> select date(hiredate),count(*) from test group by date(hiredate);+----------------+----------+| date(hiredate) | count(*) |+----------------+----------+| 2015-12-01 | 99963 || 2015-12-02 | 100032 || 2015-12-03 | 100150 || 2015-12-04 | 99989 || 2015-12-05 | 99908 || 2015-12-06 | 99897 || 2015-12-07 | 100137 || 2015-12-08 | 100171 || 2015-12-09 | 99851 || 2015-12-10 | 99902 |+----------------+----------+10 rows in set (0.98 sec)
测试的维度
测试的维度主要从两个方面进行,
一、分区剪裁
针对特定的查询,是否能进行分区剪裁(即只查询相关的分区,而不是所有分区)
二、查询时间
鉴于该批测试数据是静止的(即没有并发进行的insert,update和delete操作),数据量也不太大,从这个维度来考量貌似意义也不是很大。
因此,重点测试第一个维度。
基于range的分区方案
在这里,选用了to_days函数
create table range_datetime( id int, hiredate datetime)partition by range (to_days(hiredate) ) ( partition p1 values less than ( to_days('20151202') ), partition p2 values less than ( to_days('20151203') ), partition p3 values less than ( to_days('20151204') ), partition p4 values less than ( to_days('20151205') ), partition p5 values less than ( to_days('20151206') ), partition p6 values less than ( to_days('20151207') ), partition p7 values less than ( to_days('20151208') ), partition p8 values less than ( to_days('20151209') ), partition p9 values less than ( to_days('20151210') ), partition p10 values less than ( to_days('20151211') ));
插入数据并查看特定查询的执行计划
mysql> insert into range_datetime select * from test; query ok, 1000000 rows affected (8.15 sec)records: 1000000 duplicates: 0 warnings: 0mysql> explain partitions select * from range_datetime where hiredate >= '20151207124503' and hiredate insert into range_columns select * from test; query ok, 1000000 rows affected (9.20 sec)records: 1000000 duplicates: 0 warnings: 0mysql> explain partitions select * from range_columns where hiredate >= '20151207124503' and hiredate insert into hash_datetime select * from test;query ok, 1000000 rows affected (9.43 sec)records: 1000000 duplicates: 0 warnings: 0mysql> explain partitions select * from hash_datetime where hiredate >= '20151207124503' and hiredate insert into range_timestamp select * from test;query ok, 1000000 rows affected (13.25 sec)records: 1000000 duplicates: 0 warnings: 0mysql> explain partitions select * from range_timestamp where hiredate >= '20151207124503' and hiredate<='20151210111230';+----+-------------+-----------------+--------------+------+---------------+------+---------+------+--------+-------------+| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | extra |+----+-------------+-----------------+--------------+------+---------------+------+---------+------+--------+-------------+| 1 | simple | range_timestamp | p7,p8,p9,p10 | all | null | null | null | null | 400448 | using where |+----+-------------+-----------------+--------------+------+---------------+------+---------+------+--------+-------------+1 row in set (0.00 sec)
同样也能实现分区裁剪。
总结:
1. 经过对比,个人倾向于第二种方案,即基于range columns的分区实现。
2. 在5.7版本之前,对于data和datetime类型的列,如果要实现分区裁剪,只能使用year() 和to_days()函数,在5.7版本中,又新增了to_seconds()函数。
3. 其实list也能实现基于天的分区方案,但在这个需求上,相比于range,还是显得很鸡肋。
4. timestamp类型的列,只能基于unix_timestamp函数进行分区,切记!