詳解MySQL主從復(fù)制實(shí)戰(zhàn) - 基于GTID的復(fù)制
基于GTID的復(fù)制
簡介
基于GTID的復(fù)制是MySQL 5.6后新增的復(fù)制方式.
GTID (global transaction identifier) 即全局事務(wù)ID, 保證了在每個(gè)在主庫上提交的事務(wù)在集群中有一個(gè)唯一的ID.
在原來基于日志的復(fù)制中, 從庫需要告知主庫要從哪個(gè)偏移量進(jìn)行增量同步, 如果指定錯(cuò)誤會(huì)造成數(shù)據(jù)的遺漏, 從而造成數(shù)據(jù)的不一致.
而基于GTID的復(fù)制中, 從庫會(huì)告知主庫已經(jīng)執(zhí)行的事務(wù)的GTID的值, 然后主庫會(huì)將所有未執(zhí)行的事務(wù)的GTID的列表返回給從庫. 并且可以保證同一個(gè)事務(wù)只在指定的從庫執(zhí)行一次.
實(shí)戰(zhàn)
1、在主庫上建立復(fù)制賬戶并授予權(quán)限
基于GTID的復(fù)制會(huì)自動(dòng)地將沒有在從庫執(zhí)行的事務(wù)重放, 所以不要在其他從庫上建立相同的賬號(hào). 如果建立了相同的賬戶, 有可能造成復(fù)制鏈路的錯(cuò)誤.
mysql> create user 'repl'@'172.%' identified by '123456';
注意在生產(chǎn)上的密碼必須依照相關(guān)規(guī)范以達(dá)到一定的密碼強(qiáng)度, 并且規(guī)定在從庫上的特定網(wǎng)段上才能訪問主庫.
mysql> grant replication slave on *.* to 'repl'@'172.%';
查看用戶
mysql> select user, host from mysql.user; +-----------+-----------+ | user | host | +-----------+-----------+ | prontera | % | | root | % | | mysql.sys | localhost | | root | localhost | +-----------+-----------+ 4 rows in set (0.00 sec)
查看授權(quán)
mysql> show grants for repl@'172.%'; +--------------------------------------------------+ | Grants for repl@172.% | +--------------------------------------------------+ | GRANT REPLICATION SLAVE ON *.* TO 'repl'@'172.%' | +--------------------------------------------------+ 1 row in set (0.00 sec)
2、配置主庫服務(wù)器
[mysqld] log_bin = /var/log/mysql/mysql-bin log_bin_index = /var/log/mysql/mysql-bin.index binlog_format = row server_id = 101 gtid_mode = ON enforce_gtid_consistency = ON #log_slave_updates = ON
NOTE: 把日志與數(shù)據(jù)分開是個(gè)好習(xí)慣, 最好能放到不同的數(shù)據(jù)分區(qū)
enforce_gtid_consistency 強(qiáng)制GTID一致性, 啟用后以下命令無法再使用
create table ... select ...
mysql> create table dept select * from departments; ERROR 1786 (HY000): Statement violates GTID consistency: CREATE TABLE ... SELECT.
因?yàn)閷?shí)際上是兩個(gè)獨(dú)立事件, 所以只能將其拆分先建立表, 然后再把數(shù)據(jù)插入到表中
create temporary table
事務(wù)內(nèi)部不能創(chuàng)建臨時(shí)表
mysql> begin; Query OK, 0 rows affected (0.00 sec) mysql> create temporary table dept(id int); ERROR 1787 (HY000): Statement violates GTID consistency: CREATE TEMPORARY TABLE and DROP TEMPORARY TABLE can only be executed outside transactional context. These statements are also not allowed in a function or trigger because functions and triggers are also considered to be multi-statement transactions.
同一事務(wù)中更新事務(wù)表與非事務(wù)表(MyISAM)
mysql> CREATE TABLE `dept_innodb` (id INT(11) UNSIGNED NOT NULL PRIMARY KEY AUTO_INCREMENT); Query OK, 0 rows affected (0.04 sec) mysql> CREATE TABLE `dept_myisam` (id INT(11) UNSIGNED NOT NULL PRIMARY KEY AUTO_INCREMENT) ENGINE = `MyISAM`; Query OK, 0 rows affected (0.03 sec) mysql> begin; Query OK, 0 rows affected (0.00 sec) mysql> insert into dept_innodb(id) value(1); Query OK, 1 row affected (0.00 sec) mysql> insert into dept_myisam(id) value(1); ERROR 1785 (HY000): Statement violates GTID consistency: Updates to non-transactional tables can only be done in either autocommitted statements or single-statement transactions, and never in the same statement as updates to transactional tables.
所以建議選擇Innodb作為默認(rèn)的數(shù)據(jù)庫引擎.
log_slave_updates 該選項(xiàng)在MySQL 5.6版本時(shí)基于GTID的復(fù)制是必須的, 但是其增大了從服務(wù)器的IO負(fù)載, 而在MySQL 5.7中該選項(xiàng)已經(jīng)不是必須項(xiàng)
3、配置從庫服務(wù)器
master_info_repository 與relay_log_info_repository
在MySQL 5.6.2之前, slave記錄的master信息以及slave應(yīng)用binlog的信息存放在文件中, 即master.info與relay-log.info. 在5.6.2版本之后, 允許記錄到table中. 對(duì)應(yīng)的表分別為mysql.slave_master_info與mysql.slave_relay_log_info, 且這兩個(gè)表均為innodb引擎表.
[mysqld] log_bin = /var/log/mysql/mysql-bin log_bin_index = /var/log/mysql/mysql-bin.index server_id = 102 # slaves relay_log = /var/log/mysql/relay-bin relay_log_index = /var/log/mysql/relay-bin.index relay_log_info_file = /var/log/mysql/relay-bin.info enforce_gtid_consistency = ON log_slave_updates = ON read_only = ON master_info_repository = TABLE relay_log_info_repository = TABLE
4、從庫數(shù)據(jù)初始化 - [optional]
先在主庫上備份數(shù)據(jù)
mysqldump --single-transaction --master-data=2 --triggers --routines --all-databases --events -u root -p > backup.sql
—master-data=2 該選項(xiàng)將當(dāng)前服務(wù)器的binlog的位置和文件名追加到輸出文件中(show master status). 如果為1, 將偏移量拼接到CHANGE MASTER 命令. 如果為2, 輸出的偏移量信息將會(huì)被注釋。
--all-databases 因?yàn)榛贕TID的復(fù)制會(huì)記錄全部的事務(wù), 所以要構(gòu)建一個(gè)完整的dump這個(gè)選項(xiàng)是推薦的
常見錯(cuò)誤
當(dāng)從庫導(dǎo)入SQL的時(shí)候出現(xiàn)
ERROR 1840 (HY000) at line 24: @@GLOBAL.GTID_PURGED can only be set when @@GLOBAL.GTID_EXECUTED is empty.
此時(shí)進(jìn)入從庫的MySQL Command Line, 使用reset master即可
5、啟動(dòng)基于GTID的復(fù)制
現(xiàn)有master@172.20.0.2和slave@172.20.0.3, 并且已經(jīng)通過mysqldump將數(shù)據(jù)同步至從庫slave中. 現(xiàn)在在從服務(wù)器slave上配置復(fù)制鏈路
mysql> change master to master_host='master', master_user='repl', master_password='123456', master_auto_position=1; Query OK, 0 rows affected, 2 warnings (0.06 sec)
啟動(dòng)復(fù)制
mysql> start slave;
啟動(dòng)成功后查看slave的狀態(tài)
mysql> show slave status\G *************************** 1. row *************************** Slave_IO_State: Queueing master event to the relay log Master_Host: master Master_User: repl Master_Port: 3306 Connect_Retry: 60 Master_Log_File: mysql-bin.000002 Read_Master_Log_Pos: 12793692 Relay_Log_File: relay-bin.000002 Relay_Log_Pos: 1027 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: 814 Relay_Log_Space: 12794106 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: 5096 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: 101 Master_UUID: a9fd4765-ec70-11e6-b543-0242ac140002 Master_Info_File: mysql.slave_master_info SQL_Delay: 0 SQL_Remaining_Delay: NULL Slave_SQL_Running_State: Reading event from the relay log Master_Retry_Count: 86400 Master_Bind: Last_IO_Error_Timestamp: Last_SQL_Error_Timestamp: Master_SSL_Crl: Master_SSL_Crlpath: Retrieved_Gtid_Set: a9fd4765-ec70-11e6-b543-0242ac140002:1-39 Executed_Gtid_Set: a9fd4765-ec70-11e6-b543-0242ac140002:1-4 Auto_Position: 1 Replicate_Rewrite_DB: Channel_Name: Master_TLS_Version: 1 row in set (0.00 sec)
當(dāng)Slave_IO_Running, Slave_SQL_Running為YES,
且Slave_SQL_Running_State 為Slave has read all relay log; waiting for more updates時(shí)表示成功構(gòu)建復(fù)制鏈路
6、總結(jié)
優(yōu)點(diǎn)
- 因?yàn)椴挥檬止ぴO(shè)置日志偏移量, 可以很方便地進(jìn)行故障轉(zhuǎn)移
- 如果啟用log_slave_updates那么從庫不會(huì)丟失主庫上的任何修改
缺點(diǎn)
- 對(duì)執(zhí)行的SQL有一定限制
- 僅支持MySQL 5.6之后的版本, 而且不建議使用早期5.6版本
以上就是本文的全部內(nèi)容,希望對(duì)大家的學(xué)習(xí)有所幫助,也希望大家多多支持腳本之家。
相關(guān)文章
MySQL中distinct語句去查詢重復(fù)記錄及相關(guān)的性能討論
這篇文章主要介紹了MySQL中distinct語句去查詢重復(fù)記錄及相關(guān)的性能討論,文中的觀點(diǎn)是在一定情況下避免在最高層查詢中使用distinct,需要的朋友可以參考下2016-01-01InnoDB的關(guān)鍵特性-插入緩存,兩次寫,自適應(yīng)hash索引詳解
下面小編就為大家?guī)硪黄狪nnoDB的關(guān)鍵特性-插入緩存,兩次寫,自適應(yīng)hash索引詳解。小編覺得挺不錯(cuò)的,現(xiàn)在就分享給大家,也給大家做個(gè)參考。一起跟隨小編過來看看吧2017-03-03MySql?InnoDB存儲(chǔ)引擎之Buffer?Pool運(yùn)行原理講解
緩沖池是用于存儲(chǔ)InnoDB表,索引和其他輔助緩沖區(qū)的緩存數(shù)據(jù)的內(nèi)存區(qū)域。緩沖池的大小對(duì)于系統(tǒng)性能很重要。更大的緩沖池可以減少磁盤I/O來多次訪問同一表數(shù)據(jù)。在專用數(shù)據(jù)庫服務(wù)器上,可以將緩沖池大小設(shè)置為計(jì)算機(jī)物理內(nèi)存大小的百分之802023-01-01MySQL多個(gè)字段拼接去重的實(shí)現(xiàn)示例
在MySQL中,我們經(jīng)常會(huì)遇到需要將多個(gè)字段進(jìn)行拼接并去重的情況,本文就來介紹一下MySQL多個(gè)字段拼接去重的實(shí)現(xiàn)示例,具有一定的參考價(jià)值,感興趣的可以了解一下2024-01-01