# Day12 传统主从复制

# 本节关键词

  • 传统主从复制搭建
  • 传统主从复制监控

# 复制介绍

复制介绍:
    将主库的DDLDML等操作通过binlog日志,传输到复制服务器(副本),副本进行回放这些日志,从而使得从库和主库数据保持<近似>同步的工作方式

复制架构:
    1. 传统:1主1从、1主多从、级联主从、双主(逐渐淘汰)
    2. 演变:(增强)半同步、过滤、延时、GTIDMTS
    3. 新型:多源复制(5.7+支持)
    4. MGR:组复制(5.7.17+支持),金融级别,8.0增强(WS:WriteSets)

复制场景:
    1. 备份
    2. 高可用
    3. 读写分离
    4. "分布式"架构
    5. 迁移升级

# 传统主从搭建

  • 安装、配置与启动
# 主服务master_ip配置  vim /etc/my.cnf
[mysqld]
user=mysql
basedir=/usr/local/mysql
datadir=/data/3306/data
socket=/tmp/mysql.sock
log_bin=/data/3306/log/binlog
binlog_format=row
server_id=51
port=3306
secure-file-priv=/tmp
gtid-mode=off

[mysql]
socket=/tmp/mysql.sock


# 从服务slave_ip配置 vim /etc/my.cnf
[mysqld]
user=mysql
basedir=/usr/local/mysql
datadir=/data/3306/data
socket=/tmp/mysql.sock
log_bin=/data/3306/log/binlog
binlog_format=row
server_id=52
port=3306
secure-file-priv=/tmp
gtid-mode=off

[mysql]
socket=/tmp/mysql.sock

# 注意
1. server_id 不同
2. 先关闭 gtid-mode=off 模拟传统的pos复制
  • 主服务器创建用户
# 用于同步 repl@'<slave_ip>'
mysql -e "create user repl@'<slave_ip>' identified with mysql_native_password by '123';grant replication slave, replication client on *.* to repl@'<slave_ip>';"

# 用于远程管理 root@'<slave_ip>' 
mysql -e "create user root@'<slave_ip>' identified with mysql_native_password by '123';grant all on *.* to root@'<slave_ip>';"

# 查看
mysql -e "select user, host, plugin from mysql.user;"
  • 从库备份与还原
mysqldump -uroot -p123 -h <master_ip> -P 3306 -A --master-data=2 --single-transaction -R -E --triggers > /tmp/full.sql

mysql> source /tmp/full.sql;
  • 从服务器启动复制
[root@slave]# grep "\--\ CHANGE MASTER" /tmp/full.sql
-- CHANGE MASTER TO MASTER_LOG_FILE='binlog.000001', MASTER_LOG_POS=2057;
[root@slave]# mysql -e \
"CHANGE MASTER TO \
MASTER_HOST='<master_ip>', \
MASTER_USER='repl', \
MASTER_PASSWORD='123', \
MASTER_PORT=3306, \
MASTER_LOG_FILE='binlog.000001', \
MASTER_LOG_POS=2057, \
MASTER_CONNECT_RETRY=10;"
[root@slave]# mysql -e "start slave;"
[root@slave]# mysql -e "show slave status\G;" | grep "Running"

# 传统复制和GTID转换

a. 未开启 gtid_mode
mysql> select @@gtid_mode;
+-------------+
| @@gtid_mode |
+-------------+
| OFF         |
+-------------+

b. 修改 enforce_gtid_consistency 保证强一致性,且观察一段时间,无错误提醒
[root@master]# mysql -e "set global enforce_gtid_consistency=warn;"
[root@slave]# mysql -e "set global enforce_gtid_consistency=warn;"

c. 修改 enforce_gtid_consistency=on
[root@master]# mysql -e "set global enforce_gtid_consistency=on;"
[root@slave]# mysql -e "set global enforce_gtid_consistency=on;"

d.修改 gtid_mode=off_permissive
新生成的事务为匿名事务,同时允许复制的事务为匿名和GTID
[root@master]# mysql -e "set global gtid_mode=off_permissive;"
[root@slave]#]# mysql -e "set global gtid_mode=off_permissive;"

e. gtid_mode=on_permissive
新生成的事务为GTID,同时允许复制的事务为匿名和GTID
[root@master]# mysql -e "set global gtid_mode=on_permissive;"
[root@slave]#]# mysql -e "set global gtid_mode=on_permissive;"

f.各从节点检查剩余事务数 0 
mysql -e "show status like 'ongoing_anonymous_transaction_count';"
mysql -e "flush logs;"

g. 启用gtid_mode
mysql -e "set global gtid_mode=on;"

h. 从库切换为复制模式
mysql -e  "stop slave;change master to master_auto_position=1;start slave;"
mysql -e "show slave status \G"

i. 修改配置永久有效
gtid_mode=on
enforce_gtid_consistency=true
log-slave-updates=1

# 主从复制原理

  • 流程图

  • 源码图

-- 保存连接主库信息存储在table中,比file较快
mysql> show variables like 'master_info_repository';
+------------------------+-------+
| Variable_name          | Value |
+------------------------+-------+
| master_info_repository | TABLE |
+------------------------+-------+
mysql> select * from mysql.slave_master_info\G


mysql> show slave hosts;
+-----------+------+------+-----------+--------------------------------------+
| Server_id | Host | Port | Master_id | Slave_UUID                           |
+-----------+------+------+-----------+--------------------------------------+
|        52 |      | 3306 |        51 | d5819128-5814-11ed-89f9-00163e047ddd |
+-----------+------+------+-----------+--------------------------------------+
如果想显示 Host 从库配置添加 vim /etc/my.cnf 
report_host=<slave_id>
  • GTID在复制中的改变
-- 新增参数 master_auto_position
change master to 
user password ip port
master_auto_position=1
start slave 

# 半同步复制

传统复制痛点:异步,可能导致数据不一致

单机时:redo日志成功,说明事务成功
集群时:redo和binlog日志成功,说明事务成功

# 主从复制监控

  • 主库查看
mysql> show processlist;
+----+-----------------+---------------------+------+------------------+-------+-----------------------------------------------------------------+------------------+
| Id | User            | Host                | db   | Command          | Time  | State                                                           | Info             |
+----+-----------------+---------------------+------+------------------+-------+-----------------------------------------------------------------+------------------+
|  8 | repl            | slave_ip:50066      | NULL | Binlog Dump GTID | 10269 | Source has sent all binlog to replica; waiting for more updates | NULL             |                                                       
+----+-----------------+---------------------+------+------------------+-------+-----------------------------------------------------------------+------------------+

mysql> show slave hosts;
+-----------+---------------+------+-----------+--------------------------------------+
| Server_id | Host          | Port | Master_id | Slave_UUID                           |
+-----------+---------------+------+-----------+--------------------------------------+
|        52 | 47.92.159.156 | 3306 |        51 | d5819128-5814-11ed-89f9-00163e047ddd |
+-----------+---------------+------+-----------+--------------------------------------+
  • 从库查看
 show slave status \G
 *************************** 1. row ***************************
               Slave_IO_State: Waiting for source to send event
                  Master_Host: 39.103.192.233
                  Master_User: repl
                  Master_Port: 3306
                Connect_Retry: 10
              Master_Log_File: binlog.000009    -- IO线程有关 已接收到binlog
          Read_Master_Log_Pos: 196              -- IO线程有关 位置
               Relay_Log_File: iZ8vbeb633iui3aghasnpdZ-relay-bin.000007
                Relay_Log_Pos: 405
        Relay_Master_Log_File: binlog.000009
             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: 196      -- SQL线程 已执行
              Relay_Log_Space: 672
              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: 51
                  Master_UUID: dd07cc10-4d07-11ed-9e7c-00163e160f39
             Master_Info_File: mysql.slave_master_info
                    SQL_Delay: 0
          SQL_Remaining_Delay: NULL
      Slave_SQL_Running_State: Replica 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: dd07cc10-4d07-11ed-9e7c-00163e160f39:1-2  -- 已接收gtid
            Executed_Gtid_Set: dd07cc10-4d07-11ed-9e7c-00163e160f39:1-2  -- 已回放gtid
                Auto_Position: 1
         Replicate_Rewrite_DB:
                 Channel_Name:
           Master_TLS_Version:
       Master_public_key_path:
        Get_master_public_key: 0
            Network_Namespace:

已开启GTID可关注重要参数
           Retrieved_Gtid_Set: dd07cc10-4d07-11ed-9e7c-00163e160f39:1-2  -- 已接收gtid
            Executed_Gtid_Set: dd07cc10-4d07-11ed-9e7c-00163e160f39:1-2  -- 已回放gtid

# 主从复制故障

上次更新: 10/31/2022, 5:19:53 PM