GTID主从复制
环境介绍
master开启gtid,ip为10.10.10.100
slave开启gtid,ip为10.10.10.101
master配置文件
# master
[mysqld]
server-id=1003306
##binlog
log-bin=mysql-bin
sync-binlog=1
innodb_support_xa=1
binlog_format=row
##GTID
gtid_mode=on
log_slave_updates=1
enforce_gtid_consistency=1
slave配置文件
# slave
[mysqld]
server-id=1013306
##binlog
log-bin=mysql-bin
sync-binlog=1
innodb_support_xa=1
binlog_format=row
##GTID
gtid_mode=on
log_slave_updates=1
enforce_gtid_consistency=1
read-only=1 ##保证数据一致性
导出master上的数据,导入到slave中;
# master
[root@mysql-master-1003306 ~]# mysqldump -uroot -p --single-transaction -A --master-data=2 > all.sql
Enter password:
##这里加不加--master-data=2都行,因为复制已经不再是基于position号的形式了。
[root@mysql-master-1003306 ~]# scp all.sql 10.10.10.101:/root #将备份文件拷贝到从库
从库导入数据
# slave
[root@mysql-slave-1013306 ~]# mysql -uroot -p < all.sql
Enter password:
ERROR 1840 (HY000) at line 24: @@GLOBAL.GTID_PURGED can only be set when @@GLOBAL.GTID_EXECUTED is empty.
## 从库导入时报这个错误,是因为从库当前的GLOBAL.GTID_EXECUTED不为空,使用reset master可以重置;
mysql> show master status;
+------------------+----------+--------------+------------------+----------------------------------------+
| File | Position | Binlog_Do_DB | Binlog_Ignore_DB | Executed_Gtid_Set |
+------------------+----------+--------------+------------------+----------------------------------------+
| mysql-bin.000002 | 398 | | | 8d3e071d-41b8-11e8-aaef-000c29661dd8:1 |
+------------------+----------+--------------+------------------+----------------------------------------+
1 row in set (0.00 sec)
mysql> reset master;
Query OK, 0 rows affected (0.01 sec)
mysql>
mysql> show master status;
+------------------+----------+--------------+------------------+-------------------+
| File | Position | Binlog_Do_DB | Binlog_Ignore_DB | Executed_Gtid_Set |
+------------------+----------+--------------+------------------+-------------------+
| mysql-bin.000001 | 154 | | | |
+------------------+----------+--------------+------------------+-------------------+
1 row in set (0.00 sec)
##再次导入
[root@mysql-slave-1013306 ~]# mysql -uroot -p < all.sql
Enter password:
##导入成功
在master上创建复制账号
mysql> GRANT REPLICATION SLAVE ON *.* TO 'repluser'@'10.10.10.%' IDENTIFIED BY 'echo123.';
Query OK, 0 rows affected, 1 warning (0.00 sec)
在slave上开启复制
mysql> CHANGE MASTER TO MASTER_HOST='10.10.10.100',MASTER_USER='repluser',MASTER_PASSWORD='echo123.',MASTER_PORT=3306,MASTER_AUTO_POSITION=1;
Query OK, 0 rows affected, 2 warnings (0.04 sec)
查看主从状态
# slave
mysql> start slave;
Query OK, 0 rows affected (0.06 sec)
mysql> show slave status\G;
*************************** 1. row ***************************
Slave_IO_State: Waiting for master to send event
Master_Host: 10.10.10.100
Master_User: repluser
Master_Port: 3306
Connect_Retry: 60
Master_Log_File: mysql-bin.000010
Read_Master_Log_Pos: 1719
Relay_Log_File: mysql-relay-bin.000002
Relay_Log_Pos: 1220
Relay_Master_Log_File: mysql-bin.000010
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: 1719
Relay_Log_Space: 1427
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: 1003306
Master_UUID: 91daaeb1-3eab-11e8-bbc1-000c29ffc6cd
Master_Info_File: /data/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: 91daaeb1-3eab-11e8-bbc1-000c29ffc6cd:4-6
Executed_Gtid_Set: 91daaeb1-3eab-11e8-bbc1-000c29ffc6cd:1-6
Auto_Position: 1
Replicate_Rewrite_DB:
Channel_Name:
Master_TLS_Version:
1 row in set (0.00 sec)
验证
在主库上插入数据
# master
mysql> select * from t1;
+----+
| id |
+----+
| 1 |
| 2 |
| 3 |
+----+
3 rows in set (0.00 sec)
mysql> insert into t1 values (4);
Query OK, 1 row affected (0.03 sec)
mysql> insert into t1 values (5);
Query OK, 1 row affected (0.01 sec)
在从库上查看
mysql> select * from t1;
+----+
| id |
+----+
| 1 |
| 2 |
| 3 |
+----+
3 rows in set (0.00 sec)
mysql> select * from t1;
+----+
| id |
+----+
| 1 |
| 2 |
| 3 |
| 4 |
| 5 |
+----+
5 rows in set (0.00 sec)
GTID如何跳过事务冲突
1、这个功能主要跳过事务,代替原来的set global sql_slave_skip_counter = 1。
2、由于在这个GTID必须是连续的,正常情况同一个服务器产生的GTID是不会存在空缺的。所以不能简单的skip掉一个事务,只能通过注入空事物的方法替换掉一个实际操作事务。
3、注入空事物的方法:
stop slave;
set gtid_next='xxxxxxx:N'; ##这里的xxxxx:N 也就是你的slave sql thread报错的GTID,或者说是你想要跳过的GTID。
begin;
commit;
set gtid_next='AUTOMATIC';
start slave;
mysql> stop slave;
Query OK, 0 rows affected (0.02 sec)
mysql> set gtid_next='91daaeb1-3eab-11e8-bbc1-000c29ffc6cd:15'; ##跳过的GTID号
Query OK, 0 rows affected (0.00 sec)
mysql> begin;commit;
Query OK, 0 rows affected (0.00 sec)
Query OK, 0 rows affected (0.01 sec)
mysql> set gtid_next='AUTOMATIC';
Query OK, 0 rows affected (0.00 sec)
mysql> start slave;
Query OK, 0 rows affected (0.00 sec)
转载请注明来源,欢迎对文章中的引用来源进行考证,欢迎指出任何有错误或不够清晰的表达。可以在下面评论区评论,也可以邮件至 289211569@qq.com