首页 » MySQL » 正文

MariaDB的主从复制

一、主从复制

操作系统: CentOS 7.8.2003
MariaDB版本: 5.5.65
Server1: 10.40.200.191
Server2: 10.40.200.192

1、安装MariaDB数据库

yum install mariadb mariadb-devel mariadb-server -y
systemctl start mariadb
systemctl enable mariadb
###开启防火墙 
firewall-cmd --permanent --zone=public --add-service=mysql 
firewall-cmd --reload

2、配置主从复制

a、打开Server1的/etc/my.cnf文件,在其中[mysqld]项下添加如下内容,开启日志功能
[mysqld]
log-bin=mysql-bin
relay-log = relay-bin
server-id=191
b、打开Server1的/etc/my.cnf文件,在其中[mysqld]项下添加如下内容
[mysqld]
#log-bin=mysql-bin
#relay-log = relay-bin
server-id=192
添加完成之后重启数据库
systemctl restart mariadb
Server1上登陆数据库,执行以下操作
mysql -uroot -p
###创建同步账号
grant replication slave,replication client on *.* to 'sync'@'%' identified by '123456';

###查看master节点信息
MariaDB [(none)]> show master status;
+------------------+----------+--------------+------------------+
| File             | Position | Binlog_Do_DB | Binlog_Ignore_DB |
+------------------+----------+--------------+------------------+
| mysql-bin.000001 |     1570 |              |                  |
+------------------+----------+--------------+------------------+
1 row in set (0.000 sec)

###锁定数据表只读
###备份数据库之前一定要锁定数据表只读,不然如果有新的数据写入数据库会导致同步不完整,后期数据同步的时候会出现问题,一定要同步工作做完之后再解除数据表只读!!!
flush tables with read lock;

###备份数据库
mysqldump -u root -p --all-databases >all.sql

###将数据传送到Server2,数据量小的情况下可以通过scp传送。
###如果数据量很大的情况下可以分库分表备份然后逐步传送到Server2

scp all.sql root@10.40.200.192:/root
Server2上登陆数据库,执行以下操作
MariaDB  rpm安装默认空密码,可以使用mysql_secure_installation命令初始化
###导入来自Server1的数据
mysql -uroot -p < /root/all.sql

###连接到master主节点的数据库并开启同步
change master to \
master_host='10.40.200.191', \
master_user='sync', \
master_password='123456', \
master_log_file='mysql-bin.000001', \
master_log_pos=1570;

###开启同步
start slave;
执行完毕之后解除Server1数据表的只读
unlock tables;
在Server2上登陆数据库后查看同步信息,"\G"是格式化输出信息,不加会显示非常乱,不便于查看
MariaDB [(none)]> show slave status\G
*************************** 1. row ***************************
                Slave_IO_State: Waiting for master to send event
                   Master_Host: 10.40.200.191
                   Master_User: sync
                   Master_Port: 3306
                 Connect_Retry: 60
               Master_Log_File: mysql-bin.000001
           Read_Master_Log_Pos: 1570
                Relay_Log_File: linux192-relay-bin.000004
                 Relay_Log_Pos: 680
         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: 1570
               Relay_Log_Space: 992
               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: 191
                Master_SSL_Crl:
            Master_SSL_Crlpath:
                    Using_Gtid: No
                   Gtid_IO_Pos:
       Replicate_Do_Domain_Ids:
   Replicate_Ignore_Domain_Ids:
                 Parallel_Mode: conservative
                     SQL_Delay: 0
           SQL_Remaining_Delay: NULL
       Slave_SQL_Running_State: Slave has read all relay log; waiting for the slave I/O thread to update it
              Slave_DDL_Groups: 1
Slave_Non_Transactional_Groups: 0
    Slave_Transactional_Groups: 0
1 row in set (0.000 sec)
###有如下内容表示服务启动成功
Slave_IO_Running: Yes   #负责与主机的io通信
Slave_SQL_Running: Yes  #负责自己的slave mariadb进程
\G后面不能再加分号;,因为\G在功能上等同于;,如果加了分号,那么就是;;(2个分号)。
如果在\G后加了分号会报ERROR: No query specified错误

测试同步

在Server1和Server2上分别登陆数据库后执行以下操作
###Server1
###创建数据库
MariaDB [mysql]> create database a1;
Query OK, 1 row affected (0.000 sec)

###使用数据库a1
MariaDB [mysql]> use a1;
Database changed

###创建数据表,数据类型为int型
MariaDB [a1]> create table test (id int);
Query OK, 0 rows affected (0.007 sec)

###打印表结构
MariaDB [a1]> desc test;
+-------+---------+------+-----+---------+-------+
| Field | Type    | Null | Key | Default | Extra |
+-------+---------+------+-----+---------+-------+
| id    | int(11) | YES  |     | NULL    |       |
+-------+---------+------+-----+---------+-------+
1 row in set (0.001 sec)

###插入测试数据
MariaDB [a1]> insert into test values(1);
Query OK, 1 row affected (0.001 sec)

MariaDB [a1]> insert into test values(2);
Query OK, 1 row affected (0.002 sec)

###查看数据
MariaDB [a1]> select * from test;
+------+
| id   |
+------+
|    1 |
|    2 |
+------+
2 rows in set (0.000 sec)

###Server2查看数据同步结果

二、主主复制

主主复制其实就是把从库当成主库,主库当成从库,再执行一下复制。
因为之前Server1和Server2之间的主从复制是复制所有数据,所以可以直接采用之前创建的同步账号,也可以另外创建进行区分。
Server2上登陆数据库后执行以下命令
MariaDB [(none)]> show master status;
+------------------+----------+--------------+------------------+
| File             | Position | Binlog_Do_DB | Binlog_Ignore_DB |
+------------------+----------+--------------+------------------+
| mysql-bin.000002 |      973 |              |                  |
+------------------+----------+--------------+------------------+
1 row in set (0.000 sec)
Server1上登陆数据库后执行以下命令
######查看master节点信息
change master to \
master_host='10.40.200.191', \
master_user='sync', \
master_password='123456', \
master_log_file='mysql-bin.000002', \
master_log_pos=973;

###开启同步
start slave;

###查看同步信息
MariaDB [(none)]> show slave status\G
*************************** 1. row ***************************
                Slave_IO_State: Waiting for master to send event
                   Master_Host: 10.40.200.192
                   Master_User: sync
                   Master_Port: 3306
                 Connect_Retry: 60
               Master_Log_File: mysql-bin.000002
           Read_Master_Log_Pos: 973
                Relay_Log_File: linux191-relay-bin.000004
                 Relay_Log_Pos: 657
         Relay_Master_Log_File: mysql-bin.000002
              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: Query caused different errors on master and slave.     Error on master: message (format)='Column count of %s.%s is wrong. Expected %d, found %d. The table is probably corrupted' error code=1805 ; Error on slave: actual message='no error', error code=0. Default database: 'a1'. Query: 'drop database a1'
                  Skip_Counter: 0
           Exec_Master_Log_Pos: 358
               Relay_Log_Space: 1883
               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: NULL
 Master_SSL_Verify_Server_Cert: No
                 Last_IO_Errno: 0
                 Last_IO_Error:
                Last_SQL_Errno: 0
                Last_SQL_Error: Query caused different errors on master and slave.     Error on master: message (format)='Column count of %s.%s is wrong. Expected %d, found %d. The table is probably corrupted' error code=1805 ; Error on slave: actual message='no error', error code=0. Default database: 'a1'. Query: 'drop database a1'
   Replicate_Ignore_Server_Ids:
              Master_Server_Id: 192
                Master_SSL_Crl:
            Master_SSL_Crlpath:
                    Using_Gtid: No
                   Gtid_IO_Pos:
       Replicate_Do_Domain_Ids:
   Replicate_Ignore_Domain_Ids:
                 Parallel_Mode: conservative
                     SQL_Delay: 0
           SQL_Remaining_Delay: NULL
       Slave_SQL_Running_State:
              Slave_DDL_Groups: 6
Slave_Non_Transactional_Groups: 0
    Slave_Transactional_Groups: 0
1 row in set (0.000 sec)
数据同步测试
###Server2上插入数据
MariaDB [a1]> insert into test values(123);
Query OK, 1 row affected (0.01 sec)

MariaDB [a1]> insert into test values(456);
Query OK, 1 row affected (0.00 sec)

###Server1上查看数据
MariaDB [a1]> select * from test;
+------+
| id   |
+------+
|    1 |
|    2 |
|  123 |
|  456 |
+------+
4 rows in set (0.00 sec)
MariaDB主主复制搭建成功

故障解决

在从服务器数据库上执行以下命令开启同步时出现错误信息
change master to \
master_host='10.40.200.191', \
master_user='sync', \
master_password='123456', \
master_log_file='mysql-bin.000002', \
master_log_pos=973;
错误信息
ERROR 1201 (HY000): Could not initialize master info structure for ''; more error messages can be found in the MariaDB error log
原因:数据库程序版本升级,没有移除旧的mysql-bin及mysql-bin.index文件,在其中保存旧的mysql-bin日志文件的路径,而在其中又找不到新的相匹配的日志文件,故而出现此错误。
解决方案1:停止同步,并移除相应的mysql-bin级mysql-bin.index文件后重新开启同步。(不推荐,除非数据有完整的备份)
解决方案二:
###在从服务器上登陆数据库,依次执行以下命令
###stop slave;

###重置slave
reset slave;

change master to \
master_host='10.40.200.191', \
master_user='sync', \
master_password='123456', \
master_log_file='mysql-bin.000002', \
master_log_pos=973;

start slave;

###问题解决
查看slave同步状态时候出现以下错误信息
Slave_IO_Running:Connecting 
Slave_SQL_Running:Yes
故障原因
1、同步账号密码错误
2、网络故障
3、防火墙未开启数据库访问端口
4、权限不足
Slave_IO_Running:Yes
Slave_SQL_Running:No
故障原因
在Server2上执行systemctl stop mariadb模拟从数据库宕机之后重新启动数据库之后在start slave后出现此故障信息
解决方案:
stop slave ;
set GLOBAL SQL_SLAVE_SKIP_COUNTER=1;
start slave ;

执行以上命令之后,使用命令查看slave同步状态:

###查看同步状态
show slave status \G
###若仍旧出现以下信息
Slave_IO_Running:Yes
Slave_SQL_Running:No

###重复执行以下命令
stop slave ;
set GLOBAL SQL_SLAVE_SKIP_COUNTER=1;
start slave ;

###有时候多试几次就OK了,具体原因未知
###网上查找了很多信息都是千篇一律的执行这三条命令,命令没有问题,重复执行几次就正常了。
###显示正常之后注意进行数据同步测试,有时显示正常数据同步失败。

开启bin-log后,spug运维程序在登陆时出现如下错误信息

Cannot execute statement: impossible to write to binary log since BINLOG_FORMAT = STATEMENT and at least one table uses a storage engine limited to row-based logging. InnoDB is limited to row-logging when transaction isolation level is READ COMMITTED or READ UNCOMMITTED.
参考链接
mysql默认的binlog_format是STATEMENT。
从 MySQL 5.1.12 开始,可以用以下三种模式来实现:基于SQL语句的复制(statement-based replication, SBR),基于行的复制(row-based replication, RBR),混合模式复制(mixed-based replication, MBR)。相应地,binlog的格式也有三种:STATEMENT,ROW,MIXED。
如果你采用默认隔离级别REPEATABLE-READ,那么建议binlog_format=ROW。如果你是READ-COMMITTED隔离级别,binlog_format=MIXED和binlog_format=ROW效果是一样的,binlog记录的格式都是ROW,对主从复制来说是很安全的参数。

解决方案

方法一
mysql> STOP SLAVE;
Query OK, 0 rows affected (0.02 sec)

 mysql>  SET GLOBAL binlog_format=ROW;
Query OK, 0 rows affected (0.00 sec)

 mysql> START SLAVE;
Query OK, 0 rows affected (0.00 sec)
但是这样只是一次性的,重启后失效。
方案二
永久生效,需要修改my.cnf
# binary logging format - ROW
binlog_format=ROW

###修改之后重启数据库生效,重启之前先stop slave,然后再重启数据库,最后在start mariadb

发表评论