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 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 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.
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 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.
When running mysqlbinlog against a large
binary log, be careful that the filesystem has enough space for
the resulting files. To configure the directory that
mysqlbinlog uses for temporary files, use the
TMPDIR environment variable.
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.6, “Using Option Files”.
Table 4.12 mysqlbinlog Options
| Format | Description | Introduced |
|---|---|---|
| --base64-output | Print binary log entries using base-64 encoding | 5.1.5 |
| --bind-address | Use specified network interface to connect to MySQL Server | 5.1.22-ndb-6.3.4 |
| --character-sets-dir | Directory where character sets are installed | |
| --database | List entries for just this database | |
| --debug | Write debugging log | |
| --debug-check | Print debugging information when program exits | 5.1.21 |
| --debug-info | Print debugging information, memory, and CPU statistics when program exits | 5.1.21 |
| --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 | |
| --force-if-open | Read binary log files even if open or not closed properly | 5.1.15 |
| --force-read | If mysqlbinlog reads a binary log event that it does not recognize, it prints a warning | |
| --help | Display help message and exit | |
| --hexdump | Display a hex dump of the log in comments | 5.1.2 |
| --host | Connect to MySQL server on given host | |
| --local-load | Prepare local temporary files for LOAD DATA INFILE in the specified directory | |
| --no-defaults | Read no option files | |
| --offset | Skip the first N entries in the log | |
| --password | Password to use when connecting to server | |
| --port | TCP/IP port number to use for connection | |
| --position | Deprecated. Use --start-position | |
| --print-defaults | Print default options | |
| --protocol | Connection protocol to use | |
| --read-from-remote-server | Read binary log from MySQL server rather than local log file | |
| --result-file | Direct output to named file | |
| --server-id | Extract only those events created by the server having the given server ID | 5.1.4 |
| --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 | 5.1.47-ndb-7.1.6 |
| --set-charset | Add a SET NAMES charset_name statement to the output | 5.1.12 |
| --shared-memory-base-name | The name of shared memory to use for shared-memory connections | 5.1.41 |
| --short-form | Display only the statements contained in the log | |
| --socket | For connections to localhost, the Unix socket file to use | |
| --start-datetime | Read binary log from first event with timestamp equal to or later than datetime argument | |
| --start-position | Read 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-position | Stop reading binary log at first event with position equal to or greater than argument | |
| --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 | 5.1.28 |
| --version | Display version information and exit |
--help,-?Display a help message and exit.
This option determines when events should be displayed encoded as base-64 strings using
BINLOGstatements. The option has these permissible values (not case sensitive):AUTO("automatic") orUNSPEC("unspecified") displaysBINLOGstatements automatically when necessary (that is, for format description events and row events). If no--base64-outputoption is given, the effect is the same as--base64-output=AUTO.NoteAutomatic
BINLOGdisplay is the only safe behavior if you intend to use the output of mysqlbinlog to re-execute binary log file contents. The other option values are intended only for debugging or testing purposes because they may produce output that does not include all events in executable form.ALWAYSdisplaysBINLOGstatements whenever possible. If the--base64-outputoption is given without a value, the effect is the same as--base64-output=ALWAYS.NEVERcausesBINLOGstatements not to be displayed. mysqlbinlog exits with an error if a row event is found that must be displayed usingBINLOG.DECODE-ROWSspecifies to mysqlbinlog that you intend for row events to be decoded and displayed as commented SQL statements by also specifying the--verboseoption. LikeNEVER,DECODE-ROWSsuppresses display ofBINLOGstatements, but unlikeNEVER, it does not exit with an error if a row event is found.
The
--base64-outputoption was introduced in MySQL 5.1.5, to be given as--base64-outputor--skip-base64-output(with the sense ofAUTOorNEVER). The option values described in the preceding list may be used as of MySQL 5.1.24, with the exception ofUNSPECandDECODE-ROWS, which are available as of MySQL 5.1.28.For examples that show the effect of
--base64-outputand--verboseon row event output, see Section 4.6.7.2, “mysqlbinlog Row Event Display”.On a computer having multiple network interfaces, use this option to select which interface to use for connecting to the MySQL server.
This option is supported only in the version of mysqlbinlog that is supplied with MySQL Cluster, beginning with MySQL Cluster NDB 6.3.4. It is not available in standard MySQL 5.1 releases.
The directory where character sets are installed. See Section 10.5, “Character Set Configuration”.
--database=,db_name-ddb_nameThis option causes mysqlbinlog to output entries from the binary log (local log only) that occur while
db_nameis been selected as the default database byUSE.The
--databaseoption for mysqlbinlog is similar to the--binlog-do-dboption for mysqld, but can be used to specify only one database. If--databaseis given multiple times, only the last instance is used.The effects of this option depend on whether the statement-based or row-based logging format is in use, in the same way that the effects of
--binlog-do-dbdepend on whether statement-based or row-based logging is in use.Statement-based logging. The
--databaseoption works as follows:While
db_nameis the default database, statements are output whether they modify tables indb_nameor a different database.Unless
db_nameis selected as the default database, statements are not output, even if they modify tables indb_name.There is an exception for
CREATE DATABASE,ALTER DATABASE, andDROP DATABASE. The database being created, altered, or dropped is considered to be the default database when determining whether to output the statement.
Suppose that the binary log was created by executing these statements using statement-based-logging:
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
INSERTstatements because there is no default database. It outputs the threeINSERTstatements followingUSE test, but not the threeINSERTstatements followingUSE db2.mysqlbinlog --database=db2 does not output the first two
INSERTstatements because there is no default database. It does not output the threeINSERTstatements followingUSE test, but does output the threeINSERTstatements followingUSE db2.Row-based logging. mysqlbinlog outputs only entries that change tables belonging to
db_name. 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 modifyt1in the test database, regardless of whetherUSEwas issued or what the default database is.If a server is running with
binlog_formatset toMIXEDand you want it to be possible to use mysqlbinlog with the--databaseoption, you must ensure that tables that are modified are in the database selected byUSE. (In particular, no cross-database updates should be used.)This option did not work correctly for mysqlbinlog with row-based logging prior to MySQL 5.1.37. (Bug #42941)
NotePrior to MySQL Cluster NDB 7.0.28 and MySQL Cluster NDB 7.1.17, this option did not work correctly with MySQL Cluster tables unless, unless the binary log was generated using
--log-bin-use-v1-row-events=0. (Bug #13067813)--debug[=,debug_options]-# [debug_options]Write a debugging log. A typical
debug_optionsstring isd:t:o,. The default isfile_named:t:o,/tmp/mysqlbinlog.trace.Print some debugging information when the program exits. This option was added in MySQL 5.1.21.
Print debugging information and memory and CPU usage statistics when the program exits. This option was added in MySQL 5.1.21.
--defaults-extra-file=file_nameRead this option file after the global option file but (on Unix) before the user option file. If the file does not exist or is otherwise inaccessible, an error occurs.
file_nameis the full path name to the file.Use only the given option file. If the file does not exist or is otherwise inaccessible, an error occurs.
file_nameis the full path name to the file.Read not only the usual option groups, but also groups with the usual names and a suffix of
str. For example, mysqlbinlog normally reads the[client]and[mysqlbinlog]groups. If the--defaults-group-suffix=_otheroption is given, mysqlbinlog also reads the[client_other]and[mysqlbinlog_other]groups.Disable binary logging. This is useful for avoiding an endless loop if you use the
--to-last-logoption and are sending the output to the same MySQL server. This option also is useful when restoring after a crash to avoid duplication of the statements you have logged.This option requires that you have the
SUPERprivilege. It causes mysqlbinlog to include aSET sql_log_bin = 0statement in its output to disable binary logging of the remaining output. TheSETstatement is ineffective unless you have theSUPERprivilege.--force-if-open,-FRead binary log files even if they are open or were not closed properly. This option was added in MySQL 5.1.15.
--force-read,-fWith this option, if mysqlbinlog reads a binary log event that it does not recognize, it prints a warning, ignores the event, and continues. Without this option, mysqlbinlog stops if it reads such an event.
--hexdump,-HDisplay a hex dump of the log in comments, as described in Section 4.6.7.1, “mysqlbinlog Hex Dump Format”. The hex output can be helpful for replication debugging. This option was added in MySQL 5.1.2.
--host=,host_name-hhost_nameGet the binary log from the MySQL server on the given host.
--local-load=,dir_name-ldir_namePrepare local temporary files for
LOAD DATA INFILEin the specified directory.ImportantThese temporary files are not automatically removed by mysqlbinlog or any other MySQL program.
Do not read any option files. If program startup fails due to reading unknown options from an option file,
--no-defaultscan be used to prevent them from being read.--offset=,N-oNSkip the first
Nentries in the log.--password[=,password]-p[password]The password to use when connecting to the server. If you use the short option form (
-p), you cannot have a space between the option and the password. If you omit thepasswordvalue following the--passwordor-poption on the command line, mysqlbinlog prompts for one.Specifying a password on the command line should be considered insecure. See Section 6.1.2.1, “End-User Guidelines for Password Security”. You can use an option file to avoid giving the password on the command line.
--port=,port_num-Pport_numThe TCP/IP port number to use for connecting to a remote server.
Deprecated. Use
--start-positioninstead.--positionis removed in MySQL 5.5.Print the program name and all options that it gets from option files.
--protocol={TCP|SOCKET|PIPE|MEMORY}The connection protocol to use for connecting to the server. It is useful when the other connection parameters normally would cause a protocol to be used other than the one you want. For details on the permissible values, see Section 4.2.2, “Connecting to the MySQL Server”.
Read the binary log from a MySQL server rather than reading a local log file. Any connection parameter options are ignored unless this option is given as well. These options are
--host,--password,--port,--protocol,--socket, and--user.This option requires that the remote server be running. It works only for binary log files on the remote server, not relay log files.
--result-file=,name-rnameDirect output to the given file.
Display only those events created by the server having the given server ID. This option is available as of MySQL 5.1.4.
Use only the first
Nbits of theserver_idto identify the server. If the binary log was written by a mysqld with server-id-bits set to less than 32 and user data stored in the most significant bit, running mysqlbinlog with--server-id-bitsset to 32 enables this data to be seen.This option was added in MySQL Cluster NDB 7.0.17 and MySQL Cluster NDB 7.1.6, and is supported only by the versions of mysqlbinlog supplied with these and later releases of MySQL Cluster.
Add a
SET NAMESstatement to the output to specify the character set to be used for processing log files. This option was added in MySQL 5.1.12.charset_name--shared-memory-base-name=nameOn Windows, the shared-memory name to use, for connections made using shared memory to a local server. The default value is
MYSQL. The shared-memory name is case sensitive.The server must be started with the
--shared-memoryoption to enable shared-memory connections.This option was added in MySQL 5.1.41.
--short-form,-sDisplay only the statements contained in the log, without any extra information or row-based events. This is for testing only, and should not be used in production systems.
--socket=,path-SpathFor connections to
localhost, the Unix socket file to use, or, on Windows, the name of the named pipe to use.Start reading the binary log at the first event having a timestamp equal to or later than the
datetimeargument. Thedatetimevalue is relative to the local time zone on the machine where you run mysqlbinlog. The value should be in a format accepted for theDATETIMEorTIMESTAMPdata types. For example:shell>
mysqlbinlog --start-datetime="2005-12-25 11:25:56" binlog.000003This option is useful for point-in-time recovery. See Section 7.3, “Example Backup and Recovery Strategy”.
--start-position=,N-jNStart reading the binary log at the first event having a position equal to or greater than
N. This option applies to the first log file named on the command line.This option is useful for point-in-time recovery. See Section 7.3, “Example Backup and Recovery Strategy”.
Stop reading the binary log at the first event having a timestamp equal to or later than the
datetimeargument. This option is useful for point-in-time recovery. See the description of the--start-datetimeoption for information about thedatetimevalue.This option is useful for point-in-time recovery. See Section 7.3, “Example Backup and Recovery Strategy”.
Stop reading the binary log at the first event having a position equal to or greater than
N. This option applies to the last log file named on the command line.This option is useful for point-in-time recovery. See Section 7.3, “Example Backup and Recovery Strategy”.
--to-last-log,-tDo not stop at the end of the requested binary log from a MySQL server, but rather continue printing until the end of the last binary log. If you send the output to the same MySQL server, this may lead to an endless loop. This option requires
--read-from-remote-server.--user=,user_name-uuser_nameThe MySQL user name to use when connecting to a remote server.
--verbose,-vReconstruct row events and display them as commented SQL statements. If this option is given twice, the output includes comments to indicate column data types and some metadata. This option was added in MySQL 5.1.28.
For examples that show the effect of
--base64-outputand--verboseon row event output, see Section 4.6.7.2, “mysqlbinlog Row Event Display”.--version,-VDisplay version information and exit.
In MySQL 5.1, the version number shown for mysqlbinlog is always 3.3.
You can also set the following variable by using
--
syntax:
var_name=value
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
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 > tmpfileshell> ...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.sqlshell>mysqlbinlog binlog.000002 >> /tmp/statements.sqlshell>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”.
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-#-#.
mysqlbinlog -d mydb -r mydb.sql mydb-bin.001
/*The above command will create a file called mydb.sql in my CWD(current working directory) with queries extracted from binary log mydb-bin.001 for mydb database queries only*/
Now say I had some load data infile statements in my binary log. If my /tmp directory did not contain those files mysqbinlog would create them for me. Here's th problem, if the file aready exists mysqlbinlog will error out with message File: 'tmp/XXX.csv' not found. Yet if you look in your /tmp directory there it is! Don't panic...mysqlbinlog won't write over an existing file and there is no flag to do so (in my opinion there should be that option).
Now you could delete the files from your /tmp directory and et mysqlbinlog recreate them for you but it is simpler to create a tmp directory in your CWD like this:
mkdir tmp
Now use the mysqlbinlog flag --local-load to specify your CWD/tmp directory to WRITE the files like this:
mysqlbinlog -d mydb -r mydb.sql --local-load="tmp/" mydb-bin.001
Your files will be created in CWD/tmp. Should you need to run the mysqlbinlog utilty again just rm CWD/tmp/* and run the utility again.
Hope this helps,
Tom
--read-from-remote-server :
1) with this option you can only read files present in binary_log-bin.index on the master so you cannot read relay log files on the distant server
2) the distant mysql server must be up (you cannot just read the distant files), so it loses much of its utility : if the distant master is up you can "start slave" or "change master to MASTER_LOG_FILE=...".
But if the master is down and you want to get the latest changes you must copy the remote (with scp for example) binary logs and then run mysqlbinlog locally ...
--start-position (or --position) :
1) it must be the exact position of an event.
2) it is the first position that will be read so you must not use the "Read_Master_Log_Pos" (as shown by "show slave status") which is the position of the last event done.
You have to use :
--start-position=Read_Master_Log_Pos --offset=1 Master_Log_File
to skip the first event.
As Read_Master_Log_Pos is one of the most easy position to get it is a pity that you have to specify the offset each time...
--start-position (or --position) :
1) it must be the exact position of an event.
2) it is the first position that will be read so you must not use the "Read_Master_Log_Pos" (as shown by "show slave status") which is the position of the last event done.
You have to use :
--start-position=Read_Master_Log_Pos --offset=1 Master_Log_File
to skip the first event.
As Read_Master_Log_Pos is one of the most easy position to get it is a pity that you have to specify the offset each time...
I tested and i found that you do not need to use the offset=1 like KEvin is saying above, because the exec_master_log_pos on the 'show slave status' view contains the next not yet executed command of the binlog
This is useful if your log files have a lot of very large LOAD DATA INFILE statements, and you don't want to incur the overhead of writing them to disk and then deleting them.
http://bugs.mysql.com/bug.php?id=34541
(And that you have configured your server to execute "set autocommit=0" on client connect.)
An indication is that the mysql client complains on this line:
SET /*!*/;
A workaround would be replacing the bad line:
mysqlbinlog mysql-bin.000011 | sed -e 's/SET \/\*\!\*\//SET AUTOCOMMIT=0/g' | mysql
If you use the --start-datetime= option and you have a large binlog, be patient. It may take a while to return results. Don't hit control+c thinking it's broken or something. Just wait patiently for what you're looking for to be found.
Don't listen to KEvin and use the --offset=1 switch, it will miss the first command. If there's only been one command since the downtime then you won't be updating your slave.
Caused me a world of pain listening to this while testing.