备注:测试数据库版本为MySQL 8.0
这个blog我们来聊聊MySQL 的主从GTID复制
概述
GTID复制又叫全局事物ID(global transaction ID),是一个已提交事物的编号,并且是一个全局唯一的编号,MYSQL5.6版本之后在主从复制类型上新增了GTID复制。
GTID是由server_uuid和事物id组成的,即GTID=servier_uuid:transacton_id。Server_uuid是在数据库启动过程中自动生成的,每台机器的server-uuid不一样。UUID存放在数据目录的auto.cnf文件下。而trasaciton_id就是事物提交时由系统顺序分配的一个不会重复的序列号。
GTID存在的价值:
1、GTID使用master_auto_position=1 代替了基于binlog和position号的主从复制搭建的方式,更便于主从复制的搭建。
2、GTID可以知道事务在最开始是在哪个实例上提交的。
3、GTID方便实现主从之间的failover,再也不用不断的去找position和binlog。
GTID搭建模式:
GTID不需要传统的binlog和position号了,而是在从库”change master to”时使用”master_auto_position=1”的方式搭建,这就让操作变得更加方便和可靠了。
GTID使用限制条件
GTID复制是针对事物,一个gtid对于一个事务。
1、 不能使用create table table_name select * from table_name。
2、 在一个事务中即包含事务表的操作,又包含非事物表。
3、 不支持create temporary table or drop temporary table语句操作。
4、 使用GTID复制从库调过错误,不支持执行slave_skip_errors。
一.传统复制切换成GTID过程
主从数据库服务器同时修改以下参数:
-- error log 不会出现警告信息,如果有,需要先修复,才能继续后面操作。
set global enforce_gtid_consistency=warn;
set global enforce_gtid_consistency=on;
set global gtid_mode=off_permissive;
set global gtid_mode=on_permissive;
mysql> set global enforce_gtid_consistency=warn;
Query OK, 0 rows affected (0.00 sec)
mysql> set global enforce_gtid_consistency=on;
Query OK, 0 rows affected (0.00 sec)
mysql> set global gtid_mode=off_permissive;
Query OK, 0 rows affected (0.01 sec)
mysql> set global gtid_mode=on_permissive;
Query OK, 0 rows affected (0.01 sec)
确认从库没等待的事务:
0代表没有等待的事务。
mysql> show global status like '%ongoing%';
+-------------------------------------+-------+
| Variable_name | Value |
+-------------------------------------+-------+
| Ongoing_anonymous_transaction_count | 0 |
+-------------------------------------+-------+
1 row in set (0.00 sec)
主从库上同时设置gtid_mode=on;
set global gtid_mode=OFF_PERMISSIVE;
set global gtid_mode=ON_PERMISSIVE;
set global enforce_gtid_consistency=on;
set global gtid_mode=on;
show variables like '%gtid%';
mysql> set global gtid_mode=OFF_PERMISSIVE;
Query OK, 0 rows affected (0.00 sec)
mysql> set global gtid_mode=ON_PERMISSIVE;
Query OK, 0 rows affected (0.01 sec)
mysql> set global gtid_mode=ON;
ERROR 3111 (HY000): SET @@GLOBAL.GTID_MODE = ON is not allowed because ENFORCE_GTID_CONSISTENCY is not ON.
mysql> set global enforce_gtid_consistency=on;
Query OK, 0 rows affected (0.01 sec)
mysql> set global gtid_mode=ON;
Query OK, 0 rows affected (0.01 sec)
mysql> show variables like '%gtid%';
+----------------------------------+-----------+
| Variable_name | Value |
+----------------------------------+-----------+
| binlog_gtid_simple_recovery | ON |
| enforce_gtid_consistency | ON |
| gtid_executed | |
| gtid_executed_compression_period | 1000 |
| gtid_mode | ON |
| gtid_next | AUTOMATIC |
| gtid_owned | |
| gtid_purged | |
| session_track_gtids | OFF |
+----------------------------------+-----------+
9 rows in set (0.02 sec)
把传统复制模式改为(GTID)复制
stop slave;
change master to master_auto_position=1;
start slave;
show slave status \G
mysql> stop slave;
Query OK, 0 rows affected (0.01 sec)
mysql> change master to master_auto_position=1;
Query OK, 0 rows affected (0.00 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: 10.31.1.112
Master_User: repl
Master_Port: 3306
Connect_Retry: 60
Master_Log_File: binlog.000017
Read_Master_Log_Pos: 156
Relay_Log_File: ipctest-relay-bin.000003
Relay_Log_Pos: 365
Relay_Master_Log_File: binlog.000017
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: 156
Relay_Log_Space: 576
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: 08260f93-cbe5-11ea-bd0d-000c293fa60d
Master_Info_File: mysql.slave_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: 16186d18-cbe5-11ea-8c79-000c297ccd64:1
Auto_Position: 1
Replicate_Rewrite_DB:
Channel_Name:
Master_TLS_Version:
Master_public_key_path:
Get_master_public_key: 0
Network_Namespace:
1 row in set (0.00 sec)
mysql>
二.GTID复制与传统复制的切换
主库
mysql> show master status;
+---------------+----------+--------------+------------------+------------------------------------------+
| File | Position | Binlog_Do_DB | Binlog_Ignore_DB | Executed_Gtid_Set |
+---------------+----------+--------------+------------------+------------------------------------------+
| binlog.000017 | 648 | | | 08260f93-cbe5-11ea-bd0d-000c293fa60d:1-2 |
+---------------+----------+--------------+------------------+------------------------------------------+
1 row in set (0.00 sec)
主从同时执行
把gtid_mode=off和enforce_gtid_consistency=off写入主从库配置文件中。重启后可以继续生效,并进行测试。
set global gtid_mode='on_permissive';
set global gtid_mode='off_permissive';
set global enforce_gtid_consistency=off;
set global gtid_mode=off;
从库切换操作:
stop slave;
change master to master_auto_position=0;
change master to
master_host='10.31.1.112',
master_user='repl',
master_password='test',
MASTER_LOG_FILE='binlog.000017',
MASTER_LOG_POS=648 ,
get_master_public_key=1;
start slave;
show slave status \G