一、环境说明:
系统和软件包说明:
3台阿里ECS 系统centos7.6 x86_64位最小化安装
MySQL的版本为MySQL5.7.22 二进制包安装
percona-xtrabackup 安装包为:
percona-xtrabackup-24-2.4.14-1.el7.x86_64.rpm
服务器主机名:
tidb06 172.16.0.247
tidb05 172.16.0.246
tidb04 172.16.0.197
架构说明:
MySQL5.7.22多源复制架构
主库tidb06上的test001,test003库同步到 从库 tidb04
主库tidb05上的test002,test004库同步到 从库 tidb04
二、tidb06到tidb04多源复制部署操作过程如下:
2.1、tidb06 服务器安装percona-xtrabackup-24-2.4.14操作:
下载包
percona-xtrabackup-24-2.4.14 安装
yum localinstall percona-xtrabackup-24-2.4.14-1.el7.x86_64.rpm
2.2、授权innobackupex备份用户:
GRANT RELOAD, PROCESS, SUPER, LOCK TABLES, REPLICATION CLIENT ON *.* TO ‘backupuser‘@‘localhost‘ identified by ‘123456‘;flush privileges;
2.3 备份tidb06服务器上需要复制的库表结构:
mysqldump -uroot -p‘123456‘ --no-data -F -B test001 test003 >test.sql
特殊说明下:
-F参数此处的作用是切换到下一个binlog文件。
此处为何建议备份表结构时要加-F 参数切换binlog文件呢?
原因:给一直运行的主库添加新的从库时,由于不太清楚主库之前都做了什么操作,有无记录binlog文件也不是很清楚。所以说在配置新的slave从库之前,最好是切换下binlog文件。让后面在配置slave复制时,指定最新的binlog文件和pos位置点,这样的话可以避免在配置主从时,从库报错。
本次演示环境执行的是下面的命令,并没有加—F参数切换binglog文件:
mysqldump -uroot -p‘123456‘ --no-data -B test001 test003 >test.sql
2.4 构造tidb06服务器上需要复制的表的禁用和开启表空间的sql:
mysql -sse "select concat(‘ALTER TABLE ‘,TABLE_SCHEMA,‘.‘,TABLE_NAME,‘ DISCARD TABLESPACE;‘) from information_schema.tables where TABLE_SCHEMA=‘test001‘" >> discard_tbs.sql
mysql -sse "select concat(‘ALTER TABLE ‘,TABLE_SCHEMA,‘.‘,TABLE_NAME,‘ DISCARD TABLESPACE;‘) from information_schema.tables where TABLE_SCHEMA=‘test003‘" >> discard_tbs.sql
mysql -sse "select concat(‘ALTER TABLE ‘,TABLE_SCHEMA,‘.‘,TABLE_NAME,‘ IMPORT TABLESPACE;‘) from information_schema.tables where TABLE_SCHEMA=‘test001‘" >> import_tbs.sql
mysql -sse "select concat(‘ALTER TABLE ‘,TABLE_SCHEMA,‘.‘,TABLE_NAME,‘ IMPORT TABLESPACE;‘) from information_schema.tables where TABLE_SCHEMA=‘test003‘" >> import_tbs.sql
2.5、innobackupex 备份的tidb06上的需要配置同步的库:
[root@tidb06 backup]# innobackupex --defaults-file=/etc/my.cnf -ubackupuser -p123456 -S /tmp/mysql.sock --databases=/tmp/data2.txt --no-timestamp /data1/backup/db_3306_`date +%Y%m%d`
/tmp/data2.txt文件说明:
在文件 /tmp/data2.txt 中指定 需要备份的tidb06上的库名称列表,特别要注意/tmp/data2.txt 文件每行结尾不能出现空格
[root@tidb06 ~]# cat /tmp/data2.txt
test001
test003
2.6、把innobackup备份的文件传输到tidb04服务器上:
[root@tidb06 backup]# scp -rp db_3306_20210605 root@172.16.0.197:/data/soft/
[root@tidb04 soft]# innobackupex --apply-log --export /data/soft/db_3306_20210605/
特殊说明:
--apply-log 和 --apply-log-only区别和作用:
参考地址:
https://mp.weixin.qq.com/s/yJ_zkGkSOLJglJa395OdQA
##export执行完后sbtest库下备份文件如下所示
##exp结尾的文件为Percona针对Percona XtraDB做export的配置文件
##cfg结尾的文件为Percona针对MySQL可传输表空间export的配置文件
举例列出下test003下的文件名称:
[root@tidb04 ~]# ll /data/soft/db_3306_20210605/test003/
total 642296
-rw-r--r-- 1 root root 2576 Jun 5 08:40 b_lease.cfg
-rw-r----- 1 root root 16384 Jun 5 08:40 b_lease.exp
-rw-r----- 1 root root 10362 Jun 5 08:38 b_lease.frm
-rw-r----- 1 root root 67108864 Jun 5 08:38 b_lease.ibd
-rw-r----- 1 root root 67 Jun 5 08:38 db.opt
-rw-r--r-- 1 root root 1901 Jun 5 08:40 sheet.cfg
-rw-r----- 1 root root 16384 Jun 5 08:40 sheet.exp
-rw-r----- 1 root root 25964 Jun 5 08:38 sheet.frm
-rw-r----- 1 root root 98304 Jun 5 08:38 sheet.ibd
-rw-r--r-- 1 root root 1624 Jun 5 08:40 s_stock_device_finance_201712.cfg
-rw-r----- 1 root root 16384 Jun 5 08:40 s_stock_device_finance_201712.exp
-rw-r----- 1 root root 9268 Jun 5 08:38 s_stock_device_finance_201712.frm
-rw-r----- 1 root root 15728640 Jun 5 08:38 s_stock_device_finance_201712.ibd
-rw-r--r-- 1 root root 2458 Jun 5 08:40 t_reclassify.cfg
-rw-r----- 1 root root 16384 Jun 5 08:40 t_reclassify.exp
-rw-r----- 1 root root 10291 Jun 5 08:38 t_reclassify.frm
-rw-r----- 1 root root 574619648 Jun 5 08:38 t_reclassify.ibd
2.7、导入tidb06上的需要同步的库下面所有的表结构sql:
root@tidb04 08:49: [test001]> source /root/test.sql
禁用刚才tidb04上的创建的表的表空间:
ALTER TABLE test001.b_lease DISCARD TABLESPACE;
ALTER TABLE test001.s_stock_device_finance_201712_copy1 DISCARD TABLESPACE;
ALTER TABLE test001.s_stock_device_finance_201805_copy1 DISCARD TABLESPACE;
ALTER TABLE test001.t_assets_invoice_sn DISCARD TABLESPACE;
ALTER TABLE test001.t_customer_pool DISCARD TABLESPACE;
ALTER TABLE test001.t_reclassify_3year_bak DISCARD TABLESPACE;
ALTER TABLE test003.b_lease DISCARD TABLESPACE;
ALTER TABLE test003.s_stock_device_finance_201712 DISCARD TABLESPACE;
ALTER TABLE test003.sheet DISCARD TABLESPACE;
ALTER TABLE test003.t_reclassify DISCARD TABLESPACE;
2.8、复制cfg和ibd文件到tidb04库test001和test003目录下并授权MySQL权限:
复制 innobackupex备份tidb06的test001和test003下的表cfg和ibd文件:到tidb04库的test001和test003目录下
[root@tidb04 test001]# pwd
/data/soft/db_3306_20210605/test001
[root@tidb04 test001]# cp *.cfg /data1/mysql/data/test001/
[root@tidb04 test001]# cp *.ibd /data1/mysql/data/test001/
[root@tidb04 test003]# pwd
/data/soft/db_3306_20210605/test003
[root@tidb04 test003]# cp *.cfg /data1/mysql/data/test003/
[root@tidb04 test003]# cp *.ibd /data1/mysql/data/test003/
授权mysql权限:
[root@tidb04 test001]# chown -R mysql.mysql *
[root@tidb04 test003]# chown -R mysql.mysql *
2.9、导入tidb06上的需要同步库test001和test003下面所有表的表空间:
ALTER TABLE test001.b_lease IMPORT TABLESPACE;
ALTER TABLE test001.s_stock_device_finance_201712_copy1 IMPORT TABLESPACE;
ALTER TABLE test001.s_stock_device_finance_201805_copy1 IMPORT TABLESPACE;
ALTER TABLE test001.t_assets_invoice_sn IMPORT TABLESPACE;
ALTER TABLE test001.t_customer_pool IMPORT TABLESPACE;
ALTER TABLE test001.t_reclassify_3year_bak IMPORT TABLESPACE;
ALTER TABLE test003.b_lease IMPORT TABLESPACE;
ALTER TABLE test003.s_stock_device_finance_201712 IMPORT TABLESPACE;
ALTER TABLE test003.sheet IMPORT TABLESPACE;
ALTER TABLE test003.t_reclassify IMPORT TABLESPACE;
2.10、校验下恢复的库:
[root@tidb04 data]# mysqlcheck -c test001
test001.b_lease OK
test001.s_stock_device_finance_201712_copy1 OK
test001.s_stock_device_finance_201805_copy1 OK
test001.t_assets_invoice_sn OK
test001.t_customer_pool OK
test001.t_reclassify_3year_bak OK
[root@tidb04 data]# mysqlcheck -c test003
test003.b_lease OK
test003.s_stock_device_finance_201712 OK
test003.sheet OK
test003.t_reclassify OK
2.11、配置从库复制
从xtrabackup的备份文件中 找到需要配置主从复制的binglog文件和pos位置点:
[root@tidb04 db_3306_20210605]# cat xtrabackup_binlog_pos_innodb
mysql-bin.000002 66849324
tidb06服务器上创建复制账户:rep
grant replication slave ON *.* TO ‘rep‘@‘172.16.0.197‘ identified by ‘123456‘;flush privileges;
tidb04服务器上配置多源复制tidb06:
mysql> CHANGE MASTER TO
MASTER_HOST=‘172.16.0.247‘,
MASTER_USER=‘rep‘,
MASTER_PORT=3306,
MASTER_PASSWORD=‘123456‘,
MASTER_LOG_FILE=‘mysql-bin.000002‘,
MASTER_LOG_POS=66849324 FOR CHANNEL ‘tidb06‘;
mysql> CHANGE REPLICATION FILTER REPLICATE_WILD_DO_TABLE=(‘test001.%‘,‘test003.%‘);
mysql> START SLAVE FOR CHANNEL ‘tidb06‘;
mysql> SHOW SLAVE STATUS FOR CHANNEL ‘tidb06‘\G;
2.12 tidb04 slave库配置过程中报错以及解决:
| Worker 1 failed executing transaction ‘ANONYMOUS‘ at master log mysql-bin.000002, end_log_pos 66849961; Error ‘Tablespace is missing for table `test003`.`s_stock_device_finance_201712`.‘ on query. Default database: ‘test003‘. Query: ‘ALTER TABLE test003.s_stock_device_finance_201712 import TABLESPACE‘ | 2021-06-05 09:09:39
Last_Errno: 1812报错分析和解决方法:
由于之前tidb06主库上test003
.s_stock_device_finance_201712
这个表有 discard tablespace和import tablespace操作。这样的sql是会记录到主库的binlog文件的,导致在部署主从复制时,discard tablespace和import tablespace sql会在从库的slave sql_thread线程上执行一遍。所以才导致上面从库的复制报错
解决方法:
[root@tidb04 ~]# cp /data/soft/db_3306_20210605/test003/s_stock_device_finance_201712.ibd /data1/mysql/data/test003/
[root@tidb04 test003]# pwd
/data1/mysql/data/test003
[root@tidb04 test003]# chown mysql.mysql s_stock_device_finance_201712.ibd
root@tidb04 12:45: [(none)]> start slave for channel ‘tidb06‘;
又出现如下的报错:
Worker 1 failed executing transaction ‘ANONYMOUS‘ at master log mysql-bin.000003, end_log_pos 535; Error ‘Tablespace is missing for table `test003`.`b_lease`.‘ on query. Default database: ‘test003‘. Query: ‘alter table test003.b_lease import tablespace‘ | 2
解决方法同上,解决方法:
[root@tidb04 test003]# cp /data/soft/db_3306_20210605/test003/b_lease.ibd /data1/mysql/data/test003/
[root@tidb04 test003]# pwd
/data1/mysql/data/test003
[root@tidb04 test003]# chown mysql.mysql b_lease.ibd
root@tidb04 12:45: [(none)]> stop slave for channel ‘tidb06‘;
Query OK, 0 rows affected (0.00 sec)
root@tidb04 12:45: [(none)]> start slave for channel ‘tidb06‘;
Query OK, 0 rows affected (0.04 sec)
2.13、到此处多源复制复制通道tidb06 只同步复制test001和test003库配置完成:
[root@tidb04 ~]# mysql -e "SHOW SLAVE STATUS FOR CHANNEL ‘tidb06‘\G"|egrep -i ‘Slave_IO_Running|Slave_SQL_Running|Replicate_Wild_Do_Table|Replicate_Wild_Ignore_Table|Channel_Name‘
Slave_IO_Running: Yes
Slave_SQL_Running: Yes
Replicate_Wild_Do_Table: test001.%,test003.%
Replicate_Wild_Ignore_Table: mysql.%
Slave_SQL_Running_State: Slave has read all relay log; waiting for more updates
Channel_Name: tidb06
三、tidb05 配置多源复制到tidb04
操作步骤和第二步完全一致,所以下面只粘贴具体操作代码。不在详细叙述说明
tidb05 服务器安装percona-xtrabackup-24-2.4.14操作:
percona-xtrabackup-24-2.4.14 安装
yum localinstall percona-xtrabackup-24-2.4.14-1.el7.x86_64.rpm
授权innobackupex备份用户:
GRANT RELOAD, PROCESS, SUPER, LOCK TABLES, REPLICATION CLIENT ON . TO ‘backupuser‘@‘localhost‘ identified by ‘123456‘;flush privileges;
[root@tidb05 ~]# mysqldump -uroot -pEdianyun689 --no-data -B test002 test004 >tidb05.sql
mysql -sse "select concat(‘ALTER TABLE ‘,TABLE_SCHEMA,‘.‘,TABLE_NAME,‘ DISCARD TABLESPACE;‘) from information_schema.tables where TABLE_SCHEMA=‘test002‘" >> discard_tbs.sql
mysql -sse "select concat(‘ALTER TABLE ‘,TABLE_SCHEMA,‘.‘,TABLE_NAME,‘ DISCARD TABLESPACE;‘) from information_schema.tables where TABLE_SCHEMA=‘test004‘" >> discard_tbs.sql
mysql -sse "select concat(‘ALTER TABLE ‘,TABLE_SCHEMA,‘.‘,TABLE_NAME,‘ IMPORT TABLESPACE;‘) from information_schema.tables where TABLE_SCHEMA=‘test002‘" >> import_tbs.sql
mysql -sse "select concat(‘ALTER TABLE ‘,TABLE_SCHEMA,‘.‘,TABLE_NAME,‘ IMPORT TABLESPACE;‘) from information_schema.tables where TABLE_SCHEMA=‘test004‘" >> import_tbs.sql
[root@tidb05 ~]# cat import_tbs.sql
ALTER TABLE test002.t_customer_order_sn IMPORT TABLESPACE;
ALTER TABLE test004.b_lease IMPORT TABLESPACE;
[root@tidb05 ~]# cat discard_tbs.sql
ALTER TABLE test002.t_customer_order_sn DISCARD TABLESPACE;
ALTER TABLE test004.b_lease DISCARD TABLESPACE;
[root@tidb05 backup]# innobackupex --defaults-file=/etc/my.cnf -ubackupuser -p123456 -S /tmp/mysql.sock --databases=/tmp/data2.txt --no-timestamp /data1/backup/db_3306_`date +%Y%m%d`
[root@tidb05 backup]# scp -rp db_3306_20210605 root@172.16.0.197:/data/backup/
root@tidb04 14:03: [test004]> ALTER TABLE test002.t_customer_order_sn DISCARD TABLESPACE;
Query OK, 0 rows affected (0.02 sec)
root@tidb04 14:03: [test004]> ALTER TABLE test004.b_lease DISCARD TABLESPACE;
Query OK, 0 rows affected (0.02 sec)
[root@tidb04 test002]# pwd
/data1/mysql/data/test002
[root@tidb04 test002]# ll
total 16
-rw-r----- 1 mysql mysql 67 Jun 5 14:03 db.opt
-rw-r----- 1 mysql mysql 9485 Jun 5 14:03 t_customer_order_sn.frm
[root@tidb04 test002]# cd /data1/mysql/data/test004/
[root@tidb04 test004]# ll
total 16
-rw-r----- 1 mysql mysql 10362 Jun 5 14:03 b_lease.frm
-rw-r----- 1 mysql mysql 67 Jun 5 14:03 db.opt
[root@tidb04 backup]# innobackupex --apply-log-only --export /data/backup/db_3306_20210605/
特殊说明:
--apply-log 和 --apply-log-only区别和作用:
参考地址:
https://mp.weixin.qq.com/s/yJ_zkGkSOLJglJa395OdQA
[root@tidb04 backup]# cd /data/backup/db_3306_20210605/test002/
[root@tidb04 test002]# cp *.cfg /data1/mysql/data/test002/
cp: cannot stat ‘*.cfg’: No such file or directory
[root@tidb04 test002]# ls
db.opt t_customer_order_sn.frm t_customer_order_sn.ibd
[root@tidb04 test004]# cd /data/backup/db_3306_20210605/test004/
[root@tidb04 test004]# ls
b_lease.frm b_lease.ibd db.opt
root@tidb04 test004]# cp *.ibd /data1/mysql/data/test004/
cd /data1/mysql/data/test002/
chown mysql.mysql *
cd /data1/mysql/data/test004/
chown mysql.mysql *
root@tidb04 14:06: [test004]> ALTER TABLE test002.t_customer_order_sn IMPORT TABLESPACE;
root@tidb04 14:18: [test004]> ALTER TABLE test004.b_lease IMPORT TABLESPACE;
[root@tidb04 db_3306_20210605]# cat /data/backup/db_3306_20210605/xtrabackup_binlog_info
mysql-bin.000005 655
tidb05服务器上创建复制账户:rep
grant replication slave ON *.* TO ‘rep‘@‘172.16.0.197‘ identified by ‘123456‘;flush privileges;
tidb04服务器上配置多源复制tidb05:
mysql> CHANGE MASTER TO
MASTER_HOST=‘172.16.0.246‘,
MASTER_USER=‘rep‘,
MASTER_PORT=3306,
MASTER_PASSWORD=‘123456‘,
MASTER_LOG_FILE=‘mysql-bin.000005‘,
MASTER_LOG_POS=655 FOR CHANNEL ‘tidb05‘;
mysql> CHANGE REPLICATION FILTER REPLICATE_WILD_DO_TABLE=(‘test002.%‘,‘test004.%‘);
root@tidb04 14:25: [test004]> CHANGE REPLICATION FILTER REPLICATE_WILD_DO_TABLE=(‘test002.%‘,‘test004.%‘);
ERROR 3017 (HY000): This operation cannot be performed with a running slave sql thread; run STOP SLAVE SQL_THREAD first
root@tidb04 14:25: [test004]> stop slave sql_thread;
Query OK, 0 rows affected, 1 warning (0.00 sec)
root@tidb04 14:26: [test004]> CHANGE REPLICATION FILTER REPLICATE_WILD_DO_TABLE=(‘test002.%‘,‘test004.%‘);
Query OK, 0 rows affected (0.00 sec)
mysql> START SLAVE FOR CHANNEL ‘tidb05‘;
mysql> SHOW SLAVE STATUS FOR CHANNEL ‘tidb05‘\G;
到此处 tidb04复制tidb05配置完成:
[root@tidb04 ~]# mysql -e "SHOW SLAVE STATUS FOR CHANNEL ‘tidb05‘\G"|egrep -i ‘Slave_IO_Running|Slave_SQL_Running|Replicate_Wild_Do_Table|Replicate_Wild_Ignore_Table|Channel_Name‘
Slave_IO_Running: Yes
Slave_SQL_Running: Yes
Replicate_Wild_Do_Table: test002.%,test004.%
Replicate_Wild_Ignore_Table: mysql.%
Slave_SQL_Running_State: Slave has read all relay log; waiting for more updates
Channel_Name: tidb05
参考文档:
基于Xtrabackup及可传输表空间实现多源数据恢复
https://mp.weixin.qq.com/s/1Y18j1-c7QPhKBM2XLziFg