4.6.7 mysqlbinlog — Utility for Processing Binary Log Files (original) (raw)

4.6.7 mysqlbinlog — Utility for Processing Binary Log Files

The server's binary log consists of files containing“events” that describe modifications to database contents. The server writes these files in binary format. To display their contents in text format, use themysqlbinlog utility. You can also usemysqlbinlog to display the contents of relay log files written by a replica server in a replication setup because relay logs have the same format as binary logs. The binary log and relay log are discussed further inSection 5.4.4, “The Binary Log”, andSection 16.2.4, “Relay Log and Replication Metadata Repositories”.

Invoke mysqlbinlog like this:

mysqlbinlog [options] log_file ...

For example, to display the contents of the binary log file named binlog.000003, use this command:

mysqlbinlog binlog.000003

The output includes events contained inbinlog.000003. For statement-based logging, event information includes the SQL statement, the ID of the server on which it was executed, the timestamp when the statement was executed, how much time it took, and so forth. For row-based logging, the event indicates a row change rather than an SQL statement. See Section 16.2.1, “Replication Formats”, for information about logging modes.

Events are preceded by header comments that provide additional information. For example:

# at 141
#100309  9:28:36 server id 123  end_log_pos 245
  Query thread_id=3350  exec_time=11  error_code=0

In the first line, the number following at indicates the file offset, or starting position, of the event in the binary log file.

The second line starts with a date and time indicating when the statement started on the server where the event originated. For replication, this timestamp is propagated to replica servers.server id is theserver_id value of the server where the event originated. end_log_pos indicates where the next event starts (that is, it is the end position of the current event + 1). thread_id indicates which thread executed the event.exec_time is the time spent executing the event, on a replication source server. On a replica, it is the difference of the end execution time on the replica minus the beginning execution time on the source. The difference serves as an indicator of how much replication lags behind the source.error_code indicates the result from executing the event. Zero means that no error occurred.

Note

When using event groups, the file offsets of events may be grouped together and the comments of events may be grouped together. Do not mistake these grouped events for blank file offsets.

The output from mysqlbinlog can be re-executed (for example, by using it as input tomysql) to redo the statements in the log. This is useful for recovery operations after an unexpected server exit. For other usage examples, see the discussion later in this section and in Section 7.5, “Point-in-Time (Incremental) Recovery”.

You can use mysqlbinlog to read binary log files directly and apply them to the local MySQL server. You can also read binary logs from a remote server by using the--read-from-remote-server option. To read remote binary logs, the connection parameter options can be given to indicate how to connect to the server. These options are --host,--password,--port,--protocol,--socket, and--user.

When running mysqlbinlog against a large binary log, be careful that the filesystem has enough space for the resulting files. To configure the directory thatmysqlbinlog uses for temporary files, use theTMPDIR environment variable.

mysqlbinlog sets the value ofpseudo_slave_mode to true before executing any SQL statements. This system variable affects the handling of XA transactions.

mysqlbinlog supports the following options, which can be specified on the command line or in the[mysqlbinlog] and [client] groups of an option file. For information about option files used by MySQL programs, see Section 4.2.2.2, “Using Option Files”.

Table 4.23 mysqlbinlog Options

Option Name Description Introduced Deprecated
--base64-output Print binary log entries using base-64 encoding
--bind-address Use specified network interface to connect to MySQL Server
--binlog-row-event-max-size Binary log max event size
--character-sets-dir Directory where character sets are installed
--connection-server-id Used for testing and debugging. See text for applicable default values and other particulars
--database List entries for just this database
--debug Write debugging log
--debug-check Print debugging information when program exits
--debug-info Print debugging information, memory, and CPU statistics when program exits
--default-auth Authentication plugin to use
--defaults-extra-file Read named option file in addition to usual option files
--defaults-file Read only named option file
--defaults-group-suffix Option group suffix value
--disable-log-bin Disable binary logging
--exclude-gtids Do not show any of the groups in the GTID set provided
--force-if-open Read binary log files even if open or not closed properly
--force-read If mysqlbinlog reads a binary log event that it does not recognize, it prints a warning
--get-server-public-key Request RSA public key from server 5.7.23
--help Display help message and exit
--hexdump Display a hex dump of the log in comments
--host Host on which MySQL server is located
--idempotent Cause the server to use idempotent mode while processing binary log updates from this session only
--include-gtids Show only the groups in the GTID set provided
--local-load Prepare local temporary files for LOAD DATA in the specified directory
--login-path Read login path options from .mylogin.cnf
--no-defaults Read no option files
--offset Skip the first N entries in the log
--open-files-limit Specify the number of open file descriptors to reserve
--password Password to use when connecting to server
--plugin-dir Directory where plugins are installed
--port TCP/IP port number for connection
--print-defaults Print default options
--protocol Transport protocol to use
--raw Write events in raw (binary) format to output files
--read-from-remote-master Read the binary log from a MySQL replication source server rather than reading a local log file
--read-from-remote-server Read binary log from MySQL server rather than local log file
--result-file Direct output to named file
--rewrite-db Create rewrite rules for databases when playing back from logs written in row-based format. Can be used multiple times
--secure-auth Do not send passwords to server in old (pre-4.1) format Yes
--server-id Extract only those events created by the server having the given server ID
--server-id-bits Tell mysqlbinlog how to interpret server IDs in binary log when log was written by a mysqld having its server-id-bits set to less than the maximum; supported only by MySQL Cluster version of mysqlbinlog
--server-public-key-path Path name to file containing RSA public key 5.7.23
--set-charset Add a SET NAMES charset_name statement to the output
--shared-memory-base-name Shared-memory name for shared-memory connections (Windows only)
--short-form Display only the statements contained in the log
--skip-gtids Do not include the GTIDs from the binary log files in the output dump file
--socket Unix socket file or Windows named pipe to use
--ssl Enable connection encryption
--ssl-ca File that contains list of trusted SSL Certificate Authorities
--ssl-capath Directory that contains trusted SSL Certificate Authority certificate files
--ssl-cert File that contains X.509 certificate
--ssl-cipher Permissible ciphers for connection encryption
--ssl-crl File that contains certificate revocation lists
--ssl-crlpath Directory that contains certificate revocation-list files
--ssl-key File that contains X.509 key
--ssl-mode Desired security state of connection to server 5.7.11
--ssl-verify-server-cert Verify host name against server certificate Common Name identity
--start-datetime Read binary log from first event with timestamp equal to or later than datetime argument
--start-position Decode binary log from first event with position equal to or greater than argument
--stop-datetime Stop reading binary log at first event with timestamp equal to or greater than datetime argument
--stop-never Stay connected to server after reading last binary log file
--stop-never-slave-server-id Slave server ID to report when connecting to server
--stop-position Stop decoding binary log at first event with position equal to or greater than argument
--tls-version Permissible TLS protocols for encrypted connections 5.7.10
--to-last-log Do not stop at the end of requested binary log from a MySQL server, but rather continue printing to end of last binary log
--user MySQL user name to use when connecting to server
--verbose Reconstruct row events as SQL statements
--verify-binlog-checksum Verify checksums in binary log
--version Display version information and exit
INSERT INTO test.t1 (i) VALUES(100);  
INSERT INTO db2.t2 (j)  VALUES(200);  
USE test;  
INSERT INTO test.t1 (i) VALUES(101);  
INSERT INTO t1 (i)      VALUES(102);  
INSERT INTO db2.t2 (j)  VALUES(201);  
USE db2;  
INSERT INTO test.t1 (i) VALUES(103);  
INSERT INTO db2.t2 (j)  VALUES(202);  
INSERT INTO t2 (j)      VALUES(203);  

mysqlbinlog --database=test does not output the first two INSERT statements because there is no default database. It outputs the three INSERT statements following USE test, but not the threeINSERT statements followingUSE db2.
mysqlbinlog --database=db2 does not output the first two INSERT statements because there is no default database. It does not output the three INSERT statements followingUSE test, but does output the three INSERT statements followingUSE db2.
Row-based logging. mysqlbinlog outputs only entries that change tables belonging to_dbname_. The default database has no effect on this. Suppose that the binary log just described was created using row-based logging rather than statement-based logging. mysqlbinlog --database=test outputs only those entries that modify t1 in the test database, regardless of whether USE was issued or what the default database is.
If a server is running withbinlog_format set toMIXED and you want it to be possible to use mysqlbinlog with the--database option, you must ensure that tables that are modified are in the database selected by USE. (In particular, no cross-database updates should be used.)
When used together with the--rewrite-db option, the--rewrite-db option is applied first; then the --database option is applied, using the rewritten database name. The order in which the options are provided makes no difference in this regard.

mysqlbinlog --rewrite-db='dbcurrent->dbold' --rewrite-db='dbtest->dbcurrent' \  
    binlog.00001 > /tmp/statements.sql  

When used together with the--database option, the--rewrite-db option is applied first; then--database option is applied, using the rewritten database name. The order in which the options are provided makes no difference in this regard.
This means that, for example, ifmysqlbinlog is started with--rewrite-db='mydb->yourdb' --database=yourdb, then all updates to any tables in databases mydb andyourdb are included in the output. On the other hand, if it is started with--rewrite-db='mydb->yourdb' --database=mydb, thenmysqlbinlog outputs no statements at all: since all updates to mydb are first rewritten as updates to yourdb before applying the --database option, there remain no updates that match--database=mydb.

mysqlbinlog --skip-gtids binlog.000001 >  /tmp/dump.sql  
mysql -u root -p -e "source /tmp/dump.sql"  

You should not normally use this option in production or in recovery, except in the specific, and rare, scenarios where the GTIDs are actively unwanted. For example, an administrator might want to duplicate selected transactions (such as table definitions) from a deployment to another, unrelated, deployment that will not replicate to or from the original. In that scenario,--skip-gtids can be used to enable the administrator to apply the transactions as if they were new, and ensure that the deployments remain unrelated. However, you should only use this option if the inclusion of the GTIDs causes a known issue for your use case.

mysqlbinlog --start-datetime="2005-12-25 11:25:56" binlog.000003  

This option is useful for point-in-time recovery. SeeSection 7.5, “Point-in-Time (Incremental) Recovery”.

You can pipe the output of mysqlbinlog into the mysql client to execute the events contained in the binary log. This technique is used to recover from an unexpected exit when you have an old backup (seeSection 7.5, “Point-in-Time (Incremental) Recovery”). For example:

mysqlbinlog binlog.000001 | mysql -u root -p

Or:

mysqlbinlog binlog.[0-9]* | mysql -u root -p

If the statements produced by mysqlbinlog may contain BLOB values, these may cause problems when mysql processes them. In this case, invoke mysql with the--binary-mode option.

You can also redirect the output ofmysqlbinlog to a text file instead, if you need to modify the statement log first (for example, to remove statements that you do not want to execute for some reason). After editing the file, execute the statements that it contains by using it as input to the mysql program:

mysqlbinlog binlog.000001 > tmpfile
... edit tmpfile ...
mysql -u root -p < tmpfile

When mysqlbinlog is invoked with the--start-position option, it displays only those events with an offset in the binary log greater than or equal to a given position (the given position must match the start of one event). It also has options to stop and start when it sees an event with a given date and time. This enables you to perform point-in-time recovery using the--stop-datetime option (to be able to say, for example, “roll forward my databases to how they were today at 10:30 a.m.”).

Processing multiple files. If you have more than one binary log to execute on the MySQL server, the safe method is to process them all using a single connection to the server. Here is an example that demonstrates what may be unsafe:

mysqlbinlog binlog.000001 | mysql -u root -p # DANGER!!
mysqlbinlog binlog.000002 | mysql -u root -p # DANGER!!

Processing binary logs this way using multiple connections to the server causes problems if the first log file contains aCREATE TEMPORARY TABLE statement and the second log contains a statement that uses the temporary table. When the firstmysql process terminates, the server drops the temporary table. When the second mysql process attempts to use the table, the server reports“unknown table.”

To avoid problems like this, use a single mysql process to execute the contents of all binary logs that you want to process. Here is one way to do so:

mysqlbinlog binlog.000001 binlog.000002 | mysql -u root -p

Another approach is to write all the logs to a single file and then process the file:

mysqlbinlog binlog.000001 >  /tmp/statements.sql
mysqlbinlog binlog.000002 >> /tmp/statements.sql
mysql -u root -p -e "source /tmp/statements.sql"

mysqlbinlog can produce output that reproduces a LOAD DATA operation without the original data file. mysqlbinlog copies the data to a temporary file and writes aLOAD DATA LOCAL statement that refers to the file. The default location of the directory where these files are written is system-specific. To specify a directory explicitly, use the--local-load option.

Because mysqlbinlog convertsLOAD DATA statements toLOAD DATA LOCAL statements (that is, it addsLOCAL), both the client and the server that you use to process the statements must be configured with theLOCAL capability enabled. SeeSection 6.1.6, “Security Considerations for LOAD DATA LOCAL”.

Warning

The temporary files created forLOAD DATA LOCAL statements are not automatically deleted because they are needed until you actually execute those statements. You should delete the temporary files yourself after you no longer need the statement log. The files can be found in the temporary file directory and have names like_originalfilename-#-#_.