實做MySQL Master Master Replication
MySQL Master Master Replication 顧名思義就是兩台MySQL DB server都是Master Role
意指 : 資料的寫入無論在哪一台DB server都能夠同步到另一台
環境架構 : CentOS 7 + MariaDB 5.5
Master 1 IP : 192.168.10.147
Master 2 IP : 192.168.10.41
※ 在Master 1主機下
1. 編輯 /etc/my.cnf,加入以下,然後重啟MariaDB
log-bin=mysql-bin
server_id=1
systemctl restart mariadb
2. 建立同步user account和權限
# mysql -uroot -p
MariaDB [(none)]> CREATE USER 'rep'@'%' IDENTIFIED BY '2wsx#EDC';
MariaDB [(none)]> GRANT REPLICATION SLAVE ON *.* TO 'rep'@'%';
MariaDB [(none)]> flush privileges;
3. 查看目前Binlog狀態,並記錄一下
MariaDB [(none)]> show master status;
+------------------+----------+--------------+------------------+
| File | Position | Binlog_Do_DB | Binlog_Ignore_DB |
+------------------+----------+--------------+------------------+
| mysql-bin.000001 | 334 | | |
+------------------+----------+--------------+------------------+
1 row in set (0.00 sec)
※ 在Master 2主機下
1. 編輯 /etc/my.cnf,加入以下,然後重啟MariaDB
server_id=2
log-bin=mysql-bin
systemctl restart mariadb
2. 建立同步user account和權限
# mysql -uroot -p
MariaDB [(none)]> CREATE USER 'rep'@'%' IDENTIFIED BY '2wsx#EDC';
MariaDB [(none)]> GRANT REPLICATION SLAVE ON *.* TO 'rep'@'%';
MariaDB [(none)]> flush privileges;
3. 啟用Master2同步
MariaDB [(none)]> stop slave;
-> change master to master_host = '192.168.10.147' ,
-> master_user = 'rep' , master_password = '2wsx#EDC' ,
-> master_log_file = 'mysql-bin.000001' , master_log_pos = 334;
Query OK, 0 rows affected (0.04 sec)
MariaDB [(none)]> start slave;
4. 查看是否啟用同步
MariaDB [(none)]> show slave status\G ;
*************************** 1. row ***************************
Slave_IO_State: Waiting for master to send event
Master_Host: 192.168.10.147
Master_User: rep
Master_Port: 3306
Connect_Retry: 60
Master_Log_File: mysql-bin.000001
Read_Master_Log_Pos: 334
Relay_Log_File: mariadb-relay-bin.000004
Relay_Log_Pos: 618
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: 334
Relay_Log_Space: 914
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: 1
1 row in set (0.00 sec)
5. 查看目前Binlog狀態,並記錄一下
MariaDB [(none)]> show master status;
+------------------+----------+--------------+------------------+
| File | Position | Binlog_Do_DB | Binlog_Ignore_DB |
+------------------+----------+--------------+------------------+
| mysql-bin.000001 | 332 | | |
+------------------+----------+--------------+------------------+
1 row in set (0.00 sec)
※ 在Master 1主機下
1. 啟用同步
MariaDB [(none)]> stop slave;
change master to master_host = '192.168.10.41' ,
-> master_user = 'rep' , master_password = '2wsx#EDC' ,
-> master_log_file = 'mysql-bin.000001' , master_log_pos = 332;
Query OK, 0 rows affected (0.04 sec)
MariaDB [(none)]> start slave;
2. 查看同步狀態
MariaDB [(none)]> show slave status \G;
*************************** 1. row ***************************
Slave_IO_State: Waiting for master to send event
Master_Host: 192.168.10.41
Master_User: rep
Master_Port: 3306
Connect_Retry: 60
Master_Log_File: mysql-bin.000001
Read_Master_Log_Pos: 332
Relay_Log_File: mariadb-relay-bin.000002
Relay_Log_Pos: 616
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: 332
Relay_Log_Space: 912
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: 2
1 row in set (0.00 sec)
最後測試一下
在Master 1上新增DB,看看Master 2會不會也建立
在Master 2上刪除DB,看看Master 1會不會也刪除