MySQL 5.7多源复制详解

教程发布:风哥 教程分类:ITPUX技术网 更新日期:2022-02-12 浏览学习:742

MySQL 5.7多源复制详解

MySQL5.7开始支持多源复制,也就是多主一从的复制架构:

使用多源复制的考虑:
1、灾备作用:将各个库汇总在一起,就算是其他库都挂了(整个机房都无法连接了),还有最后一个救命稻草;
2、备份:直接在这个从库中做备份,不影响线上的数据库;
3、减少成本:不需要每个库都做一个实例,也减少了DBA的维护成本;
4、数据统计:后期的一些数据统计,需要将所有的库汇总在一起。
... ...

实验环境:
Master1:10.157.26.132:3307
Master2:10.157.26.133:3307
Slave:10.157.26.134:3307
多源复制是支持GTID和Binlog+Position,我这里是GTID复制。

一、配置文件:
Master1和Master2:
#GTID
gtid_mode = on
enforce_gtid_consistency = 1
binlog_gtid_simple_recovery = 1
binlog_format = row
log_bin = /data/mysql/mysql_3307/logs/binlog/mysql-bin
skip_slave_start = 1

Slave:
#binlog
server_id = 1343307
binlog_format = row
log_bin = /data/mysql/mysql_3307/logs/binlog/mysql-bin

#GTID
gtid_mode = on
enforce_gtid_consistency = 1 #修改MySQL存储master-info和relay-info的方式,即从文件存储改为表存储
binlog_gtid_simple_recovery = 1
master_info_repository = TABLE
relay_log_info_repository = TABLE
replicate_ignore_db = mysql   #忽略mysql库的同步
skip_slave_start = 1

二、主库创建复制账号:
Master1:grant replication slave,replication client on *.* to sampson_132@'10.157.26.%'identified by 'sampson_132';
Master2:grant replication slave,replication client on *.* to sampson_133@'10.157.26.%'identified by 'sampson_133';

三:从库启动复制:
mysql> change master to master_host='10.157.26.132',master_port=3307,master_user='sampson_132',master_password='sampson_132',master_auto_position=1 for channel 'Master_132';
mysql> change master to master_host='10.157.26.133',master_port=3307,master_user='sampson_133',master_password='sampson_133',master_auto_position=1 for channel 'Master_133';
mysql> start slave;
也可以start slave for channel 'Master_132 '启动单个channel的复制。

四:查看slave状态
【也可以直接show slave status for channel 'Master_132' \G查看各个channel的复制状态】
mysql> show slave status\G
*************************** 1. row ***************************
Slave_IO_State: Waiting for master to send event
Master_Host: 10.157.26.132
Master_User: sampson_132
Master_Port: 3307
Connect_Retry: 60
Master_Log_File: mysql-bin.000001
Read_Master_Log_Pos: 154
Relay_Log_File: relay_log-master_132.000002
Relay_Log_Pos: 367
Relay_Master_Log_File: mysql-bin.000001
Slave_IO_Running: Yes
Slave_SQL_Running: Yes
Replicate_Do_DB:
Replicate_Ignore_DB: mysql
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: 154
Relay_Log_Space: 579
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: 1323307
Master_UUID: 8785129a-3ace-11e7-9f13-fa163e48cafd
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:
Auto_Position: 1
Replicate_Rewrite_DB:
Channel_Name: master_132
Master_TLS_Version:
*************************** 2. row ***************************
Slave_IO_State: Waiting for master to send event
Master_Host: 10.157.26.133
Master_User: sampson_133
Master_Port: 3307
Connect_Retry: 60
Master_Log_File: mysql-bin.000001
Read_Master_Log_Pos: 154
Relay_Log_File: relay_log-master_133.000002
Relay_Log_Pos: 367
Relay_Master_Log_File: mysql-bin.000001
Slave_IO_Running: Yes
Slave_SQL_Running: Yes
Replicate_Do_DB:
Replicate_Ignore_DB: mysql
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: 154
Relay_Log_Space: 579
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: 1333307
Master_UUID: 3d5ae510-3acf-11e7-82a4-fa163e8e91ad
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:
Auto_Position: 1
Replicate_Rewrite_DB:
Channel_Name: master_133
Master_TLS_Version:
2 rows in set (0.01 sec)

通过查看performance_schema相关的表查看同步状态:
mysql> select * from performance_schema.replication_connection_status\G
*************************** 1. row ***************************
CHANNEL_NAME: master_132
GROUP_NAME:
SOURCE_UUID: 8785129a-3ace-11e7-9f13-fa163e48cafd
THREAD_ID: 89
SERVICE_STATE: ON
COUNT_RECEIVED_HEARTBEATS: 1
LAST_HEARTBEAT_TIMESTAMP: 2017-05-17 16:59:45
RECEIVED_TRANSACTION_SET:
LAST_ERROR_NUMBER: 0
LAST_ERROR_MESSAGE:
LAST_ERROR_TIMESTAMP: 0000-00-00 00:00:00
*************************** 2. row ***************************
CHANNEL_NAME: master_133
GROUP_NAME:
SOURCE_UUID: 3d5ae510-3acf-11e7-82a4-fa163e8e91ad
THREAD_ID: 91
SERVICE_STATE: ON
COUNT_RECEIVED_HEARTBEATS: 1
LAST_HEARTBEAT_TIMESTAMP: 2017-05-17 16:59:45
RECEIVED_TRANSACTION_SET:
LAST_ERROR_NUMBER: 0
LAST_ERROR_MESSAGE:
LAST_ERROR_TIMESTAMP: 0000-00-00 00:00:00
2 rows in set (0.01 sec)

五、数据同步检查:
Master1建库建表并插入数据:
mysql> CREATE DATABASE /*!32312 IF NOT EXISTS*/ `sampson_132` /*!40100 DEFAULT CHARACTER SET utf8mb4 */;
mysql> use sampson_132;
mysql> create table t_132(id int primary key auto_increment,name varchar(20) not null);
mysql> insert into t_132(id,name)values(1,'132'),(2,'132'),(3,'132');
mysql> select * from t_132;
+----+------+
| id | name |
+----+------+
| 1 | 132 |
| 2 | 132 |
| 3 | 132 |
+----+------+
3 rows in set (0.00 sec)

Master2建库建表并插入数据:
mysql> CREATE DATABASE /*!32312 IF NOT EXISTS*/ `sampson_133` /*!40100 DEFAULT CHARACTER SET utf8mb4 */;
mysql> use sampson_133;
mysql> create table t_133(id int primary key auto_increment,name varchar(20) not null);
mysql> insert into t_133(id,name)values(1,'133'),(2,'133'),(3,'133');
mysql> select * from sampson_133.t_133;
+----+------+
| id | name |
+----+------+
| 1 | 133 |
| 2 | 133 |
| 3 | 133 |
+----+------+
3 rows in set (0.00 sec)

Slave查看数据是否同步:
mysql> show databases;
+--------------------+
| Database |
+--------------------+
| information_schema |
| mysql |
| performance_schema |
| sampson_132 |
| sampson_133 |
| sys |
+--------------------+
6 rows in set (0.00 sec)

mysql> select * from sampson_132.t_132;
+----+------+
| id | name |
+----+------+
| 1 | 132 |
| 2 | 132 |
| 3 | 132 |
+----+------+
3 rows in set (0.00 sec)

mysql> select * from sampson_133.t_133;
+----+------+
| id | name |
+----+------+
| 1 | 133 |
| 2 | 133 |
| 3 | 133 |
+----+------+
3 rows in set (0.00 sec)

再次查看从库状态:
mysql> show slave status\G
*************************** 1. row ***************************
Slave_IO_State: Waiting for master to send event
Master_Host: 10.157.26.132
Master_User: sampson_132
Master_Port: 3307
Connect_Retry: 60
Master_Log_File: mysql-bin.000001
Read_Master_Log_Pos: 930
Relay_Log_File: relay_log-master_132.000002
Relay_Log_Pos: 1143
Relay_Master_Log_File: mysql-bin.000001
Slave_IO_Running: Yes
Slave_SQL_Running: Yes
Replicate_Do_DB:
Replicate_Ignore_DB: mysql
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: 930
Relay_Log_Space: 1355
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: 1323307
Master_UUID: 8785129a-3ace-11e7-9f13-fa163e48cafd
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: 8785129a-3ace-11e7-9f13-fa163e48cafd:1-3
Executed_Gtid_Set: 3d5ae510-3acf-11e7-82a4-fa163e8e91ad:1-3,
8785129a-3ace-11e7-9f13-fa163e48cafd:1-3
Auto_Position: 1
Replicate_Rewrite_DB:
Channel_Name: master_132
Master_TLS_Version:
*************************** 2. row ***************************
Slave_IO_State: Waiting for master to send event
Master_Host: 10.157.26.133
Master_User: sampson_133
Master_Port: 3307
Connect_Retry: 60
Master_Log_File: mysql-bin.000001
Read_Master_Log_Pos: 930
Relay_Log_File: relay_log-master_133.000002
Relay_Log_Pos: 1143
Relay_Master_Log_File: mysql-bin.000001
Slave_IO_Running: Yes
Slave_SQL_Running: Yes
Replicate_Do_DB:
Replicate_Ignore_DB: mysql
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: 930
Relay_Log_Space: 1355
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: 1333307
Master_UUID: 3d5ae510-3acf-11e7-82a4-fa163e8e91ad
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: 3d5ae510-3acf-11e7-82a4-fa163e8e91ad:1-3
Executed_Gtid_Set: 3d5ae510-3acf-11e7-82a4-fa163e8e91ad:1-3,
8785129a-3ace-11e7-9f13-fa163e48cafd:1-3
Auto_Position: 1
Replicate_Rewrite_DB:
Channel_Name: master_133
Master_TLS_Version:
2 rows in set (0.00 sec)

本文标签:
网站声明:本文由风哥整理发布,转载请保留此段声明,本站所有内容将不对其使用后果做任何承诺,请读者谨慎使用!
【上一篇】
【下一篇】