之所以把MySQL.GTID_EXECUTED表的作用和PREVIOUS GTID EVENT的改变放到一起进行描述是因为它们后面文章探讨的基础。这部分使用到了我自己使用C语言写的原生BINLOG解析工具INFOBIN。
百度云盘下载如下:http://pan.baidu.com/s/1jHIWUN0
一、GTID EVENT
为什么要先描述什么是GTID EVENT呢?因为后面会用到,实际上在其中核心元素就是一个形如:
31704d8a-da74-11e7-b6bf-52540a7d243:100009
的一个GTID 处于整个事务EVENT中的开始,用于描述这个事务的GTID 是多少,当然在5.7中为了支持MTS其中还封装了LAST_COMMIT/SEQUENCE_NUMBER。那么使用INFOBIN工具查看一个INSERT单条语句完整事务的EVENT包括如下:
>Gtid Event:Pos:234(0Xea) N_pos:299(0X12b) Time:1513135186 Event_size:65(bytes)
Gtid:31704d8a-da74-11e7-b6bf-52540a7d243:100009 last_committed=0 sequence_number=1
-->Query Event:Pos:299(0X12b) N_Pos:371(0X173) Time:1513135186 Event_size:72(bytes)
Exe_time:0 Use_db:test Statment(35b-trun):BEGIN /*!Trx begin!*/ Gno:100009
---->Map Event:Pos371(0X173) N_pos:415(0X19f) Time:1513135186 Event_size:44(bytes)
TABLE_ID:108 DB_NAME:test TABLE_NAME:a Gno:100009
------>Insert Event:Pos:415(0X19f) N_pos:455(0X1c7) Time:1513135186 Event_size:40(bytes)
Dml on table: test.a table_id:108 Gno:100009
>Xid Event:Pos:455(0X1c7) N_Pos:486(0X1e6) Time:1513135186 Event_size:31(bytes)
COMMIT; /*!Trx end*/ Gno:100009
当然也可以使用MySQLBINLOG进行分析,只是格式稍微不那么友好。
二、GTID_EXECUTED表的作用
这一部分是重点中的重点,也是我以前一直疑惑的,请大家细细品读。
官方文档这样描述GTID_EXECUTED表
Beginning with MySQL 5.7.5, GTIDs are stored in a table named gtid_executed, in the mysql
database. A row in this table contains, for each GTID or set of GTIDs that it represents, the UUID of the
originating server, and the starting and ending transaction IDs of the set; for a row referencing only a
single GTID, these last two values are the same.
也就是说GTID_EXECUTED表是GTID持久化的一个工具,如前文所描述GTID_STATE中的
GET_EXECUTED_GTIDS/GET_LOST_GTIDS/GET_GTIDS_ONLY_IN_TABLE/GET_PREVIOUS_GTIDS_LOGGED这些数据都是存储在内存中的,那么在数据库重启后需要进行初始化,那么这需要读取GTID持久化的介质,我们可以发现GTID_EXECUTED是一个
INNODB表建表语句如下,并且我们可以手动更改它,但是千万不要这么干:
Table: gtid_executed
Create Table: CREATE TABLE `gtid_executed` (
`source_uuid` char(36) NOT NULL COMMENT 'uuid of the source where the transaction was originally executed.',
`interval_start` bigint(20) NOT NULL COMMENT 'First number of interval.',
`interval_end` bigint(20) NOT NULL COMMENT 'Last number of interval.',
PRIMARY KEY (`source_uuid`,`interval_start`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8 STATS_PERSISTENT=0
那么在5.7.5以前没有GTID_EXECUTED表不是也没有问题吗?其实除了GTID_EXECUTED表以外我们还有一个GTID持久化的介质那就是BINLOG中的GTID EVENT。所以总结一下GTID持久化介质:
GTID_EXECUTED表
BINLOG中的GTID EVENT
那么既然有了BINLOG的GTID EVENT进行持久化那么为什么还需要GTID_EXECUTED表呢?这实际上就是5.7.5过后的一个优化,我们可以反过来思考在5.6中如果使用了GTID 做从库,从库如果不开启BINLOG并且同时设置LOG_SLAVE_UPDATES=TURE那么从库的执行过的GTID事务是没有办法持久化的。我们来一段5.6官方文档对于搭建GTID从库的其中一步:
Step 3: Restart both servers with GTIDs enabled. To enable binary logging with global
transaction identifiers, each server must be started with GTID mode, binary logging, slave update
logging enabled, and with statements that are unsafe for GTID-based replication disabled. In addition,
you should prevent unwanted or accidental updates from being performed on either server by starting
both in read-only mode. This means that both servers must be started with (at least) the options shown
in the following invocation of mysqld_safe:
shell> mysqld_safe --gtid_mode=ON --log-bin --log-slave-updates --enforce-gtid-consistency &
开启BINLOG同时设置设置LOG_SLAVE_UPDATES=TURE必然造成一个问题,实际上从库很多时候我们是不需要做级联SLAVE,设置LOG_SLAVE_UPDATES=TURE会造成需要额外的空间和性能开销。自然这种情况下我们需要另外的一种GTID持久化介质,而并不是BINLOG中的GTID EVENT。为了解决这个问题,5.7中GTID_EXECUTED表应运而生了。然而GTID_EXECUTED表是否需要实时更新呢?显然在slave端不开启BINLOG或者开启BINLOG不设置LOG_SLAVE_UPDATES=TURE的情况下它需要实时更新,因为I/O THREAD执行过得GTID是必须持久化的,而在主库上因为有BINLOG的GTID EVENT的存在他是不需要实时更新的,这样不同的对待方式也能够减轻负担提高性能。
同时在官方文档上也有相关描述它分为是否开始BINLOG进行描述,但是其描述并不是最详细的。所以这部分在后面我会进行详细描述。
三、PREVIOUS GTID EVENT的改变
PREVIOUS GTID EVENT是包含在每一个BINLOG的开头用于描述所有以前BINLOG所包含的全部GTID的一个集合(包括已经删除的BINLOG)如:
da267088-9c22-11e7-ab56-5254008768e3:1-32
在5.6中如果不开启GTID,那么BINLOG是不会包含这个PREVIOUS GTID EVENT的,但是在5.7中不开启GTID也会包含这个PREVIOUS GTID EVENT,实际这一点的改变其意义也是非常巨大,简单的说他为快速扫描BINLOG(BINLOG_GTID_SIMPLE_RECOVERY=TURE)获得正确GTID集合提供了基础,否则将会扫描大量的BINLOG,从而浪费I/O性能,这是5.6中一个非常严重的问题,在5.7的官方文档这样描述:
When binlog_gtid_simple_recovery=TRUE, which is the default in MySQL 5.7.7 and
later, the server iterates only the oldest and the newest binary log files and the values of
gtid_purged and gtid_executed are computed based only on Previous_gtids_log_event
or Gtid_log_event found in these files. This ensures only two binary log files are iterated during
server restart or when binary logs are being purged
当然这部分也会在后面进行详细的描述,这里只是简单提一下。那么我们通过MySQLBINLOG 和INFOBIN工具分别确认这一点。
- 5.6. 26 不开启GTID
MySQLBINLOG:
*!50530 SET @@SESSION.PSEUDO_SLAVE_MODE=1*/;
/*!50003 SET @OLD_COMPLETION_TYPE=@@COMPLETION_TYPE,COMPLETION_TYPE=0*/;
DELIMITER /*!*/;
# at 4
#171211 16:20:10 server id 20155 end_log_pos 120 CRC32 0x12617db7 Start: binlog v 4, server v 5.6.26-74.0-log created 171211 16:20:10
# Warning: this binlog is either in use or was not closed properly.
# at 120
#171211 16:20:14 server id 20155 end_log_pos 192 CRC32 0x696752cb Query thread_id=30
INFOBIN:
------------Detail now--------------
>Format description log Event:Pos:4(0X4) N_pos:120(0X78) Time:1512980410 Event_size:116(bytes)
-->Query Event:Pos:120(0X78) N_Pos:192(0Xc0) Time:1512980414 Event_size:72(bytes)
Exe_time:0 Use_db:test Statment(35b-trun):BEGIN /*!Trx begin!*/ Gno:0
---->Map Event:Pos192(0Xc0) N_pos:241(0Xf1) Time:1512980414 Event_size:49(bytes)
TABLE_ID:91 DB_NAME:test TABLE_NAME:testpo Gno:0
------>Insert Event:Pos:241(0Xf1) N_pos:281(0X119) Time:1512980414 Event_size:40(bytes)
Dml on table: test.testpo table_id:91 Gno:0
>Xid Event:Pos:281(0X119) N_Pos:312(0X138) Time:1512980414 Event_size:31(bytes)
COMMIT; /*!Trx end*/ Gno:0
我们并没有发现PREVIOUS GTID EVENT,也就是5.6如果不开启GTID则不包含PREVIOUS GTID EVENT。
- 5.7.14
MySQLBINLOG:
/*!50530 SET @@SESSION.PSEUDO_SLAVE_MODE=1*/;
/*!50003 SET @OLD_COMPLETION_TYPE=@@COMPLETION_TYPE,COMPLETION_TYPE=0*/;
DELIMITER /*!*/;
# at 4
#171211 16:26:49 server id 1 end_log_pos 123 CRC32 0xf9a36298 Start: binlog v 4, server v 5.7.14-7-debug-log created 171211 16:26:49
# Warning: this binlog is either in use or was not closed properly.
# at 123
#171211 16:26:49 server id 1 end_log_pos 194 CRC32 0x5865633f **Previous-GTIDs**
# da267088-9c22-11e7-ab56-5254008768e3:1-32
# at 194
INFOBIN:
------------Detail now--------------
>Format description log Event:Pos:4(0X4) N_pos:123(0X7b) Time:1512980809 Event_size:119(bytes)
>Previous gtid Event:Pos:123(0X7b) N_pos:194(0Xc2) Time:1512980809 Event_size:71(bytes)
>Anonymous gtid Event:Pos:194(0Xc2) N_pos:259(0X103) Time:1512980814 Event_size:65(bytes)
Gtid:Anonymous(Gno=0) last_committed=0 sequence_number=1
-->Query Event:Pos:259(0X103) N_Pos:331(0X14b) Time:1512980814 Event_size:72(bytes)
Exe_time:0 Use_db:test Statment(35b-trun):BEGIN /*!Trx begin!*/ Gno:0
---->Map Event:Pos331(0X14b) N_pos:380(0X17c) Time:1512980814 Event_size:49(bytes)
TABLE_ID:154 DB_NAME:test TABLE_NAME:testpo Gno:0
------>Insert Event:Pos:380(0X17c) N_pos:420(0X1a4) Time:1512980814 Event_size:40(bytes)
Dml on table: test.testpo table_id:154 Gno:0
>Xid Event:Pos:420(0X1a4) N_Pos:451(0X1c3) Time:1512980814 Event_size:31(bytes)
COMMIT; /*!Trx end*/ Gno:0
我们清晰的看到这里包含了PREVIOUS GTID EVENT,当然我们还发现了ANONYMOUS GTID EVENT这也是5.7中变化,5.7中即使不开始GTID每个事务也包含也一个ANONYMOUS GTID EVENT,虽然没有GTID但是它任然包含了LAST_COMMITTED/SEQUENCE_NUMBER。
四、本节小结
学习完本节至少能够学习到:
- 1、什么是GTID EVENT。包含什么重要元素。
- 2、为什么需要GTID_EXECUTED表及其作用。
- 3、5.7中PREVIOUS GTID EVENT发生了哪些改变。
- 4、简单了解PREVIOUS GTID EVENT的改变意味着什么。
原文发布时间为:2018-01-17
本文作者:高鹏(重庆八怪)
本文来自云栖社区合作伙伴“老叶茶馆”,了解相关信息可以关注“老叶茶馆”微信公众号