背景:哈啰出行旗下包括哈啰单车、助力车、顺风车、打车、电动车、换电等几乎所有业务都基于PostgreSQL数据库构建,PostgreSQL的安全、稳定、高效为哈啰出行的上亿用户提供了强大的基础。随着时间的推移,表里的数据量越来越大,有些需要分库分表处理,有些可以通过简单的分区处理即可,表分区有很多好处:
一.测试描述
二.测试说明
三.测试CASE

四.测试结论
五.测试环境硬件配置信息
六.pg_pathman 分区测试
CREATE TABLE pathman_emp_20190710 (emp_id SERIAL,emp_level INTEGER,emp_name TEXT,create_time TIMESTAMP NOT NULL);
INSERT INTO pathman_emp_20190710 (create_time, emp_level, emp_name)SELECT g, random() * 6,md5(g::text) FROM generate_series('2016-01-01'::date,'2019-12-31'::date, '1 minute') as g;
CREATE INDEX ON pathman_emp_20190710(create_time);CREATE INDEX ON pathman_emp_20190710(emp_name);
SELECT create_range_partitions('pathman_emp_20190710',--主表名'create_time', --分区字段'2016-01-01'::date, --分区起始日期'1 month'::interval, --分区间隔null, --不指定分区数量,根据时间与间隔会自动计算出数量false --默认true立即迁移数据,false是不迁移数据);
select count(*) from only pathman_emp_20190710;
selectpartition_table_concurrently('pathman_emp_20190710',10000,1.0);
select count(*) from only pathman_emp_20190710;postgres=#\dt+
select_pathman_emp_20190710.sql 、insert_pathman_emp_20190710.sqlpostgres@VECS04164:~$ cat select_pathman_new.sqlselect * from public.pathman_emp where emp_name='e0cf722200f2833a04415347324a85f3' andcreate_time >='2016-07-01' and create_time<'2016-08-01';postgres@VECS04164:~$ cat insert_pathman_new.sqlinsert into pathman_emp_new values(emp_name,emp_level,create_time)values('测试',100,now());
/usr/pgsql-10/bin/pgbench -f select_pathman_new.sql -c 4/10 -j 4/10 -n-P 10 -r -T 180 -R 10000 -p 7474 -d postgres -U postgres -h localhost/usr/pgsql-10/bin/pgbench -f insert_pathman_new.sql -c 4/10 -j 4/10 -n-P 10 -r -T 180 -R 10000 -p 7474 -d postgres -U postgres -h localhost
七.native 分区测试
CREATE TABLE native_emp_20190710 (emp_id SERIAL,emp_level INTEGER,emp_name TEXT,create_time TIMESTAMP NOT NULL)partition by range(create_time);
create table native_emp_20190710_201601 partition ofnative_emp_20190710 for values from ('20160101') to ('20160201');create table native_emp_20190710_201602 partition ofnative_emp_20190710 for values from ('20160201') to ('20160301');create table native_emp_20190710_201603 partition ofnative_emp_20190710 for values from ('20160301') to ('20160401');.........create table native_emp_20190710_201910 partition ofnative_emp_20190710 for values from ('20191001') to ('20191101');create table native_emp_20190710_201911 partition ofnative_emp_20190710 for values from ('20191101') to ('20191201');create table native_emp_20190710_201912 partition ofnative_emp_20190710 for values from ('20191201') to ('20200101');
insert into native_emp_20190710 select * from pathman_emp_new;
CREATE INDEX ON native_emp_20190710_201601(emp_name);CREATE INDEX ON native_emp_20190710_201602(emp_name);CREATE INDEX ON native_emp_20190710_201603(emp_name);.....CREATE INDEX ON native_emp_20190710_201910(emp_name);CREATE INDEX ON native_emp_20190710_201911(emp_name);CREATE INDEX ON native_emp_20190710_201912(emp_name);CREATE INDEX ON native_emp_20190710_201601(create_time);CREATE INDEX ON native_emp_20190710_201602(create_time);CREATE INDEX ON native_emp_20190710_201603(create_time);.....CREATE INDEX ON native_emp_20190710_201910(create_time);CREATE INDEX ON native_emp_20190710_201911(create_time);CREATE INDEX ON native_emp_20190710_201912(create_time);
postgres=# select count(*) from native_emp_20190710;count---------2102400(1 row)postgres=# select count(*) from only native_emp_20190710;count-------0(1 row)
select_native_emp_20190710.sql 、insert_native_emp_20190710.sqlpostgres@VECS04164:~$ cat select_native_new.sqlselect * from public.native_emp_new where emp_id=87289589 andcreate_time >='2016-07-01' and create_time<'2016-08-01' limit 1;postgres@VECS04164:~$ cat insert_native_emp_20190710.sqlinsert into native_emp_20190710 (emp_name,emp_level,create_time)values('测试',100,now());
/usr/pgsql-10/bin/pgbench -f select_native_emp_20190710.sql -c 4/10 -j4/10 -n -P 10 -r -T 180 -R 10000 -p 7474 -d postgres -U postgres -h localhost/usr/pgsql-10/bin/pgbench -f insert_native_emp_20190710 -c 4/10 -j4/10 -n -P 10 -r -T 180 -R 10000 -p 7474 -d postgres -U postgres -h localhost
八.Inherits 分区测试
CREATE TABLE inherits_emp_20190710 (emp_id SERIAL,emp_levelINTEGER,emp_name TEXT,create_time TIMESTAMP NOT NULL);
CREATE TABLE inherits_emp_20190710_201601 ( CHECK ( create_time >= DATE'2016-01-01' AND create_time < DATE '2016-02-01' )) INHERITS(inherits_emp_20190710);CREATE TABLE inherits_emp_20190710_201602 ( CHECK ( create_time >= DATE'2016-02-01' AND create_time < DATE '2016-03-01' )) INHERITS(inherits_emp_20190710);CREATE TABLE inherits_emp_20190710_201603 ( CHECK ( create_time >= DATE'2016-03-01' AND create_time < DATE '2016-04-01' )) INHERITS (inherits_emp_20190710);.....CREATE TABLE inherits_emp_20190710_201910 ( CHECK ( create_time >= DATE'2019-10-01' AND create_time < DATE '2019-11-01' )) INHERITS(inherits_emp_20190710);CREATE TABLE inherits_emp_20190710_201911 ( CHECK ( create_time >= DATE'2019-11-01' AND create_time < DATE '2019-12-01' )) INHERITS(inherits_emp_20190710);CREATE TABLE inherits_emp_20190710_201912 ( CHECK ( create_time >= DATE'2019-12-01' AND create_time < DATE '2020-01-01' )) INHERITS(inherits_emp_20190710);
CREATE OR REPLACE FUNCTION insert_inherits_emp_20190710_trigger()RETURNS trigger AS$BODY$DECLAREpartition_date TEXT;partition TEXT;BEGINpartition_date := to_char(NEW.create_time,'YYYYMM');partition := TG_TABLE_NAME || '_' || partition_date;EXECUTE 'INSERT INTO ' || partition || ' SELECT(' || TG_TABLE_NAME || ' ' ||quote_literal(NEW) || ').*;';RETURN NULL;END;$BODY$LANGUAGE plpgsql VOLATILECOST 100;
--create triggerCREATE TRIGGER insert_inherits_emp_20190710BEFORE INSERT ON inherits_emp_20190710FOR EACH ROW EXECUTE PROCEDURE insert_inherits_emp_20190710_trigger()
insert into inherits_emp_20190710 select * from pathman_emp_new;INSERT 0 0
postgres=#\dt+
CREATE INDEX ON inherits_emp_20190710_201601(create_time);CREATE INDEX ON inherits_emp_20190710_201602(create_time);CREATE INDEX ON inherits_emp_20190710_201603(create_time);......CREATE INDEX ON inherits_emp_20190710_201910(create_time);CREATE INDEX ON inherits_emp_20190710_201911(create_time);CREATE INDEX ON inherits_emp_20190710_201912(create_time);CREATE INDEX ON inherits_emp_20190710_201601(emp_name);CREATE INDEX ON inherits_emp_20190710_201602(emp_name);CREATE INDEX ON inherits_emp_20190710_201603(emp_name);......CREATE INDEX ON inherits_emp_20190710_201910(emp_name);CREATE INDEX ON inherits_emp_20190710_201911(emp_name);CREATE INDEX ON inherits_emp_20190710_201912(emp_name);
select_inherits_emp_20190710.sql 、insert_inherits_emp_20190710.sqlpostgres@VECS04164:~$ cat select_inherits_emp_20190710.sqlselect * from public.inherits_emp_20190710 where emp_name='e0cf722200f2833a04415347324a85f3' andcreate_time >='2016-07-01' and create_time<'2016-08-01';postgres@VECS04164:~$ cat insert_inherits_emp_20190710.sqlinsert into inherits_emp_20190710 (emp_name,emp_level,create_time)values('测试',100,now());
/usr/pgsql-10/bin/pgbench -f select_inherits_emp_20190710 -c 4/10 -j 4/10 -n -P10 -r -T 180 -R 10000 -p 7474 -d postgres -U postgres -h localhost/usr/pgsql-10/bin/pgbench -f insert_inherits_emp_20190710.sql -c 4/10 -j 4/10 -n -P10 -r -T 180 -R 10000 -p 7474 -d postgres -U postgres -h localhost
九.不分区表测试
CREATE TABLE test_tmp_14m (emp_id SERIAL,emp_level INTEGER,emp_nameTEXT,create_time TIMESTAMP NOT NULL);
/usr/pgsql-10/bin/pgbench -f select_test_tmp_14m.sql -c 4/10 -j 4/10 -n-P 10 -r -T 180 -R 10000 -p 7474 -d postgres -U postgres -h localhost/usr/pgsql-10/bin/pgbench -f insert_test_tmp_14m.sql -c 4/10 -j 4/10 -n-P 10 -r -T 180 -R 10000 -p 7474 -d postgres -U postgres -h localhost
十.峰值qps压测
十一.CPU利用率监控视图
1)10个并发select的CPU使用率对比:
pg_pathman 10个并发select的cpu:




2)4个并发select的CPU使用率对比:




3)10个并发insert的CPU使用率对比:



不分区 10个并发insert的cpu:

4)4个并发insert的CPU使用率对比:




I Love PG
关于我们
中国开源软件推进联盟PostgreSQL分会(简称:中国PG分会)于2017年成立,由国内多家PostgreSQL生态企业所共同发起,业务上接受工信部中国电子信息产业发展研究院指导。中国PG分会是一个非盈利行业协会组织。我们致力于在中国构建PostgreSQL产业生态,推动PostgreSQL产学研用发展。
技术文章精彩回顾 PostgreSQL学习的九层宝塔 PostgreSQL职业发展与学习攻略 2019,年度数据库舍 PostgreSQL 其谁? Postgres是最好的开源软件 PostgreSQL是世界上最好的数据库 从Oracle迁移到PostgreSQL的十大理由 从“非主流”到“潮流”,开源早已值得拥有 PG活动精彩回顾 创建PG全球生态!PostgresConf.CN2019大会盛大召开 首站起航!2019“让PG‘象’前行”上海站成功举行 走进蓉城丨2019“让PG‘象’前行”成都站成功举行 中国PG象牙塔计划发布,首批合作高校授牌仪式在天津举行 群英论道聚北京,共话PostgreSQL 相聚巴厘岛| PG Conf.Asia 2019 DAY0、DAY1简报 相知巴厘岛| PG Conf.Asia 2019 DAY2简报 独家|硅谷Postgres大会简报 直播回顾 | Bruce Momjian:原生分布式将在PG 14版本发布 PG培训认证精彩回顾 中国首批PGCA认证考试圆满结束,203位考生成功获得认证! 中国第二批PGCA认证考试圆满结束,115位考生喜获认证! 重要通知:三方共建,中国PostgreSQL认证权威升级! 近500人参与!首次PGCE中级、第三批次PGCA初级认证考试落幕! 2020年首批 | 中国PostgreSQL初级认证考试圆满结束 一分耕耘一分收获,第五批次PostgreSQL认证考试成绩公布
文章转载自开源软件联盟PostgreSQL分会,如果涉嫌侵权,请发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。





