由于GTID的优势,我们需要将传统基于file-pos的复制更改为基于GTID的复制,如何在线变更成为我们关心的一个点,如下为具体的方法:
目前我们有一个传统复制下的M-S结构:
port 3301 master
port 3302 slave
master上(3301):
[zejin] 3301>select * from t_users;
+----+------+
| id | name |
+----+------+
| 1 | hao |
| 2 | zhou |
+----+------+
rows in set (0.00 sec)
slave上(3302):
[zejin] 3302>show slave status\G
*************************** 1. row ***************************
Slave_IO_State: Waiting for master to send event
Master_Host: 192.168.1.240
Master_User: repl
Master_Port: 3301
Connect_Retry: 60
Master_Log_File: binlog57.000002
Read_Master_Log_Pos: 417
Relay_Log_File: zejin240-relay-bin.000004
Relay_Log_Pos: 628
Relay_Master_Log_File: binlog57.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: 417
Relay_Log_Space: 884
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: 3301
Master_UUID: a97983fc-5a29-11e6-9d28-000c29d4dc3f
Master_Info_File: /home/mysql/I3302/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:
Auto_Position: 0
Replicate_Rewrite_DB:
Channel_Name:
Master_TLS_Version:
row in set (0.00 sec)
[zejin] 3302>select * from t_users;
+----+------+
| id | name |
+----+------+
| 1 | hao |
| 2 | zhou |
+----+------+
rows in set (0.00 sec)
如下为在线变更的具体的操作步骤:
前提:
1.要求所有的mysql版本5.7.6或更高的版本。
2.目前拓扑结构中所有的mysql的gtid_mode的值为off状态。
3.如下的操作步骤都是有序的,不要跳跃着进行。
补充一下全局系统变量GTID_MODE变量值说明:
OFF 新事务是非GTID, Slave只接受不带GTID的事务,传送来GTID的事务会报错
OFF_PERMISSIVE 新事务是非GTID, Slave即接受不带GTID的事务也接受带GTID的事务
ON_PERMISSIVE 新事务是GTID, Slave即接受不带GTID的事务也接受带GTID的事务
ON 新事务是GTID, Slave只接受带GTID的事务
需要注意的是,这几个值的改变是有顺序的,即
off--->OFF_PERMISSIVE--->ON_PERMISSIVE--->ON
不能跳跃执行,会报错。
step1:在每个mysql实例上,将ENFORCE_GTID_CONSISTENCY设置为warning,哪台先执行不影响结果。
[zejin] 3302>set @@global.enforce_gtid_consistency=warn;
Query OK, 0 rows affected (0.00 sec)
[zejin] 3301>set @@global.enforce_gtid_consistency=warn;
Query OK, 0 rows affected (0.00 sec)
注意:执行完这条语句后,如果出现GTID不兼容的语句用法,在错误日志会记录相关信息,那么需要调整应该程序避免不兼容的写法,直到完全没有产生不兼容的语句,可以通过应该程序去排查所有的sql,也可以设置后观察错误日志一段时间,这一步非常重要。
step2:在每个mysql实例上,设置ENFORCE_GTID_CONSISTENCY为ON,哪台先执行不影响结果
在第一步完成后,就可以将值设置为on。
[zejin] 3301>set @@global.enforce_gtid_consistency=on;
Query OK, 0 rows affected (0.03 sec)
[zejin] 3302>set @@global.enforce_gtid_consistency=on;
Query OK, 0 rows affected (0.00 sec)
step3:在每个mysql实例上,设置GTID_MODE为off_permissiv;哪台先执行不影响结果
[zejin] 3301>SET @@GLOBAL.GTID_MODE = OFF_PERMISSIVE;
Query OK, 0 rows affected (0.00 sec)
[zejin] 3302>SET @@GLOBAL.GTID_MODE = OFF_PERMISSIVE;
Query OK, 0 rows affected (0.00 sec)
step4:在每个mysql实例上,设置GTID_MODE为on_permissiv;;哪台先执行不影响结果
[zejin] 3302>SET @@GLOBAL.GTID_MODE = on_permissive;
Query OK, 0 rows affected (0.00 sec)
[zejin] 3301>SET @@GLOBAL.GTID_MODE = on_permissive;
Query OK, 0 rows affected (0.01 sec)
step5:在每个mysql实例上检查变量ONGOING_ANONYMOUS_TRANSACTION_COUNT
[zejin] 3301>SHOW STATUS LIKE 'ONGOING_ANONYMOUS_TRANSACTION_COUNT';
+-------------------------------------+-------+
| Variable_name | Value |
+-------------------------------------+-------+
| Ongoing_anonymous_transaction_count | 0 |
+-------------------------------------+-------+
row in set (0.02 sec)
[zejin] 3302>SHOW STATUS LIKE 'ONGOING_ANONYMOUS_TRANSACTION_COUNT';
+-------------------------------------+-------+
| Variable_name | Value |
+-------------------------------------+-------+
| Ongoing_anonymous_transaction_count | 0 |
+-------------------------------------+-------+
row in set (0.02 sec)
需要等到此变量为0
step6: 确保所有的匿名事务(非GTID事务)已经被完全复制到所有的server上。
检查方法:
在master上:
[zejin] 3301>show master status;
+-----------------+----------+--------------+------------------+-------------------+
| File | Position | Binlog_Do_DB | Binlog_Ignore_DB | Executed_Gtid_Set |
+-----------------+----------+--------------+------------------+-------------------+
| binlog57.000005 | 154 | | | |
+-----------------+----------+--------------+------------------+-------------------+
row in set (0.00 sec)
在slave上,
[zejin] 3302>show slave status\G
*************************** 1. row ***************************
……
Relay_Master_Log_File: binlog57.000005
Exec_Master_Log_Pos: 154
……
检查这两项Relay_Master_Log_File的值大于binlog57.000005,
或者等于Relay_Master_Log_File等于binlog57.000005并且Exec_Master_Log_Pos的值大于等于154即可
或者slave直接用函数:
[zejin] 3302>SELECT MASTER_POS_WAIT('binlog57.000005', 154);
+-----------------------------------------+
| MASTER_POS_WAIT('binlog57.000005', 154) |
+-----------------------------------------+
| 0 |
+-----------------------------------------+
row in set (0.00 sec)
返回结果大于等于0就说明匿名事务已经全部复制完成
step7: 确认整个拓扑结构中已经没有匿名事务的存在,如之前产生的所有匿名事务已经全部被执行完毕,甚至二进制日志中也不要有匿名事务,可以通过flush logs,并让mysql来自动清理旧的二进制日志文件。
step8: 在每个mysql实例上,设置GTID_MODE为on,
[zejin] 3301>SET @@GLOBAL.GTID_MODE = ON;
Query OK, 0 rows affected (0.04 sec)
[zejin] 3302>SET @@GLOBAL.GTID_MODE = ON;
Query OK, 0 rows affected (0.04 sec)
step9: 在每个mysql实例的配置文件my.cnf上,增加gtid-mode=ON
验证:
[zejin] 3301>insert into t_users values(3,'chen');
Query OK, 1 row affected (0.02 sec)
[zejin] 3301>update t_users set name='li' where id=1;
Query OK, 1 row affected (0.03 sec)
Rows matched: 1 Changed: 1 Warnings: 0
[zejin] 3301>select * from t_users;
+----+------+
| id | name |
+----+------+
| 1 | li |
| 2 | zhou |
| 3 | chen |
+----+------+
rows in set (0.00 sec)
[zejin] 3302>show slave status\G
*************************** 1. row ***************************
Slave_IO_State: Waiting for master to send event
Master_Host: 192.168.1.240
Master_User: repl
Master_Port: 3301
Connect_Retry: 60
Master_Log_File: binlog57.000006
Read_Master_Log_Pos: 462
Relay_Log_File: zejin240-relay-bin.000012
Relay_Log_Pos: 673
Relay_Master_Log_File: binlog57.000006
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: 462
Relay_Log_Space: 969
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: 3301
Master_UUID: a97983fc-5a29-11e6-9d28-000c29d4dc3f
Master_Info_File: /home/mysql/I3302/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: a97983fc-5a29-11e6-9d28-000c29d4dc3f:1-2
Executed_Gtid_Set: a97983fc-5a29-11e6-9d28-000c29d4dc3f:1-2
Auto_Position: 0
Replicate_Rewrite_DB:
Channel_Name:
Master_TLS_Version:
row in set (0.00 sec)
至此完成从传统复制到GTID复制的在线转换。
以上这篇MySQL5.7不停业务将传统复制变更为GTID复制的实例就是小编分享给大家的全部内容了,希望能给大家一个参考,也希望大家多多支持脚本之家。
您可能感兴趣的文章:- MySQL GTID全面总结
- MYSQL数据库GTID实现主从复制实现(超级方便)
- MySQL5.6 GTID模式下同步复制报错不能跳过的解决方法
- Mysql GTID Mha配置方法
- 详解MySQL主从复制实战 - 基于GTID的复制
- MySQL 5.6 GTID新特性实践
- MySQL5.6基于GTID的主从复制
- 在MySQL中使用GTIDs复制协议和中断协议的教程
- MySQL是如何实现主备同步
- 关于mysql主备切换canal出现的问题解决
- 基于mysql+mycat搭建稳定高可用集群负载均衡主备复制读写分离操作
- MySQL GTID主备不一致的修复方案