mysql基于GTID复制冷备份导入,定义复制开始位置
目的
新建基于GTID从节点,先从master上备份历史数据过来,导入到从节点,在定义从节点复制开始位置。
对于比较大的库,建议用冷备份 + 自定义复制起点。
env
- master + slave GTID
- mysql 5.7
- container
mysql基于GTID复制方式
//master my.cnf
[mysqld]
server-id = 1
log_bin = mysql-bin
binlog_format = ROW
gtid_mode = ON
enforce_gtid_consistency = ON
# read_only = ON
# relay_log = relay-log
//slave my.cnf
[mysqld]
server-id = 2
log_bin = mysql-bin
binlog_format = ROW
gtid_mode = ON
enforce_gtid_consistency = ON
# read_only = ON # 第一次数据恢复需关闭,恢复后开启从库只读
relay_log = relay-log
1.master
1.1锁表
flush tables with read lock; //锁标仅仅支持可读
show master status;
unlock tables; //表解锁,等开始同步在解锁
1.2查看master 当前gtid值
mysql> show master status\G
*************************** 1. row ***************************
File: mysql-bin.000002
Position: 739
Binlog_Do_DB:
Binlog_Ignore_DB:
Executed_Gtid_Set: 463f21f3-f2b7-11ef-8ad6-0242c0a8d702:1-3
1 row in set (0.00 sec)
当前master gtid: 463f21f3-f2b7-11ef-8ad6-0242c0a8d702:1-3
1.3全库备份
docker exec -it master sh -c "mysqldump -uroot -p321321 --all-databases --set-gtid-purged=OFF >/tmp/all.sql"
docker cp master:/tmp/all.sql /tmp/all.sql
2.slave
2.1恢复冷备份数据
docker cp /tmp/all.sql slave1:/tmp/
docker exec -it slave1 sh -c "mysql -uroot -p321321 </tmp/all.sql"
2.2设置gtid_purged及建立复制
启动slave线程之前使用gtid_purged变量来指定需要跳过的gtid集合。因为要确保gtid_purged必须保证全局变量gtid_executed为空,所以先在slave上执行reset master(注意,不是reset slave),再设置gtid_purged。
# login
docker exec -it slave1 mysql -uroot -p321321
# 为gtid_purged设置空值
reset master;
show variables like 'gtid_purged';
# 设置master当前gtid
set @@global.gtid_purged='463f21f3-f2b7-11ef-8ad6-0242c0a8d702:1-3';
# 建立复制
change master to
master_host='192.168.3.59',
master_port=3306,
master_user='repl',
master_password='321321',
master_auto_position=1;
start slave;
show slave status\G;
操作过程日志
mysql> show master status \G;
*************************** 1. row ***************************
File: mysql-bin.000003
Position: 6271761
Binlog_Do_DB:
Binlog_Ignore_DB:
Executed_Gtid_Set: 38236f3f-f327-11ef-b00b-0242c0a8d702:1-289
1 row in set (0.01 sec)
ERROR:
No query specified
mysql> reset master;
Query OK, 0 rows affected (0.02 sec)
mysql> show master status \G;
*************************** 1. row ***************************
File: mysql-bin.000001
Position: 154
Binlog_Do_DB:
Binlog_Ignore_DB:
Executed_Gtid_Set:
1 row in set (0.00 sec)
ERROR:
No query specified
mysql> show variables like 'gtid_purged';
+---------------+-------+
| Variable_name | Value |
+---------------+-------+
| gtid_purged | |
+---------------+-------+
1 row in set (0.01 sec)
mysql> set @@global.gtid_purged='463f21f3-f2b7-11ef-8ad6-0242c0a8d702:1-3';
Query OK, 0 rows affected (0.01 sec)
mysql> show variables like 'gtid_purged';
+---------------+------------------------------------------+
| Variable_name | Value |
+---------------+------------------------------------------+
| gtid_purged | 463f21f3-f2b7-11ef-8ad6-0242c0a8d702:1-3 |
+---------------+------------------------------------------+
1 row in set (0.00 sec)
mysql> change master to
-> master_host='192.168.3.59',
-> master_port=3306,
-> master_user='repl',
-> master_password='321321',
-> master_auto_position=1;
Query OK, 0 rows affected, 2 warnings (0.04 sec)
mysql> start slave;
Query OK, 0 rows affected (0.01 sec)
mysql> show slave status\G
*************************** 1. row ***************************
Slave_IO_State: Waiting for master to send event
Master_Host: 192.168.3.59
Master_User: repl
Master_Port: 3306
Connect_Retry: 60
Master_Log_File: mysql-bin.000002
Read_Master_Log_Pos: 739
Relay_Log_File: relay-log.000002
Relay_Log_Pos: 414
Relay_Master_Log_File: mysql-bin.000002
Slave_IO_Running: Yes
Slave_SQL_Running: Yes
Replicate_Do_DB:
Replicate_Ignore_DB:
Replicate_Do_Table:
Replicate_Ignore_Table:
Replicate_Wild_Do_Table:
Replicate_Wild_Ignore_Table:
Last_Errno: 0
Last_Error:
Skip_Counter: 0
Exec_Master_Log_Pos: 739
Relay_Log_Space: 615
Until_Condition: None
Until_Log_File:
Until_Log_Pos: 0
Master_SSL_Allowed: No
Master_SSL_CA_File:
Master_SSL_CA_Path:
Master_SSL_Cert:
Master_SSL_Cipher:
Master_SSL_Key:
Seconds_Behind_Master: 0
Master_SSL_Verify_Server_Cert: No
Last_IO_Errno: 0
Last_IO_Error:
Last_SQL_Errno: 0
Last_SQL_Error:
Replicate_Ignore_Server_Ids:
Master_Server_Id: 1
Master_UUID: 463f21f3-f2b7-11ef-8ad6-0242c0a8d702
Master_Info_File: /var/lib/mysql/master.info
SQL_Delay: 0
SQL_Remaining_Delay: NULL
Slave_SQL_Running_State: Slave has read all relay log; waiting for more updates
Master_Retry_Count: 86400
Master_Bind:
Last_IO_Error_Timestamp:
Last_SQL_Error_Timestamp:
Master_SSL_Crl:
Master_SSL_Crlpath:
Retrieved_Gtid_Set:
Executed_Gtid_Set: 463f21f3-f2b7-11ef-8ad6-0242c0a8d702:1-3
Auto_Position: 1
Replicate_Rewrite_DB:
Channel_Name:
Master_TLS_Version:
1 row in set (0.01 sec)
2.3从节点开启read_only及master unlock table
//slave
# 临时设置
SET GLOBAL read_only = ON;
# 配置文件开启从库只读
[mysqld]
read_only = ON
//master
unlock table;