本文由yueliangdao0608在论坛所发,CU技术文章整理,供大家参考学习,转载请注明出处,谢谢。
终于有点空闲时间了,测试一下LIST分区,因为LIST在我们的开发中用到。他分区以后再补上。
版本:
Server version: 5.1.23a-maria-alpha-log MySQL Community Server [Maria] (GPL)
一、讲在前面
注意:
1、ALTER TABLE也可以用于对带分区的表进行重新分区,所以不能在建表之后再用ALTER TABLE语法。
2、如果你表中有KEY。用来分区的字段必须是KEY的一部份。
3、现在的分区属于水平分区。(垂直分区我们可以自己模拟,这个以后再写)
mysql> use t_girl
Database changed
先建立一个普通表
mysql> create table category( cid int unsigned not null auto_increment primary key, cname varchar(64) not null, parent_id int not null);
Query OK, 0 rows affected (0.00 sec)
mysql> create table parent(parent_id int not null auto_increment primary key,pname varchar(64) not null);
Query OK, 0 rows affected (0.00 sec)
分区表
mysql> create table category_part( cid int unsigned not null auto_increment,cname varchar(64) not null,parent_id int not null,primary key (cid,parent_id))
partition by list(parent_id)(
partition p1 values in (1,2,3,6,9),
partition p2 values in (4,5,10,22,23),
partition p3 values in (7,8,11,12,13),
partition p4 values in (14,15,16,17,20),
partition p5 values in (18,19,21,24,25)
);
Query OK, 0 rows affected (0.01 sec)
插入数据部分省略。。。
建立索引。
mysql> create index f_parent_id on category(parent_id);
Query OK, 2048000 rows affected (17.61 sec)
Records: 2048000 Duplicates: 0 Warnings: 0
mysql> show index from category;
+----------+------------+-------------+--------------+-------------+-----------+-------------+----------+--------+------+------------+---------+
| Table | Non_unique | Key_name | Seq_in_index | Column_name | Collation | Cardinality | Sub_part | Packed | Null | Index_type | Comment |
+----------+------------+-------------+--------------+-------------+-----------+-------------+----------+--------+------+------------+---------+
| category | 0 | PRIMARY | 1 | cid | A | 2048000 | NULL | NULL | | BTREE | |
| category | 1 | f_parent_id | 1 | parent_id | A | 25 | NULL | NULL | | BTREE | |
+----------+------------+-------------+--------------+-------------+-----------+-------------+----------+--------+------+------------+---------+
2 rows in set (0.00 sec)
mysql> create index f_parent_id on category_part(parent_id);
Query OK, 2048000 rows affected (18.57 sec)
Records: 2048000 Duplicates: 0 Warnings: 0
mysql> show index from category_part;
+---------------+------------+-------------+--------------+-------------+-----------+-------------+----------+--------+------+------------+---------+
| Table | Non_unique | Key_name | Seq_in_index | Column_name | Collation | Cardinality | Sub_part | Packed | Null | Index_type | Comment |
+---------------+------------+-------------+--------------+-------------+-----------+-------------+----------+--------+------+------------+---------+
| category_part | 0 | PRIMARY | 1 | cid | A | 2048000 | NULL | NULL | | BTREE | |
| category_part | 0 | PRIMARY | 2 | parent_id | A | 2048000 | NULL | NULL | | BTREE | |
| category_part | 1 | f_parent_id | 1 | parent_id | A | 318 | NULL | NULL | | BTREE | |
+---------------+------------+-------------+--------------+-------------+-----------+-------------+----------+--------+------+------------+---------+
3 rows in set (0.01 sec)
mysql> select count(*) from category;
+----------+
| count(*) |
+----------+
| 2048000 |
+----------+
1 row in set (0.00 sec)
mysql> select count(*) from category_part;
+----------+
| count(*) |
+----------+
| 2048000 |
+----------+
1 row in set (0.00 sec)
mysql> select count(*) from parent;
+----------+
| count(*) |
+----------+
| 25 |
+----------+
1 row in set (0.00 sec)
二、具体测试
1、我们来看一下查询性能比较:
1)、单表查询
mysql> select count(*) from category where parent_id in (22,20);
+----------+
| count(*) |
+----------+
| 17002 |
+----------+
1 row in set (0.03 sec)
mysql> select count(*) from category_part where parent_id in (22,20);
+----------+
| count(*) |
+----------+
| 17002 |
+----------+
1 row in set (0.02 sec)
分区表普通的做了索引的速度上快了一点,不过差别不是很大。
mysql> explain select count(*) from category where parent_id in (22,20);
+----+-------------+----------+-------+---------------+-------------+---------+------+-------+--------------------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+----------+-------+---------------+-------------+---------+------+-------+--------------------------+
| 1 | SIMPLE | category | range | f_parent_id | f_parent_id | 4 | NULL | 14335 | Using where; Using index |
+----+-------------+----------+-------+---------------+-------------+---------+------+-------+--------------------------+
1 row in set (0.00 sec)
mysql> explain partitions select count(*) from category_part where parent_id in (22,20);
+----+-------------+---------------+------------+-------+---------------+-------------+---------+------+-------+--------------------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+---------------+------------+-------+---------------+-------------+---------+------+-------+--------------------------+
| 1 | SIMPLE | category_part | p2,p4 | range | f_parent_id | f_parent_id | 4 | NULL | 16893 | Using where; Using index |
+----+-------------+---------------+------------+-------+---------------+-------------+---------+------+-------+--------------------------+
1 row in set (0.00 sec)
mysql> select count(*) from category where parent_id = 25;
+----------+
| count(*) |
+----------+
| 2001 |
+----------+
1 row in set (0.01 sec)
mysql> select count(*) from category_part where parent_id = 25;
+----------+
| count(*) |
+----------+
| 2001 |
+----------+
1 row in set (0.00 sec)
mysql> explain select count(*) from category where parent_id = 25;
+----+-------------+----------+------+---------------+-------------+---------+-------+-------+-------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+----------+------+---------------+-------------+---------+-------+-------+-------------+
| 1 | SIMPLE | category | ref | f_parent_id | f_parent_id | 4 | const | 38240 | Using index |
+----+-------------+----------+------+---------------+-------------+---------+-------+-------+-------------+
1 row in set (0.00 sec)
mysql> explain partitions select count(*) from category_part where parent_id = 25;
+----+-------------+---------------+------------+------+---------------+-------------+---------+-------+------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+---------------+------------+------+---------------+-------------+---------+-------+------+-------------+
| 1 | SIMPLE | category_part | p5 | ref | f_parent_id | f_parent_id | 4 | const | 4647 | Using index |
+----+-------------+---------------+------------+------+---------------+-------------+---------+-------+------+-------------+
1 row in set (0.00 sec)
可以看出,扫描的行数大幅度减少
2)、多表内联性能
mysql> select count(*) from category as a inner join parent as b using(parent_id);
+----------+
| count(*) |
+----------+
| 2048000 |
+----------+
1 row in set (0.84 sec)
mysql> select count(*) from category_part as a inner join parent as b using(parent_id);
+----------+
| count(*) |
+----------+
| 2048000 |
+----------+
1 row in set (0.88 sec)
mysql> explain select count(*) from category as a inner join parent as b using(parent_id);
+----+-------------+-------+-------+---------------+-------------+---------+--------------------+-------+-------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+-------+-------+---------------+-------------+---------+--------------------+-------+-------------+
| 1 | SIMPLE | b | index | PRIMARY | PRIMARY | 4 | NULL | 25 | Using index |
| 1 | SIMPLE | a | ref | f_parent_id | f_parent_id | 4 | t_girl.b.parent_id | 81920 | Using index |
+----+-------------+-------+-------+---------------+-------------+---------+--------------------+-------+-------------+
2 rows in set (0.00 sec)
mysql> explain partitions select count(*) from category_part as a inner join parent as b using(parent_id);
+----+-------------+-------+----------------+-------+---------------+-------------+---------+--------------------+------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+-------+----------------+-------+---------------+-------------+---------+--------------------+------+-------------+
| 1 | SIMPLE | b | NULL | index | PRIMARY | PRIMARY | 4 | NULL | 25 | Using index |
| 1 | SIMPLE | a | p1,p2,p3,p4,p5 | ref | f_parent_id | f_parent_id | 4 | t_girl.b.parent_id | 6421 | Using index |
+----+-------------+-------+----------------+-------+---------------+-------------+---------+--------------------+------+-------------+
2 rows in set (0.00 sec)
可以看出,扫描的行数大幅度减少
mysql> explain select count(*) from category as a inner join parent as b using(parent_id) where a.parent_id =19;
+----+-------------+-------+-------+---------------+-------------+---------+-------+------+-------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+-------+-------+---------------+-------------+---------+-------+------+-------------+
| 1 | SIMPLE | b | const | PRIMARY | PRIMARY | 4 | const | 1 | Using index |
| 1 | SIMPLE | a | ref | f_parent_id | f_parent_id | 4 | const | 6746 | Using index |
+----+-------------+-------+-------+---------------+-------------+---------+-------+------+-------------+
2 rows in set (0.00 sec)
mysql> explain partitions select count(*) from category_part as a inner join parent as b using(parent_id) where a.parent_id =19;
+----+-------------+-------+------------+-------+---------------+-------------+---------+-------+------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | Extra |
+----+-------------+-------+------------+-------+---------------+-------------+---------+-------+------+-------------+
| 1 | SIMPLE | b | NULL | const | PRIMARY | PRIMARY | 4 | const | 1 | Using index |
| 1 | SIMPLE | a | p5 | ref | f_parent_id | f_parent_id | 4 | const | 5203 | Using index |
+----+-------------+-------+------------+-------+---------------+-------------+---------+-------+------+-------------+
2 rows in set (0.00 sec)
由以上数据可以看出,数据越大,查询性能提升的越明显!
2、下来看看写性能
mysql> insert into category(cname,parent_id) values ('Test',1);
Query OK, 1 row affected (0.01 sec)
mysql> insert into category_part(cname,parent_id) values ('Test',1);
Query OK, 1 row affected (0.00 sec)
mysql> select * from category into outfile '/tmp/a.txt';
ERROR 1086 (HY000): File '/tmp/a.txt' already exists
mysql> select * from category into outfile '/tmp/test.dat';
Query OK, 2048005 rows affected (2.82 sec)
mysql> truncate table category;
Query OK, 0 rows affected (0.06 sec)
mysql> truncate table category_part;
Query OK, 2048005 rows affected (0.10 sec)
mysql> load data infile '/tmp/test.dat' into table category;
Query OK, 2048005 rows affected (17.67 sec)
Records: 2048005 Deleted: 0 Skipped: 0 Warnings: 0
mysql> load data infile '/tmp/test.dat' into table category_part;
Query OK, 2048005 rows affected (21.62 sec)
Records: 2048005 Deleted: 0 Skipped: 0 Warnings: 0
可以看出,写性能损失不了多少。
牺牲了少许写的性能却大幅度提高了查询的性能,这个是值得的。
如果我有什么说的不对的地方,欢迎各位提意见!
阅读(1560) | 评论(0) | 转发(0) |