MySQL 删库到恢复
1 实验介绍
IP | 作用 | 环境 |
2 数据写入
mysql> create database backup;
Query OK, 1 row affected (0.06 sec)
mysql> use backup;
Database changed
mysql> CREATE TABLE `number` (
`id` int(11) NOT NULL AUTO_INCREMENT COMMENT '主键',
`updatetime` timestamp NOT NULL DEFAULT '1970-01-02 00:00:00',
PRIMARY KEY (`id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
Query OK, 0 rows affected, 1 warning (0.85 sec)
mysql> insert into number(updatetime) values(now());Query OK, 1 row affected (0.04 sec)
mysql> select * from number; +----+---------------------+ | id | updatetime | +----+---------------------+ | 1 | 2021-07-02 11:01:52 | +----+---------------------+ 1 row in set (0.00 sec)
3 全量备份
mysql> CREATE USER `u_xtrabackup`@`localhost` IDENTIFIED WITH MYSQL_NATIVE_PASSWORD BY 'Ijnbgt@123';
Query OK, 0 rows affected (0.02 sec)
mysql> GRANT SELECT, RELOAD, PROCESS, SUPER, LOCK TABLES,BACKUP_ADMIN ON *.* TO `u_xtrabackup`@`localhost`;
Query OK, 0 rows affected, 1 warning (0.05 sec)
xtrabackup --defaults-file=/data/mysql/conf/my.cnf -uu_xtrabackup -p'Ijnbgt@123' --backup --stream=xbstream --target-dir=./ >/data/backup/xtrabackup.xbstream
scp /data/backup/xtrabackup.xbstream 192.168.150.123:/data/backup/recover/
4 模拟增量数据写入
mysql> insert into number(updatetime) values(now());
Query OK, 1 row affected (0.05 sec)
mysql> select * from number;
+----+---------------------+
| id | updatetime |
+----+---------------------+
| 1 | 2021-07-02 15:06:04 |
| 2 | 2021-07-02 15:08:05 |
+----+---------------------+
2 rows in set (0.00 sec)
5 模拟误操作
mysql> drop database backup;Query OK, 1 row affected (0.07 sec)
6 恢复全量备份的数据
mysqladmin -S /tmp/mysql.sock -p shutdown
rm /data/mysql/data/* -rfrm /data/mysql/binlog/* -rf
cd /data/backup/recover/xbstream -x < xtrabackup.xbstreamxtrabackup --prepare --target-dir=./xtrabackup --defaults-file=/data/mysql/conf/my.cnf --copy-back --target-dir=./
chown -R mysql.mysql /data/mysql/
[mysqld]skip-slave-start = 1relay_log_info_repository=fileserver-id = 150123
nohup /usr/local/mysql/bin/mysqld_safe --defaults-file=/data/mysql/conf/my.cnf --user=mysql &
mysql> select * from backup.number; +----+---------------------+ | id | updatetime | +----+---------------------+ | 1 | 2021-07-02 15:06:04 | +----+---------------------+ 1 row in set (0.00 sec)
7 恢复增量数据
mysql> reset master;Query OK, 0 rows affected (0.01 sec)
mysql> set global gtid_purged='10242962-da16-11eb-8ea5-fa163e1c875d:1-22';Query OK, 0 rows affected (0.00 sec)
mysql> change master to master_host='192.168.1.1';Query OK, 0 rows affected (0.04 sec)
mysqladmin -S /tmp/mysql.sock -p shutdown
rm /data/mysql/data/relay-log.info -rf
rm /data/mysql/binlog/mysql-relay-bin.* -rf
scp /data/mysql/binlog/mysql-bin.000008 192.168.150.123:/data/mysql/binlog
cd /data/mysql/binlog/rename mysql-bin mysql-relay-bin mysql-bin.000008
ls /data/mysql/binlog/mysql-relay-bin.0* >mysql-relay-bin.index
# cat mysql-relay-bin.index/data/mysql/binlog/mysql-relay-bin.000008
chown -R mysql.mysql /data/mysql/binlog
nohup /usr/local/mysql/bin/mysqld_safe --defaults-file=/data/mysql/conf/my.cnf --user=mysql &
执行 change master:
change master to relay_log_file='mysql-relay-bin.000008',relay_log_pos=196;
(这个位点来源于 备份 xtrabackup_binlog_info)
mysqlbinlog mysql-relay-bin.000008 --base64-output=decode-rows -v >/data/0702.sql
解析 Binlog 的结果文件 /data/0702.sql 内容如下:
/*!50530 SET @@SESSION.PSEUDO_SLAVE_MODE=1*/;/*!50003 SET @OLD_COMPLETION_TYPE=@@COMPLETION_TYPE,COMPLETION_TYPE=0*/;DELIMITER /*!*/;# at 4#210702 15:06:36 server id 6666 end_log_pos 125 CRC32 0x5ebbec6f Start: binlog v 4, server v 8.0.25 created 210702 15:06:36# Warning: this binlog is either in use or was not closed properly.# at 125#210702 15:06:36 server id 6666 end_log_pos 196 CRC32 0x9ed4ca96 Previous-GTIDs# 10242962-da16-11eb-8ea5-fa163e1c875d:1-22# at 196#210702 15:08:05 server id 6666 end_log_pos 275 CRC32 0x70a004b6 GTIDlast_committed=0sequence_number=1rbr_only=yesoriginal_committed_timestamp=162520968587783immediate_commit_timestamp=1625209685877833transaction_length=363/*!50718 SET TRANSACTION ISOLATION LEVEL READ COMMITTED*//*!*/;# original_commit_timestamp=1625209685877833 (2021-07-02 15:08:05.877833 CST)# immediate_commit_timestamp=1625209685877833 (2021-07-02 15:08:05.877833 CST)/*!80001 SET @@session.original_commit_timestamp=1625209685877833*//*!*/;/*!80014 SET @@session.original_server_version=80025*//*!*/;/*!80014 SET @@session.immediate_server_version=80025*//*!*/;SET @@SESSION.GTID_NEXT= '10242962-da16-11eb-8ea5-fa163e1c875d:23'/*!*/;# at 275#210702 15:08:05 server id 6666 end_log_pos 360 CRC32 0xbf114777 Querythread_id=18exec_time=0error_code=0SET TIMESTAMP=1625209685/*!*/;SET @@session.pseudo_thread_id=18/*!*/;SET @@session.foreign_key_checks=1, @@session.sql_auto_is_null=0, @@session.unique_checks=1, @@session.autocommit=1/*!*/;SET @@session.sql_mode=1168113696/*!*/;SET @@session.auto_increment_increment=1, @@session.auto_increment_offset=1/*!*/;/*!\C utf8mb4 *//*!*/;SET @@session.character_set_client=255,@@session.collation_connection=255,@@session.collation_server=255/*!*/;SET @@session.time_zone='SYSTEM'/*!*/;SET @@session.lc_time_names=0/*!*/;SET @@session.collation_database=DEFAULT/*!*/;/*!80011 SET @@session.default_collation_for_utf8mb4=255*//*!*/;BEGIN/*!*/;# at 360# at 428#210702 15:08:05 server id 6666 end_log_pos 484 CRC32 0x5fdcc2f8 Table_map: `backup`.`number` mapped to number 179# at 484#210702 15:08:05 server id 6666 end_log_pos 528 CRC32 0x954f3089 Write_rows: table id 179 flags: STMT_END_F### INSERT INTO `backup`.`number`### SET### @1=2### @2=1625209685# at 528#210702 15:08:05 server id 6666 end_log_pos 559 CRC32 0x3f3da548 Xid = 162COMMIT/*!*/;# at 559#210702 15:08:38 server id 6666 end_log_pos 636 CRC32 0x2f89ff88 GTIDlast_committed=1sequence_number=2rbr_only=nooriginal_committed_timestamp=162520971877835immediate_commit_timestamp=1625209718778358transaction_length=187# original_commit_timestamp=1625209718778358 (2021-07-02 15:08:38.778358 CST)# immediate_commit_timestamp=1625209718778358 (2021-07-02 15:08:38.778358 CST)/*!80001 SET @@session.original_commit_timestamp=1625209718778358*//*!*/;/*!80014 SET @@session.original_server_version=80025*//*!*/;/*!80014 SET @@session.immediate_server_version=80025*//*!*/;SET @@SESSION.GTID_NEXT= '10242962-da16-11eb-8ea5-fa163e1c875d:24'/*!*/;# at 636#210702 15:08:38 server id 6666 end_log_pos 746 CRC32 0xb477763c Querythread_id=18exec_time=0error_code=0Xid = 164SET TIMESTAMP=1625209718/*!*/;drop database backup/*!*/;SET @@SESSION.GTID_NEXT= 'AUTOMATIC' /* added by mysqlbinlog */ /*!*/;DELIMITER ;# End of log file/*!50003 SET COMPLETION_TYPE=@OLD_COMPLETION_TYPE*/;/*!50530 SET @@SESSION.PSEUDO_SLAVE_MODE=0*/;
start slave sql_thread until sql_before_gtids='10242962-da16-11eb-8ea5-fa163e1c875d:24';
该 gtid 值取至上面解析的 Binlog,为误操作这个事务的 GTID。
mysql> select * from backup.number; +----+---------------------+ | id | updatetime | +----+---------------------+ | 1 | 2021-07-02 15:06:04 | | 2 | 2021-07-02 15:08:05 | +----+---------------------+ 2 rows in set (0.00 sec)
发表评论