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.4.2, “Replication Relay and Status Files”.
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
. Event information includes
the 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.
The output from mysqlbinlog can be re-executed (for example, by using it as input to mysql) to reapply 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.
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. When you 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. It also reads option files and supports the options for processing them described at Section 4.2.3.3.1, “Command-Line Options that Affect Option-File Handling”.
Table 4.11. mysqlbinlog
Options
Format | Config File | Description | Introduction | Deprecated | Removed |
---|---|---|---|---|---|
--base64-output[=value] | base64-output | Print binary log entries using base-64 encoding | 5.1.5 | ||
--character-sets-dir=path | character-sets-dir | The directory where character sets are installed | |||
--database=db_name | database | List entries for just this database | |||
--debug[=debug_options] | debug | Write a debugging log | |||
--debug-check | debug-check | Print debugging information when the program exits | 5.1.21 | ||
--debug-info | debug-info | Print debugging information, memory and CPU statistics when the program exits | 5.1.21 | ||
--disable-log-bin | disable-log-bin | Disable binary logging | |||
--force-read | 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 | hexdump | Display a hex dump of the log in comments | 5.1.2 | ||
--host=host_name | host | Connect to the MySQL server on the given host | |||
--local-load=path | local-load | Prepare local temporary files for LOAD DATA INFILE in the specified directory | |||
--offset=# | offset | Skip the first N entries in the log | |||
--password[=password] | password | The password to use when connecting to the server | |||
--port=port_num | port | The TCP/IP port number to use for the connection | |||
--protocol=type | protocol | The connection protocol to use | |||
--read-from-remote-server | read-from-remote-server | Read the binary log from a MySQL server rather than reading a local log file | |||
--result-file=name | result-file | Direct output to the given file | |||
--server-id=id | server-id | Extract only those events created by the server having the given server ID | 5.1.4 | ||
--set-charset=charset_name | set-charset | Add a SET NAMES charset_name statement to the output | 5.1.12 | ||
--short-form | short-form | Display only the statements contained in the log | |||
--socket=path | socket | For connections to localhost | |||
--start-datetime=datetime | start-datetime | Start reading the binary log at the first event having a timestamp equal to or later than the datetime argument | |||
--start-position=# | start-position | Start reading the binary log at the first event having a position equal to or greater than the argument | |||
--stop-datetime=datetime | stop-datetime | Stop reading the binary log at the first event having a timestamp equal to or greater than the datetime argument | |||
--stop-position=# | stop-position | Stop reading the binary log at the first event having a position equal to or greater than the argument | |||
--to-last-log | to-last-log | Do 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 | |||
--user=user_name, | user | The MySQL user name to use when connecting to the server | |||
--verbose | Reconstruct row events as SQL statements | 5.1.28 | |||
--version | Display version information and exit | ||||
--write-binlog | write-binlog | Log ANALYZE, OPTIMIZE, REPAIR statements to binary log. --skip-write-binlog adds NO_WRITE_TO_BINLOG to these statements. | 5.1.18 |
--help
,
-?
Display a help message and exit.
This option determines when events should be displayed
encoded as base-64 strings using
BINLOG
statements. The option
has these allowable values (not case sensitive):
AUTO
("automatic") or
UNSPEC
("unspecified") displays
BINLOG
statements
automatically when necessary (that is, for format
description events and row events). This is the default
if no
--base64-output
option is given.
Automatic BINLOG
display 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.
ALWAYS
displays
BINLOG
statements
whenever possible. This is the implied value if the
option is given as
--base64-output
without a value.
NEVER
causes
BINLOG
statements not to
be displayed. mysqlbinlog exits with
an error if a row event is found that must be displayed
using BINLOG
.
DECODE-ROWS
specifies to
mysqlbinlog that you intend for row
events to be decoded and displayed as commented SQL
statements by also specifying the
--verbose
option.
Like NEVER
,
DECODE-ROWS
suppresses display of
BINLOG
statements, but
unlike NEVER
, it does not exit with
an error if a row event is found.
The --base64-output
option was introduced in MySQL 5.1.5, to be given as
--base64-output
or
--skip-base64-output
(with the sense of AUTO
or
NEVER
). The option values described in
the preceding list may be used as of MySQL 5.1.24, with the
exception of UNSPEC
and
DECODE-ROWS
, which are available as of
MySQL 5.1.28.
For examples that show the effect of
--base64-output
and
--verbose
on row event
output, see Section 4.6.7.2, “mysqlbinlog Row Event Display”.
The directory where character sets are installed. See Section 9.2, “The Character Set Used for Data and Sorting”.
--database=
,
db_name
-d
db_name
List entries for just this database (local log only). You
can only specify one database with this option - if you
specify multiple
--database
options, only
the last one is used. This option forces
mysqlbinlog to output entries from the
binary log where the default database (that is, the one
selected by USE
) is
db_name
. Note that this does not
replicate cross-database statements such as UPDATE
while having selected a different
database or no database.
some_db.some_table
SET
foo='bar'
This option did not work correctly for mysqlbinlog with row-based logging prior to MySQL 5.1.37. (Bug#42941)
--debug[=
,
debug_options
]-#
[
debug_options
]
Write a debugging log. A typical
debug_options
string is
'd:t:o,
.
The default is
file_name
''d: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.
Disable binary logging. This is useful for avoiding an
endless loop if you use the
--to-last-log
option 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
SUPER
privilege. It causes
mysqlbinlog to include a SET
sql_log_bin = 0
statement in its output to disable
binary logging of the remaining output. The
SET
statement is ineffective unless you have the
SUPER
privilege.
--force-read
,
-f
With 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
,
-H
Display a hex dump of the log in comments, as described in Section 4.6.7.1, “mysqlbinlog Hex Dump Format”. This output can be helpful for replication debugging. This option was added in MySQL 5.1.2.
--host=
,
host_name
-h
host_name
Get the binary log from the MySQL server on the given host.
--local-load=
,
path
-l
path
Prepare local temporary files for
LOAD DATA
INFILE
in the specified directory.
--offset=
,
N
-o
N
Skip the first N
entries 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 the
password
value following the
--password
or
-p
option on the command line, you are
prompted for one.
Specifying a password on the command line should be considered insecure. See Section 5.5.6.2, “End-User Guidelines for Password Security”.
--port=
,
port_num
-P
port_num
The TCP/IP port number to use for connecting to a remote server.
--position=
,
N
-j
N
Deprecated. Use
--start-position
instead.
--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 allowable 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
-r
name
Direct output to the given file.
Extract only those events created by the server having the given server ID. This option is available as of MySQL 5.1.4.
Add a SET NAMES
statement
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
--short-form
,
-s
Display only the statements contained in the log, without any extra information.
--socket=
,
path
-S
path
For 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
datetime
argument. The
datetime
value is relative to the
local time zone on the machine where you run
mysqlbinlog. The value should be in a
format accepted for the
DATETIME
or
TIMESTAMP
data types. For
example:
shell> mysqlbinlog --start-datetime="2005-12-25 11:25:56" binlog.000003
This option is useful for point-in-time recovery. See Section 6.2, “Example Backup and Recovery Strategy”.
Start 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.
Stop reading the binary log at the first event having a
timestamp equal to or later than the
datetime
argument. This option is
useful for point-in-time recovery. See the description of
the --start-datetime
option for information about the
datetime
value.
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.
--to-last-log
,
-t
Do 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
-u
user_name
The MySQL user name to use when connecting to a remote server.
--verbose
,
-v
Reconstruct row events and display them as commented SQL statements. If 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-output
and
--verbose
on row event
output, see Section 4.6.7.2, “mysqlbinlog Row Event Display”.
--version
,
-V
Display version information and exit.
This option is enabled by default, so that
ANALYZE TABLE
,
OPTIMIZE TABLE
, and
REPAIR TABLE
statements
generated by mysqlcheck are written to
the binary log. Use
--skip-write-binlog
to cause NO_WRITE_TO_BINLOG
to be added
to the statements so that they are not logged. Use the
--skip-write-binlog
when these statements should not be sent to replication
slaves or run when using the binary logs for recovery from
backup. This option was added in MySQL 5.1.18.
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 statements contained in the binary log. This is used to recover from a crash when you have an old backup (see Section 6.1, “Database Backups”). For example:
shell> mysqlbinlog binlog.000001 | mysql
Or:
shell> mysqlbinlog binlog.[0-9]* | mysql
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.
mysqlbinlog has the
--start-position
option,
which prints only those statements 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 # DANGER!!
shell>mysqlbinlog binlog.000002 | mysql # DANGER!!
Processing binary logs this way using different 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 connection 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
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 -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 to allow
LOCAL
capability. See
Section 5.3.4, “Security Issues with LOAD
DATA LOCAL
”.
MySQL Enterprise.
For expert advice on the security implications of enabling
LOCAL
, subscribe to the MySQL Enterprise
Monitor. For more information, see
http://www.mysql.com/products/enterprise/advisors.html.
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-#-#
.
User Comments
I had some problems using mysqlbinlog with temporary files. It would have helped to have an explanation above but here is a brief example:
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
Some things to know about mysqlbinlog which did not strike me as obvious (also it is hinted by the doc) :
--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...
I found the --start-datetime and --stop-datetime to be finicky about the format. While yyyy-mm-dd hh:mm:ss work fine elsewhere, this expected yy-mm-dd hh:mm:ss to work.
Regarding KEvin
--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
On Linux, you can use -l /dev/null to avoid the temp files if you're just looking through the output. mysqlbinlog will complain, but it won't create the file and it won't create the corresponding LOAD DATA INFILE statement (because it couldn't create the file).
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.
If the sql generated by mysqlbinlog is not processed by mysql, this could be the root cause:
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
This may seem obvious but I had to help someone with this...
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.
Yiannis Mavridis is right.
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.
Add your own comment.