www.colben.cn/content/post/mysql-group-replication.md
2021-11-14 14:32:08 +08:00

149 lines
4.4 KiB
Markdown
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

---
title: "MySQL 组复制"
date: 2020-04-28T00:52:00+08:00
lastmod: 2020-04-28T00:52:00+08:00
tags: ["mysql", "group", "replication", "组复制"]
categories: ["database"]
---
# 环境
hostname | ip | os | mysql
---- | ---- | ---- | ----
mysql_11 | 192.168.1.11 | centos7.7 | 8.0.19
mysql_22 | 192.168.1.22 | centos7.7 | 8.0.19
mysql_33 | 192.168.1.33 | centos7.7 | 8.0.19
# 安装 mysql
- 懒得写了 ...
# 修改 my.cnf
```
# mysql_11(选择一个)
server-id = 11
# mysql_22(选择一个)
server-id = 22
# mysql_33(选择一个)
server-id = 33
# 开启 binlog
log-bin = /var/log/mysql-bin/master
binlog-format = ROW
# 关闭 binlog 校验
binlog-checksum = NONE
# 保留 2 天的 binlog
binlog-expire-logs-seconds = 172800
# 开启 gtid
gtid-mode = ON
enforce-gtid-consistency = TRUE
# 指定 relay-log 存储位置
relay-log = /var/lib/mysql-bin/slave
# relay-log 更新计入 binlog
log-slave-updates = TRUE
# 多线程执行从库日志(可选)
slave-parallel-workers = 2
slave-parallel-type = LOGICAL_CLOCK
slave-preserve-commit-order = ON
# 存储引擎只能用 InnoDB
disabled-storage-engines = "MyISAM,BLACKHOLE,FEDERATED,ARCHIVE,MEMORY"
# 加载插件,克隆插件用于快速 state transfer
plugin-load-add = "group_replication.so;mysql_clone.so"
# 集群 uuid
group-replication-group-name = "aaaa1111-bbbb-2222-cccc-3333dddd4444"
# mysql_11(选择一个)
group-replication-local-address = "192.168.1.11:33061"
# mysql_22(选择一个)
group-replication-local-address = "192.168.1.22:33061"
# mysql_33(选择一个)
group-replication-local-address = "192.168.1.33:33061"
# 种子节点
group-replication-group-seeds = "192.168.1.11:33061,192.168.1.22:33061,192.168.1.33:33061"
# 新主库在执行完自己的从库日志后,再处理用户的写请求
group-replication-consistency = BEFORE_ON_PRIMARY_FAILOVER
# 启动时,不自动创建/初始化新集群
group-replication-bootstrap-group = OFF
# 新节点启动时,先不启动组复制,待手动配置完成并确认正常后,再把 OFF 改成 ON
group-replication-start-on-boot = OFF
# 怀疑某节点不可用2秒内如果该嫌疑节点依旧无响应则开除它(可选)
group-replication-member-expel-timeout = 2
# 2秒内依旧连接不上主网(majority),则退出组复制,进入 ERROR 状态(可选)
group-replication-unreachable-majority-timeout = 2
# 退出组复制后,不再尝试重新加入组复制,直接执行指定的退出动作(默认)
group-replication-autorejoin-tries = 0
# 指定退出动作: 数据库设置超级只读并关闭客户端连接(推荐)
group-replication-exit-state-action = OFFLINE_MODE
```
# 初始化集群
- 重新启动节点 mysql_11
```bash
systemctl restart mysqld
```
- 创建同步用户
```sql
SET SQL_LOG_BIN = 0;
CREATE USER rpl_user@'%' IDENTIFIED BY 'password';
GRANT REPLICATION SLAVE ON *.* TO rpl_user@'%';
GRANT BACKUP_ADMIN ON *.* TO rpl_user@'%';
FLUSH PRIVILEGES;
SET SQL_LOG_BIN = 1;
```
- 配置同步信息
```sql
CHANGE MASTER TO
MASTER_USER='rpl_user',
MASTER_PASSWORD='password'
FOR CHANNEL 'group_replication_recovery';
```
- 启动集群
```sql
SET GLOBAL group_replication_bootstrap_group=ON;
START GROUP_REPLICATION;
SET GLOBAL group_replication_bootstrap_group=OFF;
```
- 查看集群成员(只有一个)
```sql
SELECT * FROM performance_schema.replication_group_members;
```
- 修改 my.cnf配置 group-replication-start-on-boot = ON
# 增加节点
- 重新启动节点 mysql_22
```bash
systemctl restart mysql_22
```
- 创建同步用户,与 mysql_11 相同
```sql
SET SQL_LOG_BIN = 0;
CREATE USER rpl_user@'%' IDENTIFIED BY 'password';
GRANT REPLICATION SLAVE ON *.* TO rpl_user@'%';
GRANT BACKUP_ADMIN ON *.* TO rpl_user@'%';
FLUSH PRIVILEGES;
SET SQL_LOG_BIN = 1;
```
- 配置同步信息
```sql
CHANGE MASTER TO
MASTER_USER='rpl_user',
MASTER_PASSWORD='password'
FOR CHANNEL 'group_replication_recovery';
```
- 启动组复制
```sql
START GROUP_REPLICATION;
```
- 在 mysql_33 上重复 mysql_22 的步骤
- 查看集群成员(有三个)
```sql
SELECT * FROM performance_schema.replication_group_members;
```
- 修改 mysql_22 和 mysql_33 的 my.cnf配置 group-replication-start-on-boot = ON
# 注意
- 每张表都必须显式指定主键