文章目录
上传并安装MySQL 5.7.35
(172.25.0.19与172.25.0.20均部署安装并启动)
[root@QYWLAQ_VMC4234 ~]# hostnamectl
Static hostname: QYWLAQ_VMC4234
Icon name: computer-vm
Chassis: vm
Machine ID: cd3605d12efd430fb723eb507cf5ce3b
Boot ID: 00f929e5510944efb40d53ef55d92a49
Virtualization: kvm
Operating System: CentOS Linux 7 (Core)
CPE OS Name: cpe:/o:centos:centos:7
Kernel: Linux 3.10.0-1160.el7.x86_64
Architecture: x86-64
[root@QYWLAQ_VMC4234 ~]# ll
-rw-r--r-- 1 citc unicom 26658592 12月 25 17:02 mysql-community-client-5.7.35-1.el7.x86_64.rpm
-rw-r--r-- 1 citc unicom 317800 12月 25 17:03 mysql-community-common-5.7.35-1.el7.x86_64.rpm
-rw-r--r-- 1 citc unicom 2473348 12月 25 17:03 mysql-community-libs-5.7.35-1.el7.x86_64.rpm
-rw-r--r-- 1 citc unicom 1263816 12月 26 14:35 mysql-community-libs-compat-5.7.35-1.el7.x86_64.rpm
-rw-r--r-- 1 citc unicom 182213816 12月 25 17:05 mysql-community-server-5.7.35-1.el7.x86_64.rpm
# 安装rpm包
[root@QYWLAQ_VMC4234 ~]# yum localinstall -y *.rpm
# 启动并设置开启自启
[root@QYWLAQ_VMC4234 ~]# systemctl enable --now mysqld
[root@QYWLAQ_VMC4234 citc]# systemctl status mysqld
● mysqld.service - MySQL Server
Loaded: loaded (/usr/lib/systemd/system/mysqld.service; enabled; vendor preset: disabled)
Active: active (running) since 三 2025-02-26 12:24:03 CST; 4min 26s ago
Docs: man:mysqld(8)
http://dev.mysql.com/doc/refman/en/using-systemd.html
Process: 8441 ExecStart=/usr/sbin/mysqld --daemonize --pid-file=/var/run/mysqld/mysqld.pid $MYSQLD_OPTS (code=exited, status=0/SUCCESS)
Process: 8374 ExecStartPre=/usr/bin/mysqld_pre_systemd (code=exited, status=0/SUCCESS)
Main PID: 8444 (mysqld)
Tasks: 27
Memory: 289.2M
CGroup: /system.slice/mysqld.service
└─8444 /usr/sbin/mysqld --daemonize --pid-file=/var/run/mysqld/mysqld.pid
2月 26 12:23:57 QYWLAQ_VMC4234 systemd[1]: Starting MySQL Server...
2月 26 12:24:03 QYWLAQ_VMC4234 systemd[1]: Started MySQL Server.
# 获取初始密码
[root@QYWLAQ_VMC4234 citc]# sudo grep 'temporary password' /var/log/mysqld.log
2025-02-26T04:23:59.794639Z 1 [Note] A temporary password is generated for root@localhost: IlM3/)Ya6VMH
# 登录
[root@QYWLAQ_VMC4234 citc]# mysql -u root -p'IlM3/)Ya6VMH'
mysql: [Warning] Using a password on the command line interface can be insecure.
Welcome to the MySQL monitor. Commands end with ; or \g.
Your MySQL connection id is 2
Server version: 5.7.35
Copyright (c) 2000, 2021, Oracle and/or its affiliates.
Oracle is a registered trademark of Oracle Corporation and/or its
affiliates. Other names may be trademarks of their respective
owners.
Type 'help;' or '\h' for help. Type '\c' to clear the current input statement.
mysql> ALTER USER 'root'@'localhost' IDENTIFIED BY '8th3xY]:NA'; -- 修改root密码
Query OK, 0 rows affected (0.00 sec)
mysql> FLUSH PRIVILEGES; -- 刷新权限以使修改立即生效
Query OK, 0 rows affected (0.01 sec)
双主复制的配置
实例一:172.25.0.19:
# 此配置文件中追加下述配置
[root@QYWLAQ_VMC4234 ~]# vi /etc/my.cnf
[mysqld]
# 基本配置
server-id = 1 # 每个实例的 server-id 必须唯一
log_bin = /var/log/mysql/mysql-bin.log # 启用二进制日志
binlog_format = ROW # 推荐使用 ROW 格式
expire_logs_days = 7 # 自动清理 7 天前的日志
max_binlog_size = 100M # 每个二进制日志文件的最大大小
# 双主复制配置
log_slave_updates = 1 # 从库记录二进制日志(必须启用)
auto_increment_increment = 2 # 自增步长
auto_increment_offset = 1 # 自增起始值(实例 1 为 1,实例 2 为 2)
# 复制过滤(可选)
replicate-do-db = my_database # 只复制指定的数据库
replicate-ignore-db = mysql # 忽略系统库
# 其他配置
bind-address = 0.0.0.0 # 允许远程连接
重启MySQL
[root@QYWLAQ_VMC4234 ~]# systemctl restart mysqld
实例二:172.25.0.20:
# 此配置文件中追加下述配置
[root@QYWLAQ_VMC1091 ~]# vi /etc/my.cnf
[mysqld]
# 基本配置
server-id = 2 # 每个实例的 server-id 必须唯一
log_bin = /var/log/mysql/mysql-bin.log # 启用二进制日志
binlog_format = ROW # 推荐使用 ROW 格式
expire_logs_days = 7 # 自动清理 7 天前的日志
max_binlog_size = 100M # 每个二进制日志文件的最大大小
# 双主复制配置
log_slave_updates = 1 # 从库记录二进制日志(必须启用)
auto_increment_increment = 2 # 自增步长
auto_increment_offset = 2 # 自增起始值(实例 1 为 1,实例 2 为 2)
# 复制过滤(可选)
replicate-do-db = my_database # 只复制指定的数据库
replicate-ignore-db = mysql # 忽略系统库
# 其他配置
bind-address = 0.0.0.0 # 允许远程连接
重启MySQL
[root@QYWLAQ_VMC1091 ~]# systemctl restart mysqld
配置复制用户
在每个 MySQL 实例上创建一个用于复制的用户。
在实例 1 (172.25.0.19)上执行:
mysql> CREATE USER 'replication'@'172.25.0.20' IDENTIFIED BY '@2X0wZY/rq';
Query OK, 0 rows affected (0.01 sec)
mysql> GRANT REPLICATION SLAVE ON *.* TO 'replication'@'172.25.0.20';
Query OK, 0 rows affected (0.00 sec)
mysql> FLUSH PRIVILEGES;
Query OK, 0 rows affected (0.01 sec)
查询用户
mysql> SELECT User, Host FROM mysql.user;
+---------------+-------------+
| User | Host |
+---------------+-------------+
| replication | 172.25.0.20 |
| mysql.session | localhost |
| mysql.sys | localhost |
| root | localhost |
+---------------+-------------+
4 rows in set (0.00 sec)
在实例 2 (172.25.0.20)上执行:
mysql> CREATE USER 'replication'@'172.25.0.19' IDENTIFIED BY '@2X0wZY/rq';
Query OK, 0 rows affected (0.00 sec)
mysql> GRANT REPLICATION SLAVE ON *.* TO 'replication'@'172.25.0.19';
Query OK, 0 rows affected (0.00 sec)
mysql> FLUSH PRIVILEGES;
Query OK, 0 rows affected (0.00 sec)
查询用户
mysql> SELECT User, Host FROM mysql.user;
+---------------+-------------+
| User | Host |
+---------------+-------------+
| replication | 172.25.0.19 |
| mysql.session | localhost |
| mysql.sys | localhost |
| root | localhost |
+---------------+-------------+
4 rows in set (0.00 sec)
配置主从复制
在每个实例上配置对方为主库。
查看实例 2 节点状态:
mysql> SHOW MASTER STATUS;
+------------------+----------+--------------+------------------+-------------------+
| File | Position | Binlog_Do_DB | Binlog_Ignore_DB | Executed_Gtid_Set |
+------------------+----------+--------------+------------------+-------------------+
| mysql-bin.000002 | 964 | | | |
+------------------+----------+--------------+------------------+-------------------+
1 row in set (0.00 sec)
在实例 1 上执行:
CHANGE MASTER TO
MASTER_HOST='172.25.0.20',
MASTER_USER='replication',
MASTER_PASSWORD='@2X0wZY/rq',
MASTER_LOG_FILE='mysql-bin.000002', -- 替换为实例 2 的当前 binlog 文件
MASTER_LOG_POS=1784; -- 替换为实例 2 的当前 binlog 位置
START SLAVE;
查看实例 1 节点状态:
mysql> SHOW MASTER STATUS;
+------------------+----------+--------------+------------------+-------------------+
| File | Position | Binlog_Do_DB | Binlog_Ignore_DB | Executed_Gtid_Set |
+------------------+----------+--------------+------------------+-------------------+
| mysql-bin.000002 | 964 | | | |
+------------------+----------+--------------+------------------+-------------------+
1 row in set (0.00 sec)
在实例 2 上执行:
CHANGE MASTER TO
MASTER_HOST='172.25.0.19',
MASTER_USER='replication',
MASTER_PASSWORD='@2X0wZY/rq',
MASTER_LOG_FILE='mysql-bin.000002', -- 替换为实例 1 的当前 binlog 文件
MASTER_LOG_POS=1784; -- 替换为实例 1 的当前 binlog 位置
START SLAVE;
验证复制状态
在每个实例上执行以下命令,检查复制状态:
SHOW SLAVE STATUS\G;
确保以下字段的值为 Yes
:
Slave_IO_Running
Slave_SQL_Running
测试双主复制
在 Server A 上操作:
创建测试数据库和表:
CREATE DATABASE test_db;
USE test_db;
CREATE TABLE test_table (
id INT AUTO_INCREMENT PRIMARY KEY,
name VARCHAR(50)
) ENGINE=InnoDB;
插入数据:
INSERT INTO test_table (name) VALUES ('Server A Data');
在 Server B 上操作:
检查数据是否同步:
USE test_db;
SELECT * FROM test_table;
应该能看到 Server A Data
。
插入数据:
INSERT INTO test_table (name) VALUES ('Server B Data');
回到 Server A 上操作:
检查数据是否同步:
USE test_db;
SELECT * FROM test_table;
table (name) VALUES (‘Server A Data’);
### 在 Server B 上操作:
**检查数据是否同步**:
USE test_db;
SELECT * FROM test_table;
应该能看到 `Server A Data`。
**插入数据**:
INSERT INTO test_table (name) VALUES (‘Server B Data’);
### 回到 Server A 上操作:
**检查数据是否同步**:
USE test_db;
SELECT * FROM test_table;
应该能看到 `Server B Data`。