MySQL以GTID方式搭建主备集群 原创 数据库 2022年6月1日 23:04 夏至未至 1110 当前内容 8785 字,在路上,马上到,马上到 ### 目录 [TOC] ### 环境准备 server1 192.168.78.188 3308 Master server2 192.168.78.189 3306 Slave ### 主从配置文件修改 #### master 在 .cnf 中 `[mysqld]`下配置: [mysqld] # 服务器基础参数 port=3308 pid-file = /var/run/mysqld/mysqld.pid socket = /var/run/mysqld/mysqld.sock datadir = /var/lib/mysql secure-file-priv= NULL # GTID: # 服务器id,设置为机器 IP 地址后三位即可 server_id=188 # 开启gtid模式 gtid_mode=on # 强制gtid一致性,开启后对于特定create table不被支持 enforce_gtid_consistency=on # binlog: # 二进制日志文件存放路径 log_bin = mysql-bin log-slave-updates=true # 强烈建议,其他格式可能造成数据不一致 binlog_format=row # relay log: skip_slave_start=1 切记,配置完成后,重启数据库服务,连接数据库并验证配置是否生效(不报错,基本都是生效了)。如下方式验证: MySQL [(none)]> show variables like '%gtid%'; +----------------------------------+-----------+ | Variable_name | Value | +----------------------------------+-----------+ | binlog_gtid_simple_recovery | ON | | enforce_gtid_consistency | ON | | gtid_executed | | | gtid_executed_compression_period | 0 | | gtid_mode | ON | | gtid_next | AUTOMATIC | | gtid_owned | | | gtid_purged | | | session_track_gtids | OFF | +----------------------------------+-----------+ 9 rows in set (0.01 sec) MySQL [(none)]> #### slave 在 .cnf 中 `[mysqld]`下配置: [mysqld] pid-file = /var/run/mysqld/mysqld.pid socket = /var/run/mysqld/mysqld.sock datadir = /var/lib/mysql secure_file_priv= # GTID: # 开启gtid模式 gtid_mode=on enforce_gtid_consistency=on # 服务器id,设置为机器 IP 地址后三位 server_id=189 # binlog log-bin=slave-binlog log-slave-updates=true # 强烈建议,其他格式可能造成数据不一致 binlog_format=row #relay log skip_slave_start=1 配置完成后,重启数据库服务,连接数据库用同样的方式验证配置。 ### 主节点创建复制用户 一般使用 root 用户来做GTID复制,这样是不合理的,故需在**主节点**建一个专用复制用户,命令如下: GRANT REPLICATION SLAVE ON *.* TO '用户名'@'从机IP' IDENTIFIED BY '密码'; 其中**用户名**是给从节点访问主节点时使用,**从机IP**为从机IP,意为限制只能是固定从节点、固定用户名来连接主节点,如下为实际操作: MySQL [(none)]> create user 'gtid_copy'@'%' identified by '123456'; Query OK, 0 rows affected (0.01 sec) MySQL [(none)]> grant replication slave on *.* to 'gtid_copy'@'%'; Query OK, 0 rows affected (0.01 sec) MySQL [(none)]> FLUSH PRIVILEGES; Query OK, 0 rows affected (0.03 sec) MySQL [(none)]> 创建完成用户,最保险的方式,就是使用次用户在从机上连接主节点,看看连接情况: [root@localhost ~]# mysql -ugtid_copy -p123456 -P3308 -h192.168.78.188 ERROR 2059 (HY000): Authentication plugin 'caching_sha2_password' cannot be loaded: /usr/lib64/mysql/plugin/caching_sha2_password.so: cannot open shared object file: No such file or directory [root@localhost ~]# 辛亏验证,不然主从关系必然不正常,以上报错,那是因为 8 的密码加密规则变了,连接主节点数据,给复制用户做配置,配置下: MySQL [(none)]> MySQL [(none)]> ALTER USER 'gtid_copy'@'%' IDENTIFIED BY 'password' PASSWORD EXPIRE NEVER; Query OK, 0 rows affected (0.00 sec) MySQL [(none)]> ALTER USER 'gtid_copy'@'%' IDENTIFIED WITH mysql_native_password BY 'password'; Query OK, 0 rows affected (0.00 sec) MySQL [(none)]> FLUSH PRIVILEGES; Query OK, 0 rows affected (0.00 sec) MySQL [(none)]> ALTER USER 'gtid_copy'@'%' IDENTIFIED BY '123456'; Query OK, 0 rows affected (0.01 sec) MySQL [(none)]> 更多细节详见站内博文:[容器版MySQL安装和配置(Docker)](https://www.codecomeon.com/posts/177/#%E5%AE%BF%E4%B8%BB%E6%9C%BA%E4%B8%8A%E8%BF%9E%E6%8E%A5%E6%95%B0%E6%8D%AE%E5%BA%93 "容器版MySQL安装和配置(Docker)") 再次在从上连接主验证: [root@localhost ~]# mysql -ugtid_copy -p123456 -P3308 -h192.168.78.188 Welcome to the MariaDB monitor. Commands end with ; or \g. Your MySQL connection id is 32 Server version: 8.0.29 MySQL Community Server - GPL Copyright (c) 2000, 2018, Oracle, MariaDB Corporation Ab and others. Type 'help;' or '\h' for help. Type '\c' to clear the current input statement. MySQL [(none)]> ### 从节点配置复制关系 salve连接到master CHANGE MASTER TO MASTER_HOST='master的IP', MASTER_USER='用户名', MASTER_PASSWORD='密码', MASTER_PORT=端口号, # 1 代表采用GTID协议复制 # 0 代表采用老的binlog复制 MASTER_AUTO_POSITION = 1; 如下本机实操: MySQL [(none)]> MySQL [(none)]> change master to master_host='192.168.78.188', master_user='gtid_copy', master_password='123456', master_port=3308, master_auto_position=1; Query OK, 0 rows affected, 8 warnings (0.02 sec) MySQL [(none)]> start slave; Query OK, 0 rows affected, 1 warning (0.00 sec) MySQL [(none)]> **特别注意**:只用在从节点 `start slave` 即可,含义为启动从起点的 I/O 线程和SQL线程。 ### 集群状态查看 主从关系一切正常后,即可验证同步逻辑,验证方式,和传统复制方式一样:[MySQL主从集群快速搭建](https://www.codecomeon.com/posts/130/#%E4%B8%BB%E4%BB%8E%E6%B5%8B%E8%AF%95%E9%AA%8C%E8%AF%81 "MySQL主从集群快速搭建") #### 从节点查看slave状态 MySQL [(none)]> show slave status\G; *************************** 1. row *************************** Slave_IO_State: Waiting for source to send event Master_Host: 192.168.78.188 Master_User: gtid_copy Master_Port: 3308 Connect_Retry: 60 Master_Log_File: mysql-bin.000001 Read_Master_Log_Pos: 2106 Relay_Log_File: 67bf0b455536-relay-bin.000002 Relay_Log_Pos: 2322 Relay_Master_Log_File: mysql-bin.000001 Slave_IO_Running: Yes Slave_SQL_Running: 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: 2106 Relay_Log_Space: 2539 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: 188 Master_UUID: 1d9b633d-e1ae-11ec-8ece-0242ac110002 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: 1d9b633d-e1ae-11ec-8ece-0242ac110002:1-8 Executed_Gtid_Set: 1d9b633d-e1ae-11ec-8ece-0242ac110002:1-8 Auto_Position: 1 Replicate_Rewrite_DB: Channel_Name: Master_TLS_Version: Master_public_key_path: Get_master_public_key: 0 Network_Namespace: 1 row in set, 1 warning (0.01 sec) ERROR: No query specified MySQL [(none)]> #### 主节点查看slave状态 如下命令在主节点执行,用户查看,当前主下,有从节点几何: MySQL [(none)]> show slave hosts\G; *************************** 1. row *************************** Server_id: 189 Host: Port: 3306 Master_id: 188 Slave_UUID: f19b117a-cf6d-11ec-9fd7-0242ac110002 1 row in set, 1 warning (0.00 sec) ERROR: No query specified MySQL [(none)]> ### gtid与传统模式建立复制时候语句的不同点 #### 传统复制 change master to master_host="127.0.0.1",master_port=3310,MASTER_USER='sync',MASTER_PASSWORD='GreatSQL',MASTER_LOG_FILE='log-bin.000005', MASTER_LOG_POS=4111; ####GTID复制 change master to master_host="127.0.0.1",master_port=3310,MASTER_USER='sync',MASTER_PASSWORD='GreatSQL',MASTER_AUTO_POSITION=1 GTID同步在建立复制的时候,将传统复制由人为指定binlog的pos位点改为了MASTER_AUTO_POSITION=1自动获取binlog的pos位点。 本文标题: MySQL以GTID方式搭建主备集群 本文作者: 夏至未至 发布时间: 2022年6月1日 23:04 最近更新: 2022年6月2日 14:45 原文链接: 许可协议: 署名-非商业性-禁止演绎 4.0 国际(CC BY-NC-ND 4.0) 请按协议转载并保留原文链接及作者 GTID(3) 上一个 MySQL主备复制集群跳过错误方法(GTID) 下一个 MySQL GTID快速了解 请可爱的你登录后回复 评论列表 (0条) 查看更多评论
评论列表 (0条)