4.6.8 mysqlbinlog — Utility for Processing Binary Log Files

4.6.8.1 mysqlbinlog Hex Dump Format
4.6.8.2 mysqlbinlog Row Event Display
4.6.8.3 Using mysqlbinlog to Back Up Binary Log Files
4.6.8.4 Specifying the mysqlbinlog Server ID

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 the mysqlbinlog utility. You can also use mysqlbinlog to display the contents of relay log files written by a slave server in a replication setup because relay logs have the same format as binary logs. The binary log and relay log are discussed further in Section 5.2.4, “The Binary Log”, and Section 16.2.2, “Replication Relay and Status Logs”.

Invoke mysqlbinlog like this:

shell> mysqlbinlog [options] log_file ...

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

shell> mysqlbinlog binlog.0000003

The output includes events contained in binlog.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.1.2, “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 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 slave servers. server id is the server_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 master server. On a slave, it is the difference of the end execution time on the slave minus the beginning execution time on the master. The difference serves as an indicator of how much replication lags behind the master. error_code indicates the result from executing the event. Zero means that no error occurred.

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

Normally, you use mysqlbinlog to read binary log files directly and apply them to the local MySQL server. It is also possible to 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; they are ignored except when you also use the --read-from-remote-server option.

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, see Section 4.2.3.3, “Using Option Files”.

Table 4.15 mysqlbinlog Options

FormatOption FileDescriptionIntroduced
--base64-output=valuebase64-outputPrint binary log entries using base-64 encoding 
--bind-address=ip_addressbind-addressUse the specified network interface to connect to the MySQL Server 
--binlog-row-event-max-size=#binlog-row-event-max-sizeBinary log max event size 
--character-sets-dir=pathcharacter-sets-dirThe directory where character sets are installed 
--database=db_namedatabaseList entries for just this database 
--debug[=debug_options]debugWrite a debugging log 
--debug-checkdebug-checkPrint debugging information when the program exits 
--debug-infodebug-infoPrint debugging information, memory and CPU statistics when the program exits 
--default-auth=plugindefault-auth=pluginThe authentication plugin to use5.6.2
--defaults-extra-file=file_name Read option file in addition to the usual option files 
--defaults-file=file_name Read only the given option file 
--defaults-group-suffix=str Option group suffix value 
--disable-log-bindisable-log-binDisable binary logging 
--exclude-gtids=gtid_setexclude-gtidsDo not show any of the groups in the GTID set provided5.6.5
--force-if-openforce-if-openRead binary log files even if open or not closed properly 
--force-readforce-readIf mysqlbinlog reads a binary log event that it does not recognize, it prints a warning 
--help Display help message and exit 
--hexdumphexdumpDisplay a hex dump of the log in comments 
--host=host_namehostConnect to the MySQL server on the given host 
--idempotentidempotentCause the server to use idempotent mode while processing binary log updates from this session only 
--include-gtids=gtid_setinclude-gtidsShow only the groups in the GTID set provided5.6.5
--local-load=pathlocal-loadPrepare local temporary files for LOAD DATA INFILE in the specified directory 
--login-path=name Read login path options from .mylogin.cnf5.6.6
--no-defaults Do not read any option files 
--offset=#offsetSkip the first N entries in the log 
--password[=password]passwordThe password to use when connecting to the server 
--plugin-dir=pathplugin-dir=pathThe directory where plugins are located5.6.2
--port=port_numportThe TCP/IP port number to use for the connection 
--print-defaults Print defaults 
--protocol=typeprotocolThe connection protocol to use 
--rawrawWrite events in raw (binary) format to output files 
--read-from-remote-master=typeread-from-remote-masterRead the binary log from a MySQL master rather than reading a local log file5.6.5
--read-from-remote-serverread-from-remote-serverRead binary log from MySQL server rather than local log file 
--result-file=nameresult-fileDirect output to the given file 
--secure-authsecure-authDo not send passwords to the server in old (pre-4.1.1) format5.6.17
--server-id=idserver-idExtract only those events created by the server having the given server ID 
--set-charset=charset_nameset-charsetAdd a SET NAMES charset_name statement to the output 
--short-formshort-formDisplay only the statements contained in the log 
--skip-gtids[=true|false]skip-gtidsDo not print any GTIDs; use this when writing a dump file from binary logs containing GTIDs.5.6.5
--socket=pathsocketFor connections to localhost 
--ssl-crl=file_name The path to a file that contains certificate revocation lists5.6.3
--ssl-crlpath=dir_name The path to a directory that contains certificate revocation list files5.6.3
--start-datetime=datetimestart-datetimeRead binary log from first event with timestamp equal to or later than datetime argument 
--start-position=#start-positionRead binary log from first event with position equal to or greater than argument 
--stop-datetime=datetimestop-datetimeStop reading binary log at first event with timestamp equal to or greater than datetime argument 
--stop-neverstop-neverStay connected to server after reading last binary log file 
--stop-never-slave-server-id=#stop-never-slave-server-idSlave server ID to report when connecting to server 
--stop-position=#stop-positionStop reading binary log at first event with position equal to or greater than argument 
--to-last-logto-last-logDo not stop at the end of requested binary log from a MySQL server, but rather continue printing to end of last binary log 
--user=user_name,userMySQL user name to use when connecting to server 
--verbose Reconstruct row events as SQL statements 
--verify-binlog-checksum Verify checksums in binary log5.6.1
--version Display version information and exit 

You can also set the following variable by using --var_name=value syntax:

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 a crash when you have an old backup (see Section 7.5, “Point-in-Time (Incremental) Recovery Using the Binary Log”). For example:

shell> mysqlbinlog binlog.000001 | mysql -u root -p

Or:

shell> 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 of mysqlbinlog 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:

shell> mysqlbinlog binlog.000001 > tmpfile
shell> ... edit tmpfile ...
shell> 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.).

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:

shell> mysqlbinlog binlog.000001 | mysql -u root -p # DANGER!!
shell> 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 a CREATE TEMPORARY TABLE statement and the second log contains a statement that uses the temporary table. When the first mysql 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:

shell> 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:

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

mysqlbinlog can produce output that reproduces a LOAD DATA INFILE operation without the original data file. mysqlbinlog copies the data to a temporary file and writes a LOAD DATA LOCAL INFILE 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 converts LOAD DATA INFILE statements to LOAD DATA LOCAL INFILE statements (that is, it adds LOCAL), both the client and the server that you use to process the statements must be configured with the LOCAL capability enabled. See Section 6.1.6, “Security Issues with LOAD DATA LOCAL.

Warning

The temporary files created for LOAD 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 original_file_name-#-#.