準(zhǔn)備:
服務(wù)器1:192.168.37.130 (主)
服務(wù)器2:192.168.37.131 (從)
MySQL 版本:5.7.24
開始:
主服務(wù)器設(shè)置:
- 修改 my.cnf 配置冒掌,完成后重啟數(shù)據(jù)庫(kù)
[mysqld]
# 主服務(wù)器啟用二進(jìn)制日志篷朵,之后從服務(wù)器將讀取該日志岗照,復(fù)制到從服務(wù)器的 Relay log 中,并定時(shí)執(zhí)行新增的內(nèi)容
log-bin=/usr/local/mysql/logs/mysql-bin
# 指定數(shù)據(jù)庫(kù)
binlog-do-db=xxxx 二進(jìn)制日志記錄的數(shù)據(jù)庫(kù)
# 忽略數(shù)據(jù)庫(kù)
binlog-ignore-db=xxxx
# 忽略 server-id 配置時(shí)吨凑,默認(rèn)其為 0磅崭,主服務(wù)器將拒絕來(lái)自從服務(wù)器的任何連接
server-id=1
# 使用帶事務(wù)的InnoDB進(jìn)行復(fù)制設(shè)置時(shí)盡可能提高持久性和一致性
innodb_flush_log_at_trx_commit = 1
sync_binlog = 1
- 確保 skip_networking 為關(guān)閉狀態(tài)(OFF)
mysql> SHOW VARIABLES LIKE '%skip_networking%';
+-----------------+-------+
| Variable_name | Value |
+-----------------+-------+
| skip_networking | OFF |
+-----------------+-------+
1 row in set (0.00 sec)
- 創(chuàng)建從服務(wù)器用戶復(fù)制數(shù)據(jù)的用戶并授予權(quán)限
mysql> GRANT REPLICATION SLAVE ON *.* to 'slave1'@'192.168.10.131' identified by 'password';
從服務(wù)器配置:
- 修改 my.cnf 配置柱徙,完成后重啟
[mysqld]
server-id=2
# 設(shè)定需要復(fù)制的數(shù)據(jù)庫(kù)
replicate-do-db=xxx
# 設(shè)定需要忽略的數(shù)據(jù)庫(kù)
replicate-ignore-db=xxx
- 配置連接主服務(wù)器的賬號(hào)信息
mysql> CHANGE MASTER TO
-> MASTER_HOST='192.168.37.130',
-> MASTER_USER='slave1',
-> MASTER_PASSWORD='password';
Query OK, 0 rows affected, 2 warnings
- 啟動(dòng)復(fù)制線程
mysql> start slave;
Query OK, 0 rows affected (0.01 sec)
- 檢查狀態(tài) Slave_IO_Running 與 Slave_SQL_Running 為 YES 則表示成功啟動(dòng)
mysql> SHOW slave status\G;
*************************** 1. row ***************************
Slave_IO_State: Waiting for master to send event
Master_Host: 192.168.37.130
Master_User: slave1
Master_Port: 3306
Connect_Retry: 60
Master_Log_File: mysql-bin.000002
Read_Master_Log_Pos: 1464
Relay_Log_File: localhost-relay-bin.000004
Relay_Log_Pos: 1677
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:
Skip_Counter: 0
Exec_Master_Log_Pos: 1464
Relay_Log_Space: 2101
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
Master_UUID: c19b2ca3-b2e7-11ea-9aaa-000c29839863
Master_Info_File: /usr/local/mysql/data/master.info
SQL_Delay: 0
SQL_Remaining_Delay: NULL
Slave_SQL_Running_State: Slave 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:
Executed_Gtid_Set:
Auto_Position: 0
Replicate_Rewrite_DB:
Channel_Name:
Master_TLS_Version:
1 row in set (0.00 sec)
ERROR:
No query specified
測(cè)試效果
在主服務(wù)器上執(zhí)行創(chuàng)建或插入語(yǔ)句澎粟,在從服務(wù)器中檢查是否成功復(fù)制
注意事項(xiàng):
- 當(dāng)啟用主從復(fù)制并主服務(wù)器中還有數(shù)據(jù)時(shí),需要另外進(jìn)行處理纤控,可以先使用 mysqldump 將之前的數(shù)據(jù)復(fù)制到從數(shù)據(jù)庫(kù)
- 添加新的從服務(wù)器時(shí)挂捻,新的服務(wù)器的 server-id 不可與之前的服務(wù)器重復(fù)
常用命令
# 關(guān)閉從服務(wù)器所有類型線程,也就是停止從主服務(wù)器復(fù)制數(shù)據(jù)的操作
mysql> STOP SLAVE;
# 單獨(dú)關(guān)閉某個(gè)線程
mysql> STOP SLAVE IO_THREAD;
mysql> STOP SLAVE SQL_THREAD;
# 啟動(dòng)線程
mysql> START SLAVE;
mysql> START SLAVE IO_THREAD;
mysql> START SLAVE SQL_THREAD;
# 從庫(kù)刪除主從關(guān)系
mysql> RESET SLAVE;