RDS MySQL 8.0 Recycle Bin
背景
MySQL 在生产环境使用过程中,会伴随着开发和运维人员的误操作,比如 DROP TABLE / DATABASE,这类 DDL 语句不具有可操作的回滚特性,而导致数据丢失。
Recycle Bin 管理接口
Recycle Bin 提供了两个管理接口,分别是:
展示回收站中所有临时保存的表:
*注:左右滑动阅览
mysql> call dbms_recycle.show_tables();
+-----------------+---------------+---------------+--------------+---------------------+---------------------+
| SCHEMA | TABLE | ORIGIN_SCHEMA | ORIGIN_TABLE | RECYCLED_TIME | PURGE_TIME |
+-----------------+---------------+---------------+--------------+---------------------+---------------------+
| __recycle_bin__ | __innodb_1063 | product_db | t1 | 2019-08-08 11:01:46 | 2019-08-15 11:01:46 |
| __recycle_bin__ | __innodb_1064 | product_db | t2 | 2019-08-08 11:01:46 | 2019-08-15 11:01:46 |
| __recycle_bin__ | __innodb_1065 | product_db | parent | 2019-08-08 11:01:46 | 2019-08-15 11:01:46 |
| __recycle_bin__ | __innodb_1066 | product_db | child | 2019-08-08 11:01:46 | 2019-08-15 11:01:46 |
+-----------------+---------------+---------------+--------------+---------------------+---------------------+
4 rows in set (0.00 sec)
-- Columns 解释:
🔸SCHEMA
回收站的 schema
🔸TABLE
进入回收站后的表名
🔸ORIGIN_SCHEMA
原始表的 schema
🔸ORIGIN_TABLE
原始表的表名
🔸RECYCLED_TIME
回收时间
🔸PURGE_TIME
未来被清理掉的时间
(*左右滑动阅览)
mysql> call dbms_recycle.purge_table("__innodb_1063");
Query OK, 0 rows affected (0.01 sec)
清理掉回收站中的"__innodb_1063" 表
Recycle Bin 参数
Recycle Bin 一共设计了 5 个参数,分别是:
recycle_bin
-- 是否打开回收功能, session + global 级别。
recycle_bin_retention
-- 回收站保留最长时间是多少,单位是seconds,默认是一周。
recycle_scheduler
-- 是否打开回收站的异步清理任务线程
recycle_scheduler_interval
-- 回收站异步清理线程的轮询间隔,单位是seconds, 默认是30s。
recycle_scheduler_purge_table_print
-- 是否打印异步清理现场工作的详细日志
Recycle Bin 设计
1. 回收机制
Recycle schema 和权限控制
mysql> show databases;
+--------------------+
| Database |
+--------------------+
| __recycle_bin__ |
| information_schema |
| mysql |
| performance_schema |
| sys |
+--------------------+
6 rows in set (0.00 sec)
2. 权限控制
mysql> drop table __recycle_bin__.__innodb_1064;
ERROR 1044 (42000): Access denied for user 'b1'@'%' to database '__recycle_bin__'
recycled table 权限:
比如:
mysql> call dbms_recycle.purge_table("__innodb_1064");
ERROR 1142 (42000): DROP command denied to user 'b1'@'localhost' for table '__innodb_1064'
-- Grant 回收站权限
mysql> grant drop on __recycle_bin__.__innodb_1064 to b1@'%';
Query OK, 0 rows affected (0.00 sec)
-- Grant 原表权限
mysql> grant drop on product_db.t2 to b1@'%';
Query OK, 0 rows affected (0.00 sec)
mysql> call dbms_recycle.purge_table("__innodb_1064");
Query OK, 0 rows affected (0.01 sec)
Recycled table 命名规则
"__" + Storge Engine + SE private id
Recycled table 关联对象
在回收表的过程中,需要处理表的相关对象,其处理的原则是:
CREATE TABLE parent (
id INT NOT NULL,
PRIMARY KEY (id)
) ENGINE=INNODB;
CREATE TABLE child (
id INT,
parent_id INT,
self_id INT,
INDEX id_ind (id),
INDEX par_ind (parent_id),
INDEX sel_ind (self_id),
FOREIGN KEY (self_id) REFERENCES child(id),
FOREIGN KEY (parent_id) REFERENCES parent(id) ON DELETE CASCADE
) ENGINE=INNODB;
CREATE TABLE log(id INT);
delimiter //
CREATE TRIGGER trigger_child
before INSERT ON child FOR EACH ROW
BEGIN
INSERT INTO log value(1);
END//
delimiter ;
CREATE VIEW view_child AS SELECT * FROM child;
1. 删除表 child;
mysql> drop table child;
Query OK, 0 rows affected (0.01 sec)
2. 查看回收站,及 child 表在回收站的结构
mysql> call dbms_recycle.show_tables();
+-----------------+---------------+---------------+--------------+---------------------+---------------------+
| SCHEMA | TABLE | ORIGIN_SCHEMA | ORIGIN_TABLE | RECYCLED_TIME | PURGE_TIME |
+-----------------+---------------+---------------+--------------+---------------------+---------------------+
| __recycle_bin__ | __innodb_1068 | test | child | 2019-08-08 12:32:48 | 2019-08-15 12:32:48 |
+-----------------+---------------+---------------+--------------+---------------------+---------------------+
mysql> show create table __recycle_bin__.__innodb_1068\G
*************************** 1. row ***************************
Table: __innodb_1068
Create Table: CREATE TABLE `__innodb_1068` (
`id` int(11) DEFAULT NULL,
`parent_id` int(11) DEFAULT NULL,
`self_id` int(11) DEFAULT NULL,
KEY `id_ind` (`id`),
KEY `par_ind` (`parent_id`),
KEY `sel_ind` (`self_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8
-- 相关的 Foreign key 已经全部删除。
3. 查看相关trigger。
mysql> show create trigger trigger_child;
ERROR 1360 (HY000): Trigger does not exist
-- 相关的trigger已经全部删除。
4. 查看相关view。
mysql> show create view view_child\G
*************************** 1. row ***************************
View: view_child
Create View: CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `view_child` AS select `child`.`id` AS `id`,`child`.`parent_id` AS `parent_id`,`child`.`self_id` AS `self_id` from `child`
character_set_client: utf8mb4
collation_connection: utf8mb4_0900_ai_ci
1 row in set, 1 warning (0.01 sec)
mysql> show warnings;
+---------+------+-----------------------------------------------------------------------------------------------------------------------------------+
| Level | Code | Message |
+---------+------+-----------------------------------------------------------------------------------------------------------------------------------+
| Warning | 1356 | View 'test.view_child' references invalid table(s) or column(s) or function(s) or definer/invoker of view lack rights to use them |
+---------+------+-----------------------------------------------------------------------------------------------------------------------------------+
1 row in set (0.00 sec)
-- 相关的view 已经失效。
Master-slave 独立回收
在 master - slave 结构中, 是否回收,或回收站保留的周期,都是实例本身的设置,不会影响到 binlog 复制到的节点上,所以,我们可以在 master 节点上设置回收,保留 7 天周期,在slave 节点上,设置回收,保留14天周期。
--recycle_bin = on
--recycle_bin_retention = 7 * 24 * 60 * 60
master节点上,回收站保留 7 天
slave:
--recycle_bin = on
--recycle_bin_retention = 14 * 24 * 60 * 60
slave 节点上,回收站保留 14 天
当 recycle scheduler 异步线程 purge 回收站的表时候,如果遇到大表,那么将会启动大表异步删除逻辑,相关参数如下:
(*左右滑动阅览)
INNODB_DATA_FILE_PURGE: Whether enable the async purge strategy
INNODB_DATA_FILE_PURGE_IMMEDIATE: Unlink data file rather than truncate
INNODB_DATA_FILE_PURGE_ALL_AT_SHUTDOWN: Cleanup all when normal shutdown
INNODB_DATA_FILE_PURGE_DIR: Temporary file directory
INNODB_DATA_FILE_PURGE_INTERVAL: Purge time interval (by milliseconds)
INNODB_DATA_FILE_PURGE_MAX_SIZE: Purge max size every time (by MB)
INNODB_PRINT_DATA_FILE_PURGE_PROCESS: Print the process of file purge worker
set global INNODB_DATA_FILE_PURGE = on;
set global INNODB_DATA_FILE_PURGE_INTERVAL = 100;
set global INNODB_DATA_FILE_PURGE_MAX_SIZE = 128;
每 100ms,删除 128MB 大小。
mysql> select * from information_schema.innodb_purge_files;
+--------+---------------------+--------------------------------------+---------------+------------------------+--------------+
| log_id | start_time | original_path | original_size | temporary_path | current_size |
+--------+---------------------+--------------------------------------+---------------+------------------------+--------------+
| 36 | 2019-08-08 12:06:38 | ./__recycle_bin__/__innodb_1064.ibd | 37748736 | purge/#FP_1557846107_1 | 20971520 |
+--------+---------------------+--------------------------------------+---------------+------------------------+--------------+
注意事项
1,回收站跨文件系统
如果你的回收站目录 "_recycle__bin"_ 和回收的表跨了文件系统,那么drop table,将会搬迁表空间文件,耗时较长。
2,General tablespace
general tablespace 会存在多个表共享同一个表空间的情况, 当回收其中一张表的时候,不会搬迁相关的表空间文件,如果master 和 slave 设置的回收保留时间不同,那么就会存在在某一个时间点,主备间的这个general tablespace中的表数量不相等的情况。
阿里巴巴数据库技术
微信:alibabadba
分享数据库前沿
解构实战干货
长按二维码关注