将 "数据与人" 设为 "星标⭐"
第一时间收到文章更新
背景
近期凌晨经常收到 MySQL 一套实例(一主一从)告警。
告警的原因是存在一定程度的主从延迟。主从延迟过大会影响故障切换,因为若发生切换,需要长时间才可以完成切换,要追延迟来保证主从数据的一致性。
这套 MySQL 实例上的慢查询数量也多,原因是应用每天晚上跑批,在做删除三个月前数据的任务。
分析
使用 pt-query-digest 工具分析一周的慢日志:
pt-query-digest --since=148h mysql-slow.log | less
结果一:
最近的一周时间里,所有记录的慢查询总共消耗了 25403s,其中,执行时间最长的 SQL 耗时 266s,平均每个慢 SQL 执行时间 5s,平均扫描的行数为 1766 万。
结果二:
大多数慢查询都集中在 select arrival_record 操作上,平均响应时间为 4s,delete arrival_record 记录了 6 次,平均响应时间 258s。最多扫描的行数为 5600 万、平均扫描的行数为 172 万,推断由于扫描的行数多导致的执行时间长。
执行计划:
explain select count(*) from arrival_record where product_id=26 and receive_time between '2024-03-25 14:00:00' and '2024-03-25 15:00:00' and receive_spend_ms>=0G;
*************************** 1. row ***************************
id: 1
select_type: SIMPLE
table: arrival_record
partitions: NULL
type: ref
possible_keys: IXFK_arrival_record
key: IXFK_arrival_record
key_len: 8
ref: const
rows: 32261320
filtered: 3.70
Extra: Using index condition; Using where
1 row in set, 1 warning (0.00 sec)
执行计划走了索引 IXFK_arrival_record,但预估扫描的行数依然很高,有 3000 多万行:
show index from arrival_record;
+----------------+------------+---------------------+--------------+--------------+-----------+-------------+----------+--------+------+------------+---------+---------------+
| Table | Non_unique | Key_name | Seq_in_index | Column_name | Collation | Cardinality | Sub_part | Packed | Null | Index_type | Comment | Index_comment |
+----------------+------------+---------------------+--------------+--------------+-----------+-------------+----------+--------+------+------------+---------+---------------+
| arrival_record | 0 | PRIMARY | 1 | id | A | 107990720 | NULL | NULL | | BTREE | | |
| arrival_record | 1 | IXFK_arrival_record | 1 | product_id | A | 1344 | NULL | NULL | | BTREE | | |
| arrival_record | 1 | IXFK_arrival_record | 2 | station_no | A | 22161 | NULL | NULL | YES | BTREE | | |
| arrival_record | 1 | IXFK_arrival_record | 3 | sequence | A | 77233384 | NULL | NULL | | BTREE | | |
| arrival_record | 1 | IXFK_arrival_record | 4 | receive_time | A | 65854652 | NULL | NULL | YES | BTREE | | |
| arrival_record | 1 | IXFK_arrival_record | 5 | arrival_time | A | 73861904 | NULL | NULL | YES | BTREE | | |
+----------------+------------+---------------------+--------------+--------------+-----------+-------------+----------+--------+------+------------+---------+---------------+
show create table arrival_record;
..........
arrival_spend_ms bigint(20) DEFAULT NULL,
total_spend_ms bigint(20) DEFAULT NULL,
PRIMARY KEY (id),
KEY IXFK_arrival_record (product_id,station_no,sequence,receive_time,arrival_time) USING BTREE,
CONSTRAINT FK_arrival_record_product FOREIGN KEY (product_id) REFERENCES product (id) ON DELETE NO ACTION ON UPDATE NO ACTION
) ENGINE=InnoDB AUTO_INCREMENT=614538979 DEFAULT CHARSET=utf8 COLLATE=utf8_bin |
该表是典型的大表,总记录数约1亿条,表上只有一个复合索引,且product_id 选择性不好。
分析过滤条件,根据最左前缀原则,只用到了复合索引 IXFK_arrival_record 的第一个字段 product_id,而该字段选择性很差,导致扫描的行数很多,执行时间长。
receive_time 字段的基数大,选择性好,可考虑对该字段单独建立索引。
使用 tcpdump 抓包一段时间对该表的 select 语句:
tcpdump -i bond0 -s 0 -l -w - dst port 3316 | strings | grep select | egrep -i 'arrival_record' >/tmp/select_arri.log
获取 select 语句中 from 后面的 where 条件语句:
IFS_OLD=$IFS
IFS=$'n'
for i in `cat /tmp/select_arri.log `;do echo ${i#*'from'}; done | less
IFS=$IFS_OLD
arrival_record arrivalrec0_ where arrivalrec0_.sequence='2024-03-27 08:40' and arrivalrec0_.product_id=17 and arrivalrec0_.station_no='56742'
arrival_record arrivalrec0_ where arrivalrec0_.sequence='2024-03-27 08:40' and arrivalrec0_.product_id=22 and arrivalrec0_.station_no='S7100'
arrival_record arrivalrec0_ where arrivalrec0_.sequence='2024-03-27 08:40' and arrivalrec0_.product_id=24 and arrivalrec0_.station_no='V4631'
arrival_record arrivalrec0_ where arrivalrec0_.sequence='2024-03-27 08:40' and arrivalrec0_.product_id=22 and arrivalrec0_.station_no='S9466'
arrival_record arrivalrec0_ where arrivalrec0_.sequence='2024-03-27 08:40' and arrivalrec0_.product_id=24 and arrivalrec0_.station_no='V4205'
arrival_record arrivalrec0_ where arrivalrec0_.sequence='2024-03-27 08:40' and arrivalrec0_.product_id=24 and arrivalrec0_.station_no='V4105'
arrival_record arrivalrec0_ where arrivalrec0_.sequence='2024-03-27 08:40' and arrivalrec0_.product_id=24 and arrivalrec0_.station_no='V4506'
arrival_record arrivalrec0_ where arrivalrec0_.sequence='2024-03-27 08:40' and arrivalrec0_.product_id=24 and arrivalrec0_.station_no='V4617'
arrival_record arrivalrec0_ where arrivalrec0_.sequence='2024-03-27 08:40' and arrivalrec0_.product_id=22 and arrivalrec0_.station_no='S8356'
arrival_record arrivalrec0_ where arrivalrec0_.sequence='2024-03-27 08:40' and arrivalrec0_.product_id=22 and arrivalrec0_.station_no='S8356'
过滤条件中有 product_id,station_no,sequence 字段,可以使用到复合索引 IXFK_arrival_record 的前三个字段。
综上,优化方法为:
- 删除复合索引 IXFK_arrival_record
- 建立复合索引 idx_sequence_station_no_product_id
- 建立单独索引 indx_receive_time
再分析 delete xxx_record 语句
该 delete 操作平均扫描行数为 1.1 亿行,平均执行时间是 262s。
执行计划:
explain select * from arrival_record where receive_time >${log_file} 2>& 1
red_echo "onlie ddl stop"
red_echo "add foreign key"
mysql -uroot -p$passwd --socket=/datas/mysql/data/${port}/mysqld.sock -e"set sql_log_bin=0;ALTER TABLE $db_.${table_name} ADD CONSTRAINT _FK_${table_name}_product FOREIGN KEY (product_id) REFERENCES cq_new_cimiss.product (id) ON DELETE NO ACTION ON UPDATE NO ACTION;" >>${log_file} 2>& 1
check_las_comm "$?" "add foreign key error"
red_echo "add foreign key stop"
red_echo "start slave"
mysql -uroot -p$passwd --socket=/datas/mysql/data/${port}/mysqld.sock -e"start slave"
check_las_comm "$?" "start slave failed"
执行时间:
2024-04-08-11:17:36 stop slave
mysql: [Warning] Using a password on the command line interface can be insecure.
ddl_start
2024-04-08 11:17:36
ddl_stop
2024-04-08 11:45:13
2024-04-08-11:45:13 onlie ddl stop
2024-04-08-11:45:13 add foreign key
mysql: [Warning] Using a password on the command line interface can be insecure.
2024-04-08-12:33:48 add foreign key stop
2024-04-08-12:33:48 start slave
删除重建索引耗时 28 分钟,添加外键耗时 48 分钟。
再次查看执行计划:
explain select count(*) from arrival_record where receive_time =0G;
*************************** 1. row ***************************
id: 1
select_type: SIMPLE
table: arrival_record
partitions: NULL
type: range
possible_keys: idx_product_id_sequence_station_no,idx_receive_time
key: idx_receive_time
key_len: 6
ref: NULL
rows: 291448
filtered: 16.66
Extra: Using index condition; Using where
执行计划良好,行扫描大大降低。
后续
delete 操作还是花费了 77s 时间,效率不尽如人意:
建议应用端小批量多次删除,后续没有再出现主从延迟告警。
更多精彩内容,关注我们▼▼