知乎专栏 |
delete from mytable 必死无疑,你需要分批删除,尽量缩小每个批次删除的记录数,delete 是可以并行执行的,你可以同时运行多个删除操作
通过 where 条件和 limit 限制条数,缩小删除结果集,分多笔执行,手工删除。
mysql> show processlist; +--------+-----------------+---------------------+-----------+---------+-------+-----------------------------+--------------------------------------------------------+ | Id | User | Host | db | Command | Time | State | Info | +--------+-----------------+---------------------+-----------+---------+-------+-----------------------------+--------------------------------------------------------+ | 1 | event_scheduler | localhost | NULL | Daemon | 52 | Waiting for next activation | NULL | | 115986 | dba | localhost | example | Query | 0 | NULL | show processlist | | 117446 | dba | localhost | example | Query | 20 | updating | delete from mytable where OPEN_TIME like '2011.11.28%' | | 117525 | dba | localhost | example | Query | 2 | updating | delete from mytable where OPEN_TIME like '2011.12.02%' | | 117526 | dba | localhost | example | Query | 49 | updating | delete from mytable where OPEN_TIME like '2011.12.12%' | | 117527 | dba | localhost | example | Query | 6 | updating | delete from mytable where OPEN_TIME like '2011.12.21%' | | 117528 | dba | localhost | example | Query | 64 | updating | delete from mytable where OPEN_TIME like '2011.12.30%' | | 117546 | dba | localhost | example | Query | 33 | updating | delete from mytable where OPEN_TIME like '2011.11.10%' | +--------+-----------------+---------------------+-----------+---------+-------+-----------------------------+--------------------------------------------------------+ 23 rows in set (0.00 sec)
需求:数据需要删除100万条数据,直接删除会对系统造成压力,导致主库阻塞。
解决方案:分批删除,使用 event 定时执行删除 SQL 直到删完位置。
开启 EVENT
set global event_scheduler = on;
准备数据备份、删除和回撤所需的三条SQL
备份 SQL: CREATE TABLE mytable_2022_7_30 SELECT * FROM mytable; 删除 SQL: DELETE FROM mytable LIMIT 1; 回撤 SQL: INSERT INTO mytable SELECT * FROM mytable_2022_7_30;
通过 where 缩小结果集
备份 SQL: CREATE TABLE mytable_2022_7_30 SELECT * FROM mytable where level = 'info'; 删除 SQL: DELETE FROM mytable where level = 'info' LIMIT 1; 回撤 SQL: INSERT INTO mytable SELECT * FROM mytable_2022_7_30;
上面条SQL在测试环境验证无误后,编写定时删除 EVENT
DELIMITER $$ CREATE EVENT IF NOT EXISTS event_delete ON SCHEDULE EVERY 1 SECOND ON COMPLETION PRESERVE DO BEGIN DECLARE num integer; SELECT COUNT(*) INTO num FROM mytable; IF num > 0 THEN delete from mytable limit 1; insert into logs(ctime) values(now()); END IF; END$$
EVENT 在测试环境运行无误才能在生产环境执行。
通过 limit 调整每次删除的数量,为了观察 EVENT 执行状态,这里会插入一条执行日志。
数据删除完毕之后回收 EVENT
DROP EVENT event_delete;
在电商领域常常遇到一个问题“调价”,经常需要调整一批商品的价格, 程序猿一条语句搞定有没有?
update goods set price=price+10 where category_id = xxx
在开发,测试环境是可以通过测试的,一旦部署到生产环境,必死无疑
大表创建索引需要很久的时间,通常要经历 manage keys 与 copy to tmp table 的过程
mysql> show processlist; +--------+-----------------+---------------------+----------+---------+-------+-----------------------------+------------------------------------------------------------------+ | Id | User | Host | db | Command | Time | State | Info | +--------+-----------------+---------------------+----------+---------+-------+-----------------------------+------------------------------------------------------------------+ | 1 | event_scheduler | localhost | NULL | Daemon | 47 | Waiting for next activation | NULL | | 115986 | dba | localhost | example | Query | 0 | NULL | show processlist | | 118814 | dba | 192.168.6.20:50459 | example | Query | 8 | copy to tmp table | ALTER TABLE `mytable` ADD INDEX `modifiy_time` (`MODIFY_TIME`) | +--------+-----------------+---------------------+----------+---------+-------+-----------------------------+------------------------------------------------------------------+ 17 rows in set (0.00 sec)
删除索引,也需要经理 copy to tmp table 过程,漫长的等待
mysql> show processlist; +--------+-----------------+---------------------+--------------+---------+-------+-----------------------------+-------------------------------------------------+ | Id | User | Host | db | Command | Time | State | Info | +--------+-----------------+---------------------+--------------+---------+-------+-----------------------------+-------------------------------------------------+ | 1 | event_scheduler | localhost | NULL | Daemon | 11 | Waiting for next activation | NULL | | 115986 | dba | localhost | example | Query | 0 | NULL | show processlist | | 118814 | dba | 192.168.6.20:50459 | example | Query | 4 | copy to tmp table | ALTER TABLE `mytable` DROP INDEX `modifiy_time` | +--------+-----------------+---------------------+--------------+---------+-------+-----------------------------+-------------------------------------------------+ 17 rows in set (0.00 sec)
所以数据设计要深思熟虑,做到提前未雨绸缪,不要亡羊补牢
OPTIMIZE 的操作是将当前表复制到临时表操作后再删除当前表,最后将临时表改名
mysql> show processlist; +--------+-----------------+---------------------+---------------------------+---------+-------+-----------------------------+--------------------------+ | Id | User | Host | db | Command | Time | State | Info | +--------+-----------------+---------------------+---------------------------+---------+-------+-----------------------------+--------------------------+ | 1 | event_scheduler | localhost | NULL | Daemon | 14 | Waiting for next activation | NULL | | 115835 | dba | 192.168.6.20:49664 | example | Query | 9 | copy to tmp table | OPTIMIZE TABLE `mytable` | | 115986 | dba | localhost | example | Query | 0 | NULL | show processlist | +--------+-----------------+---------------------+---------------------------+---------+-------+-----------------------------+--------------------------+ 17 rows in set (0.00 sec)
转换ENGINE从MyISAM到InnoDB会经历creating table然后copy to tmp table在修改表名几个阶段,过程非常缓慢
mysql> show processlist; +------+-----------------+---------------------+---------+---------+-------+-----------------------------+------------------------------------------+ | Id | User | Host | db | Command | Time | State | Info | +------+-----------------+---------------------+---------+---------+-------+-----------------------------+------------------------------------------+ | 1 | event_scheduler | localhost | NULL | Daemon | 10 | Waiting for next activation | NULL | | 3167 | dba | 192.168.6.20:56723 | example | Query | 2 | creating table | ALTER TABLE `mytable` ENGINE=InnoDB | | 3172 | dba | localhost | example | Query | 0 | NULL | show processlist | +------+-----------------+---------------------+---------+---------+-------+-----------------------------+------------------------------------------+ 18 rows in set (0.00 sec)
copy to tmp table 过程
mysql> show processlist; +------+-----------------+---------------------+---------+---------+-------+-----------------------------+------------------------------------------+ | Id | User | Host | db | Command | Time | State | Info | +------+-----------------+---------------------+---------+---------+-------+-----------------------------+------------------------------------------+ | 1 | event_scheduler | localhost | NULL | Daemon | 21 | Waiting for next activation | NULL | | 3167 | dba | 192.168.6.20:56723 | example | Query | 13 | copy to tmp table | ALTER TABLE `mytable` ENGINE=InnoDB | | 3172 | dba | localhost | example | Query | 0 | NULL | show processlist | +------+-----------------+---------------------+---------+---------+-------+-----------------------------+------------------------------------------+ 18 rows in set (0.00 sec)
此时我们查看mysql data目录会看到临时表文件
# ll /var/lib/mysql/hx9999_real_history/ -rw-rw---- 1 mysql mysql 9522 May 16 17:17 #sql-c2f_c5f.frm -rw-rw---- 1 mysql mysql 48 May 16 17:17 #sql-c2f_c5f.par -rw-rw---- 1 mysql mysql 637534208 May 16 17:29 #sql-c2f_c5f#P#p0.ibd -rw-rw---- 1 mysql mysql 180224 May 16 17:17 #sql-c2f_c5f#P#p1.ibd -rw-rw---- 1 mysql mysql 180224 May 16 17:17 #sql-c2f_c5f#P#p2.ibd -rw-rw---- 1 mysql mysql 180224 May 16 17:17 #sql-c2f_c5f#P#p3.ibd -rw-rw---- 1 mysql mysql 180224 May 16 17:17 #sql-c2f_c5f#P#p4.ibd -rw-rw---- 1 mysql mysql 180224 May 16 17:17 #sql-c2f_c5f#P#p5.ibd -rw-rw---- 1 mysql mysql 180224 May 16 17:17 #sql-c2f_c5f#P#p6.ibd -rw-rw---- 1 mysql mysql 180224 May 16 17:17 #sql-c2f_c5f#P#p7.ibd
使用各种手段保证select操作不被受阻,只要select一直可以查询网站前端就能提供80%的功能,一旦select受阻一切都是浮云。
保证 select 操作优先于其他操作
UPDATE [LOW_PRIORITY] [IGNORE] tbl_name SET col_name1=expr1 [, col_name2=expr2 ...] [WHERE where_definition] [ORDER BY ...] [LIMIT row_count]
update的时候增加 LOW_PRIORITY 参数,可以降低更新语句的优先级。
my.cnf
[mysqld] low_priority_updates=1
或者启动是添加--low-priority-updates参数
全局开启
SET @@global.low_priority_updates = 1;
适用于本次会话连接
SET @@session.low_priority_updates = 1;
使用 limit 限制更新记录的数量
update mytable set status='Y' where status='N' limit 1000;