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.3, “The Binary Log”, and Section 16.2.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 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.
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 Section 6.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]
option file groups. mysqlbinlog also supports
the options for processing option files described at
Section 4.2.3.3.1, “Command-Line Options that Affect Option-File Handling”.
Table 4.10. mysqlbinlog
Options
Format | Config File | Description | Introduction | Deprecated | Removed |
---|---|---|---|---|---|
--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 | |||
--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.0.16 | ||
--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 | |||
--position=# | position | Deprecated. Use --start-position | |||
--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 | |||
--set-charset=charset_name | set-charset | Add a SET NAMES charset_name statement to the output | 5.0.23 | ||
--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 | |||
--version | Display version information and exit |
--help
,
-?
Display a help message and exit.
The directory where character sets are installed. See Section 9.5, “Character Set Configuration”.
--database=
,
db_name
-d
db_name
This option causes mysqlbinlog to output
entries from the binary log (local log only) that occur
while db_name
is been selected as
the default database by USE
.
The --database
option
for mysqlbinlog is similar to the
--binlog-do-db
option for
mysqld, but can be used to specify only
one database. If
--database
is given
multiple times, only the last instance is used.
The --database
option
works as follows:
While db_name
is the default
database, statements are output whether they modify
tables in db_name
or a
different database.
Unless db_name
is selected as
the default database, statements are not output, even if
they modify tables in
db_name
.
There is an exception for CREATE
DATABASE
, ALTER
DATABASE
, and DROP
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 contains these statements:
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 three
INSERT
statements following
USE 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 following
USE test
, but
does output the three INSERT
statements following
USE db2
.
--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'
.
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. The hex output can be helpful for replication debugging. Hex dump format is discussed later in this section. This option was added in MySQL 5.0.16.
--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,
mysqlbinlog prompts for one.
Specifying a password on the command line should be considered insecure. See Section 5.3.2.2, “End-User Guidelines for Password Security”. You can use an option file to avoid giving the password on the command line.
--port=
,
port_num
-P
port_num
The TCP/IP port number to use for connecting to a remote server.
Deprecated. Use
--start-position
instead. --position
is
removed in MySQL 5.5.
--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.
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.0.23.
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.3, “Example Backup and Recovery Strategy”.
--start-position=
,
N
-j
N
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.
This option is useful for point-in-time recovery. See Section 6.3, “Example Backup and Recovery Strategy”.
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.
This option is useful for point-in-time recovery. See Section 6.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 6.3, “Example Backup and Recovery Strategy”.
--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.
--version
,
-V
Display version information and exit.
You can also set the following variable by using
--
syntax:
var_name
=value
It is also possible to set variables by using
--set-variable=
or var_name
=value
-O
syntax. This syntax is deprecated.
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 6.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 > 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 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 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 5.3.5, “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-#-#
.
The --hexdump
option
produces a hex dump of the log contents:
shell> mysqlbinlog --hexdump master-bin.000001
The hex output consists of comment lines beginning with
#
, so the output might look like this for the
preceding command:
/*!40019 SET @@session.max_insert_delayed_threads=0*/; /*!50003 SET @OLD_COMPLETION_TYPE=@@COMPLETION_TYPE,COMPLETION_TYPE=0*/; # at 4 #051024 17:24:13 server id 1 end_log_pos 98 # Position Timestamp Type Master ID Size Master Pos Flags # 00000004 9d fc 5c 43 0f 01 00 00 00 5e 00 00 00 62 00 00 00 00 00 # 00000017 04 00 35 2e 30 2e 31 35 2d 64 65 62 75 67 2d 6c |..5.0.15.debug.l| # 00000027 6f 67 00 00 00 00 00 00 00 00 00 00 00 00 00 00 |og..............| # 00000037 00 00 00 00 00 00 00 00 00 00 00 00 00 00 00 00 |................| # 00000047 00 00 00 00 9d fc 5c 43 13 38 0d 00 08 00 12 00 |.......C.8......| # 00000057 04 04 04 04 12 00 00 4b 00 04 1a |.......K...| # Start: binlog v 4, server v 5.0.15-debug-log created 051024 17:24:13 # at startup ROLLBACK;
Hex dump output currently contains the following elements. This format is subject to change.
Position
: The byte position within the
log file.
Timestamp
: The event timestamp. In the
example shown, '9d fc 5c 43'
is the
representation of '051024 17:24:13'
in
hexadecimal.
Type
: The event type code. In the example
shown, '0f'
indicates a
FORMAT_DESCRIPTION_EVENT
. The following
table lists the possible type codes.
Type | Name | Meaning |
00 |
UNKNOWN_EVENT |
This event should never be present in the log. |
01 |
START_EVENT_V3 |
This indicates the start of a log file written by MySQL 4 or earlier. |
02 |
QUERY_EVENT |
The most common type of events. These contain statements executed on the master. |
03 |
STOP_EVENT |
Indicates that master has stopped. |
04 |
ROTATE_EVENT |
Written when the master switches to a new log file. |
05 |
INTVAR_EVENT |
Used for AUTO_INCREMENT values or when the
LAST_INSERT_ID()
function is used in the statement. |
06 |
LOAD_EVENT |
Used for LOAD DATA
INFILE in MySQL 3.23. |
07 |
SLAVE_EVENT |
Reserved for future use. |
08 |
CREATE_FILE_EVENT |
Used for LOAD DATA
INFILE statements. This indicates the
start of execution of such a statement. A temporary
file is created on the slave. Used in MySQL 4 only. |
09 |
APPEND_BLOCK_EVENT |
Contains data for use in a
LOAD DATA
INFILE statement. The data is stored in
the temporary file on the slave. |
0a |
EXEC_LOAD_EVENT |
Used for LOAD DATA
INFILE statements. The contents of the
temporary file is stored in the table on the slave.
Used in MySQL 4 only. |
0b |
DELETE_FILE_EVENT |
Rollback of a LOAD DATA
INFILE statement. The temporary file
should be deleted on the slave. |
0c |
NEW_LOAD_EVENT |
Used for LOAD DATA
INFILE in MySQL 4 and earlier. |
0d |
RAND_EVENT |
Used to send information about random values if the
RAND() function is
used in the statement. |
0e |
USER_VAR_EVENT |
Used to replicate user variables. |
0f |
FORMAT_DESCRIPTION_EVENT |
This indicates the start of a log file written by MySQL 5 or later. |
10 |
XID_EVENT |
Event indicating commit of an XA transaction. |
11 |
BEGIN_LOAD_QUERY_EVENT |
Used for LOAD DATA
INFILE statements in MySQL 5 and later. |
12 |
EXECUTE_LOAD_QUERY_EVENT |
Used for LOAD DATA
INFILE statements in MySQL 5 and later. |
13 |
TABLE_MAP_EVENT |
Reserved for future use. |
14 |
WRITE_ROWS_EVENT |
Reserved for future use. |
15 |
UPDATE_ROWS_EVENT |
Reserved for future use. |
16 |
DELETE_ROWS_EVENT |
Reserved for future use. |
Master ID
: The server ID of the master
that created the event.
Size
: The size in bytes of the event.
Master Pos
: The position of the next
event in the original master log file.
Flags
: 16 flags. Currently, the following
flags are used. The others are reserved for future use.
Flag | Name | Meaning |
01 |
LOG_EVENT_BINLOG_IN_USE_F |
Log file correctly closed. (Used only in
FORMAT_DESCRIPTION_EVENT .) If
this flag is set (if the flags are, for example,
'01 00' ) in a
FORMAT_DESCRIPTION_EVENT , the log
file has not been properly closed. Most probably
this is because of a master crash (for example, due
to power failure). |
02 |
Reserved for future use. | |
04 |
LOG_EVENT_THREAD_SPECIFIC_F |
Set if the event is dependent on the connection it was executed in (for
example, '04 00' ), for example,
if the event uses temporary tables. |
08 |
LOG_EVENT_SUPPRESS_USE_F |
Set in some circumstances when the event is not dependent on the default database. |
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.
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.