Mysql搭建异步主从复制

Mysql搭建异步主从复制

环境介绍

master

ip:10.10.10.100
存在一个test库,里面有张t1表

slave

ip:10.10.10.101
空库

搭建步骤(异步主从复制)

检查配置文件

master

# master
[mysqld]
server-id=1003306                     ##server-id要唯一,最好以ip地址和端口号命名
log-bin=mysql-bin                     ##开启二进制日志,必须要
sync-binlog=1                         ##日志刷新模式,按需修改
binlog_format=row                     ##日志格式最好用row,statement可能会有数据丢失

slave

# slave
[mysqld]
server-id=1013306                    ##server-id必须唯一
log-bin=mysql-bin                    ##一般来说从库不需要开启binlog,如果有特殊需要,如级联方式的复制,需要开启
sync-binlog=1
binlog_format=row
log_slave_updates=1                  ##控制slave是否把master的binlog写入自己的binlog中,级联方式需要开启
relay-log=mysql-relay-bin            ##中继日志,不写则以主机名命名,建议写上
read-only=1                          ##设置从库只读,避免数据不一致的发生

导出master上的数据,导入到slave中

# master
[root@mysql-master-1003306 ~]# mysqldump -uroot -p --single-transaction -A --master-data=2 > all.sql

## --master-data=2 表示在备份文件中记录当前备份的二进制日志文件和position号
-- CHANGE MASTER TO MASTER_LOG_FILE='mysql-bin.000007', MASTER_LOG_POS=1744;  ##记下这一行,后面会用到

[root@mysql-master-1003306 ~]# scp all.sql 10.10.10.101:/root               #将备份文件拷贝到从库

从库导入数据

# slave
[root@mysql-slave-1013306 ~]# mysql -uroot -p < all.sql              ##导入数据
Enter password:

导出数据也可以使用xtrabackup来进行,xtrabackup导出后也可以查到日志文件和position号,基于那里进行复制也可以;

在master上创建复制账号

# master
mysql> grant replication slave on *.* to 'repl'@'10.10.10.%' identified by 'echo123.';
Query OK, 0 rows affected, 1 warning (0.06 sec)

mysql> flush privileges;
Query OK, 0 rows affected (0.01 sec)

在slave上开启复制

# slave
mysql> change master to master_host='10.10.10.100',master_user='repl',master_password='echo123.',master_port=3306,master_log_file='mysql-bin.000007',master_log_pos=1744;
Query OK, 0 rows affected, 2 warnings (0.08 sec)

## master_log_file='mysql-bin.000007',master_log_pos=1744 指定二进制日志号和position号,从库将从这里开始进行复制


mysql> start slave;
Query OK, 0 rows affected (0.10 sec)

查看主从状态

# slave
mysql> show slave status\G;
*************************** 1. row ***************************
               Slave_IO_State: Waiting for master to send event
                  Master_Host: 10.10.10.100
                  Master_User: repl
                  Master_Port: 3306
                Connect_Retry: 60
              Master_Log_File: mysql-bin.000008
          Read_Master_Log_Pos: 1365
               Relay_Log_File: mysql-relay-bin.000003
                Relay_Log_Pos: 1578
        Relay_Master_Log_File: mysql-bin.000008
             Slave_IO_Running: Yes                       ##yes表示正常
            Slave_SQL_Running: Yes                       ##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: 1365
              Relay_Log_Space: 1951
              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:
            Executed_Gtid_Set:
                Auto_Position: 0
         Replicate_Rewrite_DB:
                 Channel_Name:
           Master_TLS_Version:
1 row in set (0.00 sec)

验证

在主库上插入数据

mysql> select * from t1;
+------+
| id   |
+------+
|    1 |
|    2 |
|    3 |
|    4 |
|    5 |
|    6 |
|    7 |
|    8 |
+------+
8 rows in set (0.00 sec)

mysql> insert into t1 values (9);
Query OK, 1 row affected (0.03 sec)

mysql> insert into t1 values (10);
Query OK, 1 row affected (0.02 sec)

在从库上查看

mysql> select * from t1;
+------+
| id   |
+------+
|    1 |
|    2 |
|    3 |
|    4 |
|    5 |
|    6 |
|    7 |
|    8 |
|    9 |
|   10 |
+------+
10 rows in set (0.00 sec)

使用reset slave all可以清空主从配置;


转载请注明来源,欢迎对文章中的引用来源进行考证,欢迎指出任何有错误或不够清晰的表达。可以在下面评论区评论,也可以邮件至 289211569@qq.com